diff --git a/app/client/public/index.html b/app/client/public/index.html index 827286f..c955e5d 100644 --- a/app/client/public/index.html +++ b/app/client/public/index.html @@ -12,7 +12,7 @@ Agriculture Licencing System - +
diff --git a/app/client/src/features/reports/ReportLicenceComments.jsx b/app/client/src/features/reports/ReportLicenceComments.jsx new file mode 100644 index 0000000..2837f6d --- /dev/null +++ b/app/client/src/features/reports/ReportLicenceComments.jsx @@ -0,0 +1,83 @@ +import React, { useEffect } from "react"; +import { useForm } from "react-hook-form"; +import { useSelector, useDispatch } from "react-redux"; +import { Row, Col, Form, Button } from "react-bootstrap"; + +import DocGenDownloadBar from "../../components/DocGenDownloadBar"; + +import { + generateReport, + fetchReportJob, + selectReportsJob, + completeReportJob, + startLicenceCommentsJob, +} from "./reportsSlice"; + +import { REPORTS } from "../../utilities/constants"; + +export default function ReportLicenceComments() { + const dispatch = useDispatch(); + + const job = useSelector(selectReportsJob); + const { pendingDocuments } = job; + + const form = useForm({ + reValidateMode: "onBlur", + }); + const { register, watch } = form; + + const watchLicenceNumber = watch("licenceNumber", null); + + useEffect(() => { + if (job.id && job.type === REPORTS.LICENCE_COMMENTS) { + dispatch(fetchReportJob()); + + if (pendingDocuments?.length > 0) { + dispatch(generateReport(pendingDocuments[0].documentId)); + } else { + dispatch(completeReportJob(job.id)); + } + } + }, [pendingDocuments]); // eslint-disable-line react-hooks/exhaustive-deps + + const onGenerateReport = () => { + dispatch( + startLicenceCommentsJob({ + licenceNumber: watchLicenceNumber, + }) + ); + }; + + return ( + <> + + + Licence Number + + + +   + + + +
+ +
+ + ); +} + +ReportLicenceComments.propTypes = {}; diff --git a/app/client/src/features/reports/Reports.jsx b/app/client/src/features/reports/Reports.jsx index e810b1b..75ae28d 100644 --- a/app/client/src/features/reports/Reports.jsx +++ b/app/client/src/features/reports/Reports.jsx @@ -23,6 +23,7 @@ import ReportLicenceExpiry from "./ReportLicenceExpiry"; import { clearReportsJob } from "./reportsSlice"; import RenderOnRole from "../../components/RenderOnRole"; import ReportDairyTrailerInspection from "./ReportDairyTrailerInspection"; +import ReportLicenceComments from "./ReportLicenceComments"; export default function Reports() { const dispatch = useDispatch(); @@ -70,6 +71,9 @@ export default function Reports() { case REPORTS.DAIRY_TEST_THRESHOLD: control = ; break; + case REPORTS.LICENCE_COMMENTS: + control = ; + break; case REPORTS.LICENCE_LOCATION: control = ; break; @@ -193,6 +197,18 @@ export default function Reports() { + + + + { + try { + const response = await Api.post( + `documents/reports/startJob/licenceComments`, + payload + ); + return response.data; + } catch (error) { + if (error instanceof ApiError) { + return thunkApi.rejectWithValue(error.serialize()); + } + return thunkApi.rejectWithValue({ code: -1, description: error.message }); + } + } +); + export const startLicenceExpiryJob = createAsyncThunk( "reports/startLicenceExpiryJob", async (payload, thunkApi) => { @@ -379,6 +397,9 @@ export const reportsSlice = createSlice({ [startLicenceExpiryJob.pending]: pendingStartJobReducer, [startLicenceExpiryJob.fulfilled]: fulfilledStartJobReducer, [startLicenceExpiryJob.rejected]: rejectionStartJobReducer, + [startLicenceCommentsJob.pending]: pendingStartJobReducer, + [startLicenceCommentsJob.fulfilled]: fulfilledStartJobReducer, + [startLicenceCommentsJob.rejected]: rejectionStartJobReducer, [fetchReportJob.pending]: (state) => { state.job.status = REQUEST_STATUS.PENDING; diff --git a/app/client/src/utilities/constants.js b/app/client/src/utilities/constants.js index 087078c..95cd2ea 100644 --- a/app/client/src/utilities/constants.js +++ b/app/client/src/utilities/constants.js @@ -150,6 +150,7 @@ export const REPORTS = { DAIRY_FARM_QUALITY: "DAIRY_FARM_QUALITY", DAIRY_FARM_TANK: "DAIRY_FARM_TANK", DAIRY_TEST_THRESHOLD: "DAIRY_TEST_THRESHOLD", + LICENCE_COMMENTS: "LICENCE_COMMENTS", LICENCE_LOCATION: "LICENCE_LOCATION", LICENCE_EXPIRY: "LICENCE_EXPIRY", DAIRY_TRAILER_INSPECTION: "TRAILER INSPECTION", diff --git a/app/server/routes/v1/documents.js b/app/server/routes/v1/documents.js index 84bb8ed..9c82240 100644 --- a/app/server/routes/v1/documents.js +++ b/app/server/routes/v1/documents.js @@ -955,6 +955,21 @@ async function startLicenceTypeLocationJob(licenceTypeId) { return { jobId, documents }; } +async function startLicenceCommentsJob(licenceNumber) { + const [procedureResult] = await prisma.$transaction([ + prisma.$queryRawUnsafe( + `CALL mals_app.pr_generate_print_json_licence_comments('${licenceNumber}', NULL)`, + licenceNumber + ), + ]); + + const jobId = procedureResult[0].iop_print_job_id; + + const documents = await getPendingDocuments(jobId); + + return { jobId, documents }; +} + async function startLicenceExpiryJob(startDate, endDate) { const [procedureResult] = await prisma.$transaction([ prisma.$queryRawUnsafe( @@ -1462,6 +1477,17 @@ router.post("/reports/startJob/licenceTypeLocation", async (req, res, next) => { .finally(async () => prisma.$disconnect()); }); +router.post("/reports/startJob/licenceComments", async (req, res, next) => { + const licenceNumber = req.body.licenceNumber; + + await startLicenceCommentsJob(licenceNumber) + .then(({ jobId, documents }) => { + return res.send({ jobId, documents, type: REPORTS.LICENCE_COMMENTS }); + }) + .catch(next) + .finally(async () => prisma.$disconnect()); +}); + router.post("/reports/startJob/licenceExpiry", async (req, res, next) => { const startDate = formatDate(new Date(req.body.startDate)); const endDate = formatDate(new Date(req.body.endDate)); @@ -1543,7 +1569,17 @@ router.post("/download/:jobId(\\d+)", async (req, res, next) => { const zip = new AdmZip(); let fileName = null; documents.forEach((document) => { - if (job.printCategory === constants.DOCUMENT_TYPE_REPORT) { + if ( + job.printCategory === constants.DOCUMENT_TYPE_REPORT && + document.document_type === constants.REPORTS.LICENCE_COMMENTS + ) { + fileName = `${document.document_json.Licence_Number}-${document.document_type}.xlsx`; + } else if ( + job.printCategory === constants.DOCUMENT_TYPE_REPORT && + document.document_type === constants.REPORTS.DAIRY_TRAILER_INSPECTION + ) { + fileName = `${document.document_json.LicenceNumber}-${document.document_type}.xlsx`; + } else if (job.printCategory === constants.DOCUMENT_TYPE_REPORT) { fileName = `${document.document_json.Licence_Type}-${document.document_type}.xlsx`; } else if ( document.document_type === constants.DOCUMENT_TYPE_DAIRY_INFRACTION @@ -1552,7 +1588,6 @@ router.post("/download/:jobId(\\d+)", async (req, res, next) => { } else { fileName = `${document.licence_number}-${document.document_type}.docx`; } - zip.addFile(fileName, document.document_binary); }); diff --git a/app/server/static/templates/certificates/Dairy-Farm.docx b/app/server/static/templates/certificates/Dairy-Farm.docx index 4883b6e..b216031 100644 Binary files a/app/server/static/templates/certificates/Dairy-Farm.docx and b/app/server/static/templates/certificates/Dairy-Farm.docx differ diff --git a/app/server/static/templates/certificates/Purchase-Live-Poultry.docx b/app/server/static/templates/certificates/Purchase-Live-Poultry.docx index 43307e3..cac2713 100644 Binary files a/app/server/static/templates/certificates/Purchase-Live-Poultry.docx and b/app/server/static/templates/certificates/Purchase-Live-Poultry.docx differ diff --git a/app/server/static/templates/reports/Dairy_Test_Threshold_Template.xlsx b/app/server/static/templates/reports/Dairy_Test_Threshold_Template.xlsx index 96a92db..dffe4f5 100644 Binary files a/app/server/static/templates/reports/Dairy_Test_Threshold_Template.xlsx and b/app/server/static/templates/reports/Dairy_Test_Threshold_Template.xlsx differ diff --git a/app/server/static/templates/reports/Licence_Comments_Template.xlsx b/app/server/static/templates/reports/Licence_Comments_Template.xlsx new file mode 100644 index 0000000..823dcb6 Binary files /dev/null and b/app/server/static/templates/reports/Licence_Comments_Template.xlsx differ diff --git a/app/server/utilities/constants.js b/app/server/utilities/constants.js index bac122b..bc0deab 100644 --- a/app/server/utilities/constants.js +++ b/app/server/utilities/constants.js @@ -102,5 +102,6 @@ module.exports = Object.freeze({ DAIRY_TRAILER_INSPECTION: "TRAILER INSPECTION", LICENCE_LOCATION: "LICENCE_LOCATION", LICENCE_EXPIRY: "LICENCE_EXPIRY", + LICENCE_COMMENTS: "LICENCE_COMMENTS", }, }); diff --git a/app/server/utilities/documents.js b/app/server/utilities/documents.js index df8d6e4..b09e3e8 100644 --- a/app/server/utilities/documents.js +++ b/app/server/utilities/documents.js @@ -196,6 +196,8 @@ function getReportsTemplateName(documentType) { return "Licence_Expiry_Species_NoSpecies_Template"; case constants.REPORTS.DAIRY_TRAILER_INSPECTION: return "Dairy_Trailer_Inspection_Template"; + case constants.REPORTS.LICENCE_COMMENTS: + return "Licence_Comments_Template"; default: return null; } diff --git a/spilo-db/db-scripts/releases/release_5.5_ddl.sql b/spilo-db/db-scripts/releases/release_5.5_ddl.sql new file mode 100644 index 0000000..cafea1f --- /dev/null +++ b/spilo-db/db-scripts/releases/release_5.5_ddl.sql @@ -0,0 +1,273 @@ +-- MALS-17 - New report - to show comments by license number and or IRMA number +-- Create a view and procedure to support Comments reporting. + +DROP PROCEDURE IF EXISTS mals_app.pr_generate_print_json_licence_comments; +DROP VIEW IF EXISTS mals_app.mal_licence_comment_vw; + +-- +-- VIEW: MAL_LICENCE_COMMENT_VW +-- + +CREATE OR REPLACE VIEW mals_app.mal_licence_comment_vw +AS SELECT lic.id AS licence_id, + lic.licence_number, + lic.irma_number, + reg.last_name, + reg.first_name, + lic.company_name, + reg.email_address, + lictyp.licence_type, + com.create_timestamp, + com.licence_comment + FROM mals_app.mal_licence lic + JOIN mals_app.mal_licence_type_lu lictyp ON lic.licence_type_id = lictyp.id + LEFT JOIN mals_app.mal_registrant reg ON lic.primary_registrant_id = reg.id + LEFT JOIN mals_app.mal_licence_comment com ON lic.id = com.licence_id; + +-- Permissions + +ALTER TABLE mals_app.mal_licence_comment_vw OWNER TO mals; +GRANT ALL ON TABLE mals_app.mal_licence_comment_vw TO mals; +GRANT SELECT ON TABLE mals_app.mal_licence_comment_vw TO mals_app_role; + +-- +-- PROCEDURE: PR_GENERATE_PRINT_JSON_LICENCE_COMMENTS +-- + +CREATE OR REPLACE PROCEDURE mals_app.pr_generate_print_json_licence_comments(IN ip_licence_number character varying, INOUT iop_print_job_id integer) + LANGUAGE plpgsql +AS $procedure$ + declare + l_report_json_count integer default 0; + begin + -- + -- Start a row in the mal_print_job table + call pr_start_print_job( + ip_print_category => 'REPORT', + iop_print_job_id => iop_print_job_id + ); + -- + -- Insert the JSON into the output table + with licence_comments as ( + select + lic.licence_number, + lic.licence_type, + json_agg(json_build_object('LicenceNumber', lic.licence_number, + 'Lastname', lic.last_name, + 'Firstname', lic.first_name, + 'Company', lic.company_name, + 'Email', lic.email_address, + 'LicenceType', lic.licence_type, + 'CommentDate', lic.create_timestamp, + 'Comment', lic.licence_comment) + order by lic.create_timestamp) licence_json, + count(*) num_rows + from mal_licence_comment_vw lic + WHERE (lic.irma_number = ip_licence_number) OR (CAST(lic.licence_number AS varchar) = ip_licence_number) + group by lic.licence_number, lic.licence_type + ) + -- + -- MAIN QUERY + -- + insert into mal_print_job_output( + print_job_id, + licence_type, + licence_number, + document_type, + document_json, + document_binary, + create_userid, + create_timestamp, + update_userid, + update_timestamp) + select + iop_print_job_id, + licence_type, + null, + 'LICENCE_COMMENTS', + json_build_object('DateTime', to_char(current_timestamp, 'fmyyyy-mm-dd hh24mi'), + 'Licence_Number', licence_number, + 'Licence', licence_json, + 'RowCount', num_rows) report_json, + null, + current_user, + current_timestamp, + current_user, + current_timestamp + from licence_comments; + -- + GET DIAGNOSTICS l_report_json_count = ROW_COUNT; + -- + -- Update the Print Job table. + update mal_print_job set + job_status = 'COMPLETE', + json_end_time = current_timestamp, + report_json_count = l_report_json_count, + update_userid = current_user, + update_timestamp = current_timestamp + where id = iop_print_job_id; +end; +$procedure$ +; + +-- Permissions + +ALTER PROCEDURE mals_app.pr_generate_print_json_licence_comments(in varchar, inout int4) OWNER TO mals; +GRANT ALL ON PROCEDURE mals_app.pr_generate_print_json_licence_comments(in varchar, inout int4) TO mals; +GRANT EXECUTE ON PROCEDURE mals_app.pr_generate_print_json_licence_comments(in varchar, inout int4) TO mals_app_role; + +-- MALS-19 - Add a column to the Dairy Test Threshold Report +-- Add the Penaltiesd Issued column to the licence_json JSON object. + +-- +-- PROCEDURE: PR_GENERATE_PRINT_JSON_DAIRY_FARM_TEST_THRESHOLD +-- + +CREATE OR REPLACE PROCEDURE mals_app.pr_generate_print_json_dairy_farm_test_threshold(ip_start_date date, ip_end_date date, INOUT iop_print_job_id integer) + LANGUAGE plpgsql +AS $procedure$ + declare + l_report_json_count integer default 0; + begin + -- + -- Start a row in the mal_print_job table + call pr_start_print_job( + ip_print_category => 'REPORT', + iop_print_job_id => iop_print_job_id + ); + -- + -- Insert the JSON into the output table + with result_base as ( + select lic.id licence_id, + rslt.irma_number, + coalesce(lic.company_name, nullif(trim(concat(reg.first_name, ' ', reg.last_name)),'')) derived_licence_holder_name, + coalesce(spc1_date, scc_date, cry_date, ffa_date, ih_date) derived_test_date, + rslt.spc1_infraction_flag, + case when rslt.spc1_infraction_flag then rslt.spc1_value else null end spc1_value, + case when rslt.spc1_infraction_flag then rslt.spc1_correspondence_code else null end spc1_corespondence_code, + case when rslt.spc1_infraction_flag then rslt.spc1_levy_percentage else null end spc1_levy_percentage, + case when rslt.spc1_infraction_flag then + case when rslt.spc1_correspondence_code = 'W' then 'Warning' else concat(rslt.spc1_levy_percentage, '%') end + else null end spc1_penalty_issued, + rslt.scc_infraction_flag, + case when rslt.scc_infraction_flag then rslt.scc_value else null end scc_value, + case when rslt.scc_infraction_flag then rslt.scc_correspondence_code else null end scc_corespondence_code, + case when rslt.scc_infraction_flag then rslt.scc_levy_percentage else null end scc_levy_percentage, + case when rslt.scc_infraction_flag then + case when rslt.scc_correspondence_code = 'W' then 'Warning' else concat(rslt.scc_levy_percentage, '%') end + else null end scc_penalty_issued, + rslt.cry_infraction_flag, + case when rslt.cry_infraction_flag then rslt.cry_value else null end cry_value, + case when rslt.cry_infraction_flag then rslt.cry_correspondence_code else null end cry_corespondence_code, + case when rslt.cry_infraction_flag then rslt.cry_levy_percentage else null end cry_levy_percentage, + case when rslt.cry_infraction_flag then + case when rslt.cry_correspondence_code = 'W' then 'Warning' else concat(rslt.cry_levy_percentage, '%') end + else null end cry_penalty_issued, + rslt.ffa_infraction_flag, + case when rslt.ffa_infraction_flag then rslt.ffa_value else null end ffa_value, + rslt.ih_infraction_flag, + case when rslt.ih_infraction_flag then rslt.ih_value else null end ih_value, + case when rslt.ih_infraction_flag then rslt.ih_correspondence_code else null end ih_corespondence_code, + case when rslt.ih_infraction_flag then rslt.ih_levy_percentage else null end ih_levy_percentage, + case when rslt.ih_infraction_flag then + case when rslt.ih_correspondence_code = 'W' then 'Warning' else concat(rslt.ih_levy_percentage, '%') end + else null end ih_penalty_issued, + case when spc1_infraction_flag then 1 else 0 end + + case when scc_infraction_flag then 1 else 0 end + + case when cry_infraction_flag then 1 else 0 end + + case when ih_infraction_flag then 1 else 0 end num_infractions + from mal_licence lic + inner join mal_registrant reg + on lic.primary_registrant_id = reg.id + inner join mal_dairy_farm_test_result rslt + on lic.id = rslt.licence_id + where greatest(spc1_date, scc_date, cry_date, ffa_date, ih_date) + between ip_start_date and ip_end_date + and greatest(spc1_infraction_flag, scc_infraction_flag, cry_infraction_flag, ffa_infraction_flag, ih_infraction_flag) = true + ), + infractions as ( + select licence_id, + rtrim(concat( + case when num_infractions > 1 then spc1_penalty_issued || ' SPC1, ' else spc1_penalty_issued end, + case when num_infractions > 1 then scc_penalty_issued || ' SCC, ' else scc_penalty_issued end, + case when num_infractions > 1 then cry_penalty_issued || ' CRY, ' else cry_penalty_issued end, + case when num_infractions > 1 then ih_penalty_issued || ' IH, 'else ih_penalty_issued end), ', ') penalties_issued + from result_base), + licence_list as ( + select json_agg(json_build_object('IRMA_Num', rb.irma_number, + 'LicenceHolderCompany', rb.derived_licence_holder_name, + 'TestDate', rb.derived_test_date, + 'IBC_Result', rb.spc1_value, + 'SCC_Result', rb.scc_value, + 'CRY_Result', rb.cry_value, + 'FFA_Result', rb.ffa_value, + 'IH_Result', rb.ih_value, + 'PenaltyIssued', inf.penalties_issued) + order by irma_number) licence_json + from result_base rb + left join infractions inf + on rb.licence_id = inf.licence_id), + result_summary as ( + select + count(spc1_value) spc1_count, + count(scc_value) scc_count, + count(cry_value) cry_count, + count(ffa_value) ffa_count, + count(ih_value) ih_count + from result_base) + -- + -- MAIN QUERY + -- + insert into mal_print_job_output( + print_job_id, + licence_type, + licence_number, + document_type, + document_json, + document_binary, + create_userid, + create_timestamp, + update_userid, + update_timestamp) + select + iop_print_job_id, + 'DAIRY FARM', + null, + 'DAIRY_TEST_THRESHOLD', + json_build_object('DateTime', to_char(current_timestamp, 'fmyyyy-mm-dd hh24:mi'), + 'DateRangeStart', to_char(ip_start_date, 'fmMonth dd, yyyy'), + 'DateRangeEnd', to_char(ip_end_date, 'fmMonth dd, yyyy'), + 'Reg', list.licence_json, + 'Tot_IBC_Count', smry.spc1_count, + 'Tot_SCC_Count', smry.scc_count, + 'Tot_CRY_Count', smry.cry_count, + 'Tot_FFA_Count', smry.ffa_count, + 'Tot_IH_Count', smry.ih_count) report_json, + null, + current_user, + current_timestamp, + current_user, + current_timestamp + from licence_list list + cross join result_summary smry; + -- + GET DIAGNOSTICS l_report_json_count = ROW_COUNT; + -- + -- Update the Print Job table. + update mal_print_job set + job_status = 'COMPLETE', + json_end_time = current_timestamp, + report_json_count = l_report_json_count, + update_userid = current_user, + update_timestamp = current_timestamp + where id = iop_print_job_id; +end; +$procedure$ +; + +-- MALS-24 - Purchase Live Poultry License - Act & Reg wording needs updating +-- Update the legislation column to reflec the new terminology. + +UPDATE mals_app.mal_licence_type_lu +SET legislation = 'Under the authority of the Animal Health Act and s.9(2) of the Poultry Health and Buying Regulation' +WHERE licence_type = 'PURCHASE LIVE POULTRY'; \ No newline at end of file