From c086f6d671e53b93e9c9881a88984134bb40f408 Mon Sep 17 00:00:00 2001 From: Curtis Upshall Date: Wed, 30 Aug 2023 14:04:53 -0700 Subject: [PATCH 1/8] SIMSBIOHUB-262: Create Survey Blocks table --- ...230830123800_create_survey_block_tables.ts | 181 ++++++++++++++++++ 1 file changed, 181 insertions(+) create mode 100644 database/src/migrations/20230830123800_create_survey_block_tables.ts diff --git a/database/src/migrations/20230830123800_create_survey_block_tables.ts b/database/src/migrations/20230830123800_create_survey_block_tables.ts new file mode 100644 index 0000000000..38a01a36f6 --- /dev/null +++ b/database/src/migrations/20230830123800_create_survey_block_tables.ts @@ -0,0 +1,181 @@ +import { Knex } from 'knex'; + +/** + * Adds new survey partnerships tables + * + * @export + * @param {Knex} knex + * @return {*} {Promise} + */ +export async function up(knex: Knex): Promise { + await knex.raw(`--sql + + ---------------------------------------------------------------------------------------- + -- Create new survey_block table + ---------------------------------------------------------------------------------------- + + SET search_path=biohub; + + CREATE TABLE survey_block( + survey_block_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + survey_id integer NOT NULL, + name varchar(300), + description varchar(3000), + create_date timestamptz(6) DEFAULT now() NOT NULL, + create_user integer NOT NULL, + update_date timestamptz(6), + update_user integer, + revision_count integer DEFAULT 0 NOT NULL, + CONSTRAINT survey_block_pk PRIMARY KEY (survey_block_id) + ); + + COMMENT ON COLUMN survey_block.survey_block_id IS 'System generated surrogate primary key identifier.' + ; + COMMENT ON COLUMN survey_block.survey_id IS 'System generated surrogate primary key identifier.' + ; + COMMENT ON COLUMN survey_block.name IS 'The name of the block.' + ; + COMMENT ON COLUMN survey_block.description IS 'The description of the block.' + ; + COMMENT ON COLUMN survey_block.create_date IS 'The datetime the record was created.' + ; + COMMENT ON COLUMN survey_block.create_user IS 'The id of the user who created the record as identified in the system user table.' + ; + COMMENT ON COLUMN survey_block.update_date IS 'The datetime the record was updated.' + ; + COMMENT ON COLUMN survey_block.update_user IS 'The id of the user who updated the record as identified in the system user table.' + ; + COMMENT ON COLUMN survey_block.revision_count IS 'Revision count used for concurrency control.' + ; + COMMENT ON TABLE survey_block IS 'blocks associated with a given survey.' + ; + + + ---------------------------------------------------------------------------------------- + -- Create new keys and indices + ---------------------------------------------------------------------------------------- + + -- Add foreign key constraint from child table to parent table on survey_id + ALTER TABLE survey_block ADD CONSTRAINT survey_block_fk1 + FOREIGN KEY (survey_id) + REFERENCES survey(survey_id); + + -- Add foreign key index + CREATE INDEX survey_block_idx1 ON survey_block(survey_id); + + -- Add unique constraint + + CREATE UNIQUE INDEX survey_block_uk1 ON survey_block(name, survey_id); + + -- Create audit and journal triggers + create trigger audit_observation before insert or update or delete on survey_block for each row execute procedure tr_audit_trigger(); + create trigger journal_observation after insert or update or delete on survey_block for each row execute procedure tr_journal_trigger(); + + + ---------------------------------------------------------------------------------------- + -- Create views + ---------------------------------------------------------------------------------------- + + set search_path=biohub_dapi_v1; + + create or replace view survey_block as select * from biohub.survey_block; + + + ---------------------------------------------------------------------------------------- + -- Update api_delete_survey procedure + ---------------------------------------------------------------------------------------- + + set search_path=biohub; + + CREATE OR REPLACE PROCEDURE api_delete_survey(p_survey_id integer) + LANGUAGE plpgsql + SECURITY DEFINER + AS $procedure$ + -- ******************************************************************* + -- Procedure: api_delete_survey + -- Purpose: deletes a survey and dependencies + -- + -- MODIFICATION HISTORY + -- Person Date Comments + -- ---------------- ----------- -------------------------------------- + -- shreyas.devalapurkar@quartech.com + -- 2021-06-18 initial release + -- charlie.garrettjones@quartech.com + -- 2021-06-21 added occurrence submission delete + -- charlie.garrettjones@quartech.com + -- 2021-09-21 added survey summary submission delete + -- kjartan.einarsson@quartech.com + -- 2022-08-28 added survey_vantage, survey_spatial_component, survey delete + -- charlie.garrettjones@quartech.com + -- 2022-09-07 changes to permit model + -- charlie.garrettjones@quartech.com + -- 2022-10-05 1.3.0 model changes + -- charlie.garrettjones@quartech.com + -- 2022-10-05 1.5.0 model changes, drop concept of occurrence deletion for published data + -- charlie.garrettjones@quartech.com + -- 2023-03-14 1.7.0 model changes + -- alfred.rosenthal@quartech.com + -- 2023-03-15 added missing publish tables to survey delete + -- curtis.upshall@quartech.com + -- 2023-04-28 change order of survey delete procedure + -- alfred.rosenthal@quartech.com + -- 2023-07-26 delete regions + -- curtis.upshall@quartech.com + -- 2023-08-24 delete partnerships + -- curtis.upshall@quartech.com + -- 2023-08-24 delete survey blocks and stratums + -- ******************************************************************* + declare + + begin + with occurrence_submissions as (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id), submission_spatial_components as (select submission_spatial_component_id from submission_spatial_component + where occurrence_submission_id in (select occurrence_submission_id from occurrence_submissions)) + delete from spatial_transform_submission where submission_spatial_component_id in (select submission_spatial_component_id from submission_spatial_components); + delete from submission_spatial_component where occurrence_submission_id in (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id); + + with occurrence_submissions as (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id) + , submission_statuses as (select submission_status_id from submission_status + where occurrence_submission_id in (select occurrence_submission_id from occurrence_submissions)) + delete from submission_message where submission_status_id in (select submission_status_id from submission_statuses); + delete from submission_status where occurrence_submission_id in (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id); + + delete from occurrence_submission_publish where occurrence_submission_id in (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id); + + delete from occurrence_submission where survey_id = p_survey_id; + + delete from survey_summary_submission_publish where survey_summary_submission_id in (select survey_summary_submission_id from survey_summary_submission where survey_id = p_survey_id); + delete from survey_summary_submission_message where survey_summary_submission_id in (select survey_summary_submission_id from survey_summary_submission where survey_id = p_survey_id); + delete from survey_summary_submission where survey_id = p_survey_id; + delete from survey_proprietor where survey_id = p_survey_id; + delete from survey_attachment_publish where survey_attachment_id in (select survey_attachment_id from survey_attachment where survey_id = p_survey_id); + delete from survey_attachment where survey_id = p_survey_id; + delete from survey_report_author where survey_report_attachment_id in (select survey_report_attachment_id from survey_report_attachment where survey_id = p_survey_id); + delete from survey_report_publish where survey_report_attachment_id in (select survey_report_attachment_id from survey_report_attachment where survey_id = p_survey_id); + delete from survey_report_attachment where survey_id = p_survey_id; + delete from study_species where survey_id = p_survey_id; + delete from survey_funding_source where survey_id = p_survey_id; + delete from survey_vantage where survey_id = p_survey_id; + delete from survey_spatial_component where survey_id = p_survey_id; + delete from survey_metadata_publish where survey_id = p_survey_id; + delete from survey_region where survey_id = p_survey_id; + delete from survey_first_nation_partnership where survey_id = p_survey_id; + delete from survey_block where survey_id = p_survey_id; + delete from permit where survey_id = p_survey_id; + delete from survey_type where survey_id = p_survey_id; + delete from survey_stratum where survey_id = p_survey_id; + delete from survey_block where survey_id = p_survey_id; + delete from survey where survey_id = p_survey_id; + + exception + when others THEN + raise; + end; + $procedure$; + + + `); +} + +export async function down(knex: Knex): Promise { + await knex.raw(``); +} From dd37fb850eed819a4b0737838fda6b92b8cff98e Mon Sep 17 00:00:00 2001 From: Curtis Upshall Date: Wed, 30 Aug 2023 15:28:58 -0700 Subject: [PATCH 2/8] SIMSBIOHUB-262: Added additional survey site selection strategy tables --- ...230830123800_create_survey_block_tables.ts | 2 +- ...830143800_create_survey_site_strategies.ts | 148 ++++++++++++++++++ 2 files changed, 149 insertions(+), 1 deletion(-) create mode 100644 database/src/migrations/20230830143800_create_survey_site_strategies.ts diff --git a/database/src/migrations/20230830123800_create_survey_block_tables.ts b/database/src/migrations/20230830123800_create_survey_block_tables.ts index 38a01a36f6..e0da0dd538 100644 --- a/database/src/migrations/20230830123800_create_survey_block_tables.ts +++ b/database/src/migrations/20230830123800_create_survey_block_tables.ts @@ -17,7 +17,7 @@ export async function up(knex: Knex): Promise { SET search_path=biohub; CREATE TABLE survey_block( - survey_block_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + survey_block_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), survey_id integer NOT NULL, name varchar(300), description varchar(3000), diff --git a/database/src/migrations/20230830143800_create_survey_site_strategies.ts b/database/src/migrations/20230830143800_create_survey_site_strategies.ts new file mode 100644 index 0000000000..091d7941eb --- /dev/null +++ b/database/src/migrations/20230830143800_create_survey_site_strategies.ts @@ -0,0 +1,148 @@ +import { Knex } from 'knex'; + +/** + * Adds new survey partnerships tables + * + * @export + * @param {Knex} knex + * @return {*} {Promise} + */ +export async function up(knex: Knex): Promise { + await knex.raw(`--sql + + ---------------------------------------------------------------------------------------- + -- Create new site_strategy table + ---------------------------------------------------------------------------------------- + + SET search_path=biohub; + + CREATE TABLE site_strategy( + site_strategy_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + name varchar(50) NOT NULL, + record_effective_date date NOT NULL, + description varchar(250), + record_end_date date, + create_date timestamptz(6) DEFAULT now() NOT NULL, + create_user integer NOT NULL, + update_date timestamptz(6), + update_user integer, + revision_count integer DEFAULT 0 NOT NULL, + CONSTRAINT site_strategy_pk PRIMARY KEY (site_strategy_id) + ); + + + + COMMENT ON COLUMN site_strategy.site_strategy_id IS 'System generated surrogate primary key identifier.' + ; + COMMENT ON COLUMN site_strategy.name IS 'The name of the site selection strategy.' + ; + COMMENT ON COLUMN site_strategy.record_effective_date IS 'Record level effective date.' + ; + COMMENT ON COLUMN site_strategy.description IS 'The description of the site selection strategy.' + ; + COMMENT ON COLUMN site_strategy.record_end_date IS 'Record level end date.' + ; + COMMENT ON COLUMN site_strategy.create_date IS 'The datetime the record was created.' + ; + COMMENT ON COLUMN site_strategy.create_user IS 'The id of the user who created the record as identified in the system user table.' + ; + COMMENT ON COLUMN site_strategy.update_date IS 'The datetime the record was updated.' + ; + COMMENT ON COLUMN site_strategy.update_user IS 'The id of the user who updated the record as identified in the system user table.' + ; + COMMENT ON COLUMN site_strategy.revision_count IS 'Revision count used for concurrency control.' + ; + COMMENT ON TABLE site_strategy IS 'Broad classification for the site_strategy code of the survey.' + ; + + + ---------------------------------------------------------------------------------------- + -- Create new keys and indices + ---------------------------------------------------------------------------------------- + + -- Add unique constraint + CREATE UNIQUE INDEX site_strategy_uk1 ON site_strategy(name); + + -- Create audit and journal triggers + create trigger audit_observation before insert or update or delete on site_strategy for each row execute procedure tr_audit_trigger(); + create trigger journal_observation after insert or update or delete on site_strategy for each row execute procedure tr_journal_trigger(); + + + ---------------------------------------------------------------------------------------- + -- Insert seed values + ---------------------------------------------------------------------------------------- + + insert into site_strategy (name, record_effective_date) values ('Random', now()); + insert into site_strategy (name, record_effective_date) values ('Stratified', now()); + insert into site_strategy (name, record_effective_date) values ('Systematic', now()); + + ------------------------------------------------------------------------- + -- Create new survey_site_strategy table + ------------------------------------------------------------------------- + + SET SEARCH_PATH=biohub; + + CREATE TABLE survey_site_strategy( + survey_site_strategy_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + survey_id integer NOT NULL, + type_id integer NOT NULL, + create_date timestamptz(6) DEFAULT now() NOT NULL, + create_user integer NOT NULL, + update_date timestamptz(6), + update_user integer, + revision_count integer DEFAULT 0 NOT NULL, + CONSTRAINT survey_site_strategy_pk PRIMARY KEY (survey_site_strategy_id) + ); + + COMMENT ON COLUMN survey_site_strategy.survey_site_strategy_id IS 'System generated surrogate primary key identifier.'; + COMMENT ON COLUMN survey_site_strategy.survey_id IS 'A foreign key pointing to the survey table.'; + COMMENT ON COLUMN survey_site_strategy.type_id IS 'A foreign key pointing to the type table.'; + COMMENT ON COLUMN survey_site_strategy.create_date IS 'The datetime the record was created.'; + COMMENT ON COLUMN survey_site_strategy.create_user IS 'The id of the user who created the record as identified in the system user table.'; + COMMENT ON COLUMN survey_site_strategy.update_date IS 'The datetime the record was updated.'; + COMMENT ON COLUMN survey_site_strategy.update_user IS 'The id of the user who updated the record as identified in the system user table.'; + COMMENT ON COLUMN survey_site_strategy.revision_count IS 'Revision count used for concurrency control.'; + COMMENT ON TABLE survey_site_strategy IS 'Site selection strategy classification for the survey.'; + + ------------------------------------------------------------------------- + -- Add survey_site_strategy constraints and indexes + ------------------------------------------------------------------------- + + -- add foreign key constraints + ALTER TABLE survey_site_strategy ADD CONSTRAINT survey_site_strategy_fk1 + FOREIGN KEY (survey_id) + REFERENCES survey(survey_id); + + ALTER TABLE survey_site_strategy ADD CONSTRAINT survey_site_strategy_fk2 + FOREIGN KEY (type_id) + REFERENCES type(type_id); + + -- add indexes for foreign keys + CREATE INDEX survey_site_strategy_idx1 ON survey_site_strategy(survey_id); + CREATE INDEX survey_site_strategy_idx2 ON survey_site_strategy(type_id); + + -- add unique index + CREATE UNIQUE INDEX survey_site_strategy_uk1 ON survey_site_strategy(survey_id, type_id); + + ------------------------------------------------------------------------- + -- Create audit and journal triggers for survey_site_strategy table + ------------------------------------------------------------------------- + + CREATE TRIGGER audit_survey_site_strategy BEFORE INSERT OR UPDATE OR DELETE ON survey_site_strategy for each ROW EXECUTE PROCEDURE tr_audit_trigger(); + CREATE TRIGGER journal_survey_site_strategy AFTER INSERT OR UPDATE OR DELETE ON survey_site_strategy for each ROW EXECUTE PROCEDURE tr_journal_trigger(); + + ---------------------------------------------------------------------------------------- + -- Create views + ---------------------------------------------------------------------------------------- + + set search_path=biohub_dapi_v1; + + create or replace view site_strategy as select * from biohub.site_strategy; + create or replace view survey_site_strategy as select * from biohub.survey_site_strategy; + + `); +} + +export async function down(knex: Knex): Promise { + await knex.raw(``); +} From 6cb2467f7296fdd4f43800bb6237198190a3d5aa Mon Sep 17 00:00:00 2001 From: Curtis Upshall Date: Wed, 30 Aug 2023 15:30:04 -0700 Subject: [PATCH 3/8] SIMSBIOHUB-262: Remove outdated UI --- app/src/features/projects/view/ProjectDetails.tsx | 7 ------- 1 file changed, 7 deletions(-) diff --git a/app/src/features/projects/view/ProjectDetails.tsx b/app/src/features/projects/view/ProjectDetails.tsx index 13a66ad81b..735b793850 100644 --- a/app/src/features/projects/view/ProjectDetails.tsx +++ b/app/src/features/projects/view/ProjectDetails.tsx @@ -92,13 +92,6 @@ const ProjectDetails = () => { - - - Partnerships - - - - {/* TODO: (https://apps.nrs.gov.bc.ca/int/jira/browse/SIMSBIOHUB-162) Commenting out IUCN form (view) temporarily, while its decided if IUCN information is desired */} {/* From 2e5409111bcc1532926ec88bde38d942e5033300 Mon Sep 17 00:00:00 2001 From: Curtis Upshall Date: Wed, 30 Aug 2023 15:49:14 -0700 Subject: [PATCH 4/8] SIMSBIOHUB-262: Address PR feedback --- ...230830123800_create_survey_block_tables.ts | 96 +-------------- ...830143800_create_survey_site_strategies.ts | 114 ++++++++++++++++-- 2 files changed, 106 insertions(+), 104 deletions(-) diff --git a/database/src/migrations/20230830123800_create_survey_block_tables.ts b/database/src/migrations/20230830123800_create_survey_block_tables.ts index e0da0dd538..0c31ab626c 100644 --- a/database/src/migrations/20230830123800_create_survey_block_tables.ts +++ b/database/src/migrations/20230830123800_create_survey_block_tables.ts @@ -1,7 +1,7 @@ import { Knex } from 'knex'; /** - * Adds new survey partnerships tables + * Adds a new table for creating blocks, which are associated to surveys; * * @export * @param {Knex} knex @@ -79,100 +79,6 @@ export async function up(knex: Knex): Promise { set search_path=biohub_dapi_v1; create or replace view survey_block as select * from biohub.survey_block; - - - ---------------------------------------------------------------------------------------- - -- Update api_delete_survey procedure - ---------------------------------------------------------------------------------------- - - set search_path=biohub; - - CREATE OR REPLACE PROCEDURE api_delete_survey(p_survey_id integer) - LANGUAGE plpgsql - SECURITY DEFINER - AS $procedure$ - -- ******************************************************************* - -- Procedure: api_delete_survey - -- Purpose: deletes a survey and dependencies - -- - -- MODIFICATION HISTORY - -- Person Date Comments - -- ---------------- ----------- -------------------------------------- - -- shreyas.devalapurkar@quartech.com - -- 2021-06-18 initial release - -- charlie.garrettjones@quartech.com - -- 2021-06-21 added occurrence submission delete - -- charlie.garrettjones@quartech.com - -- 2021-09-21 added survey summary submission delete - -- kjartan.einarsson@quartech.com - -- 2022-08-28 added survey_vantage, survey_spatial_component, survey delete - -- charlie.garrettjones@quartech.com - -- 2022-09-07 changes to permit model - -- charlie.garrettjones@quartech.com - -- 2022-10-05 1.3.0 model changes - -- charlie.garrettjones@quartech.com - -- 2022-10-05 1.5.0 model changes, drop concept of occurrence deletion for published data - -- charlie.garrettjones@quartech.com - -- 2023-03-14 1.7.0 model changes - -- alfred.rosenthal@quartech.com - -- 2023-03-15 added missing publish tables to survey delete - -- curtis.upshall@quartech.com - -- 2023-04-28 change order of survey delete procedure - -- alfred.rosenthal@quartech.com - -- 2023-07-26 delete regions - -- curtis.upshall@quartech.com - -- 2023-08-24 delete partnerships - -- curtis.upshall@quartech.com - -- 2023-08-24 delete survey blocks and stratums - -- ******************************************************************* - declare - - begin - with occurrence_submissions as (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id), submission_spatial_components as (select submission_spatial_component_id from submission_spatial_component - where occurrence_submission_id in (select occurrence_submission_id from occurrence_submissions)) - delete from spatial_transform_submission where submission_spatial_component_id in (select submission_spatial_component_id from submission_spatial_components); - delete from submission_spatial_component where occurrence_submission_id in (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id); - - with occurrence_submissions as (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id) - , submission_statuses as (select submission_status_id from submission_status - where occurrence_submission_id in (select occurrence_submission_id from occurrence_submissions)) - delete from submission_message where submission_status_id in (select submission_status_id from submission_statuses); - delete from submission_status where occurrence_submission_id in (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id); - - delete from occurrence_submission_publish where occurrence_submission_id in (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id); - - delete from occurrence_submission where survey_id = p_survey_id; - - delete from survey_summary_submission_publish where survey_summary_submission_id in (select survey_summary_submission_id from survey_summary_submission where survey_id = p_survey_id); - delete from survey_summary_submission_message where survey_summary_submission_id in (select survey_summary_submission_id from survey_summary_submission where survey_id = p_survey_id); - delete from survey_summary_submission where survey_id = p_survey_id; - delete from survey_proprietor where survey_id = p_survey_id; - delete from survey_attachment_publish where survey_attachment_id in (select survey_attachment_id from survey_attachment where survey_id = p_survey_id); - delete from survey_attachment where survey_id = p_survey_id; - delete from survey_report_author where survey_report_attachment_id in (select survey_report_attachment_id from survey_report_attachment where survey_id = p_survey_id); - delete from survey_report_publish where survey_report_attachment_id in (select survey_report_attachment_id from survey_report_attachment where survey_id = p_survey_id); - delete from survey_report_attachment where survey_id = p_survey_id; - delete from study_species where survey_id = p_survey_id; - delete from survey_funding_source where survey_id = p_survey_id; - delete from survey_vantage where survey_id = p_survey_id; - delete from survey_spatial_component where survey_id = p_survey_id; - delete from survey_metadata_publish where survey_id = p_survey_id; - delete from survey_region where survey_id = p_survey_id; - delete from survey_first_nation_partnership where survey_id = p_survey_id; - delete from survey_block where survey_id = p_survey_id; - delete from permit where survey_id = p_survey_id; - delete from survey_type where survey_id = p_survey_id; - delete from survey_stratum where survey_id = p_survey_id; - delete from survey_block where survey_id = p_survey_id; - delete from survey where survey_id = p_survey_id; - - exception - when others THEN - raise; - end; - $procedure$; - - `); } diff --git a/database/src/migrations/20230830143800_create_survey_site_strategies.ts b/database/src/migrations/20230830143800_create_survey_site_strategies.ts index 091d7941eb..25f4dfc695 100644 --- a/database/src/migrations/20230830143800_create_survey_site_strategies.ts +++ b/database/src/migrations/20230830143800_create_survey_site_strategies.ts @@ -1,8 +1,10 @@ import { Knex } from 'knex'; /** - * Adds new survey partnerships tables - * + * 1. Adds two new tables: + * - Codes table for site selection strategy + * - Xref table for survey site selection strategies + * 2. Updates the survey delete procedure to account for blocks, stratums and survey site selection strategies * @export * @param {Knex} knex * @return {*} {Promise} @@ -19,8 +21,8 @@ export async function up(knex: Knex): Promise { CREATE TABLE site_strategy( site_strategy_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), name varchar(50) NOT NULL, - record_effective_date date NOT NULL, description varchar(250), + record_effective_date date NOT NULL, record_end_date date, create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, @@ -31,7 +33,6 @@ export async function up(knex: Knex): Promise { ); - COMMENT ON COLUMN site_strategy.site_strategy_id IS 'System generated surrogate primary key identifier.' ; COMMENT ON COLUMN site_strategy.name IS 'The name of the site selection strategy.' @@ -61,11 +62,11 @@ export async function up(knex: Knex): Promise { ---------------------------------------------------------------------------------------- -- Add unique constraint - CREATE UNIQUE INDEX site_strategy_uk1 ON site_strategy(name); + CREATE UNIQUE INDEX site_strategy_uk1 ON site_strategy(name, record_end_date); -- Create audit and journal triggers - create trigger audit_observation before insert or update or delete on site_strategy for each row execute procedure tr_audit_trigger(); - create trigger journal_observation after insert or update or delete on site_strategy for each row execute procedure tr_journal_trigger(); + create trigger audit_site_strategy before insert or update or delete on site_strategy for each row execute procedure tr_audit_trigger(); + create trigger journal_site_strategy after insert or update or delete on site_strategy for each row execute procedure tr_journal_trigger(); ---------------------------------------------------------------------------------------- @@ -85,7 +86,7 @@ export async function up(knex: Knex): Promise { CREATE TABLE survey_site_strategy( survey_site_strategy_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), survey_id integer NOT NULL, - type_id integer NOT NULL, + site_strategy_id integer NOT NULL, create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -132,7 +133,7 @@ export async function up(knex: Knex): Promise { CREATE TRIGGER journal_survey_site_strategy AFTER INSERT OR UPDATE OR DELETE ON survey_site_strategy for each ROW EXECUTE PROCEDURE tr_journal_trigger(); ---------------------------------------------------------------------------------------- - -- Create views + -- Create new views for both new tables ---------------------------------------------------------------------------------------- set search_path=biohub_dapi_v1; @@ -140,6 +141,101 @@ export async function up(knex: Knex): Promise { create or replace view site_strategy as select * from biohub.site_strategy; create or replace view survey_site_strategy as select * from biohub.survey_site_strategy; + ---------------------------------------------------------------------------------------- + -- Update api_delete_survey procedure + ---------------------------------------------------------------------------------------- + + set search_path=biohub; + + CREATE OR REPLACE PROCEDURE api_delete_survey(p_survey_id integer) + LANGUAGE plpgsql + SECURITY DEFINER + AS $procedure$ + -- ******************************************************************* + -- Procedure: api_delete_survey + -- Purpose: deletes a survey and dependencies + -- + -- MODIFICATION HISTORY + -- Person Date Comments + -- ---------------- ----------- -------------------------------------- + -- shreyas.devalapurkar@quartech.com + -- 2021-06-18 initial release + -- charlie.garrettjones@quartech.com + -- 2021-06-21 added occurrence submission delete + -- charlie.garrettjones@quartech.com + -- 2021-09-21 added survey summary submission delete + -- kjartan.einarsson@quartech.com + -- 2022-08-28 added survey_vantage, survey_spatial_component, survey delete + -- charlie.garrettjones@quartech.com + -- 2022-09-07 changes to permit model + -- charlie.garrettjones@quartech.com + -- 2022-10-05 1.3.0 model changes + -- charlie.garrettjones@quartech.com + -- 2022-10-05 1.5.0 model changes, drop concept of occurrence deletion for published data + -- charlie.garrettjones@quartech.com + -- 2023-03-14 1.7.0 model changes + -- alfred.rosenthal@quartech.com + -- 2023-03-15 added missing publish tables to survey delete + -- curtis.upshall@quartech.com + -- 2023-04-28 change order of survey delete procedure + -- alfred.rosenthal@quartech.com + -- 2023-07-26 delete regions + -- curtis.upshall@quartech.com + -- 2023-08-24 delete partnerships + -- curtis.upshall@quartech.com + -- 2023-08-24 delete survey blocks and stratums and participation + -- ******************************************************************* + declare + + begin + with occurrence_submissions as (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id), submission_spatial_components as (select submission_spatial_component_id from submission_spatial_component + where occurrence_submission_id in (select occurrence_submission_id from occurrence_submissions)) + delete from spatial_transform_submission where submission_spatial_component_id in (select submission_spatial_component_id from submission_spatial_components); + delete from submission_spatial_component where occurrence_submission_id in (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id); + + with occurrence_submissions as (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id) + , submission_statuses as (select submission_status_id from submission_status + where occurrence_submission_id in (select occurrence_submission_id from occurrence_submissions)) + delete from submission_message where submission_status_id in (select submission_status_id from submission_statuses); + delete from submission_status where occurrence_submission_id in (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id); + + delete from occurrence_submission_publish where occurrence_submission_id in (select occurrence_submission_id from occurrence_submission where survey_id = p_survey_id); + + delete from occurrence_submission where survey_id = p_survey_id; + + delete from survey_summary_submission_publish where survey_summary_submission_id in (select survey_summary_submission_id from survey_summary_submission where survey_id = p_survey_id); + delete from survey_summary_submission_message where survey_summary_submission_id in (select survey_summary_submission_id from survey_summary_submission where survey_id = p_survey_id); + delete from survey_summary_submission where survey_id = p_survey_id; + delete from survey_proprietor where survey_id = p_survey_id; + delete from survey_attachment_publish where survey_attachment_id in (select survey_attachment_id from survey_attachment where survey_id = p_survey_id); + delete from survey_attachment where survey_id = p_survey_id; + delete from survey_report_author where survey_report_attachment_id in (select survey_report_attachment_id from survey_report_attachment where survey_id = p_survey_id); + delete from survey_report_publish where survey_report_attachment_id in (select survey_report_attachment_id from survey_report_attachment where survey_id = p_survey_id); + delete from survey_report_attachment where survey_id = p_survey_id; + delete from study_species where survey_id = p_survey_id; + delete from survey_funding_source where survey_id = p_survey_id; + delete from survey_vantage where survey_id = p_survey_id; + delete from survey_spatial_component where survey_id = p_survey_id; + delete from survey_metadata_publish where survey_id = p_survey_id; + delete from survey_region where survey_id = p_survey_id; + delete from survey_first_nation_partnership where survey_id = p_survey_id; + delete from survey_block where survey_id = p_survey_id; + delete from permit where survey_id = p_survey_id; + delete from survey_type where survey_id = p_survey_id; + delete from survey_first_nation_partnership where survey_id = p_survey_id; + delete from survey_stakeholder_partnership where survey_id = p_survey_id; + delete from survey_participation where survey_id = p_survey_id; + delete from survey_stratum where survey_id = p_survey_id; + delete from survey_block where survey_id = p_survey_id; + delete from survey_site_strategy where survey_id = p_survey_id; + delete from survey where survey_id = p_survey_id; + + exception + when others THEN + raise; + end; + $procedure$; + `); } From 1689ed7ecf099e4dec60ef8b1f7156a1f62c1f9e Mon Sep 17 00:00:00 2001 From: Curtis Upshall Date: Wed, 30 Aug 2023 16:38:36 -0700 Subject: [PATCH 5/8] SIMSBIOHUB-262: Fix migration --- .../20230830143800_create_survey_site_strategies.ts | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/database/src/migrations/20230830143800_create_survey_site_strategies.ts b/database/src/migrations/20230830143800_create_survey_site_strategies.ts index 25f4dfc695..43195b7d21 100644 --- a/database/src/migrations/20230830143800_create_survey_site_strategies.ts +++ b/database/src/migrations/20230830143800_create_survey_site_strategies.ts @@ -97,7 +97,7 @@ export async function up(knex: Knex): Promise { COMMENT ON COLUMN survey_site_strategy.survey_site_strategy_id IS 'System generated surrogate primary key identifier.'; COMMENT ON COLUMN survey_site_strategy.survey_id IS 'A foreign key pointing to the survey table.'; - COMMENT ON COLUMN survey_site_strategy.type_id IS 'A foreign key pointing to the type table.'; + COMMENT ON COLUMN survey_site_strategy.site_strategy_id IS 'A foreign key pointing to the type table.'; COMMENT ON COLUMN survey_site_strategy.create_date IS 'The datetime the record was created.'; COMMENT ON COLUMN survey_site_strategy.create_user IS 'The id of the user who created the record as identified in the system user table.'; COMMENT ON COLUMN survey_site_strategy.update_date IS 'The datetime the record was updated.'; @@ -115,15 +115,15 @@ export async function up(knex: Knex): Promise { REFERENCES survey(survey_id); ALTER TABLE survey_site_strategy ADD CONSTRAINT survey_site_strategy_fk2 - FOREIGN KEY (type_id) - REFERENCES type(type_id); + FOREIGN KEY (site_strategy_id) + REFERENCES site_strategy(site_strategy_id); -- add indexes for foreign keys CREATE INDEX survey_site_strategy_idx1 ON survey_site_strategy(survey_id); - CREATE INDEX survey_site_strategy_idx2 ON survey_site_strategy(type_id); + CREATE INDEX survey_site_strategy_idx2 ON survey_site_strategy(site_strategy_id); -- add unique index - CREATE UNIQUE INDEX survey_site_strategy_uk1 ON survey_site_strategy(survey_id, type_id); + CREATE UNIQUE INDEX survey_site_strategy_uk1 ON survey_site_strategy(survey_id, site_strategy_id); ------------------------------------------------------------------------- -- Create audit and journal triggers for survey_site_strategy table From 6ee2afac124ac33249319271c8fdecf9a83fbb58 Mon Sep 17 00:00:00 2001 From: Curtis Upshall Date: Thu, 31 Aug 2023 08:08:20 -0700 Subject: [PATCH 6/8] SIMSBIOHUB-262: PR changes --- .../migrations/20230830123800_create_survey_block_tables.ts | 4 ++-- .../20230830143800_create_survey_site_strategies.ts | 2 +- 2 files changed, 3 insertions(+), 3 deletions(-) diff --git a/database/src/migrations/20230830123800_create_survey_block_tables.ts b/database/src/migrations/20230830123800_create_survey_block_tables.ts index 0c31ab626c..c3eaae67d5 100644 --- a/database/src/migrations/20230830123800_create_survey_block_tables.ts +++ b/database/src/migrations/20230830123800_create_survey_block_tables.ts @@ -68,8 +68,8 @@ export async function up(knex: Knex): Promise { CREATE UNIQUE INDEX survey_block_uk1 ON survey_block(name, survey_id); -- Create audit and journal triggers - create trigger audit_observation before insert or update or delete on survey_block for each row execute procedure tr_audit_trigger(); - create trigger journal_observation after insert or update or delete on survey_block for each row execute procedure tr_journal_trigger(); + create trigger audit_survey_block before insert or update or delete on survey_block for each row execute procedure tr_audit_trigger(); + create trigger journal_survey_block after insert or update or delete on survey_block for each row execute procedure tr_journal_trigger(); ---------------------------------------------------------------------------------------- diff --git a/database/src/migrations/20230830143800_create_survey_site_strategies.ts b/database/src/migrations/20230830143800_create_survey_site_strategies.ts index 43195b7d21..cfefada369 100644 --- a/database/src/migrations/20230830143800_create_survey_site_strategies.ts +++ b/database/src/migrations/20230830143800_create_survey_site_strategies.ts @@ -62,7 +62,7 @@ export async function up(knex: Knex): Promise { ---------------------------------------------------------------------------------------- -- Add unique constraint - CREATE UNIQUE INDEX site_strategy_uk1 ON site_strategy(name, record_end_date); + CREATE UNIQUE INDEX site_strategy_uk1 ON site_strategy(name, (record_end_date is NULL)) where record_end_date is null; -- Create audit and journal triggers create trigger audit_site_strategy before insert or update or delete on site_strategy for each row execute procedure tr_audit_trigger(); From fa828f4f2c9dc35305f54dcf63adb9247ed715b7 Mon Sep 17 00:00:00 2001 From: Alfred Rosenthal Date: Thu, 31 Aug 2023 09:47:41 -0700 Subject: [PATCH 7/8] ran make fix --- .../src/migrations/20230830123800_create_survey_block_tables.ts | 2 +- .../migrations/20230830143800_create_survey_site_strategies.ts | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/database/src/migrations/20230830123800_create_survey_block_tables.ts b/database/src/migrations/20230830123800_create_survey_block_tables.ts index c3eaae67d5..cec65bfb4d 100644 --- a/database/src/migrations/20230830123800_create_survey_block_tables.ts +++ b/database/src/migrations/20230830123800_create_survey_block_tables.ts @@ -1,7 +1,7 @@ import { Knex } from 'knex'; /** - * Adds a new table for creating blocks, which are associated to surveys; + * Adds a new table for creating blocks, which are associated to surveys; * * @export * @param {Knex} knex diff --git a/database/src/migrations/20230830143800_create_survey_site_strategies.ts b/database/src/migrations/20230830143800_create_survey_site_strategies.ts index cfefada369..ed452fae52 100644 --- a/database/src/migrations/20230830143800_create_survey_site_strategies.ts +++ b/database/src/migrations/20230830143800_create_survey_site_strategies.ts @@ -2,7 +2,7 @@ import { Knex } from 'knex'; /** * 1. Adds two new tables: - * - Codes table for site selection strategy + * - Codes table for site selection strategy * - Xref table for survey site selection strategies * 2. Updates the survey delete procedure to account for blocks, stratums and survey site selection strategies * @export From 0d97250d4a6fd8c2ab4d00de2a02bdeb876f182f Mon Sep 17 00:00:00 2001 From: Curtis Upshall Date: Thu, 31 Aug 2023 12:15:02 -0700 Subject: [PATCH 8/8] SIMSBIOHUB-262: Renamed unique key --- .../migrations/20230830143800_create_survey_site_strategies.ts | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/database/src/migrations/20230830143800_create_survey_site_strategies.ts b/database/src/migrations/20230830143800_create_survey_site_strategies.ts index ed452fae52..dc3f81bd93 100644 --- a/database/src/migrations/20230830143800_create_survey_site_strategies.ts +++ b/database/src/migrations/20230830143800_create_survey_site_strategies.ts @@ -62,7 +62,7 @@ export async function up(knex: Knex): Promise { ---------------------------------------------------------------------------------------- -- Add unique constraint - CREATE UNIQUE INDEX site_strategy_uk1 ON site_strategy(name, (record_end_date is NULL)) where record_end_date is null; + CREATE UNIQUE INDEX site_strategy_nuk1 ON site_strategy(name, (record_end_date is NULL)) where record_end_date is null; -- Create audit and journal triggers create trigger audit_site_strategy before insert or update or delete on site_strategy for each row execute procedure tr_audit_trigger();