Skip to content

Commit

Permalink
feat: add generate reports mutation
Browse files Browse the repository at this point in the history
  • Loading branch information
Sepehr-Sobhani committed Oct 11, 2022
1 parent dab2c19 commit 9b7456e
Show file tree
Hide file tree
Showing 4 changed files with 82 additions and 0 deletions.
67 changes: 67 additions & 0 deletions schema/deploy/mutations/generate_reports.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,67 @@
-- Deploy cif:mutations/generate_reports to pg

begin;

create or replace function cif.generate_reports(revision_id int, report_type text, start_date timestamptz, end_date timestamptz)
returns setof cif.form_change as $generate_reports$
declare
form_change_record record;
start_date_year int := extract(year from start_date);
report_interval_start_date timestamptz;
report_interval interval := '1 year';
initial_index int := 1;
temp_row record;
begin
if start_date >= end_date then
raise exception 'start_date must be before end_date';

elsif $2 = 'Annual' then
-- if start date is before or equal to jan 31st, we will start the first annual report on the same year otherwise we will start on the next year
if start_date <= make_date(start_date_year, 01, 31) then
report_interval_start_date := make_date(start_date_year, 01, 31);
else
report_interval_start_date := make_date(start_date_year + 1, 01, 31);
end if;

elsif $2 = 'Quarterly' then
report_interval := '3 month'::interval;
-- choosing the closest quarter start date from a list of possible dates as a temporary table
select * from
(values (make_date(start_date_year, 01, 05)), (make_date(start_date_year, 04, 05)), (make_date(start_date_year, 07, 05)), (make_date(start_date_year, 10, 05)), (make_date(start_date_year + 1, 01, 05))) as temp_table(quarterly_report_due_date)
where start_date <= quarterly_report_due_date limit 1 into report_interval_start_date;
end if;

-- generating the reports
for temp_row in select generate_series(report_interval_start_date, end_date, report_interval) as due_date
loop
insert into cif.form_change(
new_form_data,
operation,
form_data_schema_name,
form_data_table_name,
json_schema_name,
project_revision_id
)
values
(
json_build_object(
'projectId', (select form_data_record_id from cif.form_change where form_data_table_name='project' and project_revision_id=$1),
'reportType', $2,
'reportDueDate', temp_row.due_date,
'reportingRequirementIndex', initial_index
),
'create', 'cif', 'reporting_requirement', 'reporting_requirement', $1) returning * into form_change_record;
initial_index := initial_index + 1;
return next form_change_record;
end loop;
end;
$generate_reports$ language plpgsql volatile;

grant execute on function cif.generate_reports to cif_internal, cif_external, cif_admin;
comment on function cif.generate_reports
is $$
Custom mutation to generate reports for a revision between contract_start_date and measurement_period_end_date for quarterly reports
and between report_due_date and project_assets_life_end_date for annual reports.
$$;

commit;
7 changes: 7 additions & 0 deletions schema/revert/mutations/generate_reports.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
-- Revert cif:mutations/generate_reports from pg

begin;

drop function cif.generate_reports;

commit;
1 change: 1 addition & 0 deletions schema/sqitch.plan
Original file line number Diff line number Diff line change
Expand Up @@ -144,3 +144,4 @@ tables/funding_parameter_002_add_auto_generating_report_date_columns [tables/fun
computed_columns/project_revision_effective_date 2022-09-12T22:42:51Z Mike Vesprini <[email protected]> # Create computed column for project revisions effective date
computed_columns/project_revision_rank 2022-08-31T18:41:14Z Brianna Cerkiewicz <briannacerkiewicz@pop-os> # Add project_revision_rank computed column
util_functions/get_form_status_001 2022-09-28T17:47:05Z Gurjeet Matharu <[email protected]> # Adding coalesc to get_form_status function
mutations/generate_reports 2022-09-21T23:55:42Z Sepehr Sobhani <[email protected]> # Custom mutation to generate annual or quarterly reports based on start and end dates
7 changes: 7 additions & 0 deletions schema/verify/mutations/generate_reports.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
-- Verify cif:mutations/generate_reports on pg

begin;

select pg_get_functiondef('cif.generate_reports(int, text, timestamptz, timestamptz)'::regprocedure);

rollback;

0 comments on commit 9b7456e

Please sign in to comment.