diff --git a/app/schema/schema.graphql b/app/schema/schema.graphql index 4c54e30c9e..9ad7819c92 100644 --- a/app/schema/schema.graphql +++ b/app/schema/schema.graphql @@ -50871,6 +50871,32 @@ input JSONFilter { notIn: [JSON!] } +"""All input for the `jsonbMinus` mutation.""" +input JsonbMinusInput { + """ + An arbitrary string value with no semantic meaning. Will be included in the + payload verbatim. May be used to track mutations by the client. + """ + clientMutationId: String + minuend: JSON! + subtrahend: JSON! +} + +"""The output of our `jsonbMinus` mutation.""" +type JsonbMinusPayload { + """ + The exact same `clientMutationId` that was provided in the mutation input, + unchanged and unused. May be used by a client to track mutations. + """ + clientMutationId: String + json: JSON + + """ + Our root query field type. Allows us to run any query from our mutation payload. + """ + query: Query +} + type KeycloakJwt { acr: String aud: String @@ -52297,6 +52323,12 @@ type Mutation { """ input: GenerateQuarterlyReportsInput! ): GenerateQuarterlyReportsPayload + jsonbMinus( + """ + The exclusive input argument for this mutation. An object type, make sure to see documentation for this object’s fields. + """ + input: JsonbMinusInput! + ): JsonbMinusPayload stageDirtyFormChanges( """ The exclusive input argument for this mutation. An object type, make sure to see documentation for this object’s fields. @@ -66928,7 +66960,7 @@ type Query implements Node { paymentByRowId(rowId: Int!): Payment """ - returns a form_change for a table in the pending state for the current user, i.e. allows to resume the creation of any table row + returns list of key-value pairs present in the first argument but not the second argument """ pendingNewFormChangeForTable(tableName: String!): FormChange diff --git a/app/schema/schema.json b/app/schema/schema.json index caf884b9ae..0a319f9f41 100644 --- a/app/schema/schema.json +++ b/app/schema/schema.json @@ -171233,6 +171233,102 @@ "enumValues": null, "possibleTypes": null }, + { + "kind": "INPUT_OBJECT", + "name": "JsonbMinusInput", + "description": "All input for the `jsonbMinus` mutation.", + "fields": null, + "inputFields": [ + { + "name": "clientMutationId", + "description": "An arbitrary string value with no semantic meaning. Will be included in the\npayload verbatim. May be used to track mutations by the client.", + "type": { + "kind": "SCALAR", + "name": "String", + "ofType": null + }, + "defaultValue": null + }, + { + "name": "minuend", + "description": null, + "type": { + "kind": "NON_NULL", + "name": null, + "ofType": { + "kind": "SCALAR", + "name": "JSON", + "ofType": null + } + }, + "defaultValue": null + }, + { + "name": "subtrahend", + "description": null, + "type": { + "kind": "NON_NULL", + "name": null, + "ofType": { + "kind": "SCALAR", + "name": "JSON", + "ofType": null + } + }, + "defaultValue": null + } + ], + "interfaces": null, + "enumValues": null, + "possibleTypes": null + }, + { + "kind": "OBJECT", + "name": "JsonbMinusPayload", + "description": "The output of our `jsonbMinus` mutation.", + "fields": [ + { + "name": "clientMutationId", + "description": "The exact same `clientMutationId` that was provided in the mutation input,\nunchanged and unused. May be used by a client to track mutations.", + "args": [], + "type": { + "kind": "SCALAR", + "name": "String", + "ofType": null + }, + "isDeprecated": false, + "deprecationReason": null + }, + { + "name": "json", + "description": null, + "args": [], + "type": { + "kind": "SCALAR", + "name": "JSON", + "ofType": null + }, + "isDeprecated": false, + "deprecationReason": null + }, + { + "name": "query", + "description": "Our root query field type. Allows us to run any query from our mutation payload.", + "args": [], + "type": { + "kind": "OBJECT", + "name": "Query", + "ofType": null + }, + "isDeprecated": false, + "deprecationReason": null + } + ], + "inputFields": null, + "interfaces": [], + "enumValues": null, + "possibleTypes": null + }, { "kind": "OBJECT", "name": "KeycloakJwt", @@ -176610,6 +176706,33 @@ "isDeprecated": false, "deprecationReason": null }, + { + "name": "jsonbMinus", + "description": null, + "args": [ + { + "name": "input", + "description": "The exclusive input argument for this mutation. An object type, make sure to see documentation for this object’s fields.", + "type": { + "kind": "NON_NULL", + "name": null, + "ofType": { + "kind": "INPUT_OBJECT", + "name": "JsonbMinusInput", + "ofType": null + } + }, + "defaultValue": null + } + ], + "type": { + "kind": "OBJECT", + "name": "JsonbMinusPayload", + "ofType": null + }, + "isDeprecated": false, + "deprecationReason": null + }, { "name": "stageDirtyFormChanges", "description": null, @@ -229591,7 +229714,7 @@ }, { "name": "pendingNewFormChangeForTable", - "description": "returns a form_change for a table in the pending state for the current user, i.e. allows to resume the creation of any table row", + "description": "returns list of key-value pairs present in the first argument but not the second argument", "args": [ { "name": "tableName", diff --git a/docs/concurrentRevisionHandling.md b/docs/concurrentRevisionHandling.md new file mode 100644 index 0000000000..162820d113 --- /dev/null +++ b/docs/concurrentRevisionHandling.md @@ -0,0 +1,41 @@ +# Handling of Concurrent Revisions + +The purpose of this document is to outline how we allow concurrent revisions to be made to a proeject. + +## Introduction + +By "concurrent revisions" we are referring to the ability for two discrete sets of changes to a project to exist at the same time. In CIF, we limit the number of concurrent revisions on any given project to be two: one "Amendment", and one "General Revision". While this was never intended to be a functionality of CIF, a new user flow was introduced that required it. As such, the approach taken is more of an adaptaion of the existing CIF architecture (which is described in `docs/dbRecordsHistory.md`) than an architecture designed to handle concurrency. The result is that any divergence from the original architecture pre-concureency also appears in the concurrent behaviour. For example, project contacts are handled using a different pattern than the project form in the original architecture, therfore they behave differently from the genral pattern in the concurrent approach as well. + +### Terminology + +There are three terms we need to use to identify the three `form_change` records in question: "committing", "pending", and "original parent". I'll use the more common scenario to outline the terminology used throughout this document. +An Amendment is opened on a project, and left open while it is being negotiated. While it is open, a General Revision is opened on that same project, a small change is made, and the revision is committed. The point in time of the General Revision being committed is where the terminology gets its roots. In this example, the General Revision is **committing**, the still-open amendment is **pending**, and the parent revision of the Amendment is the **original parent**. + +## Approach + +A solution that would allow us to handle concurrency without user input on conflict resolution was needed. To achieve this, the approach taken is comparable to a git rebase. When committing and pending are in conflict, the changes made in pending are applied on top of the committing form change, as if the committing `form_change` were the original parent of the pending `form_change`. While users commit on a `project_revision` level, the change propogates down to the `form_change` level, so when we're talking about this here it is at the `form_change` granularity, and the heart it takes place in the function `cif.commit_form_change_internal`. + +One of the ways our various forms can be categorized would be: + +- forms a project can have at most one of (`funding_parameter_EP`, `funding_parameter_IA`, `emission_intensity`, `project_summary_report`) +- 'project_contact' are either primary or secondary, and have a `contactIndex` +- 'project_manager' are categorized by `projectManagerLabelId` +- 'reporting_requirement' have a `reportingRequirementIndex` based on the `json_schema_name` + +Form changes can have an operation of `create`, `update`, or `archive`, each of which need to be handled for all of the above categories. This results in several unique cases, which have been explained case-by-case using in-line in the `commit_form_change_internal` where they have more context. + +After each of the following cases, the `previous_form_change_id` of the pending `form_change` is set to be the id of the committing `form_change`, which leaves every form change with a `previous_form_change_id` of the **last commit** corresponding `form_change`, while preserving the option of a full history by maintaining accurate `created_at`, `updated_at`, and `archived_at` values for all `form_change`. + +### Create (the general approach) + +If the committing project revision creates a form change that does not exist in the pending revision, for example adding a milestone, then the form needs to be created in the pending revision. In cases such as contacts which have a `contactIndex` associated with them, the index needs to be determined by the existing indices in the pending revision. This will allow the indices to stay sequential if other items were added or removed in the pending revision. + +### Update + +1. If the committing form change contains the same data as the pending's original parent, then no change to the pending data is needed. +2. If the committing and pending form changes both have changes from the pending form change's parent, then set the pending form change's new_form_data to be the committing form change's, plus the changes made in the penging form change. The result is what would the data would have been if the pending form change had the committing as it's parent, similar to a git rebase. +3. If the pending form change hasn't made any changes since its creation, but the committing form change has, set the pending form change's new_form_data to be the committing form change's, as it is the latest information. + +### Archive (the general approach) + +If the committing `form_change` is being archived, the pending form change can simply be deleted as it never would have been created in the first place had the committing project revision been the original parent of the pending revision. diff --git a/schema/deploy/functions/jsonb_minus.sql b/schema/deploy/functions/jsonb_minus.sql new file mode 100644 index 0000000000..c3e2731118 --- /dev/null +++ b/schema/deploy/functions/jsonb_minus.sql @@ -0,0 +1,31 @@ +-- Deploy cif:functions/jsonb_minus to pg + +begin; +-- A note on the functionality: +-- If a key is present in the subtrahend but not the minuend, it will not appear in the result set. +-- {"a": 1, "b": 3} - {"a": 1, "b": 2, "c": 3} = {"b": 3} +-- If however a key is present in the minuend but not the subtrahend, it will appear in the result set with its value. +-- {"a": 1, "b": 3, "c": 3} - {"a": 1, "b": 2} = {"b": 3, "c": 3} + +-- This behaviour fits our needs at the time of writing this, so the additional complexity of handling the other cases is not needed. + + +create or replace function cif.jsonb_minus(minuend jsonb, subtrahend jsonb) + returns jsonb as +$$ +declare + difference jsonb; +begin + select jsonb_object_agg(key, value) into strict difference + from ( + select * from jsonb_each($1) + except select * from jsonb_each($2) + ) as temp; + + return difference; +end +$$ language plpgsql volatile; + +comment on function cif.pending_new_form_change_for_table(text) is + 'returns list of key-value pairs present in the first argument but not the second argument'; +commit; diff --git a/schema/deploy/mutations/commit_form_change.sql b/schema/deploy/mutations/commit_form_change.sql index 0ea3a5c4cd..30a9eb0626 100644 --- a/schema/deploy/mutations/commit_form_change.sql +++ b/schema/deploy/mutations/commit_form_change.sql @@ -12,7 +12,13 @@ begin validation_errors = coalesce(form_change_patch.validation_errors, validation_errors) where id=row_id; - return (select cif_private.commit_form_change_internal((select row(form_change.*)::cif.form_change from cif.form_change where id = row_id))); + return (select cif_private.commit_form_change_internal( + (select row(form_change.*)::cif.form_change from cif.form_change where id = row_id), + -- This is guaranteed to be a single row as we have unique inidices on pending general revision and pending amendment + (select id from cif.project_revision + where project_id=(select project_id from cif.project_revision where id = form_change_patch.project_revision_id) + and change_status = 'pending' and id != form_change_patch.project_revision_id) + )); end; $$ language plpgsql volatile; diff --git a/schema/deploy/mutations/commit_form_change@1.15.0.sql b/schema/deploy/mutations/commit_form_change@1.15.0.sql new file mode 100644 index 0000000000..0ea3a5c4cd --- /dev/null +++ b/schema/deploy/mutations/commit_form_change@1.15.0.sql @@ -0,0 +1,23 @@ +-- Deploy cif:mutations/commit_form_change to pg +-- requires: tables/form_change + +begin; + +create or replace function cif.commit_form_change(row_id int, form_change_patch cif.form_change) + returns cif.form_change as $$ +begin + + update cif.form_change set + new_form_data = coalesce(form_change_patch.new_form_data, new_form_data), + validation_errors = coalesce(form_change_patch.validation_errors, validation_errors) + where id=row_id; + + return (select cif_private.commit_form_change_internal((select row(form_change.*)::cif.form_change from cif.form_change where id = row_id))); +end; + $$ language plpgsql volatile; + +grant execute on function cif.commit_form_change to cif_internal, cif_external, cif_admin; + +comment on function cif.commit_form_change is 'Custom mutation to commit a form_change record via the API. Only used for records that are independent of a project such as the lists of contacts and operators.'; + +commit; diff --git a/schema/deploy/mutations/commit_form_change_internal.sql b/schema/deploy/mutations/commit_form_change_internal.sql index bee73b915f..c70eada702 100644 --- a/schema/deploy/mutations/commit_form_change_internal.sql +++ b/schema/deploy/mutations/commit_form_change_internal.sql @@ -1,10 +1,22 @@ -- Deploy cif:mutations/commit_form_change to pg begin; +/* +To allow for pending project revisions to remain up to date with the project when other revisions are commit, a significant amount +of conditional logic has been introduced in the form of nested if statements. This should be refactored to a more maintainable & +readable structure. -create or replace function cif_private.commit_form_change_internal(fc cif.form_change) +*/ +-- We need to explicitly drop the old function here since we're changing the signature. +drop function if exists cif_private.commit_form_change_internal(cif.form_change); +create or replace function cif_private.commit_form_change_internal(fc cif.form_change, pending_project_revision_id int default null) returns cif.form_change as $$ declare recordId int; + pending_form_change cif.form_change; + parent_of_pending_form_change cif.form_change; + pending_minus_pendings_parent jsonb; + committing_minus_pendings_parent jsonb; + new_fc_in_pending_id int; begin if fc.validation_errors != '[]' then @@ -26,12 +38,238 @@ begin change_status = 'committed' where id = fc.id; + if pending_project_revision_id is not null then + if fc.operation = 'create' then +/* + These are the forms that a project can have at most one of. + If pending has created one alredy, then we need to set the previous_form_change_id and the form_data_record_id. +*/ + if ( + (fc.json_schema_name in ('funding_parameter_EP', 'funding_parameter_IA', 'emission_intensity', 'project_summary_report')) and + ((select count(id) from cif.form_change where project_revision_id = pending_project_revision_id and json_schema_name = fc.json_schema_name) > 0) + ) then + update cif.form_change set + previous_form_change_id = fc.id, + form_data_record_id = recordId + where project_revision_id = pending_project_revision_id + and json_schema_name = fc.json_schema_name; + + +/* + If the committing form_change is creating a project contact, and the contactIndex already exists in the pending revision, then we want + the contactId in pending to remain at that contactIndex. To do this, we create a new form_change in the pending project revision with + the contactId being commit, set its operation to create, and its contactIndex to one higher than the current highest index. We then + update the pending form change to have an operation of update, and give it the same form_data_record_id as committing, and assign the + committing id to be the previous_form_change_id. +*/ + + elsif ( + fc.json_schema_name = 'project_contact' + and (select count(*) from cif.form_change where + project_revision_id = pending_project_revision_id and + json_schema_name = 'project_contact' and + new_form_data ->> 'contactIndex' = fc.new_form_data ->> 'contactIndex') > 0 + ) then + select id into new_fc_in_pending_id from cif.create_form_change( + operation => 'create'::cif.form_change_operation, + form_data_schema_name => 'cif', + form_data_table_name => fc.form_data_table_name, + form_data_record_id => null, + project_revision_id => pending_project_revision_id, + json_schema_name => fc.json_schema_name, + new_form_data => (fc.new_form_data || format('{"contactIndex": %s}', + ((select max((new_form_data ->> 'contactIndex')::int) from cif.form_change + where project_revision_id = pending_project_revision_id + and json_schema_name = 'project_contact' + ) + 1))::jsonb + ) + ); + update cif.form_change set + operation = 'update'::cif.form_change_operation, + form_data_record_id = recordId, + previous_form_change_id = fc.id + where project_revision_id = pending_project_revision_id + and json_schema_name = 'project_contact' + and new_form_data ->> 'contactIndex' = fc.new_form_data ->> 'contactIndex'; + +/* + If the projectManagerLabelId already exists in pending, set the form_data_record_id and previous_form_change_id, + and the operation to 'update' to handle when pending has an opertion of 'create'. If not, then the catch all case will handle it. +*/ + elsif ( + fc.json_schema_name = 'project_manager' + and ( + (select count(*) from cif.form_change + where project_revision_id = pending_project_revision_id + and json_schema_name = fc.json_schema_name + and new_form_data ->> 'projectManagerLabelId' = fc.new_form_data ->> 'projectManagerLabelId') > 0 + ) + ) then + update cif.form_change set + previous_form_change_id = fc.id, + form_data_record_id = recordId, + operation = 'update'::cif.form_change_operation + where id = (select id from cif.form_change + where project_revision_id = pending_project_revision_id + and json_schema_name = fc.json_schema_name + and new_form_data ->> 'projectManagerLabelId' = fc.new_form_data ->> 'projectManagerLabelId'); + +/* + If reporting_requirements of this reportType already exist in pending, create the new form_change and set the reportingRequirementIndex + to the highest existing in pending plus 1. If committing is the first reporting_requirement of this reportType, then the catch-all works. +*/ + elsif ( + fc.json_schema_name = 'reporting_requirement' + and ( + (select count(*) from cif.form_change where project_revision_id = pending_project_revision_id + and json_schema_name = fc.json_schema_name + and new_form_data ->> 'reportType' = fc.new_form_data ->> 'reportType') + > 0) + ) then + select id into new_fc_in_pending_id from cif.create_form_change( + operation => 'update'::cif.form_change_operation, + form_data_schema_name => 'cif', + form_data_table_name => fc.form_data_table_name, + form_data_record_id => recordId, + project_revision_id => pending_project_revision_id, + json_schema_name => fc.json_schema_name, + new_form_data => (fc.new_form_data || format('{"reportingRequirementIndex": %s}', + (select max((new_form_data ->> 'reportingRequirementIndex')::int) from cif.form_change + where project_revision_id=pending_project_revision_id + and json_schema_name = fc.json_schema_name + and new_form_data ->> 'reportType' = fc.new_form_data ->> 'reportType' + ) + 1)::jsonb + ) + ); + update cif.form_change set previous_form_change_id = fc.id where id = new_fc_in_pending_id; + +/* + If committing is creating a milestone and milestones exist, create the milestone in pending and set the + reportingRequirementIndex to be the max existing in pending plus 1. + If pending has no milestones, the catch-all works. +*/ + elsif ( + fc.json_schema_name = 'milestone' + and ( + (select count(id) from cif.form_change where project_revision_id = pending_project_revision_id + and json_schema_name = fc.json_schema_name) + > 0) + ) then + select id into new_fc_in_pending_id from cif.create_form_change( + operation => 'update'::cif.form_change_operation, + form_data_schema_name => 'cif', + form_data_table_name => fc.form_data_table_name, + form_data_record_id => recordId, + project_revision_id => pending_project_revision_id, + json_schema_name => fc.json_schema_name, + new_form_data => (fc.new_form_data || format('{"reportingRequirementIndex": %s}', + (select max((new_form_data ->> 'reportingRequirementIndex')::int) from cif.form_change + where project_revision_id=pending_project_revision_id + and json_schema_name = fc.json_schema_name + ) + 1)::jsonb + ) + ); + update cif.form_change set previous_form_change_id = fc.id where id = new_fc_in_pending_id; + +/** + This next case acts as the catch-all for 'create'. It applies to any scenario in which the pending revision does not have an equivalent + form change to the one being committed. This includes unordered lists (e.g. attachments, milestones, etc.), the unique forms + like funding_parameter when pending has not created one yet, and ordered/pseudo ordered lists when the equivalent index does not + exist in pending. +**/ + else + + select id into new_fc_in_pending_id from cif.create_form_change( + operation => 'update'::cif.form_change_operation, + form_data_schema_name => 'cif', + form_data_table_name => fc.form_data_table_name, + form_data_record_id => recordId, + project_revision_id => pending_project_revision_id, + json_schema_name => fc.json_schema_name, + new_form_data => fc.new_form_data + ); + update cif.form_change set previous_form_change_id = fc.id where id = new_fc_in_pending_id; + end if; + + elsif fc.operation = 'update' then + -- store the pending project revisions corresponding form_change, and its parent + select * into pending_form_change from cif.form_change + where project_revision_id = pending_project_revision_id + and json_schema_name = fc.json_schema_name + and form_data_record_id = fc.form_data_record_id limit 1; + select * into parent_of_pending_form_change from cif.form_change + where id = pending_form_change.previous_form_change_id; + + select (cif.jsonb_minus(pending_form_change.new_form_data, parent_of_pending_form_change.new_form_data)) + into pending_minus_pendings_parent; + select (cif.jsonb_minus(fc.new_form_data, parent_of_pending_form_change.new_form_data)) + into committing_minus_pendings_parent; + +/* + If the committing and pending form changes both have changes from the pending form change's parent, + then set the pending form change's new_form_data to be the committing form change's, and apply the changes + made in the pending form change to that data. +*/ + if committing_minus_pendings_parent is not null then + if pending_minus_pendings_parent is not null then + update cif.form_change + set new_form_data = + (fc.new_form_data || pending_minus_pendings_parent) + where id = pending_form_change.id; + + /* + If the pending form change hasn't made any changes since its creation, but the committing form change has, + set the pending form change's new_form_data to be the committing form_change's, as it is the latest information. + */ + else + update cif.form_change + set new_form_data = (fc.new_form_data) + where id = pending_form_change.id; + end if; + end if; + -- Set the previous_form_change_id to be the committing form change. + update cif.form_change set previous_form_change_id = fc.id where id = pending_form_change.id; + + elsif fc.operation = 'archive' then + select * into pending_form_change from cif.form_change + where project_revision_id = pending_project_revision_id + and json_schema_name = fc.json_schema_name + and form_data_record_id = fc.form_data_record_id; + select * into parent_of_pending_form_change from cif.form_change + where id = pending_form_change.previous_form_change_id; + + select (cif.jsonb_minus(pending_form_change.new_form_data, parent_of_pending_form_change.new_form_data)) + into pending_minus_pendings_parent; + +/* + If pending has made changes, then set its operation to create and null the form data record id & previous form change id + since it's technically creating them now. This way the archiving still took place in the committing form change, and we + avoid trying to update the now archived record that form_data_record_id points to. +*/ + if pending_minus_pendings_parent is not null then + update cif.form_change set + operation = 'create'::cif.form_change_operation, + form_data_record_id = null, + previous_form_change_id = null + where id = pending_form_change.id; + + else +/* + If pending has not made changes to the form data, the pending record can be deleted as it never would have been made +*/ + delete from cif.form_change + where project_revision_id = pending_project_revision_id + and form_data_table_name = fc.form_data_table_name + and form_data_record_id = fc.form_data_record_id; + end if; + end if; + end if; return (select row(form_change.*)::cif.form_change from cif.form_change where id = fc.id); end; $$ language plpgsql volatile; -grant execute on function cif_private.commit_form_change_internal to cif_internal, cif_external, cif_admin; - -comment on function cif_private.commit_form_change_internal(cif.form_change) is 'Commits the form change and calls the corresponding commit handler.'; +grant execute on function cif_private.commit_form_change_internal(cif.form_change, int) to cif_internal, cif_external, cif_admin; +comment on function cif_private.commit_form_change_internal(cif.form_change, int) is + 'Commits the form change and calls the corresponding commit handler. Then, update a potential existing revision to include the changes that were just committed.'; commit; diff --git a/schema/deploy/mutations/commit_form_change_internal@1.15.0.sql b/schema/deploy/mutations/commit_form_change_internal@1.15.0.sql new file mode 100644 index 0000000000..bee73b915f --- /dev/null +++ b/schema/deploy/mutations/commit_form_change_internal@1.15.0.sql @@ -0,0 +1,37 @@ +-- Deploy cif:mutations/commit_form_change to pg +begin; + +create or replace function cif_private.commit_form_change_internal(fc cif.form_change) + returns cif.form_change as $$ +declare + recordId int; +begin + + if fc.validation_errors != '[]' then + raise exception 'Cannot commit change with validation errors: %', fc.validation_errors; + end if; + + if fc.change_status = 'committed' then + raise exception 'Cannot commit form_change. It has already been committed.'; + end if; + + -- TODO : add a conditional behaviour based on fc.form_id + execute format( + 'select "cif_private".%I($1)', + (select form_change_commit_handler from cif.form where slug = fc.json_schema_name) + ) using fc into recordId; + + update cif.form_change set + form_data_record_id = recordId, + change_status = 'committed' + where id = fc.id; + + return (select row(form_change.*)::cif.form_change from cif.form_change where id = fc.id); +end; + $$ language plpgsql volatile; + +grant execute on function cif_private.commit_form_change_internal to cif_internal, cif_external, cif_admin; + +comment on function cif_private.commit_form_change_internal(cif.form_change) is 'Commits the form change and calls the corresponding commit handler.'; + +commit; diff --git a/schema/deploy/mutations/commit_project_revision.sql b/schema/deploy/mutations/commit_project_revision.sql index bafe70a0cc..2eac2084a2 100644 --- a/schema/deploy/mutations/commit_project_revision.sql +++ b/schema/deploy/mutations/commit_project_revision.sql @@ -4,23 +4,34 @@ begin; create or replace function cif.commit_project_revision(revision_to_commit_id int) returns cif.project_revision as $$ +declare + proj_id int; + pending_project_revision_id int; begin -- defer FK constraints check to the end of the transaction set constraints all deferred; + -- Find a potential existing other pending revision that needs updating while we commit this one, that we pass as a reference for the internal commit functions + select form_data_record_id into proj_id from cif.form_change where form_data_table_name='project' and project_revision_id=$1; + select id into pending_project_revision_id from cif.project_revision + where project_id = proj_id + and change_status = 'pending' + and id != $1 + limit 1; + -- Propagate the change_status to all related form_change records -- Save the project table first to avoid foreign key violations from other potential tables. - perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change) + perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change, pending_project_revision_id) from cif.form_change where project_revision_id=$1 and form_data_table_name='project'; - perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change) + perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change, pending_project_revision_id) from cif.form_change where project_revision_id=$1 and form_data_table_name='reporting_requirement'; - perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change) + perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change, pending_project_revision_id) from cif.form_change where project_revision_id=$1 and form_data_table_name not in ('project', 'reporting_requirement'); diff --git a/schema/deploy/mutations/commit_project_revision@1.15.0.sql b/schema/deploy/mutations/commit_project_revision@1.15.0.sql new file mode 100644 index 0000000000..bafe70a0cc --- /dev/null +++ b/schema/deploy/mutations/commit_project_revision@1.15.0.sql @@ -0,0 +1,42 @@ +-- Deploy cif:mutations/commit_project_revision to pg + +begin; + +create or replace function cif.commit_project_revision(revision_to_commit_id int) +returns cif.project_revision as $$ +begin + -- defer FK constraints check to the end of the transaction + set constraints all deferred; + + -- Propagate the change_status to all related form_change records + -- Save the project table first to avoid foreign key violations from other potential tables. + perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change) + from cif.form_change + where project_revision_id=$1 + and form_data_table_name='project'; + + perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change) + from cif.form_change + where project_revision_id=$1 + and form_data_table_name='reporting_requirement'; + + perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change) + from cif.form_change + where project_revision_id=$1 + and form_data_table_name not in ('project', 'reporting_requirement'); + + update cif.project_revision set + project_id=(select form_data_record_id from cif.form_change where form_data_table_name='project' and project_revision_id=$1), + change_status='committed', + revision_status = 'Applied' + where id=$1; + + return (select row(project_revision.*)::cif.project_revision from cif.project_revision where id = $1); +end; +$$ language plpgsql; + +grant execute on function cif.commit_project_revision to cif_internal, cif_external, cif_admin; + +comment on function cif.commit_project_revision(int) is 'Commits a project_revision and all of its form changes'; + +commit; diff --git a/schema/revert/functions/jsonb_minus.sql b/schema/revert/functions/jsonb_minus.sql new file mode 100644 index 0000000000..4057447876 --- /dev/null +++ b/schema/revert/functions/jsonb_minus.sql @@ -0,0 +1,7 @@ +-- Revert cif:functions/jsonb_minus from pg + +begin; + +drop function if exists cif.jsonb_minus(jsonb, jsonb); + +commit; diff --git a/schema/revert/mutations/commit_form_change.sql b/schema/revert/mutations/commit_form_change.sql index a35011ad52..0ea3a5c4cd 100644 --- a/schema/revert/mutations/commit_form_change.sql +++ b/schema/revert/mutations/commit_form_change.sql @@ -1,7 +1,23 @@ --- Revert cif:mutations/commit_form_change from pg +-- Deploy cif:mutations/commit_form_change to pg +-- requires: tables/form_change begin; -drop function cif.commit_form_change; +create or replace function cif.commit_form_change(row_id int, form_change_patch cif.form_change) + returns cif.form_change as $$ +begin + + update cif.form_change set + new_form_data = coalesce(form_change_patch.new_form_data, new_form_data), + validation_errors = coalesce(form_change_patch.validation_errors, validation_errors) + where id=row_id; + + return (select cif_private.commit_form_change_internal((select row(form_change.*)::cif.form_change from cif.form_change where id = row_id))); +end; + $$ language plpgsql volatile; + +grant execute on function cif.commit_form_change to cif_internal, cif_external, cif_admin; + +comment on function cif.commit_form_change is 'Custom mutation to commit a form_change record via the API. Only used for records that are independent of a project such as the lists of contacts and operators.'; commit; diff --git a/schema/revert/mutations/commit_form_change@1.15.0.sql b/schema/revert/mutations/commit_form_change@1.15.0.sql new file mode 100644 index 0000000000..a35011ad52 --- /dev/null +++ b/schema/revert/mutations/commit_form_change@1.15.0.sql @@ -0,0 +1,7 @@ +-- Revert cif:mutations/commit_form_change from pg + +begin; + +drop function cif.commit_form_change; + +commit; diff --git a/schema/revert/mutations/commit_form_change_internal.sql b/schema/revert/mutations/commit_form_change_internal.sql index ae1a6bc0eb..459659eb76 100644 --- a/schema/revert/mutations/commit_form_change_internal.sql +++ b/schema/revert/mutations/commit_form_change_internal.sql @@ -1,8 +1,11 @@ -- Deploy cif:mutations/commit_form_change to pg begin; +drop function if exists cif_private.commit_form_change_internal(cif.form_change, int); create or replace function cif_private.commit_form_change_internal(fc cif.form_change) returns cif.form_change as $$ +declare + recordId int; begin if fc.validation_errors != '[]' then @@ -14,10 +17,13 @@ begin end if; -- TODO : add a conditional behaviour based on fc.form_id + execute format( + 'select "cif_private".%I($1)', + (select form_change_commit_handler from cif.form where slug = fc.json_schema_name) + ) using fc into recordId; + update cif.form_change set - form_data_record_id = ( - select cif_private.handle_default_form_change_commit(fc) - ), + form_data_record_id = recordId, change_status = 'committed' where id = fc.id; @@ -25,7 +31,7 @@ begin end; $$ language plpgsql volatile; -grant execute on function cif_private.commit_form_change_internal to cif_internal, cif_external, cif_admin; +grant execute on function cif_private.commit_form_change_internal(cif.form_change) to cif_internal, cif_external, cif_admin; comment on function cif_private.commit_form_change_internal(cif.form_change) is 'Commits the form change and calls the corresponding commit handler.'; diff --git a/schema/revert/mutations/commit_form_change_internal@1.15.0.sql b/schema/revert/mutations/commit_form_change_internal@1.15.0.sql new file mode 100644 index 0000000000..ae1a6bc0eb --- /dev/null +++ b/schema/revert/mutations/commit_form_change_internal@1.15.0.sql @@ -0,0 +1,32 @@ +-- Deploy cif:mutations/commit_form_change to pg +begin; + +create or replace function cif_private.commit_form_change_internal(fc cif.form_change) + returns cif.form_change as $$ +begin + + if fc.validation_errors != '[]' then + raise exception 'Cannot commit change with validation errors: %', fc.validation_errors; + end if; + + if fc.change_status = 'committed' then + raise exception 'Cannot commit form_change. It has already been committed.'; + end if; + + -- TODO : add a conditional behaviour based on fc.form_id + update cif.form_change set + form_data_record_id = ( + select cif_private.handle_default_form_change_commit(fc) + ), + change_status = 'committed' + where id = fc.id; + + return (select row(form_change.*)::cif.form_change from cif.form_change where id = fc.id); +end; + $$ language plpgsql volatile; + +grant execute on function cif_private.commit_form_change_internal to cif_internal, cif_external, cif_admin; + +comment on function cif_private.commit_form_change_internal(cif.form_change) is 'Commits the form change and calls the corresponding commit handler.'; + +commit; diff --git a/schema/revert/mutations/commit_project_revision.sql b/schema/revert/mutations/commit_project_revision.sql index e9549cacd9..bafe70a0cc 100644 --- a/schema/revert/mutations/commit_project_revision.sql +++ b/schema/revert/mutations/commit_project_revision.sql @@ -8,11 +8,6 @@ begin -- defer FK constraints check to the end of the transaction set constraints all deferred; - if ((select project_id from cif.project_revision where id = $1) is not null) - and ((select change_reason from cif.project_revision where id = $1) is null) then - raise exception 'Cannot commit revision if change_reason is null.'; - end if; - -- Propagate the change_status to all related form_change records -- Save the project table first to avoid foreign key violations from other potential tables. perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change) diff --git a/schema/revert/mutations/commit_project_revision@1.15.0.sql b/schema/revert/mutations/commit_project_revision@1.15.0.sql new file mode 100644 index 0000000000..e9549cacd9 --- /dev/null +++ b/schema/revert/mutations/commit_project_revision@1.15.0.sql @@ -0,0 +1,47 @@ +-- Deploy cif:mutations/commit_project_revision to pg + +begin; + +create or replace function cif.commit_project_revision(revision_to_commit_id int) +returns cif.project_revision as $$ +begin + -- defer FK constraints check to the end of the transaction + set constraints all deferred; + + if ((select project_id from cif.project_revision where id = $1) is not null) + and ((select change_reason from cif.project_revision where id = $1) is null) then + raise exception 'Cannot commit revision if change_reason is null.'; + end if; + + -- Propagate the change_status to all related form_change records + -- Save the project table first to avoid foreign key violations from other potential tables. + perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change) + from cif.form_change + where project_revision_id=$1 + and form_data_table_name='project'; + + perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change) + from cif.form_change + where project_revision_id=$1 + and form_data_table_name='reporting_requirement'; + + perform cif_private.commit_form_change_internal(row(form_change.*)::cif.form_change) + from cif.form_change + where project_revision_id=$1 + and form_data_table_name not in ('project', 'reporting_requirement'); + + update cif.project_revision set + project_id=(select form_data_record_id from cif.form_change where form_data_table_name='project' and project_revision_id=$1), + change_status='committed', + revision_status = 'Applied' + where id=$1; + + return (select row(project_revision.*)::cif.project_revision from cif.project_revision where id = $1); +end; +$$ language plpgsql; + +grant execute on function cif.commit_project_revision to cif_internal, cif_external, cif_admin; + +comment on function cif.commit_project_revision(int) is 'Commits a project_revision and all of its form changes'; + +commit; diff --git a/schema/sqitch.plan b/schema/sqitch.plan index e457b1c6e7..5f80208ae5 100644 --- a/schema/sqitch.plan +++ b/schema/sqitch.plan @@ -366,3 +366,7 @@ functions/handle_milestone_form_change_commit [functions/handle_milestone_form_c @1.16.0 2023-10-24T17:15:40Z Dylan Leard # release v1.16.0 @1.16.1 2023-11-22T17:01:35Z Dylan Leard # release v1.16.1 @1.16.2 2024-02-23T22:00:38Z Pierre Bastianelli # release v1.16.2 +functions/jsonb_minus 2023-10-30T19:55:55Z Mike Vesprini # Function to provide the object difference between two jsonb objects +mutations/commit_form_change_internal [mutations/commit_form_change_internal@1.15.0] 2023-10-30T21:34:15Z Mike Vesprini # Handle rebasing when committing with another pending revision on the same project" +mutations/commit_project_revision [mutations/commit_project_revision@1.15.0] 2023-10-31T00:07:01Z Mike Vesprini # Update function to pass new parameters to commit_form_change_internal +mutations/commit_form_change [mutations/commit_form_change@1.15.0] 2023-11-22T19:00:00Z Mike Vesprini # Add pending project revision id to args of commit_form_change_internal call diff --git a/schema/test/unit/concurrent_revisions/conflicting_creates_test.sql b/schema/test/unit/concurrent_revisions/conflicting_creates_test.sql new file mode 100644 index 0000000000..802e75a349 --- /dev/null +++ b/schema/test/unit/concurrent_revisions/conflicting_creates_test.sql @@ -0,0 +1,335 @@ +begin; + +select plan(19); + + +truncate table cif.project, cif.operator, cif.contact, cif.attachment restart identity cascade; +insert into cif.operator(legal_name) values ('test operator'); +insert into cif.contact(given_name, family_name, email) values ('John', 'Test', 'foo@abc.com'), ('Sandy', 'Olson', 'bar@abc.com'); +insert into cif.attachment (description, file_name, file_type, file_size) + values ('description1', 'file_name1', 'file_type1', 100), ('description2', 'file_name2', 'file_type1', 100); +insert into cif.cif_user(id, session_sub, given_name, family_name) + overriding system value + values (1, '11111111-1111-1111-1111-111111111111', 'Jan','Jansen'), + (2, '22222222-2222-2222-2222-222222222222', 'Max','Mustermann'), + (3, '33333333-3333-3333-3333-333333333333', 'Eva', 'Nováková'); + +-- Create a project to update. +select cif.create_project(1); -- id = 1 +update cif.form_change set new_form_data='{ + "projectName": "name", + "summary": "original (incorrect at point of test)", + "fundingStreamRfpId": 1, + "projectStatusId": 1, + "proposalReference": "1235", + "operatorId": 1 + }'::jsonb + where project_revision_id=1 + and form_data_table_name='project'; +select cif.commit_project_revision(1); + +-- create the amendment that will be "pending" +select cif.create_project_revision(1, 'Amendment'); -- id = 2 +select cif.add_contact_to_revision(2, 1, 1); +select cif.create_form_change( + 'create', + 'emission_intensity', + 'cif', + 'reporting_requirement', + json_build_object( + 'baselineEmissionIntensity', 1, + 'targetEmissionIntensity', 2, + 'postProjectEmissionIntensity', 3, + 'totalLifetimeEmissionReduction', 4 + )::jsonb, + null, + 2 +); +select cif.create_form_change( + 'create', + 'funding_parameter_EP', + 'cif', + 'funding_parameter', + json_build_object( + 'projectId', 1, + 'provinceSharePercentage', 1 + )::jsonb, + null, + 2 +); +select cif.create_form_change( + 'create', + 'project_manager', + 'cif', + 'project_manager', + json_build_object( + 'projectManagerLabelId', 1, + 'cifUserId', 1, + 'projectId', 1 + )::jsonb, + null, + 2 +); +select cif.create_form_change( + 'create', + 'reporting_requirement', + 'cif', + 'reporting_requirement', + json_build_object( + 'reportType', 'Quarterly', + 'reportingRequirementIndex', 1, + 'projectId', 1 + )::jsonb, + null, + 2 +); +select cif.create_form_change( + 'create', + 'milestone', + 'cif', + 'reporting_requirement', + json_build_object( + 'reportType', 'General Milestone', + 'reportingRequirementIndex', 1 + )::jsonb, + null, + 2 +); +select cif.add_project_attachment_to_revision(2,1); + +-- create the general revision that will be "committing" +select cif.create_project_revision(1, 'General Revision'); -- id = 3 +select cif.add_contact_to_revision(3, 1, 2); +select cif.create_form_change( + 'create', + 'emission_intensity', + 'cif', + 'reporting_requirement', + json_build_object( + 'baselineEmissionIntensity', 5, + 'targetEmissionIntensity', 6, + 'postProjectEmissionIntensity', 7, + 'totalLifetimeEmissionReduction', 8 + )::jsonb, + null, + 3 +); +select cif.create_form_change( + 'create', + 'funding_parameter_EP', + 'cif', + 'funding_parameter', + json_build_object( + 'projectId', 1, + 'provinceSharePercentage', 2 + )::jsonb, + null, + 3 +); +select cif.create_form_change( + 'create', + 'project_manager', + 'cif', + 'project_manager', + json_build_object( + 'projectManagerLabelId', 1, + 'cifUserId', 2, + 'projectId', 1 + )::jsonb, + null, + 3 +); +select cif.create_form_change( + 'create', + 'project_manager', + 'cif', + 'project_manager', + json_build_object( + 'projectManagerLabelId', 2, + 'cifUserId', 1, + 'projectId', 1 + )::jsonb, + null, + 3 +); +select cif.create_form_change( + 'create', + 'reporting_requirement', + 'cif', + 'reporting_requirement', + json_build_object( + 'reportType', 'Quarterly', + 'reportingRequirementIndex', 1, + 'projectId', 1 + )::jsonb, + null, + 3 +); +select cif.create_form_change( + 'create', + 'reporting_requirement', + 'cif', + 'reporting_requirement', + json_build_object( + 'reportType', 'Quarterly', + 'reportingRequirementIndex', 2, + 'projectId', 1 + )::jsonb, + null, + 3 +); +select cif.create_form_change( + 'create', + 'milestone', + 'cif', + 'reporting_requirement', + json_build_object( + 'reportType', 'General Milestone', + 'reportingRequirementIndex', 1 + )::jsonb, + null, + 3 +); +select cif.create_form_change( + 'create', + 'milestone', + 'cif', + 'reporting_requirement', + json_build_object( + 'reportType', 'General Milestone', + 'reportingRequirementIndex', 2 + )::jsonb, + null, + 3 +); +select cif.add_project_attachment_to_revision(3,2); + +select cif.commit_project_revision(3); + +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and json_schema_name = 'funding_parameter_EP'), + 1::bigint, + 'When committing and pending have both created a funding parameter form, only one exists in pending after the first is commit' +); + +select is ( + (select (new_form_data ->> 'provinceSharePercentage')::int from cif.form_change where project_revision_id = 2 and json_schema_name = 'funding_parameter_EP'), + 1, + 'When committing and pending have both created a funding parameter form, pending maintains its form values' +); + +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and json_schema_name = 'emission_intensity'), + 1::bigint, + 'When committing and pending have both created an emission intensity report form, only one exists in pending after the first is commit' +); + +select is ( + (select (new_form_data ->> 'baselineEmissionIntensity')::int from cif.form_change where project_revision_id = 2 and json_schema_name = 'emission_intensity'), + 1, + 'When committing and pending have both created an emission intensity report, pending maintains its form values' +); + +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and json_schema_name = 'project_contact'), + 2::bigint, + 'When committing and pending both create a primary contact, the correct nuber of contacts exist in pending' +); + +select is ( + (select (new_form_data->>'contactId')::int from cif.form_change where project_revision_id = 2 and json_schema_name = 'project_contact' and new_form_data->>'contactIndex' = '1'), + 1, + 'When committing and pending both create a primary contact, the pending primary contact contactId maintains its value' +); + +select is ( + (select (new_form_data->>'contactId')::int from cif.form_change where project_revision_id = 2 and json_schema_name = 'project_contact' and new_form_data->>'contactIndex' = '2'), + 2, + 'When committing and pending both create a primary contact, the committing primary becomes the amendments secondary contact' +); + +-- project_manager +select is ( + (select operation from cif.form_change where project_revision_id = 2 and json_schema_name = 'project_manager' and new_form_data->>'projectManagerLabelId' = '1'), + 'update', + 'When committing and pending both create a project manager with the same projectManagerLabelId, pendings operation becomes update' +); + +select is ( + (select (new_form_data->>'cifUserId')::int from cif.form_change where project_revision_id = 2 and json_schema_name = 'project_manager' and new_form_data->>'projectManagerLabelId' = '1'), + 1, + 'When committing and pending both create a project manager with the same projectManagerLabelId, the value of cifUserId in pending remains unchanged' +); + +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and json_schema_name = 'project_manager'), + 2::bigint, + 'When committing and pending both create a project managers with different labels, all created manager labels persist to the pending form change' +); + +-- Quarterly Reports +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and new_form_data->>'reportType' = 'Quarterly'), + 3::bigint, + 'When committing and pending both create Quarterly reports, all of them are kept after the commit' +); + +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and new_form_data->>'reportType' = 'Quarterly' and (new_form_data->>'reportingRequirementIndex')::int = 1), + 1::bigint, + 'When committing and pending both create Quarterly reports, reportingRequirementIndexes are not doubled up' +); + +select is ( + (select max((new_form_data->>'reportingRequirementIndex')::int) from cif.form_change where project_revision_id = 2 and new_form_data->>'reportType' = 'Quarterly'), + 3, + 'When committing and pending both create Quarterly reports, the indexes of those in pending are adjusted on commit' +); + +-- Milestones +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and new_form_data->>'reportType' = 'General Milestone'), + 3::bigint, + 'When committing and pending both create General Milestone reports, all of them are kept after the commit' +); + +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and new_form_data->>'reportType' = 'General Milestone' and (new_form_data->>'reportingRequirementIndex')::int = 1), + 1::bigint, + 'When committing and pending both create General Milestone reports, reportingRequirementIndexes are not doubled up' +); + +select is ( + (select max((new_form_data->>'reportingRequirementIndex')::int) from cif.form_change where project_revision_id = 2 and new_form_data->>'reportType' = 'General Milestone'), + 3, + 'When committing and pending both create General Milestone reports, the next sequential index is assigned to the milestone form_change record being added in pending.' +); + +select is ( + (select max(counts.index_count) from ( + select count(*) as index_count from cif.form_change + where project_revision_id = 2 and new_form_data->>'reportType' = 'General Milestone' + group by new_form_data->>'reportingRequirementIndex') as counts + ), + 1::bigint, + 'When committing and pending both create General Milestone reports, each milestone is given a unique reportingRequirementIndex.' +); + +-- Commit the pending ammednment + +select lives_ok ( + $$ + select cif.commit_project_revision(2) + $$, + 'Committing the pending project_revision does not throw an error' +); + +select is ( + (select count(*) from cif.form_change where form_data_record_id is null), + 0::bigint, + 'All of the committed form_change records have a form_data_record_id assigned after pending is committed.' +); + +select finish(); + +rollback; diff --git a/schema/test/unit/concurrent_revisions/conflicting_updates_test.sql b/schema/test/unit/concurrent_revisions/conflicting_updates_test.sql new file mode 100644 index 0000000000..4eea8e3f5e --- /dev/null +++ b/schema/test/unit/concurrent_revisions/conflicting_updates_test.sql @@ -0,0 +1,111 @@ +begin; + +select plan(5); + +truncate table cif.project, cif.operator, cif.contact, cif.attachment restart identity cascade; +insert into cif.operator(legal_name) values ('test operator'); +insert into cif.contact(given_name, family_name, email) values ('John', 'Test', 'foo@abc.com'); +insert into cif.attachment (description, file_name, file_type, file_size) + values ('description1', 'file_name1', 'file_type1', 100); + +select cif.create_project(1); -- id = 1 +update cif.form_change set new_form_data='{ + "projectName": "name", + "summary": "original (incorrect at point of test)", + "fundingStreamRfpId": 1, + "projectStatusId": 1, + "proposalReference": "1235", + "operatorId": 1 + }'::jsonb + where project_revision_id=1 + and form_data_table_name='project'; +select cif.commit_project_revision(1); + +-- create the amendment that will be "pending" +select cif.create_project_revision(1, 'Amendment'); -- id = 2 +update cif.form_change set new_form_data='{ + "projectName": "Correct", + "summary": "original (incorrect at point of test)", + "fundingStreamRfpId": 1, + "projectStatusId": 1, + "proposalReference": "1235", + "operatorId": 1 + }'::jsonb + where project_revision_id=2 + and form_data_table_name='project'; + +-- create the general revision that will be "committing" +select cif.create_project_revision(1, 'General Revision'); -- id = 3 +update cif.form_change set new_form_data='{ + "projectName": "Incorrect", + "summary": "Correct", + "fundingStreamRfpId": 1, + "projectStatusId": 1, + "proposalReference": "1235", + "operatorId": 1 + }'::jsonb + where project_revision_id=3 + and form_data_table_name='project'; + +select cif.add_contact_to_revision(3, 1, 1); +select cif.add_project_attachment_to_revision(3,1); +select cif.create_form_change( + 'create', + 'funding_parameter_EP', + 'cif', + 'funding_parameter', + json_build_object( + 'projectId', 1, + 'provinceSharePercentage', 50, + 'holdbackPercentage', 10, + 'maxFundingAmount', 1, + 'anticipatedFundingAmount', 1, + 'proponentCost',777, + 'contractStartDate', '2022-03-01 16:21:42.693489-07', + 'projectAssetsLifeEndDate', '2022-03-01 16:21:42.693489-07' + )::jsonb, + null, + 3 + ); + +select cif.commit_project_revision(3); + +select is ( + (select new_form_data->>'projectName' from cif.form_change where project_revision_id = 2 and form_data_table_name = 'project'), + 'Correct', + 'When both the committing and pending form changes have changed the same field, the value from the pending should persist' +); + +select is ( + (select previous_form_change_id from cif.form_change where project_revision_id = 2 and form_data_table_name = 'project'), + 3::int, + 'When committing, the pending form change gets the committing form change as its previous form change' +); + + +select is ( + (select project_name from cif.project where id = 1), + 'Incorrect', + 'The project receives the value from the committing form change' +); + +select is ( + (select new_form_data->>'summary' from cif.form_change where project_revision_id = 2 and form_data_table_name = 'project'), + 'Correct', + 'When the commiting form change has updated a field that the pending has not, it updates the pending form change' +); + +-- Commit the pending ammednment + +select lives_ok ( + $$ + select cif.commit_project_revision(2) + $$, + 'Committing the pending project_revision does not throw an error' +); + + + +select finish(); + +rollback; diff --git a/schema/test/unit/concurrent_revisions/creating_new_records_test.sql b/schema/test/unit/concurrent_revisions/creating_new_records_test.sql new file mode 100644 index 0000000000..0f64d69972 --- /dev/null +++ b/schema/test/unit/concurrent_revisions/creating_new_records_test.sql @@ -0,0 +1,125 @@ +begin; + +select plan(9); + +/* + Test when the committing project_revision creates records that do not exist in the pending project_revision +*/ + +truncate table cif.project, cif.operator, cif.contact, cif.attachment restart identity cascade; +insert into cif.operator(legal_name) values ('test operator'); +insert into cif.contact(given_name, family_name, email) values ('John', 'Test', 'foo@abc.com'); +insert into cif.attachment (description, file_name, file_type, file_size) + values ('description1', 'file_name1', 'file_type1', 100); + +select cif.create_project(1); -- id = 1 +update cif.form_change set new_form_data='{ + "projectName": "name", + "summary": "original (incorrect at point of test)", + "fundingStreamRfpId": 1, + "projectStatusId": 1, + "proposalReference": "1235", + "operatorId": 1 + }'::jsonb + where project_revision_id=1 + and form_data_table_name='project'; +select cif.commit_project_revision(1); + +-- create the amendment that will be "pending" +select cif.create_project_revision(1, 'Amendment'); -- id = 2 +update cif.form_change set new_form_data='{ + "projectName": "Correct", + "summary": "original (incorrect at point of test)", + "fundingStreamRfpId": 1, + "projectStatusId": 1, + "proposalReference": "1235", + "operatorId": 1 + }'::jsonb + where project_revision_id=2 + and form_data_table_name='project'; + +-- create the general revision that will be "committing" +select cif.create_project_revision(1, 'General Revision'); -- id = 3 +select cif.add_contact_to_revision(3, 1, 1); +select cif.add_project_attachment_to_revision(3,1); +select cif.create_form_change( + 'create', + 'funding_parameter_EP', + 'cif', + 'funding_parameter', + json_build_object( + 'projectId', 1, + 'provinceSharePercentage', 50, + 'holdbackPercentage', 10, + 'maxFundingAmount', 1, + 'anticipatedFundingAmount', 1, + 'proponentCost',777, + 'contractStartDate', '2022-03-01 16:21:42.693489-07', + 'projectAssetsLifeEndDate', '2022-03-01 16:21:42.693489-07' + )::jsonb, + null, + 3 + ); + +select cif.commit_project_revision(3); + +select is ( + (select new_form_data from cif.form_change where project_revision_id = 2 and form_data_table_name = 'project_contact'), + '{"contactId": 1, "projectId": 1, "contactIndex": 1}'::jsonb, + 'When the committing form change is creating a project contact, the contact also gets created in the pending revision' +); + +select is ( + (select previous_form_change_id from cif.form_change where project_revision_id = 2 and form_data_table_name = 'project_contact'), + 4::int, + 'When committing form change has an operation of create, the pending form change that is created gets the committing form_change id as its previous form change' +); + +select is ( + (select form_data_record_id from cif.form_change where project_revision_id = 2 and form_data_table_name = 'project_attachment'), + (select form_data_record_id from cif.form_change where project_revision_id = 3 and form_data_table_name = 'project_attachment'), + 'When committing has an operation of create, the form_data_record_id propogates to the pending form change for attachments' +); + +select is ( + (select form_data_record_id from cif.form_change where project_revision_id = 2 and form_data_table_name = 'project_contact'), + (select form_data_record_id from cif.form_change where project_revision_id = 3 and form_data_table_name = 'project_contact'), + 'When committing has an operation of create, the form_data_record_id propogates to the pending form change for contacts' +); + +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and form_data_table_name = 'project_attachment'), + 1::bigint, + 'When the committing form change is creating a project attachment, the attachment also gets created in the pending revision' +); + +select is ( + (select form_data_record_id from cif.form_change where project_revision_id = 2 and form_data_table_name = 'funding_parameter_EP'), + (select form_data_record_id from cif.form_change where project_revision_id = 3 and form_data_table_name = 'funding_parameter_EP'), + 'When committing has an operation of create, the form_data_record_id propogates to the pending form change for funding parameter form' +); + +select is ( + (select new_form_data from cif.form_change where project_revision_id = 2 and form_data_table_name = 'funding_parameter_EP'), + (select new_form_data from cif.form_change where project_revision_id = 3 and form_data_table_name = 'funding_parameter_EP'), + 'When committing has an operation of create, the new_form_data propogates to the pending form change for funding parameter form' +); + +-- Commit the pending ammednment + +select lives_ok ( + $$ + select cif.commit_project_revision(2) + $$, + 'Committing the pending project_revision does not throw an error' +); + +select is ( + (select count(*) from cif.form_change where form_data_record_id is null), + 0::bigint, + 'All of the committed form_change records have a form_data_record_id assigned after pending is committed.' +); + +select finish(); + +rollback; diff --git a/schema/test/unit/concurrent_revisions/discards_test.sql b/schema/test/unit/concurrent_revisions/discards_test.sql new file mode 100644 index 0000000000..3991ddf09e --- /dev/null +++ b/schema/test/unit/concurrent_revisions/discards_test.sql @@ -0,0 +1,165 @@ +begin; + +select plan(7); + + +truncate table cif.project, cif.operator, cif.contact, cif.attachment restart identity cascade; +insert into cif.operator(legal_name) values ('test operator'); +insert into cif.contact(given_name, family_name, email) values ('John', 'Test', 'foo@abc.com'), ('Sandy', 'Olson', 'bar@abc.com'); +insert into cif.attachment (description, file_name, file_type, file_size) + values ('description1', 'file_name1', 'file_type1', 100), ('description2', 'file_name2', 'file_type1', 100); +insert into cif.cif_user(id, session_sub, given_name, family_name) + overriding system value + values (1, '11111111-1111-1111-1111-111111111111', 'Jan','Jansen'), + (2, '22222222-2222-2222-2222-222222222222', 'Max','Mustermann'), + (3, '33333333-3333-3333-3333-333333333333', 'Eva', 'Nováková'); + +-- Create a project to update. +select cif.create_project(1); -- id = 1 +update cif.form_change set new_form_data='{ + "projectName": "name", + "summary": "original (incorrect at point of test)", + "fundingStreamRfpId": 1, + "projectStatusId": 1, + "proposalReference": "1235", + "operatorId": 1 + }'::jsonb + where project_revision_id=1 + and form_data_table_name='project'; + +select cif.add_contact_to_revision(1, 1, 1); +select cif.add_contact_to_revision(1, 2, 2); +select cif.add_project_attachment_to_revision(1,1); +select cif.create_form_change( + 'create', + 'funding_parameter_EP', + 'cif', + 'funding_parameter', + json_build_object( + 'projectId', 1, + 'provinceSharePercentage', 1 + )::jsonb, + null, + 1 +); +select cif.create_form_change( + 'create', + 'project_manager', + 'cif', + 'project_manager', + json_build_object( + 'projectManagerLabelId', 1, + 'cifUserId', 1, + 'projectId', 1 + )::jsonb, + null, + 1 +); +select cif.create_form_change( + 'create', + 'reporting_requirement', + 'cif', + 'reporting_requirement', + json_build_object( + 'reportType', 'Quarterly', + 'reportingRequirementIndex', 1, + 'projectId', 1 + )::jsonb, + null, + 1 +); +select cif.create_form_change( + 'create', + 'milestone', + 'cif', + 'reporting_requirement', + json_build_object( + 'reportType', 'General Milestone', + 'reportingRequirementIndex', 1 + )::jsonb, + null, + 1 +); +select cif.commit_project_revision(1); + +-- create the amendment that will be "pending" +select cif.create_project_revision(1, 'Amendment'); -- id = 2 + +-- create the general revision that will be "committing" +select cif.create_project_revision(1, 'General Revision'); -- id = 3 + +update cif.form_change set operation = 'archive' + where project_revision_id=3 + and json_schema_name='project_contact' + and new_form_data ->> 'contactIndex' = '2'; + +update cif.form_change set operation = 'archive' + where project_revision_id=3 + and json_schema_name='reporting_requirement' + and new_form_data ->> 'reportType' = 'Quarterly'; + +update cif.form_change set operation = 'archive' + where project_revision_id=3 + and json_schema_name='project_manager'; + +update cif.form_change set operation = 'archive' + where project_revision_id=3 + and json_schema_name='milestone'; + +select cif.discard_funding_parameter_form_change(3); + +select cif.discard_project_attachment_form_change( + (select id from cif.form_change where project_revision_id = 3 and form_data_table_name = 'project_attachment') +); + +select cif.commit_project_revision(3); + +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and json_schema_name = 'project_contact'), + 1::bigint, + 'When the committing form change archives a project contact, the corresponding form change in the pending revision on that project is deleted' +); + +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and json_schema_name = 'reporting_requirement' and new_form_data ->> 'reportType' = 'Quarterly'), + 0::bigint, + 'When the committing form change archives a quarterly report, the corresponding form change in the pending revision on that project is deleted' +); + +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and json_schema_name = 'project_manager'), + 0::bigint, + 'When the committing form change removes a project manager, the corresponding form change in the pending revision on that project is deleted' +); + +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and json_schema_name = 'funding_parameter_EP'), + 0::bigint, + 'When the committing form change discards the emission intensity report, the corresponding form change in the pending revision on that project is deleted' +); + +select is ( + (select count(*) from cif.form_change where project_revision_id = 2 and form_data_table_name = 'project_attachment'), + 0::bigint, + 'When the committing form change is discarding a project attachment, the pending fc is deleted.' +); + +-- Commit the pending ammednment + +select lives_ok ( + $$ + select cif.commit_project_revision(2) + $$, + 'Committing the pending project_revision does not throw an error' +); + +select is ( + (select count(*) from cif.form_change where form_data_record_id is null), + 0::bigint, + 'All of the committed form_change records have a form_data_record_id assigned after pending is committed.' +); + + +select finish(); + +rollback; diff --git a/schema/test/unit/functions/jsonb_minus_test.sql b/schema/test/unit/functions/jsonb_minus_test.sql new file mode 100644 index 0000000000..37ad6a010e --- /dev/null +++ b/schema/test/unit/functions/jsonb_minus_test.sql @@ -0,0 +1,33 @@ +begin; + +select plan(5); + +select has_function('cif', 'jsonb_minus', 'function cif.jsonb_minus exists'); + +select is( + (select * from cif.jsonb_minus('{"a": 0, "b": 0, "c": 0}'::jsonb, '{"a": 0, "b": 0, "c": 0}'::jsonb)), + NULL, + 'The difference of two identical objects is NULL' +); + +select is( + (select * from cif.jsonb_minus('{"a": 1, "b": 0, "c": null}'::jsonb, '{"a": 0, "b": 0, "c": 0}'::jsonb)), + '{"a": 1, "c": null}'::jsonb, + 'All fields that are changed are returned' +); + +select is( + (select * from cif.jsonb_minus('{"a": 1, "b": 0, "c": 1, "d": null}'::jsonb, '{"a": 0, "b": 0}'::jsonb)), + '{"a": 1, "c": 1, "d": null}'::jsonb, + 'Added fields are included in the return value, including when their value is null' +); + +select is( + (select * from cif.jsonb_minus('{"a": 1, "b": 0}'::jsonb, '{"a": 1, "b": 2, "d": "test value"}'::jsonb)), + '{"b": 0}'::jsonb, + 'Extra fields in the subtrahend are properly ignored' +); + +select finish(); + +rollback; diff --git a/schema/test/unit/mutations/commit_form_change_internal_test.sql b/schema/test/unit/mutations/commit_form_change_internal_test.sql index 3fa3a42583..13fa18ae0e 100644 --- a/schema/test/unit/mutations/commit_form_change_internal_test.sql +++ b/schema/test/unit/mutations/commit_form_change_internal_test.sql @@ -35,7 +35,7 @@ values ( ; -- make sure the function exists -select has_function('cif_private', 'commit_form_change_internal', ARRAY['cif.form_change'], 'Function commit_form_change_internal should exist'); +select has_function('cif_private', 'commit_form_change_internal', ARRAY['cif.form_change', 'int'], 'Function commit_form_change_internal should exist'); select results_eq( $$ @@ -77,7 +77,8 @@ select is( 'The form_change status should be committed' ); --- Calls the proper function set in the form table + + select finish(); diff --git a/schema/test/unit/mutations/commit_form_change_test.sql b/schema/test/unit/mutations/commit_form_change_test.sql index b058250818..61765b0c2e 100644 --- a/schema/test/unit/mutations/commit_form_change_test.sql +++ b/schema/test/unit/mutations/commit_form_change_test.sql @@ -7,7 +7,7 @@ select plan(2); /** SETUP **/ truncate cif.form_change restart identity; -create or replace function cif_private.commit_form_change_internal(fc cif.form_change) +create or replace function cif_private.commit_form_change_internal(fc cif.form_change, pending_project_revision_id int default null) returns cif.form_change as $$ begin return fc; @@ -54,7 +54,7 @@ select results_eq( validation_errors from cif.commit_form_change( 12345, - (select row( null, '{"updated":true}', null, null, null, null, null, null, null, '["hazErrors"]', null, null, null, null, null)::cif.form_change) + (select row( null, '{"updated":true}', null, null, null, null, null, null, null, '[]', null, null, null, null, null)::cif.form_change) ); $$, $$ @@ -68,7 +68,7 @@ select results_eq( null::int, 'pending'::varchar, 'reporting_requirement'::varchar, - '["hazErrors"]'::jsonb + '[]'::jsonb ) $$, 'commit_form_change calls the private commit_form_change_internal() function' diff --git a/schema/test/unit/mutations/commit_project_revision_test.sql b/schema/test/unit/mutations/commit_project_revision_test.sql index 6d4293f7d3..44b16a5fcf 100644 --- a/schema/test/unit/mutations/commit_project_revision_test.sql +++ b/schema/test/unit/mutations/commit_project_revision_test.sql @@ -1,6 +1,6 @@ begin; -select plan(9); +select plan(13); /** BEGIN SETUP **/ truncate table @@ -210,6 +210,97 @@ select results_eq( 'commit_project_revision sets revision_status to Applied when revision_type is General Revision' ); +-- Test the concurrent revision functinality + +truncate cif.project restart identity cascade; + +select cif.create_project(1); -- id = 1 +update cif.form_change set new_form_data='{ + "projectName": "name", + "summary": "original (incorrect at point of test)", + "fundingStreamRfpId": 1, + "projectStatusId": 1, + "proposalReference": "1235", + "operatorId": 1 + }'::jsonb + where project_revision_id=1 + and form_data_table_name='project'; +select cif.commit_project_revision(1); + + +select cif.create_project_revision(1, 'Amendment'); -- id = 2 +update cif.form_change set new_form_data='{ + "projectName": "Correct", + "summary": "original (incorrect at point of test)", + "fundingStreamRfpId": 1, + "projectStatusId": 1, + "proposalReference": "1235", + "operatorId": 1 + }'::jsonb + where project_revision_id=2 + and form_data_table_name='project'; + +select cif.create_project_revision(1, 'General Revision'); -- id = 3 +update cif.form_change set new_form_data='{ + "projectName": "Incorrect", + "summary": "Correct", + "fundingStreamRfpId": 1, + "projectStatusId": 1, + "proposalReference": "1235", + "operatorId": 1 + }'::jsonb + where project_revision_id=3 + and form_data_table_name='project'; + +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', 1, + 'contactId', 1, + 'contactIndex', 1 + ), + 'create', 'cif', 'project_contact', 'project_contact', 3 +); + +select lives_ok ( + $$ + select cif.commit_project_revision(3) + $$, + 'The General Revision successfully commits while there is a pending Amendment on the project' +); + +select lives_ok ( + $$ + select cif.commit_project_revision(2) + $$, + 'The Amendment successfully commits after a General Revision being committed while the Amendment was pending' +); + +select results_eq ( + $$ + (select project_name, summary from cif.project where id = 1 limit 1) + $$, + $$ + values('Correct'::varchar, 'Correct'::varchar) + $$, + 'The project table has the correct data after the Amendment is committed' +); + +select isnt_empty ( + $$ + select id from cif.project_contact where project_id=1; + $$, + 'The project_contact added in the General Revision was succesfully added after the Amendment was committed' +); + select finish(); rollback; diff --git a/schema/verify/functions/jsonb_minus.sql b/schema/verify/functions/jsonb_minus.sql new file mode 100644 index 0000000000..9f07ff4488 --- /dev/null +++ b/schema/verify/functions/jsonb_minus.sql @@ -0,0 +1,7 @@ +-- Verify cif:functions/jsonb_minus on pg + +begin; + +select pg_get_functiondef('cif.jsonb_minus(jsonb, jsonb)'::regprocedure); + +rollback; diff --git a/schema/verify/mutations/commit_form_change@1.15.0.sql b/schema/verify/mutations/commit_form_change@1.15.0.sql new file mode 100644 index 0000000000..beed54db86 --- /dev/null +++ b/schema/verify/mutations/commit_form_change@1.15.0.sql @@ -0,0 +1,7 @@ +-- Verify cif:mutations/commit_form_change on pg + +begin; + +select pg_get_functiondef('cif.commit_form_change(int, cif.form_change)'::regprocedure); + +rollback; diff --git a/schema/verify/mutations/commit_form_change_internal.sql b/schema/verify/mutations/commit_form_change_internal.sql index e45d9fa700..ac5a71a4c5 100644 --- a/schema/verify/mutations/commit_form_change_internal.sql +++ b/schema/verify/mutations/commit_form_change_internal.sql @@ -2,6 +2,6 @@ begin; -select pg_get_functiondef('cif_private.commit_form_change_internal(cif.form_change)'::regprocedure); +select pg_get_functiondef('cif_private.commit_form_change_internal(cif.form_change, int)'::regprocedure); rollback; diff --git a/schema/verify/mutations/commit_form_change_internal@1.15.0.sql b/schema/verify/mutations/commit_form_change_internal@1.15.0.sql new file mode 100644 index 0000000000..e45d9fa700 --- /dev/null +++ b/schema/verify/mutations/commit_form_change_internal@1.15.0.sql @@ -0,0 +1,7 @@ +-- Verify cif:mutations/commit_form_change on pg + +begin; + +select pg_get_functiondef('cif_private.commit_form_change_internal(cif.form_change)'::regprocedure); + +rollback; diff --git a/schema/verify/mutations/commit_project_revision@1.15.0.sql b/schema/verify/mutations/commit_project_revision@1.15.0.sql new file mode 100644 index 0000000000..efa347aea8 --- /dev/null +++ b/schema/verify/mutations/commit_project_revision@1.15.0.sql @@ -0,0 +1,7 @@ +-- Verify cif:mutations/commit_project_revision on pg + +begin; + +select pg_get_functiondef('cif.commit_project_revision(int)'::regprocedure); + +rollback;