From 93ee4a7921bdc0afb36d7ad6c1239a410932f647 Mon Sep 17 00:00:00 2001 From: charlie garrett-jones Date: Wed, 30 Jun 2021 13:50:42 -0700 Subject: [PATCH 1/6] BHBC-1173 - introduced survey_status view to encapsulate business rules for determining status of survey_status - incorporated survey status into occurrence submission, survey delete and project delete db api functions - chained occurrence submission, survey delete and project delete db api functions - introduced db api function api_user_is_administrator - introduced db api functions api_get_character_system_constant and api_get_numeric_system_constant - various data integrity checks --- .../20210225205948_biohub_release.ts | 26 ++-- .../20210618115350_delete_survey.ts | 55 ------- ...625115350_project_add_publish_timestamp.ts | 42 ------ .../src/migrations/release.0.18/indexes.sql | 16 -- .../release.0.18/secured_objects.sql | 84 ----------- .../api_delete_occurrence_submission.sql | 45 ++++++ .../api_delete_project.sql | 9 +- .../release.0.19/api_delete_survey.sql | 37 +++++ .../api_get_context_system_user_role_id.sql | 0 .../api_get_context_user_id.sql | 0 .../release.0.19/api_get_system_constant.sql | 58 ++++++++ .../api_set_context.sql | 0 .../api_user_is_administrator.sql | 38 +++++ .../{release.0.18 => release.0.19}/biohub.sql | 138 +----------------- .../create_spatial_extensions.psql | 0 .../release.0.19/dapi_custom_views.sql | 3 + .../db_setup_up.sql | 17 +-- .../populate_activity.sql | 0 ...te_administrative_activity_status_type.sql | 0 .../populate_administrative_activity_type.sql | 0 .../populate_climate_change_initiatives.sql | 0 .../populate_first_nations.sql | 0 .../populate_funding_source.sql | 0 .../populate_investment_action_category.sql | 0 .../populate_iucn_classifications.sql | 0 .../populate_management_action_type.sql | 0 .../populate_project_role.sql | 0 .../populate_project_type.sql | 0 .../populate_proprietor_type.sql | 0 .../populate_submission_message_type.sql | 0 .../populate_submission_status_type.sql | 0 .../populate_system_constants.sql | 7 + .../populate_system_role.sql | 0 .../populate_user_identity_source.sql | 0 .../populate_wldtaxonomic_units.sql | 0 .../project_audit_triggers.sql | 17 +-- .../project_dapi_views.sql | 2 - .../project_journal_triggers.sql | 16 +- .../smoketest_release.sql | 25 +++- .../tr_audit_trigger.sql | 0 .../tr_journal_trigger.sql | 0 .../tr_permit.sql | 0 .../tr_project.sql | 0 .../tr_project_funding_source.sql | 0 .../tr_survey.sql | 24 ++- .../tr_survey_proprietor.sql | 0 46 files changed, 278 insertions(+), 381 deletions(-) delete mode 100644 database/src/migrations/20210618115350_delete_survey.ts delete mode 100644 database/src/migrations/20210625115350_project_add_publish_timestamp.ts delete mode 100644 database/src/migrations/release.0.18/indexes.sql delete mode 100644 database/src/migrations/release.0.18/secured_objects.sql create mode 100644 database/src/migrations/release.0.19/api_delete_occurrence_submission.sql rename database/src/migrations/{release.0.18 => release.0.19}/api_delete_project.sql (89%) create mode 100644 database/src/migrations/release.0.19/api_delete_survey.sql rename database/src/migrations/{release.0.18 => release.0.19}/api_get_context_system_user_role_id.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/api_get_context_user_id.sql (100%) create mode 100644 database/src/migrations/release.0.19/api_get_system_constant.sql rename database/src/migrations/{release.0.18 => release.0.19}/api_set_context.sql (100%) create mode 100644 database/src/migrations/release.0.19/api_user_is_administrator.sql rename database/src/migrations/{release.0.18 => release.0.19}/biohub.sql (95%) rename database/src/migrations/{release.0.18 => release.0.19}/create_spatial_extensions.psql (100%) create mode 100644 database/src/migrations/release.0.19/dapi_custom_views.sql rename database/src/migrations/{release.0.18 => release.0.19}/db_setup_up.sql (89%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_activity.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_administrative_activity_status_type.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_administrative_activity_type.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_climate_change_initiatives.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_first_nations.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_funding_source.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_investment_action_category.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_iucn_classifications.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_management_action_type.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_project_role.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_project_type.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_proprietor_type.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_submission_message_type.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_submission_status_type.sql (100%) create mode 100644 database/src/migrations/release.0.19/populate_system_constants.sql rename database/src/migrations/{release.0.18 => release.0.19}/populate_system_role.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_user_identity_source.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/populate_wldtaxonomic_units.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/project_audit_triggers.sql (93%) rename database/src/migrations/{release.0.18 => release.0.19}/project_dapi_views.sql (95%) rename database/src/migrations/{release.0.18 => release.0.19}/project_journal_triggers.sql (95%) rename database/src/migrations/{release.0.18 => release.0.19}/smoketest_release.sql (90%) rename database/src/migrations/{release.0.18 => release.0.19}/tr_audit_trigger.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/tr_journal_trigger.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/tr_permit.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/tr_project.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/tr_project_funding_source.sql (100%) rename database/src/migrations/{release.0.18 => release.0.19}/tr_survey.sql (52%) rename database/src/migrations/{release.0.18 => release.0.19}/tr_survey_proprietor.sql (100%) diff --git a/database/src/migrations/20210225205948_biohub_release.ts b/database/src/migrations/20210225205948_biohub_release.ts index 538c75bbd6..a1ab31c230 100644 --- a/database/src/migrations/20210225205948_biohub_release.ts +++ b/database/src/migrations/20210225205948_biohub_release.ts @@ -29,6 +29,7 @@ export async function up(knex: Knex): Promise { const api_get_context_system_user_role_id = fs.readFileSync( path.join(__dirname, DB_RELEASE, 'api_get_context_system_user_role_id.sql') ); + const api_user_is_administrator = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_user_is_administrator.sql')); const tr_journal_trigger = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'tr_journal_trigger.sql')); const project_journal_triggers = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'project_journal_triggers.sql')); const tr_project_funding_source = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'tr_project_funding_source.sql')); @@ -36,9 +37,16 @@ export async function up(knex: Knex): Promise { const tr_project = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'tr_project.sql')); const tr_survey = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'tr_survey.sql')); const tr_permit = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'tr_permit.sql')); + const api_get_system_constant = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_get_system_constant.sql')); + const vw_survey_status = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'vw_survey_status.sql')); + const api_delete_occurrence_submission = fs.readFileSync( + path.join(__dirname, DB_RELEASE, 'api_delete_occurrence_submission.sql') + ); + const api_delete_survey = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_delete_survey.sql')); const api_delete_project = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_delete_project.sql')); + const populate_system_constants = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'populate_system_constants.sql')); const populate_first_nations = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'populate_first_nations.sql')); const populate_climate_change_initiatives = fs.readFileSync( path.join(__dirname, DB_RELEASE, 'populate_climate_change_initiatives.sql') @@ -72,15 +80,12 @@ export async function up(knex: Knex): Promise { path.join(__dirname, DB_RELEASE, 'populate_submission_message_type.sql') ); - const secured_objects = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'secured_objects.sql')); - - const indexes = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'indexes.sql')); - const populate_wldtaxonomic_units = fs.readFileSync( path.join(__dirname, DB_RELEASE, 'populate_wldtaxonomic_units.sql') ); const project_dapi_views = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'project_dapi_views.sql')); + const dapi_custom_views = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'dapi_custom_views.sql')); await knex.raw(` -- set up spatial extensions @@ -117,6 +122,7 @@ export async function up(knex: Knex): Promise { ${project_audit_triggers} ${api_get_context_user_id} ${api_get_context_system_user_role_id} + ${api_user_is_administrator} ${tr_journal_trigger} ${project_journal_triggers} ${tr_project_funding_source} @@ -124,11 +130,16 @@ export async function up(knex: Knex): Promise { ${tr_project} ${tr_survey} ${tr_permit} + ${api_get_system_constant} + ${vw_survey_status} + ${api_delete_occurrence_submission} + ${api_delete_survey} ${api_delete_project} -- populate look up tables set search_path = biohub; + ${populate_system_constants} ${populate_first_nations} ${populate_climate_change_initiatives} ${populate_management_action_type} @@ -145,10 +156,6 @@ export async function up(knex: Knex): Promise { ${populate_submission_status_type} ${populate_submission_message_type} - ${secured_objects} - - ${indexes} - -- temporary external interface tables ${populate_wldtaxonomic_units} @@ -156,8 +163,9 @@ export async function up(knex: Knex): Promise { set search_path = biohub_dapi_v1; set role biohub_api; ${project_dapi_views} + ${dapi_custom_views} + set role postgres; - set search_path = biohub; grant execute on function biohub.api_set_context(_system_user_identifier system_user.user_identifier%type, _user_identity_source_name user_identity_source.name%type) to ${DB_USER_API}; `); diff --git a/database/src/migrations/20210618115350_delete_survey.ts b/database/src/migrations/20210618115350_delete_survey.ts deleted file mode 100644 index 88f40b890e..0000000000 --- a/database/src/migrations/20210618115350_delete_survey.ts +++ /dev/null @@ -1,55 +0,0 @@ -import Knex from 'knex'; - -const DB_SCHEMA = process.env.DB_SCHEMA; - -export async function up(knex: Knex): Promise { - await knex.raw(` - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - - drop procedure if exists api_delete_survey; - - create or replace procedure api_delete_survey(__survey_id survey.id%type) - language plpgsql - security definer - as - $$ - -- ******************************************************************* - -- Procedure: api_delete_survey - -- Purpose: deletes a survey and dependencies - -- - -- MODIFICATION HISTORY - -- Person Date Comments - -- ---------------- ----------- -------------------------------------- - -- shreyas.devalapurkar@quartech.com - -- 2021-06-18 initial release - -- ******************************************************************* - begin - delete from survey_proprietor where s_id = __survey_id; - delete from survey_attachment where s_id = __survey_id; - delete from study_species where s_id = __survey_id; - delete from block_observation where s_id = __survey_id; - delete from survey where id = __survey_id; - exception - when others THEN - raise; - end; - $$; - `); -} - -/** - * Drop the `api_delete_survey` procedure. - * - * @export - * @param {Knex} knex - * @return {*} {Promise} - */ -export async function down(knex: Knex): Promise { - await knex.raw(` - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - - drop procedure if exists api_delete_survey; - `); -} diff --git a/database/src/migrations/20210625115350_project_add_publish_timestamp.ts b/database/src/migrations/20210625115350_project_add_publish_timestamp.ts deleted file mode 100644 index 3fcdd7bc50..0000000000 --- a/database/src/migrations/20210625115350_project_add_publish_timestamp.ts +++ /dev/null @@ -1,42 +0,0 @@ -import Knex from 'knex'; - -const DB_SCHEMA = process.env.DB_SCHEMA; - -/** - * Add the publish_timestamp. - * - * @export - * @param {Knex} knex - * @return {*} {Promise} - */ - -export async function up(knex: Knex): Promise { - await knex.raw(` - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - - ALTER TABLE project ADD COLUMN publish_timestamp timestamptz(6); - - set search_path = biohub_dapi_v1; - set role biohub_api; - - create or replace view project as select * from biohub.project; - - set role postgres; - `); -} - -export async function down(knex: Knex): Promise { - await knex.raw(` - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - - SET ROLE biohub_api; - - DROP VIEW IF EXISTS biohub_dapi_v1.project; - - SET ROLE postgres; - - ALTER TABLE project DROP COLUMN publish_timestamp; - `); -} diff --git a/database/src/migrations/release.0.18/indexes.sql b/database/src/migrations/release.0.18/indexes.sql deleted file mode 100644 index b0222bc915..0000000000 --- a/database/src/migrations/release.0.18/indexes.sql +++ /dev/null @@ -1,16 +0,0 @@ --- indexes.sql - -CREATE INDEX sec_token_idx - ON security USING btree - (security_token ASC NULLS LAST) - TABLESPACE pg_default; - -CREATE INDEX sec_table_secr_id_idx - ON security USING btree - (secr_id ASC NULLS LAST) - TABLESPACE pg_default; - -CREATE INDEX sec_table_su_id_idx - ON security USING btree - (su_id ASC NULLS LAST) - TABLESPACE pg_default; diff --git a/database/src/migrations/release.0.18/secured_objects.sql b/database/src/migrations/release.0.18/secured_objects.sql deleted file mode 100644 index cec7b408de..0000000000 --- a/database/src/migrations/release.0.18/secured_objects.sql +++ /dev/null @@ -1,84 +0,0 @@ --- secured_objects.sql -ALTER TABLE biohub.project ENABLE ROW LEVEL SECURITY; -CREATE POLICY only_admin - ON biohub.project - AS PERMISSIVE - FOR ALL - TO biohub_api - USING (biohub.api_get_context_system_user_role_id() = 1); -CREATE POLICY public - ON biohub.project - AS PERMISSIVE - FOR ALL - TO biohub_api - USING (security_token is NULL); - -ALTER TABLE biohub.project_attachment ENABLE ROW LEVEL SECURITY; -CREATE POLICY only_admin - ON biohub.project_attachment - AS PERMISSIVE - FOR ALL - TO biohub_api - USING (biohub.api_get_context_system_user_role_id() = 1); -CREATE POLICY public - ON biohub.project_attachment - AS PERMISSIVE - FOR ALL - TO biohub_api - USING (security_token is NULL); - -ALTER TABLE biohub.survey ENABLE ROW LEVEL SECURITY; -CREATE POLICY only_admin - ON biohub.survey - AS PERMISSIVE - FOR ALL - TO biohub_api - USING (biohub.api_get_context_system_user_role_id() = 1); -CREATE POLICY public - ON biohub.survey - AS PERMISSIVE - FOR ALL - TO biohub_api - USING (security_token is NULL); - -ALTER TABLE biohub.survey_attachment ENABLE ROW LEVEL SECURITY; -CREATE POLICY only_admin - ON biohub.survey_attachment - AS PERMISSIVE - FOR ALL - TO biohub_api - USING (biohub.api_get_context_system_user_role_id() = 1); -CREATE POLICY public - ON biohub.survey_attachment - AS PERMISSIVE - FOR ALL - TO biohub_api - USING (security_token is NULL); - -ALTER TABLE biohub.occurrence ENABLE ROW LEVEL SECURITY; -CREATE POLICY only_admin - ON biohub.occurrence - AS PERMISSIVE - FOR ALL - TO biohub_api - USING (biohub.api_get_context_system_user_role_id() = 1); -CREATE POLICY public - ON biohub.occurrence - AS PERMISSIVE - FOR ALL - TO biohub_api - USING (security_token is NULL); - ---ALTER TABLE biohub.webform_draft ENABLE ROW LEVEL SECURITY; ---CREATE POLICY only_owner --- ON biohub.webform_draft --- AS PERMISSIVE --- FOR ALL --- TO biohub_api --- USING (su_id = biohub.api_get_context_user_id()); ---CREATE POLICY only_admin --- ON biohub.webform_draft --- AS PERMISSIVE --- FOR ALL --- TO biohub_api --- USING (biohub.api_get_context_system_user_role_id() = 1); diff --git a/database/src/migrations/release.0.19/api_delete_occurrence_submission.sql b/database/src/migrations/release.0.19/api_delete_occurrence_submission.sql new file mode 100644 index 0000000000..43c0582a7e --- /dev/null +++ b/database/src/migrations/release.0.19/api_delete_occurrence_submission.sql @@ -0,0 +1,45 @@ +-- api_delete_occurrence_submission.sql +drop procedure if exists api_delete_occurrence_submission; + +create or replace procedure api_delete_occurrence_submission(__occurrence_submission_id occurrence_submission.id%type) +language plpgsql +security definer +as +$$ +-- ******************************************************************* +-- Procedure: api_delete_occurrence_submission +-- Purpose: deletes an occurrence submission +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-06-18 initial release +-- ******************************************************************* +declare + __is_published boolean; + __is_system_administrator boolean; +begin + select exists into __is_published (select 1 from survey_status ss, occurrence_submission os + where os.id = __occurrence_submission_id + and ss.survey_id = os.s_id + and ss.survey_status = (select api_get_character_system_constant('SURVEY_STATE_PUBLISHED'))); + + if __is_published then + select api_user_is_administrator() into __is_system_administrator; + + if not __is_system_administrator then + raise exception 'Delete cannot proceed as published occurrence submissions exist and user is not a member of the system administrator role.'; + end if; + end if; + + delete from submission_message where subs_id in (select id from submission_status where os_id = __occurrence_submission_id); + delete from submission_status where os_id = __occurrence_submission_id; + delete from occurrence where os_id = __occurrence_submission_id; + delete from occurrence_submission where id = __occurrence_submission_id; + +exception + when others THEN + raise; +end; +$$; \ No newline at end of file diff --git a/database/src/migrations/release.0.18/api_delete_project.sql b/database/src/migrations/release.0.19/api_delete_project.sql similarity index 89% rename from database/src/migrations/release.0.18/api_delete_project.sql rename to database/src/migrations/release.0.19/api_delete_project.sql index 23bb99e998..f98cbca547 100644 --- a/database/src/migrations/release.0.18/api_delete_project.sql +++ b/database/src/migrations/release.0.19/api_delete_project.sql @@ -15,12 +15,18 @@ $$ -- ---------------- ----------- -------------------------------------- -- charlie.garrettjones@quartech.com -- 2021-04-19 initial release +-- 2021-06-21 added delete survey -- ******************************************************************* +declare + v_id survey.id%type; begin + for v_id in (select id from survey where p_id = __project_id) loop + call api_delete_survey(v_id); + end loop; + delete from survey_proprietor where s_id in (select id from survey where p_id = __project_id); delete from survey_attachment where s_id in (select id from survey where p_id = __project_id); delete from study_species where s_id in (select id from survey where p_id = __project_id); - delete from block_observation where s_id in (select id from survey where p_id = __project_id); delete from permit where p_id = __project_id; delete from survey where p_id = __project_id; delete from stakeholder_partnership where p_id = __project_id; @@ -34,6 +40,7 @@ begin delete from project_first_nation where p_id = __project_id; delete from project_participation where p_id = __project_id; delete from project where id = __project_id; + exception when others THEN raise; diff --git a/database/src/migrations/release.0.19/api_delete_survey.sql b/database/src/migrations/release.0.19/api_delete_survey.sql new file mode 100644 index 0000000000..a69b1ecda6 --- /dev/null +++ b/database/src/migrations/release.0.19/api_delete_survey.sql @@ -0,0 +1,37 @@ +-- api_delete_survey.sql +drop procedure if exists api_delete_survey; + +create or replace procedure api_delete_survey(__survey_id survey.id%type) +language plpgsql +security definer +as +$$ +-- ******************************************************************* +-- 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 +-- ******************************************************************* +declare + v_id occurrence_submission.id%type; +begin + for v_id in (select id from occurrence_submission where s_id = __survey_id) loop + call api_delete_occurrence_submission(v_id); + end loop; + + delete from survey_proprietor where s_id = __survey_id; + delete from survey_attachment where s_id = __survey_id; + delete from study_species where s_id = __survey_id; + delete from survey_funding_source where s_id = __survey_id; + +exception + when others THEN + raise; +end; +$$; \ No newline at end of file diff --git a/database/src/migrations/release.0.18/api_get_context_system_user_role_id.sql b/database/src/migrations/release.0.19/api_get_context_system_user_role_id.sql similarity index 100% rename from database/src/migrations/release.0.18/api_get_context_system_user_role_id.sql rename to database/src/migrations/release.0.19/api_get_context_system_user_role_id.sql diff --git a/database/src/migrations/release.0.18/api_get_context_user_id.sql b/database/src/migrations/release.0.19/api_get_context_user_id.sql similarity index 100% rename from database/src/migrations/release.0.18/api_get_context_user_id.sql rename to database/src/migrations/release.0.19/api_get_context_user_id.sql diff --git a/database/src/migrations/release.0.19/api_get_system_constant.sql b/database/src/migrations/release.0.19/api_get_system_constant.sql new file mode 100644 index 0000000000..395dcbcdf1 --- /dev/null +++ b/database/src/migrations/release.0.19/api_get_system_constant.sql @@ -0,0 +1,58 @@ +-- api_get_system_constant.sql +drop function if exists api_get_character_system_constant; + +create or replace function api_get_character_system_constant(__constant_name system_constant.constant_name%type) returns system_constant.character_value%type +language plpgsql +security definer +stable +as +$$ +-- ******************************************************************* +-- Procedure: api_get_character_system_constant +-- Purpose: returns a text value from the system constants table +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-06-29 initial release +-- ******************************************************************* +begin + return (select character_value from system_constant where constant_name = __constant_name); + +exception + when others then + raise; +end; +$$; + +grant execute on function api_get_character_system_constant to biohub_api; + +drop function if exists api_get_numeric_system_constant; + +create or replace function api_get_numeric_system_constant(__constant_name system_constant.constant_name%type) returns system_constant.numeric_value%type +language plpgsql +security definer +stable +as +$$ +-- ******************************************************************* +-- Procedure: api_get_numeric_system_constant +-- Purpose: returns a numeric value from the system constants table +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-06-29 initial release +-- ******************************************************************* +begin + return (select numeric_value from system_constant where constant_name = __constant_name); + +exception + when others then + raise; +end; +$$; + +grant execute on function api_get_numeric_system_constant to biohub_api; diff --git a/database/src/migrations/release.0.18/api_set_context.sql b/database/src/migrations/release.0.19/api_set_context.sql similarity index 100% rename from database/src/migrations/release.0.18/api_set_context.sql rename to database/src/migrations/release.0.19/api_set_context.sql diff --git a/database/src/migrations/release.0.19/api_user_is_administrator.sql b/database/src/migrations/release.0.19/api_user_is_administrator.sql new file mode 100644 index 0000000000..d804f16bfe --- /dev/null +++ b/database/src/migrations/release.0.19/api_user_is_administrator.sql @@ -0,0 +1,38 @@ +-- api_user_is_administrator.sql +drop function if exists api_user_is_administrator; + +create or replace function api_user_is_administrator(__system_user_id system_user.id%type default null) returns boolean +language plpgsql +security definer +as +$$ +-- ******************************************************************* +-- Procedure: api_user_is_administrator +-- Purpose: returns true if user is a system administrator and false otherwise +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-06-21 initial release +-- ******************************************************************* +declare + __id system_user.id%type; +begin + if (__system_user_id is null) then + select api_get_context_user_id() into __id; + else + __id = __system_user_id; + end if; + + return (select exists (select 1 from system_user_role sur, system_role sr + where sur.su_id = __id + and sur.sr_id = sr.id + and sr.name = (select api_get_character_system_constant('SYSTEM_ROLES_SYSTEM_ADMINISTRATOR')) + and sr.record_end_date is null)); + +exception + when others THEN + raise; +end; +$$; diff --git a/database/src/migrations/release.0.18/biohub.sql b/database/src/migrations/release.0.19/biohub.sql similarity index 95% rename from database/src/migrations/release.0.18/biohub.sql rename to database/src/migrations/release.0.19/biohub.sql index 6c20afee22..4194d6ff70 100644 --- a/database/src/migrations/release.0.18/biohub.sql +++ b/database/src/migrations/release.0.19/biohub.sql @@ -2,7 +2,7 @@ -- ER/Studio Data Architect SQL Code Generation -- Project : BioHub.DM1 -- --- Date Created : Friday, June 18, 2021 14:30:41 +-- Date Created : Wednesday, June 30, 2021 11:27:02 -- Target DBMS : PostgreSQL 10.x-12.x -- @@ -609,7 +609,6 @@ CREATE TABLE occurrence( data json, geometry geometry(geometry, 3005), geography geography(geometry), - security_token uuid, create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -645,8 +644,6 @@ COMMENT ON COLUMN occurrence.geometry IS 'The containing geometry of the record. ; COMMENT ON COLUMN occurrence.geography IS 'The containing geography of the record.' ; -COMMENT ON COLUMN occurrence.security_token IS 'The token indicates that this is a non-public row and it will trigger activation of the security rules defined for this row.' -; COMMENT ON COLUMN occurrence.create_date IS 'The datetime the record was created.' ; COMMENT ON COLUMN occurrence.create_user IS 'The id of the user who created the record as identified in the system user table.' @@ -795,9 +792,9 @@ CREATE TABLE project( coordinator_email_address varchar(500) NOT NULL, coordinator_agency_name varchar(300) NOT NULL, coordinator_public boolean NOT NULL, + publish_timestamp TIMESTAMPTZ, geometry geometry(geometry, 3005), geography geography(geometry), - security_token uuid, create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -839,12 +836,12 @@ COMMENT ON COLUMN project.coordinator_agency_name IS 'Name of agency the project ; COMMENT ON COLUMN project.coordinator_public IS 'A flag that determines whether personal coordinator details are public. A value of "Y" provides that personal details are public.' ; +COMMENT ON COLUMN project.publish_timestamp IS 'A timestamp that indicates that the project metadata has been approved for discovery. If the timestamp is not null then project metadata is public. If the timestamp is null the project metadata is not yet public.' +; COMMENT ON COLUMN project.geometry IS 'The containing geometry of the record.' ; COMMENT ON COLUMN project.geography IS 'The containing geography of the record.' ; -COMMENT ON COLUMN project.security_token IS 'The token indicates that this is a non-public row and it will trigger activation of the security rules defined for this row.' -; COMMENT ON COLUMN project.create_date IS 'The datetime the record was created.' ; COMMENT ON COLUMN project.create_user IS 'The id of the user who created the record as identified in the system user table.' @@ -1368,88 +1365,6 @@ COMMENT ON COLUMN proprietor_type.revision_count IS 'Revision count used for con COMMENT ON TABLE proprietor_type IS 'Identifies the available reasons that subject data can be proprietary.' ; --- --- TABLE: security --- - -CREATE TABLE security( - id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - su_id integer NOT NULL, - secr_id integer NOT NULL, - security_token uuid 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 "PK176" PRIMARY KEY (id) -) -; - - - -COMMENT ON COLUMN security.id IS 'System generated surrogate primary key identifier.' -; -COMMENT ON COLUMN security.su_id IS 'System generated surrogate primary key identifier.' -; -COMMENT ON COLUMN security.secr_id IS 'System generated surrogate primary key identifier.' -; -COMMENT ON COLUMN security.security_token IS 'The token indicates that this is a non-public row and it will trigger activation of the security rules defined for this row.' -; -COMMENT ON COLUMN security.create_date IS 'The datetime the record was created.' -; -COMMENT ON COLUMN security.create_user IS 'The id of the user who created the record as identified in the system user table.' -; -COMMENT ON COLUMN security.update_date IS 'The datetime the record was updated.' -; -COMMENT ON COLUMN security.update_user IS 'The id of the user who updated the record as identified in the system user table.' -; -COMMENT ON COLUMN security.revision_count IS 'Revision count used for concurrency control.' -; -COMMENT ON TABLE security IS 'This is the security working table. This table does not need, journaling or audit trail as it is generated from the security rules. The tables contains references to the security rule, the security token of the secured object and the optional user id for when the rule applies to a specific user;' -; - --- --- TABLE: security_rule --- - -CREATE TABLE security_rule( - id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - name varchar(300), - rule_definition varchar(10000) NOT NULL, - target varchar(200) 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 "PK177" PRIMARY KEY (id) -) -; - - - -COMMENT ON COLUMN security_rule.id IS 'System generated surrogate primary key identifier.' -; -COMMENT ON COLUMN security_rule.name IS 'The name of the record.' -; -COMMENT ON COLUMN security_rule.rule_definition IS 'The definition of the rule suitable for application in code to apply the security rule.' -; -COMMENT ON COLUMN security_rule.target IS 'The target table that the rule applies to.' -; -COMMENT ON COLUMN security_rule.create_date IS 'The datetime the record was created.' -; -COMMENT ON COLUMN security_rule.create_user IS 'The id of the user who created the record as identified in the system user table.' -; -COMMENT ON COLUMN security_rule.update_date IS 'The datetime the record was updated.' -; -COMMENT ON COLUMN security_rule.update_user IS 'The id of the user who updated the record as identified in the system user table.' -; -COMMENT ON COLUMN security_rule.revision_count IS 'Revision count used for concurrency control.' -; -COMMENT ON TABLE security_rule IS 'Security subsystem table to persist security rules.' -; - -- -- TABLE: stakeholder_partnership -- @@ -1719,7 +1634,6 @@ CREATE TABLE survey( location_name varchar(300) NOT NULL, geometry geometry(geometry, 3005), geography geography(geometry), - security_token uuid, create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -1756,8 +1670,6 @@ COMMENT ON COLUMN survey.geometry IS 'The containing geometry of the record.' ; COMMENT ON COLUMN survey.geography IS 'The containing geography of the record.' ; -COMMENT ON COLUMN survey.security_token IS 'The token indicates that this is a non-public row and it will trigger activation of the security rules defined for this row.' -; COMMENT ON COLUMN survey.create_date IS 'The datetime the record was created.' ; COMMENT ON COLUMN survey.create_user IS 'The id of the user who created the record as identified in the system user table.' @@ -2200,11 +2112,6 @@ CREATE TABLE wldtaxonomic_units( end_date date, note varchar(2000), element_subnational_id numeric(10, 0), - 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 "PK160" PRIMARY KEY (id) ) ; @@ -2249,16 +2156,6 @@ COMMENT ON COLUMN wldtaxonomic_units.note IS 'Free form text about the taxon.' ; COMMENT ON COLUMN wldtaxonomic_units.element_subnational_id IS 'Identifier that can be used to link this record to the matching Biotics field.' ; -COMMENT ON COLUMN wldtaxonomic_units.create_date IS 'The datetime the record was created.' -; -COMMENT ON COLUMN wldtaxonomic_units.create_user IS 'The id of the user who created the record as identified in the system user table.' -; -COMMENT ON COLUMN wldtaxonomic_units.update_date IS 'The datetime the record was updated.' -; -COMMENT ON COLUMN wldtaxonomic_units.update_user IS 'The id of the user who updated the record as identified in the system user table.' -; -COMMENT ON COLUMN wldtaxonomic_units.revision_count IS 'Revision count used for concurrency control.' -; COMMENT ON TABLE wldtaxonomic_units IS 'A table to mimic a view into SPI taxonomic data, specifically CWI_TXN.WLDTAXONOMIC_UNITS, for development purposes. This table should be replaced by live views of the data in production systems.' ; @@ -2581,18 +2478,6 @@ CREATE UNIQUE INDEX pt_nuk1 ON project_type(name, (record_end_date is NULL)) whe CREATE UNIQUE INDEX prt_nuk1 ON proprietor_type(name, (record_end_date is NULL)) where record_end_date is null ; -- --- INDEX: "Ref78100" --- - -CREATE INDEX "Ref78100" ON security(su_id) -; --- --- INDEX: "Ref177102" --- - -CREATE INDEX "Ref177102" ON security(secr_id) -; --- -- INDEX: sp_uk1 -- @@ -2990,21 +2875,6 @@ ALTER TABLE project_region ADD CONSTRAINT "Refproject24" ; --- --- TABLE: security --- - -ALTER TABLE security ADD CONSTRAINT "Refsystem_user100" - FOREIGN KEY (su_id) - REFERENCES system_user(id) -; - -ALTER TABLE security ADD CONSTRAINT "Refsecurity_rule102" - FOREIGN KEY (secr_id) - REFERENCES security_rule(id) -; - - -- -- TABLE: stakeholder_partnership -- diff --git a/database/src/migrations/release.0.18/create_spatial_extensions.psql b/database/src/migrations/release.0.19/create_spatial_extensions.psql similarity index 100% rename from database/src/migrations/release.0.18/create_spatial_extensions.psql rename to database/src/migrations/release.0.19/create_spatial_extensions.psql diff --git a/database/src/migrations/release.0.19/dapi_custom_views.sql b/database/src/migrations/release.0.19/dapi_custom_views.sql new file mode 100644 index 0000000000..ee00427ef7 --- /dev/null +++ b/database/src/migrations/release.0.19/dapi_custom_views.sql @@ -0,0 +1,3 @@ +-- dapi_custom_views.sql + + create or replace view survey_status as select * from biohub.survey_status; \ No newline at end of file diff --git a/database/src/migrations/release.0.18/db_setup_up.sql b/database/src/migrations/release.0.19/db_setup_up.sql similarity index 89% rename from database/src/migrations/release.0.18/db_setup_up.sql rename to database/src/migrations/release.0.19/db_setup_up.sql index 8761b75f11..28f4a60174 100644 --- a/database/src/migrations/release.0.18/db_setup_up.sql +++ b/database/src/migrations/release.0.19/db_setup_up.sql @@ -47,6 +47,7 @@ alter role biohub_api set search_path to biohub_dapi_v1, biohub, public, topolog \i project_audit_triggers.sql \i api_get_context_user_id.sql \i api_get_context_system_user_role_id.sql +\i api_user_is_administrator.sql \i tr_journal_trigger.sql \i project_journal_triggers.sql \i tr_project_funding_source.sql @@ -54,12 +55,16 @@ alter role biohub_api set search_path to biohub_dapi_v1, biohub, public, topolog \i tr_project.sql \i tr_survey.sql \i tr_permit.sql +\i api_get_system_constant.sql +\i vw_survey_status.sql +\i api_delete_occurrence_submission.sql +\i api_delete_survey.sql \i api_delete_project.sql -- populate look up tables -set search_path = biohub; \set QUIET on +\i populate_system_constants.sql \i populate_first_nations.sql \i populate_climate_change_initiatives.sql \i populate_management_action_type.sql @@ -76,10 +81,6 @@ set search_path = biohub; \i populate_submission_status_type.sql \i populate_submission_message_type.sql -\i secured_objects.sql - -\i indexes.sql - -- temporary external interface tables \i populate_wldtaxonomic_units.sql \set QUIET off @@ -88,11 +89,7 @@ set search_path = biohub; set search_path = biohub_dapi_v1; set role biohub_api; \i project_dapi_views.sql - --- create the views -set search_path = biohub_dapi_v1; -set role biohub_api; -\i project_dapi_views.sql +\i dapi_custom_views.sql set role postgres; set search_path = biohub; diff --git a/database/src/migrations/release.0.18/populate_activity.sql b/database/src/migrations/release.0.19/populate_activity.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_activity.sql rename to database/src/migrations/release.0.19/populate_activity.sql diff --git a/database/src/migrations/release.0.18/populate_administrative_activity_status_type.sql b/database/src/migrations/release.0.19/populate_administrative_activity_status_type.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_administrative_activity_status_type.sql rename to database/src/migrations/release.0.19/populate_administrative_activity_status_type.sql diff --git a/database/src/migrations/release.0.18/populate_administrative_activity_type.sql b/database/src/migrations/release.0.19/populate_administrative_activity_type.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_administrative_activity_type.sql rename to database/src/migrations/release.0.19/populate_administrative_activity_type.sql diff --git a/database/src/migrations/release.0.18/populate_climate_change_initiatives.sql b/database/src/migrations/release.0.19/populate_climate_change_initiatives.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_climate_change_initiatives.sql rename to database/src/migrations/release.0.19/populate_climate_change_initiatives.sql diff --git a/database/src/migrations/release.0.18/populate_first_nations.sql b/database/src/migrations/release.0.19/populate_first_nations.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_first_nations.sql rename to database/src/migrations/release.0.19/populate_first_nations.sql diff --git a/database/src/migrations/release.0.18/populate_funding_source.sql b/database/src/migrations/release.0.19/populate_funding_source.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_funding_source.sql rename to database/src/migrations/release.0.19/populate_funding_source.sql diff --git a/database/src/migrations/release.0.18/populate_investment_action_category.sql b/database/src/migrations/release.0.19/populate_investment_action_category.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_investment_action_category.sql rename to database/src/migrations/release.0.19/populate_investment_action_category.sql diff --git a/database/src/migrations/release.0.18/populate_iucn_classifications.sql b/database/src/migrations/release.0.19/populate_iucn_classifications.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_iucn_classifications.sql rename to database/src/migrations/release.0.19/populate_iucn_classifications.sql diff --git a/database/src/migrations/release.0.18/populate_management_action_type.sql b/database/src/migrations/release.0.19/populate_management_action_type.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_management_action_type.sql rename to database/src/migrations/release.0.19/populate_management_action_type.sql diff --git a/database/src/migrations/release.0.18/populate_project_role.sql b/database/src/migrations/release.0.19/populate_project_role.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_project_role.sql rename to database/src/migrations/release.0.19/populate_project_role.sql diff --git a/database/src/migrations/release.0.18/populate_project_type.sql b/database/src/migrations/release.0.19/populate_project_type.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_project_type.sql rename to database/src/migrations/release.0.19/populate_project_type.sql diff --git a/database/src/migrations/release.0.18/populate_proprietor_type.sql b/database/src/migrations/release.0.19/populate_proprietor_type.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_proprietor_type.sql rename to database/src/migrations/release.0.19/populate_proprietor_type.sql diff --git a/database/src/migrations/release.0.18/populate_submission_message_type.sql b/database/src/migrations/release.0.19/populate_submission_message_type.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_submission_message_type.sql rename to database/src/migrations/release.0.19/populate_submission_message_type.sql diff --git a/database/src/migrations/release.0.18/populate_submission_status_type.sql b/database/src/migrations/release.0.19/populate_submission_status_type.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_submission_status_type.sql rename to database/src/migrations/release.0.19/populate_submission_status_type.sql diff --git a/database/src/migrations/release.0.19/populate_system_constants.sql b/database/src/migrations/release.0.19/populate_system_constants.sql new file mode 100644 index 0000000000..e08d6418f6 --- /dev/null +++ b/database/src/migrations/release.0.19/populate_system_constants.sql @@ -0,0 +1,7 @@ +-- populate_system_constants.sql + +-- survey states +insert into system_constant (constant_name, character_value, description) values ('SURVEY_STATE_PUBLISHED', 'Published', 'The survey state name that indicates that the data has been published and is discoverable.'); + +-- system roles +insert into system_constant (constant_name, character_value, description) values ('SYSTEM_ROLES_SYSTEM_ADMINISTRATOR', 'System Administrator', 'The system role name that defines a system administrator role.'); \ No newline at end of file diff --git a/database/src/migrations/release.0.18/populate_system_role.sql b/database/src/migrations/release.0.19/populate_system_role.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_system_role.sql rename to database/src/migrations/release.0.19/populate_system_role.sql diff --git a/database/src/migrations/release.0.18/populate_user_identity_source.sql b/database/src/migrations/release.0.19/populate_user_identity_source.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_user_identity_source.sql rename to database/src/migrations/release.0.19/populate_user_identity_source.sql diff --git a/database/src/migrations/release.0.18/populate_wldtaxonomic_units.sql b/database/src/migrations/release.0.19/populate_wldtaxonomic_units.sql similarity index 100% rename from database/src/migrations/release.0.18/populate_wldtaxonomic_units.sql rename to database/src/migrations/release.0.19/populate_wldtaxonomic_units.sql diff --git a/database/src/migrations/release.0.18/project_audit_triggers.sql b/database/src/migrations/release.0.19/project_audit_triggers.sql similarity index 93% rename from database/src/migrations/release.0.18/project_audit_triggers.sql rename to database/src/migrations/release.0.19/project_audit_triggers.sql index 015eaffeda..957198e655 100644 --- a/database/src/migrations/release.0.18/project_audit_triggers.sql +++ b/database/src/migrations/release.0.19/project_audit_triggers.sql @@ -15,34 +15,31 @@ create trigger audit_project_iucn_action_classification before insert or update or delete on biohub.project_iucn_action_classification for each row execute procedure tr_audit_trigger(); create trigger audit_project_management_actions before insert or update or delete on biohub.project_management_actions for each row execute procedure tr_audit_trigger(); create trigger audit_project_region before insert or update or delete on biohub.project_region for each row execute procedure tr_audit_trigger(); - create trigger audit_stakeholder_partnership before insert or update or delete on biohub.stakeholder_partnership for each row execute procedure tr_audit_trigger(); create trigger audit_submission_status before insert or update or delete on biohub.submission_status for each row execute procedure tr_audit_trigger(); + create trigger audit_project_type before insert or update or delete on biohub.project_type for each row execute procedure tr_audit_trigger(); + create trigger audit_survey before insert or update or delete on biohub.survey for each row execute procedure tr_audit_trigger(); create trigger audit_project_participation before insert or update or delete on biohub.project_participation for each row execute procedure tr_audit_trigger(); create trigger audit_project_role before insert or update or delete on biohub.project_role for each row execute procedure tr_audit_trigger(); - create trigger audit_security before insert or update or delete on biohub.security for each row execute procedure tr_audit_trigger(); - create trigger audit_security_rule before insert or update or delete on biohub.security_rule for each row execute procedure tr_audit_trigger(); + create trigger audit_stakeholder_partnership before insert or update or delete on biohub.stakeholder_partnership for each row execute procedure tr_audit_trigger(); create trigger audit_study_species before insert or update or delete on biohub.study_species for each row execute procedure tr_audit_trigger(); - create trigger audit_proprietor_type before insert or update or delete on biohub.proprietor_type for each row execute procedure tr_audit_trigger(); + create trigger audit_submission_message_type before insert or update or delete on biohub.submission_message_type for each row execute procedure tr_audit_trigger(); create trigger audit_submission_status_type before insert or update or delete on biohub.submission_status_type for each row execute procedure tr_audit_trigger(); + create trigger audit_proprietor_type before insert or update or delete on biohub.proprietor_type for each row execute procedure tr_audit_trigger(); create trigger audit_survey_funding_source before insert or update or delete on biohub.survey_funding_source for each row execute procedure tr_audit_trigger(); create trigger audit_user_identity_source before insert or update or delete on biohub.user_identity_source for each row execute procedure tr_audit_trigger(); create trigger audit_system_constant before insert or update or delete on biohub.system_constant for each row execute procedure tr_audit_trigger(); + create trigger audit_webform_draft before insert or update or delete on biohub.webform_draft for each row execute procedure tr_audit_trigger(); create trigger audit_system_user_role before insert or update or delete on biohub.system_user_role for each row execute procedure tr_audit_trigger(); - create trigger audit_survey before insert or update or delete on biohub.survey for each row execute procedure tr_audit_trigger(); + create trigger audit_system_user before insert or update or delete on biohub.system_user for each row execute procedure tr_audit_trigger(); create trigger audit_survey_attachment before insert or update or delete on biohub.survey_attachment for each row execute procedure tr_audit_trigger(); create trigger audit_survey_proprietor before insert or update or delete on biohub.survey_proprietor for each row execute procedure tr_audit_trigger(); create trigger audit_system_role before insert or update or delete on biohub.system_role for each row execute procedure tr_audit_trigger(); - create trigger audit_webform_draft before insert or update or delete on biohub.webform_draft for each row execute procedure tr_audit_trigger(); create trigger audit_administrative_activity before insert or update or delete on biohub.administrative_activity for each row execute procedure tr_audit_trigger(); - create trigger audit_system_user before insert or update or delete on biohub.system_user for each row execute procedure tr_audit_trigger(); create trigger audit_investment_action_category before insert or update or delete on biohub.investment_action_category for each row execute procedure tr_audit_trigger(); create trigger audit_iucn_conservation_action_level_1_classification before insert or update or delete on biohub.iucn_conservation_action_level_1_classification for each row execute procedure tr_audit_trigger(); create trigger audit_iucn_conservation_action_level_2_subclassification before insert or update or delete on biohub.iucn_conservation_action_level_2_subclassification for each row execute procedure tr_audit_trigger(); create trigger audit_project before insert or update or delete on biohub.project for each row execute procedure tr_audit_trigger(); - create trigger audit_project_type before insert or update or delete on biohub.project_type for each row execute procedure tr_audit_trigger(); create trigger audit_project_activity before insert or update or delete on biohub.project_activity for each row execute procedure tr_audit_trigger(); create trigger audit_project_attachment before insert or update or delete on biohub.project_attachment for each row execute procedure tr_audit_trigger(); - create trigger audit_wldtaxonomic_units before insert or update or delete on biohub.wldtaxonomic_units for each row execute procedure tr_audit_trigger(); - create trigger audit_submission_message_type before insert or update or delete on biohub.submission_message_type for each row execute procedure tr_audit_trigger(); create trigger audit_submission_message before insert or update or delete on biohub.submission_message for each row execute procedure tr_audit_trigger(); diff --git a/database/src/migrations/release.0.18/project_dapi_views.sql b/database/src/migrations/release.0.19/project_dapi_views.sql similarity index 95% rename from database/src/migrations/release.0.18/project_dapi_views.sql rename to database/src/migrations/release.0.19/project_dapi_views.sql index 1557dc7cda..449913b425 100644 --- a/database/src/migrations/release.0.18/project_dapi_views.sql +++ b/database/src/migrations/release.0.19/project_dapi_views.sql @@ -26,8 +26,6 @@ create or replace view project_role as select * from biohub.project_role; create or replace view project_type as select * from biohub.project_type; create or replace view proprietor_type as select * from biohub.proprietor_type; - create or replace view security as select * from biohub.security; - create or replace view security_rule as select * from biohub.security_rule; create or replace view stakeholder_partnership as select * from biohub.stakeholder_partnership; create or replace view study_species as select * from biohub.study_species; create or replace view submission_message as select * from biohub.submission_message; diff --git a/database/src/migrations/release.0.18/project_journal_triggers.sql b/database/src/migrations/release.0.19/project_journal_triggers.sql similarity index 95% rename from database/src/migrations/release.0.18/project_journal_triggers.sql rename to database/src/migrations/release.0.19/project_journal_triggers.sql index bd2c542f81..97c5e55078 100644 --- a/database/src/migrations/release.0.18/project_journal_triggers.sql +++ b/database/src/migrations/release.0.19/project_journal_triggers.sql @@ -15,33 +15,31 @@ create trigger journal_project_iucn_action_classification after insert or update or delete on biohub.project_iucn_action_classification for each row execute procedure tr_journal_trigger(); create trigger journal_project_management_actions after insert or update or delete on biohub.project_management_actions for each row execute procedure tr_journal_trigger(); create trigger journal_project_region after insert or update or delete on biohub.project_region for each row execute procedure tr_journal_trigger(); - create trigger journal_stakeholder_partnership after insert or update or delete on biohub.stakeholder_partnership for each row execute procedure tr_journal_trigger(); create trigger journal_submission_status after insert or update or delete on biohub.submission_status for each row execute procedure tr_journal_trigger(); + create trigger journal_project_type after insert or update or delete on biohub.project_type for each row execute procedure tr_journal_trigger(); + create trigger journal_survey after insert or update or delete on biohub.survey for each row execute procedure tr_journal_trigger(); create trigger journal_project_participation after insert or update or delete on biohub.project_participation for each row execute procedure tr_journal_trigger(); create trigger journal_project_role after insert or update or delete on biohub.project_role for each row execute procedure tr_journal_trigger(); - create trigger journal_security after insert or update or delete on biohub.security for each row execute procedure tr_journal_trigger(); - create trigger journal_security_rule after insert or update or delete on biohub.security_rule for each row execute procedure tr_journal_trigger(); + create trigger journal_stakeholder_partnership after insert or update or delete on biohub.stakeholder_partnership for each row execute procedure tr_journal_trigger(); create trigger journal_study_species after insert or update or delete on biohub.study_species for each row execute procedure tr_journal_trigger(); - create trigger journal_proprietor_type after insert or update or delete on biohub.proprietor_type for each row execute procedure tr_journal_trigger(); + create trigger journal_submission_message_type after insert or update or delete on biohub.submission_message_type for each row execute procedure tr_journal_trigger(); create trigger journal_submission_status_type after insert or update or delete on biohub.submission_status_type for each row execute procedure tr_journal_trigger(); + create trigger journal_proprietor_type after insert or update or delete on biohub.proprietor_type for each row execute procedure tr_journal_trigger(); create trigger journal_survey_funding_source after insert or update or delete on biohub.survey_funding_source for each row execute procedure tr_journal_trigger(); create trigger journal_user_identity_source after insert or update or delete on biohub.user_identity_source for each row execute procedure tr_journal_trigger(); create trigger journal_system_constant after insert or update or delete on biohub.system_constant for each row execute procedure tr_journal_trigger(); + create trigger journal_webform_draft after insert or update or delete on biohub.webform_draft for each row execute procedure tr_journal_trigger(); create trigger journal_system_user_role after insert or update or delete on biohub.system_user_role for each row execute procedure tr_journal_trigger(); - create trigger journal_survey after insert or update or delete on biohub.survey for each row execute procedure tr_journal_trigger(); + create trigger journal_system_user after insert or update or delete on biohub.system_user for each row execute procedure tr_journal_trigger(); create trigger journal_survey_attachment after insert or update or delete on biohub.survey_attachment for each row execute procedure tr_journal_trigger(); create trigger journal_survey_proprietor after insert or update or delete on biohub.survey_proprietor for each row execute procedure tr_journal_trigger(); create trigger journal_system_role after insert or update or delete on biohub.system_role for each row execute procedure tr_journal_trigger(); - create trigger journal_webform_draft after insert or update or delete on biohub.webform_draft for each row execute procedure tr_journal_trigger(); create trigger journal_administrative_activity after insert or update or delete on biohub.administrative_activity for each row execute procedure tr_journal_trigger(); - create trigger journal_system_user after insert or update or delete on biohub.system_user for each row execute procedure tr_journal_trigger(); create trigger journal_investment_action_category after insert or update or delete on biohub.investment_action_category for each row execute procedure tr_journal_trigger(); create trigger journal_iucn_conservation_action_level_1_classification after insert or update or delete on biohub.iucn_conservation_action_level_1_classification for each row execute procedure tr_journal_trigger(); create trigger journal_iucn_conservation_action_level_2_subclassification after insert or update or delete on biohub.iucn_conservation_action_level_2_subclassification for each row execute procedure tr_journal_trigger(); create trigger journal_project after insert or update or delete on biohub.project for each row execute procedure tr_journal_trigger(); - create trigger journal_project_type after insert or update or delete on biohub.project_type for each row execute procedure tr_journal_trigger(); create trigger journal_project_activity after insert or update or delete on biohub.project_activity for each row execute procedure tr_journal_trigger(); create trigger journal_project_attachment after insert or update or delete on biohub.project_attachment for each row execute procedure tr_journal_trigger(); - create trigger journal_submission_message_type after insert or update or delete on biohub.submission_message_type for each row execute procedure tr_journal_trigger(); create trigger journal_submission_message after insert or update or delete on biohub.submission_message for each row execute procedure tr_journal_trigger(); diff --git a/database/src/migrations/release.0.18/smoketest_release.sql b/database/src/migrations/release.0.19/smoketest_release.sql similarity index 90% rename from database/src/migrations/release.0.18/smoketest_release.sql rename to database/src/migrations/release.0.19/smoketest_release.sql index 78728eb055..6612d2ffbf 100644 --- a/database/src/migrations/release.0.18/smoketest_release.sql +++ b/database/src/migrations/release.0.19/smoketest_release.sql @@ -32,6 +32,8 @@ declare __ss_id study_species.id%type; __os_id occurrence_submission.id%type; __subs_id submission_status.id%type; + __survey_status_query text := 'select project_id, survey_id, survey_status from survey_status'; + __survey_rec survey_status%rowtype; begin set role biohub_api; set search_path to biohub_dapi_v1, biohub, public, topology; @@ -138,7 +140,10 @@ begin assert __count = 1, 'FAIL occurrence'; insert into submission_status (os_id, sst_id, event_timestamp) values (__os_id, (select id from submission_status_type where name = 'Submitted'), now()-interval '1 day') returning id into __subs_id; insert into submission_message (subs_id, smt_id, event_timestamp, message) values (__subs_id, (select id from submission_message_type where name = 'Notice'), now()-interval '1 day', 'A notice message at stage submitted.'); - insert into submission_status (os_id, sst_id, event_timestamp) values (__os_id, (select id from submission_status_type where name = 'Published'), now()-interval '1 day') returning id into __subs_id; + -- transpose comments on next three lines to test deletion of published surveys by system administrator + insert into submission_status (os_id, sst_id, event_timestamp) values (__os_id, (select id from submission_status_type where name = 'Awaiting Curration'), now()-interval '1 day') returning id into __subs_id; + --insert into submission_status (os_id, sst_id, event_timestamp) values (__os_id, (select id from submission_status_type where name = 'Published'), now()-interval '1 day') returning id into __subs_id; + --insert into system_user_role (su_id, sr_id) values (__system_user_id, (select id from system_role where name = 'System Administrator')); insert into submission_message (subs_id, smt_id, event_timestamp, message) values (__subs_id, (select id from submission_message_type where name = 'Notice'), now()-interval '1 day', 'A notice message at stage published.'); -- occurrence submission 2 @@ -150,13 +155,18 @@ begin assert __count = 2, 'FAIL occurrence'; insert into submission_status (os_id, sst_id, event_timestamp) values (__os_id, (select id from submission_status_type where name = 'Submitted'), now()) returning id into __subs_id; insert into submission_message (subs_id, smt_id, event_timestamp, message) values (__subs_id, (select id from submission_message_type where name = 'Notice'), now(), 'A notice message at stage submitted.'); - insert into submission_status (os_id, sst_id, event_timestamp) values (__os_id, (select id from submission_status_type where name = 'Published'), now()) returning id into __subs_id; + insert into submission_status (os_id, sst_id, event_timestamp) values (__os_id, (select id from submission_status_type where name = 'Rejected'), now()) returning id into __subs_id; insert into submission_message (subs_id, smt_id, event_timestamp, message) values (__subs_id, (select id from submission_message_type where name = 'Notice'), now(), 'A notice message at stage published.'); select count(1) into __count from submission_status; assert __count = 4, 'FAIL submission_status'; select count(1) into __count from submission_message; assert __count = 4, 'FAIL submission_message'; + raise notice 'survey status (project_id, survey_id, survey_status):'; + for __survey_rec in execute __survey_status_query loop + raise notice 'survey status results are % % %', __survey_rec.project_id, __survey_rec.survey_id, __survey_rec.survey_status; + end loop; + -- test ancillary data delete from webform_draft; insert into webform_draft (su_id, name, data) values ((select id from system_user limit 1), 'my draft name', '{ "customer": "John Doe", "items": {"product": "Beer","qty": 6}}'); @@ -181,11 +191,12 @@ begin insert into permit (number, type, issue_date, end_date, coordinator_first_name, coordinator_last_name, coordinator_email_address, coordinator_agency_name) values ('8377261', 'permit type', now(), now()+interval '1 day', 'first', 'last', 'nobody@nowhere.com', 'agency'); --- -- delete project --- delete from survey_publish_history; --- delete from survey_occurrence; --- call api_delete_project(__p_id); + -- delete project + call api_delete_project(__p_id); + + raise notice 'smoketest_release: PASS'; end $$; ---delete from administrative_activity; +delete from administrative_activity; +delete from permit; \ No newline at end of file diff --git a/database/src/migrations/release.0.18/tr_audit_trigger.sql b/database/src/migrations/release.0.19/tr_audit_trigger.sql similarity index 100% rename from database/src/migrations/release.0.18/tr_audit_trigger.sql rename to database/src/migrations/release.0.19/tr_audit_trigger.sql diff --git a/database/src/migrations/release.0.18/tr_journal_trigger.sql b/database/src/migrations/release.0.19/tr_journal_trigger.sql similarity index 100% rename from database/src/migrations/release.0.18/tr_journal_trigger.sql rename to database/src/migrations/release.0.19/tr_journal_trigger.sql diff --git a/database/src/migrations/release.0.18/tr_permit.sql b/database/src/migrations/release.0.19/tr_permit.sql similarity index 100% rename from database/src/migrations/release.0.18/tr_permit.sql rename to database/src/migrations/release.0.19/tr_permit.sql diff --git a/database/src/migrations/release.0.18/tr_project.sql b/database/src/migrations/release.0.19/tr_project.sql similarity index 100% rename from database/src/migrations/release.0.18/tr_project.sql rename to database/src/migrations/release.0.19/tr_project.sql diff --git a/database/src/migrations/release.0.18/tr_project_funding_source.sql b/database/src/migrations/release.0.19/tr_project_funding_source.sql similarity index 100% rename from database/src/migrations/release.0.18/tr_project_funding_source.sql rename to database/src/migrations/release.0.19/tr_project_funding_source.sql diff --git a/database/src/migrations/release.0.18/tr_survey.sql b/database/src/migrations/release.0.19/tr_survey.sql similarity index 52% rename from database/src/migrations/release.0.18/tr_survey.sql rename to database/src/migrations/release.0.19/tr_survey.sql index 99385315a9..57c5878e05 100644 --- a/database/src/migrations/release.0.18/tr_survey.sql +++ b/database/src/migrations/release.0.19/tr_survey.sql @@ -14,14 +14,34 @@ $$ -- charlie.garrettjones@quartech.com -- 2021-05-13 initial release -- ******************************************************************* +declare + __project_start_date project.start_date%type; + __project_end_date project.end_date%type; begin - -- ensure end date is not before start date - if new.end_date is not null then + -- start and end date validation + if (new.end_date is not null) then if new.end_date < new.start_date then raise exception 'The survey start date cannot be greater than the end date.'; end if; end if; + select start_date, end_date into strict __project_start_date, __project_end_date from project + where id = new.p_id; + + if (new.start_date < __project_start_date) then + raise exception 'The survey start date cannot be less than the associated project start date.'; + end if; + + if (__project_end_date is not null) and (new.end_date is not null) then + if (new.end_date > __project_end_date) then + raise exception 'The survey end date cannot be greater than the associated project end date.'; + end if; + end if; + + if (__project_end_date is not null) and (new.end_date is null) then + new.end_date = __project_end_date; + end if; + return new; end; $$; diff --git a/database/src/migrations/release.0.18/tr_survey_proprietor.sql b/database/src/migrations/release.0.19/tr_survey_proprietor.sql similarity index 100% rename from database/src/migrations/release.0.18/tr_survey_proprietor.sql rename to database/src/migrations/release.0.19/tr_survey_proprietor.sql From 9e540b56391a9825d9c98776c2702e497c51f4f0 Mon Sep 17 00:00:00 2001 From: charlie garrett-jones Date: Thu, 5 Aug 2021 14:40:05 -0700 Subject: [PATCH 2/6] BHBC-1249 - collapsed model changes into model mainline - implementation of api_get_eml_data_package for eml creation --- ...ts.ts => 20210715170003_secured_objects.ts | 0 .../20210225205948_biohub_release.ts | 6 +- ...15350_occurrence_submission_addFilename.ts | 52 -- ...005_adjust_procedure_api_delete_project.ts | 98 --- .../20210803170006_remove_project_region.ts | 73 -- .../release.0.21/api_delete_project.sql | 45 -- .../release.0.21/populate_system_constant.sql | 6 - .../api_delete_occurrence_submission.sql | 4 +- .../release.0.22/api_delete_project.sql | 44 ++ .../api_delete_survey.sql | 0 .../api_get_context_system_user_role_id.sql | 0 .../api_get_context_user_id.sql | 0 .../release.0.22/api_get_eml_data_package.sql | 729 ++++++++++++++++++ .../api_get_system_constant.sql | 0 .../api_get_system_metadata_constant.sql | 58 ++ .../api_set_context.sql | 0 .../api_user_is_administrator.sql | 0 .../release.0.22/api_xml_string_replace.sql | 22 + .../{release.0.21 => release.0.22}/biohub.sql | 217 +++--- .../create_spatial_extensions.psql | 0 .../dapi_custom_views.sql | 0 .../db_setup_up.sql | 4 + .../populate_activity.sql | 0 ...te_administrative_activity_status_type.sql | 0 .../populate_administrative_activity_type.sql | 0 .../populate_climate_change_initiatives.sql | 0 .../populate_first_nations.sql | 0 .../populate_funding_source.sql | 0 .../populate_investment_action_category.sql | 0 .../populate_iucn_classifications.sql | 0 .../populate_management_action_type.sql | 0 .../populate_project_role.sql | 0 .../populate_project_type.sql | 0 .../populate_proprietor_type.sql | 0 .../populate_submission_message_type.sql | 0 .../populate_submission_status_type.sql | 0 .../release.0.22/populate_system_constant.sql | 11 + .../populate_system_metadata_constant.sql | 4 +- .../populate_system_role.sql | 0 .../populate_user_identity_source.sql | 0 .../populate_wldtaxonomic_units.sql | 0 .../project_audit_triggers.sql | 26 +- .../project_dapi_views.sql | 2 +- .../project_journal_triggers.sql | 26 +- .../smoketest_release.sql | 46 +- .../tr_audit_trigger.sql | 0 .../tr_journal_trigger.sql | 0 .../release.0.22/tr_occurrence_submission.sql | 30 + .../tr_permit.sql | 0 .../tr_project.sql | 0 .../tr_project_funding_source.sql | 0 .../tr_survey.sql | 0 .../tr_survey_proprietor.sql | 0 .../vw_survey_status.sql | 4 +- 54 files changed, 1082 insertions(+), 425 deletions(-) rename database/src/migrations/20210715170003_secured_objects.ts => 20210715170003_secured_objects.ts (100%) delete mode 100644 database/src/migrations/20210726115350_occurrence_submission_addFilename.ts delete mode 100644 database/src/migrations/20210803170005_adjust_procedure_api_delete_project.ts delete mode 100644 database/src/migrations/20210803170006_remove_project_region.ts delete mode 100644 database/src/migrations/release.0.21/api_delete_project.sql delete mode 100644 database/src/migrations/release.0.21/populate_system_constant.sql rename database/src/migrations/{release.0.21 => release.0.22}/api_delete_occurrence_submission.sql (83%) create mode 100644 database/src/migrations/release.0.22/api_delete_project.sql rename database/src/migrations/{release.0.21 => release.0.22}/api_delete_survey.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/api_get_context_system_user_role_id.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/api_get_context_user_id.sql (100%) create mode 100644 database/src/migrations/release.0.22/api_get_eml_data_package.sql rename database/src/migrations/{release.0.21 => release.0.22}/api_get_system_constant.sql (100%) create mode 100644 database/src/migrations/release.0.22/api_get_system_metadata_constant.sql rename database/src/migrations/{release.0.21 => release.0.22}/api_set_context.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/api_user_is_administrator.sql (100%) create mode 100644 database/src/migrations/release.0.22/api_xml_string_replace.sql rename database/src/migrations/{release.0.21 => release.0.22}/biohub.sql (96%) rename database/src/migrations/{release.0.21 => release.0.22}/create_spatial_extensions.psql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/dapi_custom_views.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/db_setup_up.sql (92%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_activity.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_administrative_activity_status_type.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_administrative_activity_type.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_climate_change_initiatives.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_first_nations.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_funding_source.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_investment_action_category.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_iucn_classifications.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_management_action_type.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_project_role.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_project_type.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_proprietor_type.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_submission_message_type.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_submission_status_type.sql (100%) create mode 100644 database/src/migrations/release.0.22/populate_system_constant.sql rename database/src/migrations/{release.0.21 => release.0.22}/populate_system_metadata_constant.sql (81%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_system_role.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_user_identity_source.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_wldtaxonomic_units.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/project_audit_triggers.sql (97%) rename database/src/migrations/{release.0.21 => release.0.22}/project_dapi_views.sql (96%) rename database/src/migrations/{release.0.21 => release.0.22}/project_journal_triggers.sql (97%) rename database/src/migrations/{release.0.21 => release.0.22}/smoketest_release.sql (84%) rename database/src/migrations/{release.0.21 => release.0.22}/tr_audit_trigger.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/tr_journal_trigger.sql (100%) create mode 100644 database/src/migrations/release.0.22/tr_occurrence_submission.sql rename database/src/migrations/{release.0.21 => release.0.22}/tr_permit.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/tr_project.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/tr_project_funding_source.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/tr_survey.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/tr_survey_proprietor.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/vw_survey_status.sql (88%) diff --git a/database/src/migrations/20210715170003_secured_objects.ts b/20210715170003_secured_objects.ts similarity index 100% rename from database/src/migrations/20210715170003_secured_objects.ts rename to 20210715170003_secured_objects.ts diff --git a/database/src/migrations/20210225205948_biohub_release.ts b/database/src/migrations/20210225205948_biohub_release.ts index b0a91b66d6..e87a4d97b1 100644 --- a/database/src/migrations/20210225205948_biohub_release.ts +++ b/database/src/migrations/20210225205948_biohub_release.ts @@ -5,7 +5,7 @@ import path from 'path'; const DB_USER_API_PASS = process.env.DB_USER_API_PASS; const DB_USER_API = process.env.DB_USER_API; -const DB_RELEASE = 'release.0.21'; +const DB_RELEASE = 'release.0.22'; /** * Apply biohub release changes. @@ -45,6 +45,8 @@ export async function up(knex: Knex): Promise { ); const api_delete_survey = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_delete_survey.sql')); const api_delete_project = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_delete_project.sql')); + const api_xml_string_replace = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_xml_string_replace.sql')); + const api_get_eml_data_package = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_get_eml_data_package.sql')); const populate_system_constants = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'populate_system_constant.sql')); const populate_first_nations = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'populate_first_nations.sql')); @@ -139,6 +141,8 @@ export async function up(knex: Knex): Promise { ${api_delete_occurrence_submission} ${api_delete_survey} ${api_delete_project} + ${api_xml_string_replace} + ${api_get_eml_data_package} -- populate look up tables set search_path = biohub; diff --git a/database/src/migrations/20210726115350_occurrence_submission_addFilename.ts b/database/src/migrations/20210726115350_occurrence_submission_addFilename.ts deleted file mode 100644 index 4e05ec9b09..0000000000 --- a/database/src/migrations/20210726115350_occurrence_submission_addFilename.ts +++ /dev/null @@ -1,52 +0,0 @@ -import Knex from 'knex'; - -const DB_SCHEMA = process.env.DB_SCHEMA; - -export async function up(knex: Knex): Promise { - await knex.raw(` - - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - --- --- TABLE: occurrence_submission --- - -ALTER TABLE ${DB_SCHEMA}.occurrence_submission ADD file_name varchar(300) -; - -COMMENT ON COLUMN occurrence_submission.file_name IS 'The name of the file submitted.' -; - -set search_path = biohub_dapi_v1; -set role biohub_api; - -create or replace view occurrence_submission as select * from biohub.occurrence_submission; - -set role postgres; - - `); -} - -/** - * Drop the `file_name` column in the `occurrence_submission` table. - * - * @export - * @param {Knex} knex - * @return {*} {Promise} - */ -export async function down(knex: Knex): Promise { - await knex.raw(` - SET SCHEMA '${DB_SCHEMA}'; - SET SEARCH_PATH = ${DB_SCHEMA},public, biohub_dapi_v1; - - ALTER TABLE occurrence_submission DROP COLUMN file_name; - - set role biohub_api; - - create or replace view occurrence_submission as select * from biohub.occurrence_submission; - - set role postgres; - - `); -} diff --git a/database/src/migrations/20210803170005_adjust_procedure_api_delete_project.ts b/database/src/migrations/20210803170005_adjust_procedure_api_delete_project.ts deleted file mode 100644 index bbdb07f8c7..0000000000 --- a/database/src/migrations/20210803170005_adjust_procedure_api_delete_project.ts +++ /dev/null @@ -1,98 +0,0 @@ -import * as Knex from 'knex'; - -const DB_SCHEMA = process.env.DB_SCHEMA; - -export async function up(knex: Knex): Promise { - await knex.raw(` - - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - - drop procedure if exists api_delete_project; - - create or replace procedure api_delete_project(p_project_id project.project_id%type) - language plpgsql - security definer - as - $$ - - declare - _survey_id survey.survey_id%type; - begin - for _survey_id in (select survey_id from survey where project_id = p_project_id) loop - call api_delete_survey(_survey_id); - end loop; - - delete from permit where project_id = p_project_id; - delete from survey where project_id = p_project_id; - delete from stakeholder_partnership where project_id = p_project_id; - delete from project_activity where project_id = p_project_id; - delete from project_climate_initiative where project_id = p_project_id; - delete from project_management_actions where project_id = p_project_id; - delete from project_funding_source where project_id = p_project_id; - delete from project_iucn_action_classification where project_id = p_project_id; - delete from project_attachment where project_id = p_project_id; - delete from project_first_nation where project_id = p_project_id; - delete from project_participation where project_id = p_project_id; - delete from project where project_id = p_project_id; - - exception - when others THEN - raise; - end; - $$; - - `); -} - -export async function down(knex: Knex): Promise { - await knex.raw(` - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - drop procedure if exists api_delete_project; - - create or replace procedure api_delete_project(p_project_id project.project_id%type) - language plpgsql - security definer - as - $$ - -- ******************************************************************* - -- Procedure: api_delete_project - -- Purpose: deletes a project and dependencies - -- - -- MODIFICATION HISTORY - -- Person Date Comments - -- ---------------- ----------- -------------------------------------- - -- charlie.garrettjones@quartech.com - -- 2021-04-19 initial release - -- 2021-06-21 added delete survey - -- ******************************************************************* - declare - _survey_id survey.survey_id%type; - begin - for _survey_id in (select survey_id from survey where project_id = p_project_id) loop - call api_delete_survey(_survey_id); - end loop; - - delete from permit where project_id = p_project_id; - delete from survey where project_id = p_project_id; - delete from stakeholder_partnership where project_id = p_project_id; - delete from project_activity where project_id = p_project_id; - delete from project_climate_initiative where project_id = p_project_id; - delete from project_region where project_id = p_project_id; - delete from project_management_actions where project_id = p_project_id; - delete from project_funding_source where project_id = p_project_id; - delete from project_iucn_action_classification where project_id = p_project_id; - delete from project_attachment where project_id = p_project_id; - delete from project_first_nation where project_id = p_project_id; - delete from project_participation where project_id = p_project_id; - delete from project where project_id = p_project_id; - - exception - when others THEN - raise; - end; - $$; - - `); -} diff --git a/database/src/migrations/20210803170006_remove_project_region.ts b/database/src/migrations/20210803170006_remove_project_region.ts deleted file mode 100644 index 1c3284ef8a..0000000000 --- a/database/src/migrations/20210803170006_remove_project_region.ts +++ /dev/null @@ -1,73 +0,0 @@ -import * as Knex from 'knex'; - -const DB_SCHEMA = process.env.DB_SCHEMA; - -export async function up(knex: Knex): Promise { - await knex.raw(` - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - - DROP VIEW if exists biohub_dapi_v1.project_region; - - set role postgres; - - DROP TRIGGER if exists audit_project_region on project_region; - DROP TRIGGER if exists journal_project_region on project_region; - DROP TABLE if exists project_region; - - `); -} - -export async function down(knex: Knex): Promise { - await knex.raw(` - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - - - CREATE TABLE project_region( - project_region_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - project_id integer NOT NULL, - name varchar(200) 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 project_region_pk PRIMARY KEY (project_region_id) - ); - - COMMENT ON COLUMN project_region.project_region_id IS 'System generated surrogate primary key identifier.' - ; - COMMENT ON COLUMN project_region.project_id IS 'System generated surrogate primary key identifier.' - ; - COMMENT ON COLUMN project_region.name IS 'The region name.' - ; - COMMENT ON COLUMN project_region.create_date IS 'The datetime the record was created.' - ; - COMMENT ON COLUMN project_region.create_user IS 'The id of the user who created the record as identified in the system user table.' - ; - COMMENT ON COLUMN project_region.update_date IS 'The datetime the record was updated.' - ; - COMMENT ON COLUMN project_region.update_user IS 'The id of the user who updated the record as identified in the system user table.' - ; - COMMENT ON COLUMN project_region.revision_count IS 'Revision count used for concurrency control.' - ; - COMMENT ON TABLE project_region IS 'The region of a project.' - ; - - ALTER TABLE project_region ADD CONSTRAINT "Refproject131" - FOREIGN KEY (project_id) - REFERENCES project(project_id) - ; - - create trigger audit_project_region before insert or update or delete on project_region for each row execute procedure tr_audit_trigger(); - create trigger journal_project_region after insert or update or delete on project_region for each row execute procedure tr_journal_trigger(); - - set search_path = ${DB_SCHEMA}_dapi_v1; - set role ${DB_SCHEMA}_api; - create or replace view project_region as select * from ${DB_SCHEMA}.project_region; - - set role postgres; - set search_path = ${DB_SCHEMA},public; - `); -} diff --git a/database/src/migrations/release.0.21/api_delete_project.sql b/database/src/migrations/release.0.21/api_delete_project.sql deleted file mode 100644 index 389c4cedfa..0000000000 --- a/database/src/migrations/release.0.21/api_delete_project.sql +++ /dev/null @@ -1,45 +0,0 @@ --- api_delete_project.sql -drop procedure if exists api_delete_project; - -create or replace procedure api_delete_project(p_project_id project.project_id%type) -language plpgsql -security definer -as -$$ --- ******************************************************************* --- Procedure: api_delete_project --- Purpose: deletes a project and dependencies --- --- MODIFICATION HISTORY --- Person Date Comments --- ---------------- ----------- -------------------------------------- --- charlie.garrettjones@quartech.com --- 2021-04-19 initial release --- 2021-06-21 added delete survey --- ******************************************************************* -declare - _survey_id survey.survey_id%type; -begin - for _survey_id in (select survey_id from survey where project_id = p_project_id) loop - call api_delete_survey(_survey_id); - end loop; - - delete from permit where project_id = p_project_id; - delete from survey where project_id = p_project_id; - delete from stakeholder_partnership where project_id = p_project_id; - delete from project_activity where project_id = p_project_id; - delete from project_climate_initiative where project_id = p_project_id; - delete from project_region where project_id = p_project_id; - delete from project_management_actions where project_id = p_project_id; - delete from project_funding_source where project_id = p_project_id; - delete from project_iucn_action_classification where project_id = p_project_id; - delete from project_attachment where project_id = p_project_id; - delete from project_first_nation where project_id = p_project_id; - delete from project_participation where project_id = p_project_id; - delete from project where project_id = p_project_id; - -exception - when others THEN - raise; -end; -$$; diff --git a/database/src/migrations/release.0.21/populate_system_constant.sql b/database/src/migrations/release.0.21/populate_system_constant.sql deleted file mode 100644 index 37cf1ac89f..0000000000 --- a/database/src/migrations/release.0.21/populate_system_constant.sql +++ /dev/null @@ -1,6 +0,0 @@ --- populate_system_constant.sql - --- survey states -insert into system_constant (constant_name, character_value, description) values ('SURVEY_STATE_PUBLISHED', 'Published', 'The survey state name that indicates that the data has been published and is discoverable.'); --- system roles -insert into system_constant (constant_name, character_value, description) values ('SYSTEM_ROLES_SYSTEM_ADMINISTRATOR', 'System Administrator', 'The system role name that defines a system administrator role.'); \ No newline at end of file diff --git a/database/src/migrations/release.0.21/api_delete_occurrence_submission.sql b/database/src/migrations/release.0.22/api_delete_occurrence_submission.sql similarity index 83% rename from database/src/migrations/release.0.21/api_delete_occurrence_submission.sql rename to database/src/migrations/release.0.22/api_delete_occurrence_submission.sql index 6e9ea0650b..2a9e731f36 100644 --- a/database/src/migrations/release.0.21/api_delete_occurrence_submission.sql +++ b/database/src/migrations/release.0.22/api_delete_occurrence_submission.sql @@ -23,7 +23,7 @@ begin select exists into _is_published (select 1 from survey_status ss, occurrence_submission os where os.occurrence_submission_id = _occurrence_submission_id and ss.survey_id = os.survey_id - and ss.survey_status = (select api_get_character_system_constant('SURVEY_STATE_PUBLISHED'))); + and ss.survey_status = (select api_get_character_system_constant('OCCURRENCE_SUBMISSION_STATE_PUBLISHED'))); if _is_published then select api_user_is_administrator() into _is_system_administrator; @@ -36,6 +36,8 @@ begin delete from submission_message where submission_status_id in (select submission_status_id from submission_status where occurrence_submission_id = _occurrence_submission_id); delete from submission_status where occurrence_submission_id = _occurrence_submission_id; delete from occurrence where occurrence_submission_id = _occurrence_submission_id; + delete from occurrence_submission_data_package where occurrence_submission_id = _occurrence_submission_id; + delete from data_package where data_package_id in (select data_package_id from occurrence_submission_data_package where occurrence_submission_id = _occurrence_submission_id); delete from occurrence_submission where occurrence_submission_id = _occurrence_submission_id; exception diff --git a/database/src/migrations/release.0.22/api_delete_project.sql b/database/src/migrations/release.0.22/api_delete_project.sql new file mode 100644 index 0000000000..4ce7ab1584 --- /dev/null +++ b/database/src/migrations/release.0.22/api_delete_project.sql @@ -0,0 +1,44 @@ +-- api_delete_project.sql +drop procedure if exists api_delete_project; + +create or replace procedure api_delete_project(p_project_id project.project_id%type) +language plpgsql +security definer +as +$$ +-- ******************************************************************* +-- Procedure: api_delete_project +-- Purpose: deletes a project and dependencies +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-04-19 initial release +-- 2021-06-21 added delete survey +-- ******************************************************************* +declare + _survey_id survey.survey_id%type; + begin + for _survey_id in (select survey_id from survey where project_id = p_project_id) loop + call api_delete_survey(_survey_id); + end loop; + + delete from permit where project_id = p_project_id; + delete from survey where project_id = p_project_id; + delete from stakeholder_partnership where project_id = p_project_id; + delete from project_activity where project_id = p_project_id; + delete from project_climate_initiative where project_id = p_project_id; + delete from project_management_actions where project_id = p_project_id; + delete from project_funding_source where project_id = p_project_id; + delete from project_iucn_action_classification where project_id = p_project_id; + delete from project_attachment where project_id = p_project_id; + delete from project_first_nation where project_id = p_project_id; + delete from project_participation where project_id = p_project_id; + delete from project where project_id = p_project_id; + +exception + when others THEN + raise; +end; +$$; diff --git a/database/src/migrations/release.0.21/api_delete_survey.sql b/database/src/migrations/release.0.22/api_delete_survey.sql similarity index 100% rename from database/src/migrations/release.0.21/api_delete_survey.sql rename to database/src/migrations/release.0.22/api_delete_survey.sql diff --git a/database/src/migrations/release.0.21/api_get_context_system_user_role_id.sql b/database/src/migrations/release.0.22/api_get_context_system_user_role_id.sql similarity index 100% rename from database/src/migrations/release.0.21/api_get_context_system_user_role_id.sql rename to database/src/migrations/release.0.22/api_get_context_system_user_role_id.sql diff --git a/database/src/migrations/release.0.21/api_get_context_user_id.sql b/database/src/migrations/release.0.22/api_get_context_user_id.sql similarity index 100% rename from database/src/migrations/release.0.21/api_get_context_user_id.sql rename to database/src/migrations/release.0.22/api_get_context_user_id.sql diff --git a/database/src/migrations/release.0.22/api_get_eml_data_package.sql b/database/src/migrations/release.0.22/api_get_eml_data_package.sql new file mode 100644 index 0000000000..7aeed96d1a --- /dev/null +++ b/database/src/migrations/release.0.22/api_get_eml_data_package.sql @@ -0,0 +1,729 @@ +-- api_get_eml_data_package.sql + +drop function if exists api_get_eml_data_package; + +create or replace function api_get_eml_data_package(p_data_package_id data_package.data_package_id%type, p_supplied_title varchar) returns xml +language plpgsql +security definer +stable +as +$$ +-- ******************************************************************* +-- Procedure: api_get_eml_data_package +-- Purpose: returns eml xml of a data package. +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-07-29 initial release +-- ******************************************************************* +declare + _BIOHUB_EML_VERSION constant varchar := '1.0'; + _eml_xml_text varchar; + + _BIOHUB_PROVIDER_URL constant system_metadata_constant.character_value%type := api_xml_string_replace(api_get_character_system_metadata_constant('BIOHUB_PROVIDER_URL')); + _SECURITY_PROVIDER_URL constant system_metadata_constant.character_value%type := api_xml_string_replace(api_get_character_system_metadata_constant('SECURITY_PROVIDER_URL')); + _ORGANIZATION_NAME_FULL constant system_metadata_constant.character_value%type := api_xml_string_replace(api_get_character_system_metadata_constant('ORGANIZATION_NAME_FULL')); + _ORGANIZATION_URL constant system_metadata_constant.character_value%type := api_xml_string_replace(api_get_character_system_metadata_constant('ORGANIZATION_URL')); + _INTELLECTUAL_RIGHTS constant system_metadata_constant.character_value%type := api_xml_string_replace(api_get_character_system_metadata_constant('INTELLECTUAL_RIGHTS')); + _TAXONOMIC_PROVIDER_URL constant system_metadata_constant.character_value%type := api_xml_string_replace(api_get_character_system_metadata_constant('TAXONOMIC_PROVIDER_URL')); + + _r_data_package data_package%rowtype; + _r_occurrence_submission occurrence_submission%rowtype; + _r_survey survey%rowtype; + _r_project project%rowtype; + + _exists boolean := false; + _record record; + _record2 record; + _string varchar; +begin + select * into strict _r_data_package from data_package + where data_package_id = p_data_package_id; + + select a.* into strict _r_occurrence_submission from occurrence_submission a, occurrence_submission_data_package b, data_package c + where c.data_package_id = _r_data_package.data_package_id + and b.data_package_id = c.data_package_id + and a.occurrence_submission_id = b.occurrence_submission_id; + + + _eml_xml_text := format(' + + + public + read + + + + %4$s + + %5$s + + + %5$s + %6$s + ' + , _r_data_package.uuid + , _BIOHUB_PROVIDER_URL + , _SECURITY_PROVIDER_URL + , api_xml_string_replace(p_supplied_title) + , _ORGANIZATION_NAME_FULL + , _ORGANIZATION_URL + ); + + _eml_xml_text := _eml_xml_text||format('%1$s' + , (select to_char(ss.event_timestamp, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE')) from submission_status ss, submission_status_type sst + where ss.submission_status_id = (select max(submission_status_id) from submission_status ss2 + where ss2.occurrence_submission_id = _r_occurrence_submission.occurrence_submission_id) + and ss.submission_status_type_id = sst.submission_status_type_id + and sst.name = api_get_character_system_constant('OCCURRENCE_SUBMISSION_STATE_PUBLISHED') + and sst.record_end_date is null)); + + _eml_xml_text := _eml_xml_text||format('english + + %1$s + ' + , _INTELLECTUAL_RIGHTS); + + -- TODO: handle arbitrary sets of occurrence records + if _r_occurrence_submission.survey_id is not null then + -- occurrence submission is associated with survey + select * into strict _r_survey from survey where survey_id = _r_occurrence_submission.survey_id; + select * into strict _r_project from project where project_id = _r_survey.project_id; + + _eml_xml_text := _eml_xml_text||''; + if _r_project.coordinator_public then + _eml_xml_text := _eml_xml_text||format(' + + %1$s + %2$s + + %3$s + %4$s' + , api_xml_string_replace(_r_project.coordinator_first_name) + , api_xml_string_replace(_r_project.coordinator_last_name) + , api_xml_string_replace(_r_project.coordinator_agency_name) + , api_xml_string_replace(_r_project.coordinator_email_address)); + else + _eml_xml_text := _eml_xml_text||format(' + %1$s + %2$s' + , _ORGANIZATION_NAME_FULL + , _ORGANIZATION_URL); + end if; + _eml_xml_text := _eml_xml_text||''; + + _eml_xml_text := _eml_xml_text||format(' + + %3$s + ' + , _r_survey.UUID + , _BIOHUB_PROVIDER_URL + , api_xml_string_replace(_r_survey.name)); + + if _r_project.coordinator_public then + _eml_xml_text := _eml_xml_text||format(' + + %1$s + %2$s + + %3$s + pointOfContact' + , api_xml_string_replace(_r_survey.lead_first_name) + , api_xml_string_replace(_r_survey.lead_last_name) + , api_xml_string_replace(_r_project.coordinator_agency_name)); + else + _eml_xml_text := _eml_xml_text||format(' + %1$s + %2$s + custodianSteward' + , _ORGANIZATION_NAME_FULL + , _ORGANIZATION_URL); + end if; + _eml_xml_text := _eml_xml_text||''; + + _eml_xml_text := _eml_xml_text||format(' + +
+ Objectives + %1$s +
+
' + , api_xml_string_replace(_r_survey.objectives)); + + select true into _exists from project_funding_source + where exists (select project_funding_source_id from survey_funding_source where survey_id = _r_survey.survey_id); + + if _exists then + _eml_xml_text := _eml_xml_text||' + +
+ Funding Source'; + + for _record in (select a.*, b.name investment_action_category_name, c.name funding_source_name from project_funding_source a, investment_action_category b, funding_source c + where project_funding_source_id in (select project_funding_source_id from survey_funding_source where survey_id = _r_survey.survey_id) + and b.investment_action_category_id = a.investment_action_category_id + and c.funding_source_id = b.funding_source_id) loop + + _eml_xml_text := _eml_xml_text||format(' + %1$s +
+ Investment Action Category + %2$s +
+ Funding Source Project ID + %3$s +
+
+ Funding Amount + %4$s +
+
+ Funding Start Date + %5$s +
+
+ Funding Start Date + %6$s +
+
' + , api_xml_string_replace(_record.funding_source_name) + , api_xml_string_replace(_record.investment_action_category_name) + , _record.project_funding_source_id + , _record.funding_amount + , to_char(_record.funding_start_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE')) + , to_char(_record.funding_end_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE'))); + end loop; + + _eml_xml_text := _eml_xml_text||' +
+
'; + end if; + _exists := false; + + -- TODO: this only provides us with the bounding box of the first polygon + with envelope as (select ST_Envelope(geography::geometry) geom from survey s where survey_id = _r_survey.survey_id) + select st_xmax(geom), st_ymax(geom), st_xmin(geom), st_ymin(geom) into _record from envelope; + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + %2$s + %3$s + %4$s + %5$s + ' +, case when _r_survey.location_description is not null then api_xml_string_replace(_r_survey.location_name||' - '||_r_survey.location_description) + else api_xml_string_replace(_r_survey.location_name) end +-- , api_xml_string_replace(_r_survey.location_name||' - '||_r_survey.location_description) + , _record.st_xmin + , _record.st_xmax + , _record.st_ymax + , _record.st_ymin); + + for _record in (with polygons as (select (st_dumppoints(g.geom)).* from (select geography::geometry as geom from survey where survey_id = 1) as g) + select distinct(path[1]) polygon from polygons) loop + _eml_xml_text := _eml_xml_text||' + + '; + + for _record2 in (with polygons as (select (st_dumppoints(g.geom)).* from (select geography::geometry as geom from survey where survey_id = 1) as g) + , points as (select geom from polygons where path[1] = _record.polygon) + select st_x(geom) x, st_y(geom) y from points) loop + _eml_xml_text := _eml_xml_text||format(' + + %1$s + %2$s + ' + , _record2.y + , _record2.x); + end loop; + + _eml_xml_text := _eml_xml_text||' + + '; + end loop; + _eml_xml_text := _eml_xml_text||''; + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + %2$s + + + ' + , to_char(_r_survey.start_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE')) + , to_char(_r_survey.end_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE'))); + + _eml_xml_text := _eml_xml_text||' + + '; + + for _record in (select a.* from wldtaxonomic_units a, study_species b + where a.wldtaxonomic_units_id = b.wldtaxonomic_units_id + and b.survey_id = _r_survey.survey_id + and b.is_focal) loop + _eml_xml_text := _eml_xml_text||format(' + %1$s + %2$s + %3$s + %5$s' + , api_xml_string_replace(_record.tty_name) + , api_xml_string_replace(_record.unit_name1||' '||_record.unit_name2) + , api_xml_string_replace(_record.english_name) + , _TAXONOMIC_PROVIDER_URL + , api_xml_string_replace(_record.code)); + end loop; + for _record in (select a.* from wldtaxonomic_units a, study_species b + where a.wldtaxonomic_units_id = b.wldtaxonomic_units_id + and b.survey_id = _r_survey.survey_id + and not b.is_focal) loop + _eml_xml_text := _eml_xml_text||format(' + + %1$s + %2$s + %3$s + %5$s + ' + , api_xml_string_replace(_record.tty_name) + , api_xml_string_replace(_record.unit_name1||' '||_record.unit_name2) + , api_xml_string_replace(_record.english_name) + , _TAXONOMIC_PROVIDER_URL + , api_xml_string_replace(_record.code)); + end loop; + _eml_xml_text := _eml_xml_text||' + + '; + _eml_xml_text := _eml_xml_text||' + + '; + + _eml_xml_text := _eml_xml_text||format(' + + %3$s + ' + , _r_project.UUID + , _BIOHUB_PROVIDER_URL + , api_xml_string_replace(_r_project.name)); + + if _r_project.coordinator_public then + _eml_xml_text := _eml_xml_text||format(' + + %1$s + %2$s + + %3$s + %4$s + pointOfContact' + , api_xml_string_replace(_r_project.coordinator_first_name) + , api_xml_string_replace(_r_project.coordinator_last_name) + , api_xml_string_replace(_r_project.coordinator_agency_name) + , api_xml_string_replace(_r_project.coordinator_email_address)); + else + _eml_xml_text := _eml_xml_text||format(' + %1$s + %2$s + custodianSteward' + , _ORGANIZATION_NAME_FULL + , _ORGANIZATION_URL); + end if; + _eml_xml_text := _eml_xml_text||''; + + _eml_xml_text := _eml_xml_text||format(' + +
+ Objectives + %1$s +
+
+ Caveates + %2$s +
+
+ Comments + %3$s +
+
' + , api_xml_string_replace(_r_project.objectives) + , api_xml_string_replace(_r_project.caveats) + , api_xml_string_replace(_r_project.comments)); + + select true into _exists from project_funding_source + where exists (select project_funding_source_id from project_funding_source where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||' + +
+ Funding Source'; + + for _record in (select a.*, b.name investment_action_category_name, c.name funding_source_name from project_funding_source a, investment_action_category b, funding_source c + where project_funding_source_id in (select project_funding_source_id from project_funding_source where project_id = _r_project.project_id) + and b.investment_action_category_id = a.investment_action_category_id + and c.funding_source_id = b.funding_source_id) loop + + _eml_xml_text := _eml_xml_text||format(' + %1$s +
+ Investment Action Category + %2$s +
+ Funding Source Project ID + %3$s +
+
+ Funding Amount + %4$s +
+
+ Funding Start Date + %5$s +
+
+ Funding Start Date + %6$s +
+
' + , api_xml_string_replace(_record.funding_source_name) + , api_xml_string_replace(_record.investment_action_category_name) + , _record.project_funding_source_id + , _record.funding_amount + , to_char(_record.funding_start_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE')) + , to_char(_record.funding_end_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE'))); + end loop; + + _eml_xml_text := _eml_xml_text||' +
+
'; + end if; + _exists := false; + + -- TODO: this only provides us with the bounding box of the first polygon + with envelope as (select ST_Envelope(geography::geometry) geom from project where project_id = _r_project.project_id) + select st_xmax(geom), st_ymax(geom), st_xmin(geom), st_ymin(geom) into _record from envelope; + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + %2$s + %3$s + %4$s + %5$s + ' + , coalesce(api_xml_string_replace(_r_project.location_description), api_get_character_system_constant('DATA_NOT_PROVIDED_MESSAGE')) + , _record.st_xmin + , _record.st_xmax + , _record.st_ymax + , _record.st_ymin); + + for _record in (with polygons as (select (st_dumppoints(g.geom)).* from (select geography::geometry as geom from project where project_id = _r_project.project_id) as g) + select distinct(path[1]) polygon from polygons) loop + _eml_xml_text := _eml_xml_text||' + + '; + + for _record2 in (with polygons as (select (st_dumppoints(g.geom)).* from (select geography::geometry as geom from project where project_id = _r_project.project_id) as g) + , points as (select geom from polygons where path[1] = _record.polygon) + select st_x(geom) x, st_y(geom) y from points) loop + _eml_xml_text := _eml_xml_text||format(' + + %1$s + %2$s + ' + , _record2.y + , _record2.x); + end loop; + + _eml_xml_text := _eml_xml_text||' + + '; + end loop; + _eml_xml_text := _eml_xml_text||''; + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + %2$s + + + ' + , to_char(_r_project.start_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE')) + , to_char(_r_project.end_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE'))); + + _eml_xml_text := _eml_xml_text||' + + '; + _eml_xml_text := _eml_xml_text||'
'; + _eml_xml_text := _eml_xml_text||'
'; + _eml_xml_text := _eml_xml_text||'
'; + + select true into _exists from project_iucn_action_classification + where exists (select project_id from project_iucn_action_classification where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name level_1_name, b.name level_2_name, c.name level_3_name from iucn_conservation_action_level_1_classification a + , iucn_conservation_action_level_2_subclassification b, iucn_conservation_action_level_3_subclassification c, project_iucn_action_classification d + where d.project_id = _r_project.project_id + and c.iucn_conservation_action_level_3_subclassification_id = d.iucn_conservation_action_level_3_subclassification_id + and b.iucn_conservation_action_level_2_subclassification_id = c.iucn_conservation_action_level_2_subclassification_id + and a.iucn_conservation_action_level_1_classification_id = b.iucn_conservation_action_level_1_classification_id) loop + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + %1$s + %1$s + + + ' + , api_xml_string_replace(_record.level_1_name) + , api_xml_string_replace(_record.level_2_name) + , api_xml_string_replace(_record.level_3_name)); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + select true into _exists from stakeholder_partnership + where exists (select project_id from stakeholder_partnership where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name from stakeholder_partnership a + where a.project_id = _r_project.project_id) loop + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + ' + , api_xml_string_replace(_record.name)); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + select true into _exists from project_activity + where exists (select project_id from project_activity where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name from activity a, project_activity b + where b.project_id = _r_project.project_id + and a.activity_id = b.activity_id) loop + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + ' + , api_xml_string_replace(_record.name)); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + select true into _exists from project_climate_initiative + where exists (select project_id from project_climate_initiative where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name from climate_change_initiative a, project_climate_initiative b + where b.project_id = _r_project.project_id + and a.climate_change_initiative_id = b.climate_change_initiative_id) loop + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + ' + , api_xml_string_replace(_record.name)); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + select true into _exists from project_first_nation + where exists (select project_id from project_first_nation where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name from first_nations a, project_first_nation b + where b.project_id = _r_project.project_id + and a.first_nations_id = b.first_nations_id) loop + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + ' + , api_xml_string_replace(_record.name)); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + select true into _exists from project_management_actions + where exists (select project_id from project_management_actions where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name from management_action_type a, project_management_actions b + where b.project_id = _r_project.project_id + and a.management_action_type_id = b.management_action_type_id) loop + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + ' + , api_xml_string_replace(_record.name)); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + select true into _exists from survey_proprietor + where exists (select survey_id from survey_proprietor where survey_id = _r_survey.survey_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name proprietor_type_name, b.name first_nations_name, c.* from proprietor_type a, first_nations b, survey_proprietor c + where c.survey_id = _r_survey.survey_id + and b.first_nations_id = c.first_nations_id + and a.proprietor_type_id = c.proprietor_type_id) loop + + if _record.disa_required then + _string := 'Yes'; + else + _string := 'No'; + end if; + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + %2$s + %3$s + %4$s + %5$s + + + ' + , api_xml_string_replace(_record.first_nations_name) + , api_xml_string_replace(_record.proprietor_type_name) + , api_xml_string_replace(_record.rationale) + , api_xml_string_replace(_record.proprietor_name) + , _string + ); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + _eml_xml_text := _eml_xml_text||format(' + + %1$s + + + survey + %2$s + + + ' + , _r_data_package.UUID + , _BIOHUB_EML_VERSION); + + -- end occurrence submission associated with survey + end if; + + _eml_xml_text := _eml_xml_text||'
'; + return xmlparse(DOCUMENT _eml_xml_text); + +exception + when others then + raise; +end; +$$; + +grant execute on function api_get_eml_data_package to biohub_api; diff --git a/database/src/migrations/release.0.21/api_get_system_constant.sql b/database/src/migrations/release.0.22/api_get_system_constant.sql similarity index 100% rename from database/src/migrations/release.0.21/api_get_system_constant.sql rename to database/src/migrations/release.0.22/api_get_system_constant.sql diff --git a/database/src/migrations/release.0.22/api_get_system_metadata_constant.sql b/database/src/migrations/release.0.22/api_get_system_metadata_constant.sql new file mode 100644 index 0000000000..8916e5d5e7 --- /dev/null +++ b/database/src/migrations/release.0.22/api_get_system_metadata_constant.sql @@ -0,0 +1,58 @@ +-- api_get_system_metadata_constant.sql +drop function if exists api_get_character_system_metadata_constant; + +create or replace function api_get_character_system_metadata_constant(_constant_name system_metadata_constant.constant_name%type) returns system_metadata_constant.character_value%type +language plpgsql +security definer +stable +as +$$ +-- ******************************************************************* +-- Procedure: api_get_character_system_metadata_constant +-- Purpose: returns a text value from the system constants table +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-06-29 initial release +-- ******************************************************************* +begin + return (select character_value from system_metadata_constant where constant_name = _constant_name); + +exception + when others then + raise; +end; +$$; + +grant execute on function api_get_character_system_metadata_constant to biohub_api; + +drop function if exists api_get_numeric_system_metadata_constant; + +create or replace function api_get_numeric_system_metadata_constant(_constant_name system_metadata_constant.constant_name%type) returns system_metadata_constant.numeric_value%type +language plpgsql +security definer +stable +as +$$ +-- ******************************************************************* +-- Procedure: api_get_numeric_system_metadata_constant +-- Purpose: returns a numeric value from the system constants table +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-06-29 initial release +-- ******************************************************************* +begin + return (select numeric_value from system_metadata_constant where constant_name = _constant_name); + +exception + when others then + raise; +end; +$$; + +grant execute on function api_get_numeric_system_metadata_constant to biohub_api; diff --git a/database/src/migrations/release.0.21/api_set_context.sql b/database/src/migrations/release.0.22/api_set_context.sql similarity index 100% rename from database/src/migrations/release.0.21/api_set_context.sql rename to database/src/migrations/release.0.22/api_set_context.sql diff --git a/database/src/migrations/release.0.21/api_user_is_administrator.sql b/database/src/migrations/release.0.22/api_user_is_administrator.sql similarity index 100% rename from database/src/migrations/release.0.21/api_user_is_administrator.sql rename to database/src/migrations/release.0.22/api_user_is_administrator.sql diff --git a/database/src/migrations/release.0.22/api_xml_string_replace.sql b/database/src/migrations/release.0.22/api_xml_string_replace.sql new file mode 100644 index 0000000000..aaed2b8ad3 --- /dev/null +++ b/database/src/migrations/release.0.22/api_xml_string_replace.sql @@ -0,0 +1,22 @@ +-- api_xml_string_replace.sql +create or replace function api_xml_string_replace(p_string varchar) returns varchar +language plpgsql +security invoker +stable +as +$$ +-- ******************************************************************* +-- Procedure: api_xml_string_replace +-- Purpose: returns an string with replacments for <,> and & +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-01-03 initial release +-- ******************************************************************* +begin + + return replace(replace(replace(p_string, '&', '&'), '<', '<'), '>', '>'); +end; +$$; \ No newline at end of file diff --git a/database/src/migrations/release.0.21/biohub.sql b/database/src/migrations/release.0.22/biohub.sql similarity index 96% rename from database/src/migrations/release.0.21/biohub.sql rename to database/src/migrations/release.0.22/biohub.sql index 93af576fec..897c503c17 100644 --- a/database/src/migrations/release.0.21/biohub.sql +++ b/database/src/migrations/release.0.22/biohub.sql @@ -2,7 +2,7 @@ -- ER/Studio Data Architect SQL Code Generation -- Project : BioHub.DM1 -- --- Date Created : Wednesday, July 21, 2021 15:25:27 +-- Date Created : Thursday, August 05, 2021 14:02:54 -- Target DBMS : PostgreSQL 10.x-12.x -- @@ -290,7 +290,7 @@ CREATE TABLE data_package( COMMENT ON COLUMN data_package.data_package_id IS 'System generated surrogate primary key identifier.' ; -COMMENT ON COLUMN data_package.uuid IS 'System generated UUID data package identifier.' +COMMENT ON COLUMN data_package.uuid IS 'The universally unique identifier for the record.' ; COMMENT ON COLUMN data_package.create_date IS 'The datetime the record was created.' ; @@ -691,6 +691,44 @@ COMMENT ON COLUMN occurrence.revision_count IS 'Revision count used for concurre COMMENT ON TABLE occurrence IS 'Occurrence records that have been ingested from submissions sources.' ; +-- +-- TABLE: occurrence_data_package +-- + +CREATE TABLE occurrence_data_package( + occurrence_data_package_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + data_package_id integer NOT NULL, + occurrence_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 occurrence_data_package_pk PRIMARY KEY (occurrence_data_package_id) +) +; + + + +COMMENT ON COLUMN occurrence_data_package.occurrence_data_package_id IS 'System generated surrogate primary key identifier.' +; +COMMENT ON COLUMN occurrence_data_package.data_package_id IS 'System generated surrogate primary key identifier.' +; +COMMENT ON COLUMN occurrence_data_package.occurrence_id IS 'System generated surrogate primary key identifier.' +; +COMMENT ON COLUMN occurrence_data_package.create_date IS 'The datetime the record was created.' +; +COMMENT ON COLUMN occurrence_data_package.create_user IS 'The id of the user who created the record as identified in the system user table.' +; +COMMENT ON COLUMN occurrence_data_package.update_date IS 'The datetime the record was updated.' +; +COMMENT ON COLUMN occurrence_data_package.update_user IS 'The id of the user who updated the record as identified in the system user table.' +; +COMMENT ON COLUMN occurrence_data_package.revision_count IS 'Revision count used for concurrency control.' +; +COMMENT ON TABLE occurrence_data_package IS 'An associative entity that joins data package identifiers and occurrences.' +; + -- -- TABLE: occurrence_submission -- @@ -701,6 +739,7 @@ CREATE TABLE occurrence_submission( source varchar(300) NOT NULL, event_timestamp TIMESTAMPTZ NOT NULL, key varchar(1000), + file_name varchar(300), create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -722,6 +761,8 @@ COMMENT ON COLUMN occurrence_submission.event_timestamp IS 'The timestamp of the ; COMMENT ON COLUMN occurrence_submission.key IS 'The identifying key to the file in the storage system.' ; +COMMENT ON COLUMN occurrence_submission.file_name IS 'The name of the file submitted.' +; COMMENT ON COLUMN occurrence_submission.create_date IS 'The datetime the record was created.' ; COMMENT ON COLUMN occurrence_submission.create_user IS 'The id of the user who created the record as identified in the system user table.' @@ -741,8 +782,8 @@ COMMENT ON TABLE occurrence_submission IS 'Provides a historical listing of publ CREATE TABLE occurrence_submission_data_package( occurrence_submission_data_package_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - occurrence_submission_id integer NOT NULL, data_package_id integer NOT NULL, + occurrence_submission_id integer NOT NULL, create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -756,10 +797,10 @@ CREATE TABLE occurrence_submission_data_package( COMMENT ON COLUMN occurrence_submission_data_package.occurrence_submission_data_package_id IS 'System generated surrogate primary key identifier.' ; -COMMENT ON COLUMN occurrence_submission_data_package.occurrence_submission_id IS 'System generated surrogate primary key identifier.' -; COMMENT ON COLUMN occurrence_submission_data_package.data_package_id IS 'System generated surrogate primary key identifier.' ; +COMMENT ON COLUMN occurrence_submission_data_package.occurrence_submission_id IS 'System generated surrogate primary key identifier.' +; COMMENT ON COLUMN occurrence_submission_data_package.create_date IS 'The datetime the record was created.' ; COMMENT ON COLUMN occurrence_submission_data_package.create_user IS 'The id of the user who created the record as identified in the system user table.' @@ -852,29 +893,29 @@ NOTE: there are conceptual problems with associating permits to projects early i -- CREATE TABLE project( - project_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - project_type_id integer NOT NULL, - name varchar(50) NOT NULL, - objectives varchar(3000) NOT NULL, - management_recovery_action character(1), - location_description varchar(3000), - start_date date NOT NULL, - end_date date, - caveats varchar(3000), - comments varchar(3000), - coordinator_first_name varchar(50) NOT NULL, - coordinator_last_name varchar(50) NOT NULL, - coordinator_email_address varchar(500) NOT NULL, - coordinator_agency_name varchar(300) NOT NULL, - coordinator_public boolean NOT NULL, - publish_timestamp TIMESTAMPTZ, - geometry geometry(geometry, 3005), - geography geography(geometry), - 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, + project_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + project_type_id integer NOT NULL, + uuid uuid DEFAULT public.gen_random_uuid(), + name varchar(50) NOT NULL, + objectives varchar(3000) NOT NULL, + location_description varchar(3000), + start_date date NOT NULL, + end_date date, + caveats varchar(3000), + comments varchar(3000), + coordinator_first_name varchar(50) NOT NULL, + coordinator_last_name varchar(50) NOT NULL, + coordinator_email_address varchar(500) NOT NULL, + coordinator_agency_name varchar(300) NOT NULL, + coordinator_public boolean NOT NULL, + publish_timestamp TIMESTAMPTZ, + geometry geometry(geometry, 3005), + geography geography(geometry), + 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 project_pk PRIMARY KEY (project_id) ) ; @@ -885,12 +926,12 @@ COMMENT ON COLUMN project.project_id IS 'System generated surrogate primary key ; COMMENT ON COLUMN project.project_type_id IS 'System generated surrogate primary key identifier.' ; +COMMENT ON COLUMN project.uuid IS 'The universally unique identifier for the record.' +; COMMENT ON COLUMN project.name IS 'Name given to a project.' ; COMMENT ON COLUMN project.objectives IS 'The objectives for the project.' ; -COMMENT ON COLUMN project.management_recovery_action IS 'Identifies if the project addresses a management or recovery action.' -; COMMENT ON COLUMN project.location_description IS 'The location description.' ; COMMENT ON COLUMN project.start_date IS 'The start date of the project.' @@ -1264,44 +1305,6 @@ COMMENT ON COLUMN project_participation.revision_count IS 'Revision count used f COMMENT ON TABLE project_participation IS 'A associative entity that joins projects, system users and project role types.' ; --- --- TABLE: project_region --- - -CREATE TABLE project_region( - project_region_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - project_id integer NOT NULL, - name varchar(200) 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 project_region_pk PRIMARY KEY (project_region_id) -) -; - - - -COMMENT ON COLUMN project_region.project_region_id IS 'System generated surrogate primary key identifier.' -; -COMMENT ON COLUMN project_region.project_id IS 'System generated surrogate primary key identifier.' -; -COMMENT ON COLUMN project_region.name IS 'The region name.' -; -COMMENT ON COLUMN project_region.create_date IS 'The datetime the record was created.' -; -COMMENT ON COLUMN project_region.create_user IS 'The id of the user who created the record as identified in the system user table.' -; -COMMENT ON COLUMN project_region.update_date IS 'The datetime the record was updated.' -; -COMMENT ON COLUMN project_region.update_user IS 'The id of the user who updated the record as identified in the system user table.' -; -COMMENT ON COLUMN project_region.revision_count IS 'Revision count used for concurrency control.' -; -COMMENT ON TABLE project_region IS 'The region of a project.' -; - -- -- TABLE: project_role -- @@ -1699,6 +1702,7 @@ COMMENT ON TABLE submission_status_type IS 'The status types of submissions. Typ CREATE TABLE survey( survey_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), project_id integer NOT NULL, + uuid uuid DEFAULT public.gen_random_uuid(), name varchar(300), objectives varchar(3000) NOT NULL, start_date date NOT NULL, @@ -1725,6 +1729,8 @@ COMMENT ON COLUMN survey.survey_id IS 'System generated surrogate primary key id ; COMMENT ON COLUMN survey.project_id IS 'System generated surrogate primary key identifier.' ; +COMMENT ON COLUMN survey.uuid IS 'The universally unique identifier for the record.' +; COMMENT ON COLUMN survey.name IS 'Name given to a survey.' ; COMMENT ON COLUMN survey.objectives IS 'The objectives for the survey.' @@ -2396,22 +2402,40 @@ CREATE UNIQUE INDEX management_action_type_nuk1 ON management_action_type(name, CREATE INDEX "Ref165161" ON occurrence(occurrence_submission_id) ; -- +-- INDEX: "Ref185170" +-- + +CREATE INDEX "Ref185170" ON occurrence_data_package(data_package_id) +; +-- +-- INDEX: "Ref169174" +-- + +CREATE INDEX "Ref169174" ON occurrence_data_package(occurrence_id) +; +-- -- INDEX: "Ref153160" -- CREATE INDEX "Ref153160" ON occurrence_submission(survey_id) ; -- --- INDEX: "Ref165169" +-- INDEX: occurrence_submission_data_package_uk1 -- -CREATE INDEX "Ref165169" ON occurrence_submission_data_package(occurrence_submission_id) +CREATE UNIQUE INDEX occurrence_submission_data_package_uk1 ON occurrence_submission_data_package(data_package_id, occurrence_submission_id) ; -- --- INDEX: "Ref185170" +-- INDEX: "Ref185175" -- -CREATE INDEX "Ref185170" ON occurrence_submission_data_package(data_package_id) +CREATE INDEX "Ref185175" ON occurrence_submission_data_package(data_package_id) +; +-- +-- INDEX: "Ref165176" +-- + +CREATE INDEX "Ref165176" ON occurrence_submission_data_package(occurrence_submission_id) ; -- -- INDEX: permit_uk1 @@ -2588,18 +2612,6 @@ CREATE INDEX "Ref78149" ON project_participation(system_user_id) CREATE INDEX "Ref100150" ON project_participation(project_role_id) ; -- --- INDEX: project_region_uk1 --- - -CREATE UNIQUE INDEX project_region_uk1 ON project_region(name, project_id) -; --- --- INDEX: "Ref45131" --- - -CREATE INDEX "Ref45131" ON project_region(project_id) -; --- -- INDEX: project_role_nuk1 -- @@ -2856,6 +2868,21 @@ ALTER TABLE occurrence ADD CONSTRAINT "Refoccurrence_submission161" ; +-- +-- TABLE: occurrence_data_package +-- + +ALTER TABLE occurrence_data_package ADD CONSTRAINT "Refdata_package170" + FOREIGN KEY (data_package_id) + REFERENCES data_package(data_package_id) +; + +ALTER TABLE occurrence_data_package ADD CONSTRAINT "Refoccurrence174" + FOREIGN KEY (occurrence_id) + REFERENCES occurrence(occurrence_id) +; + + -- -- TABLE: occurrence_submission -- @@ -2870,16 +2897,16 @@ ALTER TABLE occurrence_submission ADD CONSTRAINT "Refsurvey160" -- TABLE: occurrence_submission_data_package -- -ALTER TABLE occurrence_submission_data_package ADD CONSTRAINT "Refoccurrence_submission169" - FOREIGN KEY (occurrence_submission_id) - REFERENCES occurrence_submission(occurrence_submission_id) -; - -ALTER TABLE occurrence_submission_data_package ADD CONSTRAINT "Refdata_package170" +ALTER TABLE occurrence_submission_data_package ADD CONSTRAINT "Refdata_package175" FOREIGN KEY (data_package_id) REFERENCES data_package(data_package_id) ; +ALTER TABLE occurrence_submission_data_package ADD CONSTRAINT "Refoccurrence_submission176" + FOREIGN KEY (occurrence_submission_id) + REFERENCES occurrence_submission(occurrence_submission_id) +; + -- -- TABLE: permit @@ -3031,16 +3058,6 @@ ALTER TABLE project_participation ADD CONSTRAINT "Refproject_role150" ; --- --- TABLE: project_region --- - -ALTER TABLE project_region ADD CONSTRAINT "Refproject131" - FOREIGN KEY (project_id) - REFERENCES project(project_id) -; - - -- -- TABLE: stakeholder_partnership -- diff --git a/database/src/migrations/release.0.21/create_spatial_extensions.psql b/database/src/migrations/release.0.22/create_spatial_extensions.psql similarity index 100% rename from database/src/migrations/release.0.21/create_spatial_extensions.psql rename to database/src/migrations/release.0.22/create_spatial_extensions.psql diff --git a/database/src/migrations/release.0.21/dapi_custom_views.sql b/database/src/migrations/release.0.22/dapi_custom_views.sql similarity index 100% rename from database/src/migrations/release.0.21/dapi_custom_views.sql rename to database/src/migrations/release.0.22/dapi_custom_views.sql diff --git a/database/src/migrations/release.0.21/db_setup_up.sql b/database/src/migrations/release.0.22/db_setup_up.sql similarity index 92% rename from database/src/migrations/release.0.21/db_setup_up.sql rename to database/src/migrations/release.0.22/db_setup_up.sql index dd6056571e..01ad66b13f 100644 --- a/database/src/migrations/release.0.21/db_setup_up.sql +++ b/database/src/migrations/release.0.22/db_setup_up.sql @@ -55,12 +55,16 @@ alter role biohub_api set search_path to biohub_dapi_v1, biohub, public, topolog \i tr_project.sql \i tr_survey.sql \i tr_permit.sql +\i tr_occurrence_submission.sql \i api_get_system_constant.sql +\i api_get_system_metadata_constant.sql \i vw_survey_status.sql \i api_delete_occurrence_submission.sql \i api_delete_survey.sql \i api_delete_project.sql +\i api_xml_string_replace.sql +\i api_get_eml_data_package.sql -- populate look up tables \set QUIET on diff --git a/database/src/migrations/release.0.21/populate_activity.sql b/database/src/migrations/release.0.22/populate_activity.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_activity.sql rename to database/src/migrations/release.0.22/populate_activity.sql diff --git a/database/src/migrations/release.0.21/populate_administrative_activity_status_type.sql b/database/src/migrations/release.0.22/populate_administrative_activity_status_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_administrative_activity_status_type.sql rename to database/src/migrations/release.0.22/populate_administrative_activity_status_type.sql diff --git a/database/src/migrations/release.0.21/populate_administrative_activity_type.sql b/database/src/migrations/release.0.22/populate_administrative_activity_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_administrative_activity_type.sql rename to database/src/migrations/release.0.22/populate_administrative_activity_type.sql diff --git a/database/src/migrations/release.0.21/populate_climate_change_initiatives.sql b/database/src/migrations/release.0.22/populate_climate_change_initiatives.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_climate_change_initiatives.sql rename to database/src/migrations/release.0.22/populate_climate_change_initiatives.sql diff --git a/database/src/migrations/release.0.21/populate_first_nations.sql b/database/src/migrations/release.0.22/populate_first_nations.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_first_nations.sql rename to database/src/migrations/release.0.22/populate_first_nations.sql diff --git a/database/src/migrations/release.0.21/populate_funding_source.sql b/database/src/migrations/release.0.22/populate_funding_source.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_funding_source.sql rename to database/src/migrations/release.0.22/populate_funding_source.sql diff --git a/database/src/migrations/release.0.21/populate_investment_action_category.sql b/database/src/migrations/release.0.22/populate_investment_action_category.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_investment_action_category.sql rename to database/src/migrations/release.0.22/populate_investment_action_category.sql diff --git a/database/src/migrations/release.0.21/populate_iucn_classifications.sql b/database/src/migrations/release.0.22/populate_iucn_classifications.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_iucn_classifications.sql rename to database/src/migrations/release.0.22/populate_iucn_classifications.sql diff --git a/database/src/migrations/release.0.21/populate_management_action_type.sql b/database/src/migrations/release.0.22/populate_management_action_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_management_action_type.sql rename to database/src/migrations/release.0.22/populate_management_action_type.sql diff --git a/database/src/migrations/release.0.21/populate_project_role.sql b/database/src/migrations/release.0.22/populate_project_role.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_project_role.sql rename to database/src/migrations/release.0.22/populate_project_role.sql diff --git a/database/src/migrations/release.0.21/populate_project_type.sql b/database/src/migrations/release.0.22/populate_project_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_project_type.sql rename to database/src/migrations/release.0.22/populate_project_type.sql diff --git a/database/src/migrations/release.0.21/populate_proprietor_type.sql b/database/src/migrations/release.0.22/populate_proprietor_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_proprietor_type.sql rename to database/src/migrations/release.0.22/populate_proprietor_type.sql diff --git a/database/src/migrations/release.0.21/populate_submission_message_type.sql b/database/src/migrations/release.0.22/populate_submission_message_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_submission_message_type.sql rename to database/src/migrations/release.0.22/populate_submission_message_type.sql diff --git a/database/src/migrations/release.0.21/populate_submission_status_type.sql b/database/src/migrations/release.0.22/populate_submission_status_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_submission_status_type.sql rename to database/src/migrations/release.0.22/populate_submission_status_type.sql diff --git a/database/src/migrations/release.0.22/populate_system_constant.sql b/database/src/migrations/release.0.22/populate_system_constant.sql new file mode 100644 index 0000000000..8124f3f4c2 --- /dev/null +++ b/database/src/migrations/release.0.22/populate_system_constant.sql @@ -0,0 +1,11 @@ +-- populate_system_constant.sql + +-- common constants +insert into system_constant (constant_name, character_value, description) values ('DATA_NOT_PROVIDED_MESSAGE', 'Not provided', 'A message to insert as appropriate where some data standard defines the data as required but that data is not available.'); +-- ISO 8601 date format strings +insert into system_constant (constant_name, character_value, description) values ('ISO_8601_DATE_FORMAT_WITH_TIMEZONE', 'YYYY-MM-DD"T"HH24:MI:SS"Z"', 'The ISO 8601 dae format string for timezone.'); +insert into system_constant (constant_name, character_value, description) values ('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE', 'YYYY-MM-DD', 'The ISO 8601 dae format string without time or timezone.'); +-- survey states +insert into system_constant (constant_name, character_value, description) values ('OCCURRENCE_SUBMISSION_STATE_PUBLISHED', 'Published', 'The occurrence submission state name that indicates that the data has been published and is discoverable.'); +-- system roles +insert into system_constant (constant_name, character_value, description) values ('SYSTEM_ROLES_SYSTEM_ADMINISTRATOR', 'System Administrator', 'The system role name that defines a system administrator role.'); \ No newline at end of file diff --git a/database/src/migrations/release.0.21/populate_system_metadata_constant.sql b/database/src/migrations/release.0.22/populate_system_metadata_constant.sql similarity index 81% rename from database/src/migrations/release.0.21/populate_system_metadata_constant.sql rename to database/src/migrations/release.0.22/populate_system_metadata_constant.sql index febce6ed0a..1b63866465 100644 --- a/database/src/migrations/release.0.21/populate_system_metadata_constant.sql +++ b/database/src/migrations/release.0.22/populate_system_metadata_constant.sql @@ -1,9 +1,9 @@ -- populate_system_metadata_constant.sql -- system metadata tombstone data -insert into system_metadata_constant (constant_name, character_value, description) values ('BIOHUB_PROVIDER_URL', 'https://biohub.bc.ca', 'The system URL. This value is used in the production of published ecological metadata language files.'); +insert into system_metadata_constant (constant_name, character_value, description) values ('BIOHUB_PROVIDER_URL', 'https://biohub.gov.bc.ca', 'The system URL. This value is used in the production of published ecological metadata language files.'); insert into system_metadata_constant (constant_name, character_value, description) values ('SECURITY_PROVIDER_URL', 'https://biohub.bc.ca', 'The security provider URL. This value is used in the production of published ecological metadata language files.'); -insert into system_metadata_constant (constant_name, character_value, description) values ('ORGANIZATION_NAME_FULL', 'Knowledge Management Branch, Ministry of Enivronment, Government of British Columbia', 'The organizations full name. This value is used in the production of published ecological metadata language files.'); +insert into system_metadata_constant (constant_name, character_value, description) values ('ORGANIZATION_NAME_FULL', 'Knowledge Management Branch, Ministry of Enivronment and Climate Change Strategy, Government of British Columbia', 'The organizations full name. This value is used in the production of published ecological metadata language files.'); insert into system_metadata_constant (constant_name, character_value, description) values ('ORGANIZATION_URL', 'https://www2.gov.bc.ca/gov/content/governments/organizational-structure/ministries-organizations/ministries/environment-climate-change', 'The organizations public facing URL. This value is used in the production of published ecological metadata language files.'); insert into system_metadata_constant (constant_name, character_value, description) values ('INTELLECTUAL_RIGHTS', 'Intellectual rights example.', 'Intellectual rights verbiage for published data. This value is used in the production of published ecological metadata language files.'); insert into system_metadata_constant (constant_name, character_value, description) values ('TAXONOMIC_PROVIDER_URL', 'https://biohub.bc.ca', 'The taxonomic system URL. This value is used in the production of published ecological metadata language files.'); \ No newline at end of file diff --git a/database/src/migrations/release.0.21/populate_system_role.sql b/database/src/migrations/release.0.22/populate_system_role.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_system_role.sql rename to database/src/migrations/release.0.22/populate_system_role.sql diff --git a/database/src/migrations/release.0.21/populate_user_identity_source.sql b/database/src/migrations/release.0.22/populate_user_identity_source.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_user_identity_source.sql rename to database/src/migrations/release.0.22/populate_user_identity_source.sql diff --git a/database/src/migrations/release.0.21/populate_wldtaxonomic_units.sql b/database/src/migrations/release.0.22/populate_wldtaxonomic_units.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_wldtaxonomic_units.sql rename to database/src/migrations/release.0.22/populate_wldtaxonomic_units.sql diff --git a/database/src/migrations/release.0.21/project_audit_triggers.sql b/database/src/migrations/release.0.22/project_audit_triggers.sql similarity index 97% rename from database/src/migrations/release.0.21/project_audit_triggers.sql rename to database/src/migrations/release.0.22/project_audit_triggers.sql index 70cd581b32..607facdcf6 100644 --- a/database/src/migrations/release.0.21/project_audit_triggers.sql +++ b/database/src/migrations/release.0.22/project_audit_triggers.sql @@ -7,42 +7,42 @@ create trigger audit_climate_change_initiative before insert or update or delete on biohub.climate_change_initiative for each row execute procedure tr_audit_trigger(); create trigger audit_first_nations before insert or update or delete on biohub.first_nations for each row execute procedure tr_audit_trigger(); create trigger audit_iucn_conservation_action_level_3_subclassification before insert or update or delete on biohub.iucn_conservation_action_level_3_subclassification for each row execute procedure tr_audit_trigger(); - create trigger audit_occurrence_submission before insert or update or delete on biohub.occurrence_submission for each row execute procedure tr_audit_trigger(); create trigger audit_occurrence before insert or update or delete on biohub.occurrence for each row execute procedure tr_audit_trigger(); - create trigger audit_occurrence_submission_data_package before insert or update or delete on biohub.occurrence_submission_data_package for each row execute procedure tr_audit_trigger(); + create trigger audit_occurrence_data_package before insert or update or delete on biohub.occurrence_data_package for each row execute procedure tr_audit_trigger(); create trigger audit_management_action_type before insert or update or delete on biohub.management_action_type for each row execute procedure tr_audit_trigger(); + create trigger audit_investment_action_category before insert or update or delete on biohub.investment_action_category for each row execute procedure tr_audit_trigger(); create trigger audit_iucn_conservation_action_level_1_classification before insert or update or delete on biohub.iucn_conservation_action_level_1_classification for each row execute procedure tr_audit_trigger(); - create trigger audit_permit before insert or update or delete on biohub.permit for each row execute procedure tr_audit_trigger(); + create trigger audit_occurrence_submission_data_package before insert or update or delete on biohub.occurrence_submission_data_package for each row execute procedure tr_audit_trigger(); create trigger audit_project_activity before insert or update or delete on biohub.project_activity for each row execute procedure tr_audit_trigger(); create trigger audit_project_climate_initiative before insert or update or delete on biohub.project_climate_initiative for each row execute procedure tr_audit_trigger(); create trigger audit_project_attachment before insert or update or delete on biohub.project_attachment for each row execute procedure tr_audit_trigger(); + create trigger audit_stakeholder_partnership before insert or update or delete on biohub.stakeholder_partnership for each row execute procedure tr_audit_trigger(); + create trigger audit_submission_message_type before insert or update or delete on biohub.submission_message_type for each row execute procedure tr_audit_trigger(); + create trigger audit_project_type before insert or update or delete on biohub.project_type for each row execute procedure tr_audit_trigger(); create trigger audit_project_first_nation before insert or update or delete on biohub.project_first_nation for each row execute procedure tr_audit_trigger(); create trigger audit_project_funding_source before insert or update or delete on biohub.project_funding_source for each row execute procedure tr_audit_trigger(); - create trigger audit_project_region before insert or update or delete on biohub.project_region for each row execute procedure tr_audit_trigger(); - create trigger audit_submission_message_type before insert or update or delete on biohub.submission_message_type for each row execute procedure tr_audit_trigger(); create trigger audit_project_iucn_action_classification before insert or update or delete on biohub.project_iucn_action_classification for each row execute procedure tr_audit_trigger(); create trigger audit_project_management_actions before insert or update or delete on biohub.project_management_actions for each row execute procedure tr_audit_trigger(); create trigger audit_project_participation before insert or update or delete on biohub.project_participation for each row execute procedure tr_audit_trigger(); create trigger audit_project_role before insert or update or delete on biohub.project_role for each row execute procedure tr_audit_trigger(); - create trigger audit_stakeholder_partnership before insert or update or delete on biohub.stakeholder_partnership for each row execute procedure tr_audit_trigger(); create trigger audit_study_species before insert or update or delete on biohub.study_species for each row execute procedure tr_audit_trigger(); + create trigger audit_submission_message before insert or update or delete on biohub.submission_message for each row execute procedure tr_audit_trigger(); create trigger audit_proprietor_type before insert or update or delete on biohub.proprietor_type for each row execute procedure tr_audit_trigger(); create trigger audit_submission_status_type before insert or update or delete on biohub.submission_status_type for each row execute procedure tr_audit_trigger(); create trigger audit_survey_funding_source before insert or update or delete on biohub.survey_funding_source for each row execute procedure tr_audit_trigger(); - create trigger audit_system_user_role before insert or update or delete on biohub.system_user_role for each row execute procedure tr_audit_trigger(); + create trigger audit_system_role before insert or update or delete on biohub.system_role for each row execute procedure tr_audit_trigger(); create trigger audit_system_constant before insert or update or delete on biohub.system_constant for each row execute procedure tr_audit_trigger(); create trigger audit_system_metadata_constant before insert or update or delete on biohub.system_metadata_constant for each row execute procedure tr_audit_trigger(); create trigger audit_survey before insert or update or delete on biohub.survey for each row execute procedure tr_audit_trigger(); + create trigger audit_submission_status before insert or update or delete on biohub.submission_status for each row execute procedure tr_audit_trigger(); create trigger audit_survey_attachment before insert or update or delete on biohub.survey_attachment for each row execute procedure tr_audit_trigger(); create trigger audit_survey_proprietor before insert or update or delete on biohub.survey_proprietor for each row execute procedure tr_audit_trigger(); - create trigger audit_system_role before insert or update or delete on biohub.system_role for each row execute procedure tr_audit_trigger(); - create trigger audit_webform_draft before insert or update or delete on biohub.webform_draft for each row execute procedure tr_audit_trigger(); + create trigger audit_system_user_role before insert or update or delete on biohub.system_user_role for each row execute procedure tr_audit_trigger(); create trigger audit_user_identity_source before insert or update or delete on biohub.user_identity_source for each row execute procedure tr_audit_trigger(); + create trigger audit_webform_draft before insert or update or delete on biohub.webform_draft for each row execute procedure tr_audit_trigger(); create trigger audit_system_user before insert or update or delete on biohub.system_user for each row execute procedure tr_audit_trigger(); - create trigger audit_investment_action_category before insert or update or delete on biohub.investment_action_category for each row execute procedure tr_audit_trigger(); create trigger audit_iucn_conservation_action_level_2_subclassification before insert or update or delete on biohub.iucn_conservation_action_level_2_subclassification for each row execute procedure tr_audit_trigger(); + create trigger audit_occurrence_submission before insert or update or delete on biohub.occurrence_submission for each row execute procedure tr_audit_trigger(); create trigger audit_project before insert or update or delete on biohub.project for each row execute procedure tr_audit_trigger(); - create trigger audit_project_type before insert or update or delete on biohub.project_type for each row execute procedure tr_audit_trigger(); - create trigger audit_submission_status before insert or update or delete on biohub.submission_status for each row execute procedure tr_audit_trigger(); - create trigger audit_submission_message before insert or update or delete on biohub.submission_message for each row execute procedure tr_audit_trigger(); + create trigger audit_permit before insert or update or delete on biohub.permit for each row execute procedure tr_audit_trigger(); diff --git a/database/src/migrations/release.0.21/project_dapi_views.sql b/database/src/migrations/release.0.22/project_dapi_views.sql similarity index 96% rename from database/src/migrations/release.0.21/project_dapi_views.sql rename to database/src/migrations/release.0.22/project_dapi_views.sql index f05b19519a..87569cd827 100644 --- a/database/src/migrations/release.0.21/project_dapi_views.sql +++ b/database/src/migrations/release.0.22/project_dapi_views.sql @@ -12,6 +12,7 @@ create or replace view iucn_conservation_action_level_3_subclassification as select * from biohub.iucn_conservation_action_level_3_subclassification; create or replace view management_action_type as select * from biohub.management_action_type; create or replace view occurrence as select * from biohub.occurrence; + create or replace view occurrence_data_package as select * from biohub.occurrence_data_package; create or replace view occurrence_submission as select * from biohub.occurrence_submission; create or replace view occurrence_submission_data_package as select * from biohub.occurrence_submission_data_package; create or replace view permit as select * from biohub.permit; @@ -24,7 +25,6 @@ create or replace view project_iucn_action_classification as select * from biohub.project_iucn_action_classification; create or replace view project_management_actions as select * from biohub.project_management_actions; create or replace view project_participation as select * from biohub.project_participation; - create or replace view project_region as select * from biohub.project_region; create or replace view project_role as select * from biohub.project_role; create or replace view project_type as select * from biohub.project_type; create or replace view proprietor_type as select * from biohub.proprietor_type; diff --git a/database/src/migrations/release.0.21/project_journal_triggers.sql b/database/src/migrations/release.0.22/project_journal_triggers.sql similarity index 97% rename from database/src/migrations/release.0.21/project_journal_triggers.sql rename to database/src/migrations/release.0.22/project_journal_triggers.sql index 9cddcc56f8..a210bc544c 100644 --- a/database/src/migrations/release.0.21/project_journal_triggers.sql +++ b/database/src/migrations/release.0.22/project_journal_triggers.sql @@ -7,42 +7,42 @@ create trigger journal_climate_change_initiative after insert or update or delete on biohub.climate_change_initiative for each row execute procedure tr_journal_trigger(); create trigger journal_first_nations after insert or update or delete on biohub.first_nations for each row execute procedure tr_journal_trigger(); create trigger journal_iucn_conservation_action_level_3_subclassification after insert or update or delete on biohub.iucn_conservation_action_level_3_subclassification for each row execute procedure tr_journal_trigger(); - create trigger journal_occurrence_submission after insert or update or delete on biohub.occurrence_submission for each row execute procedure tr_journal_trigger(); create trigger journal_occurrence after insert or update or delete on biohub.occurrence for each row execute procedure tr_journal_trigger(); - create trigger journal_occurrence_submission_data_package after insert or update or delete on biohub.occurrence_submission_data_package for each row execute procedure tr_journal_trigger(); + create trigger journal_occurrence_data_package after insert or update or delete on biohub.occurrence_data_package for each row execute procedure tr_journal_trigger(); create trigger journal_management_action_type after insert or update or delete on biohub.management_action_type for each row execute procedure tr_journal_trigger(); + create trigger journal_investment_action_category after insert or update or delete on biohub.investment_action_category for each row execute procedure tr_journal_trigger(); create trigger journal_iucn_conservation_action_level_1_classification after insert or update or delete on biohub.iucn_conservation_action_level_1_classification for each row execute procedure tr_journal_trigger(); - create trigger journal_permit after insert or update or delete on biohub.permit for each row execute procedure tr_journal_trigger(); + create trigger journal_occurrence_submission_data_package after insert or update or delete on biohub.occurrence_submission_data_package for each row execute procedure tr_journal_trigger(); create trigger journal_project_activity after insert or update or delete on biohub.project_activity for each row execute procedure tr_journal_trigger(); create trigger journal_project_climate_initiative after insert or update or delete on biohub.project_climate_initiative for each row execute procedure tr_journal_trigger(); create trigger journal_project_attachment after insert or update or delete on biohub.project_attachment for each row execute procedure tr_journal_trigger(); + create trigger journal_stakeholder_partnership after insert or update or delete on biohub.stakeholder_partnership for each row execute procedure tr_journal_trigger(); + create trigger journal_submission_message_type after insert or update or delete on biohub.submission_message_type for each row execute procedure tr_journal_trigger(); + create trigger journal_project_type after insert or update or delete on biohub.project_type for each row execute procedure tr_journal_trigger(); create trigger journal_project_first_nation after insert or update or delete on biohub.project_first_nation for each row execute procedure tr_journal_trigger(); create trigger journal_project_funding_source after insert or update or delete on biohub.project_funding_source for each row execute procedure tr_journal_trigger(); - create trigger journal_project_region after insert or update or delete on biohub.project_region for each row execute procedure tr_journal_trigger(); - create trigger journal_submission_message_type after insert or update or delete on biohub.submission_message_type for each row execute procedure tr_journal_trigger(); create trigger journal_project_iucn_action_classification after insert or update or delete on biohub.project_iucn_action_classification for each row execute procedure tr_journal_trigger(); create trigger journal_project_management_actions after insert or update or delete on biohub.project_management_actions for each row execute procedure tr_journal_trigger(); create trigger journal_project_participation after insert or update or delete on biohub.project_participation for each row execute procedure tr_journal_trigger(); create trigger journal_project_role after insert or update or delete on biohub.project_role for each row execute procedure tr_journal_trigger(); - create trigger journal_stakeholder_partnership after insert or update or delete on biohub.stakeholder_partnership for each row execute procedure tr_journal_trigger(); create trigger journal_study_species after insert or update or delete on biohub.study_species for each row execute procedure tr_journal_trigger(); + create trigger journal_submission_message after insert or update or delete on biohub.submission_message for each row execute procedure tr_journal_trigger(); create trigger journal_proprietor_type after insert or update or delete on biohub.proprietor_type for each row execute procedure tr_journal_trigger(); create trigger journal_submission_status_type after insert or update or delete on biohub.submission_status_type for each row execute procedure tr_journal_trigger(); create trigger journal_survey_funding_source after insert or update or delete on biohub.survey_funding_source for each row execute procedure tr_journal_trigger(); - create trigger journal_system_user_role after insert or update or delete on biohub.system_user_role for each row execute procedure tr_journal_trigger(); + create trigger journal_system_role after insert or update or delete on biohub.system_role for each row execute procedure tr_journal_trigger(); create trigger journal_system_constant after insert or update or delete on biohub.system_constant for each row execute procedure tr_journal_trigger(); create trigger journal_system_metadata_constant after insert or update or delete on biohub.system_metadata_constant for each row execute procedure tr_journal_trigger(); create trigger journal_survey after insert or update or delete on biohub.survey for each row execute procedure tr_journal_trigger(); + create trigger journal_submission_status after insert or update or delete on biohub.submission_status for each row execute procedure tr_journal_trigger(); create trigger journal_survey_attachment after insert or update or delete on biohub.survey_attachment for each row execute procedure tr_journal_trigger(); create trigger journal_survey_proprietor after insert or update or delete on biohub.survey_proprietor for each row execute procedure tr_journal_trigger(); - create trigger journal_system_role after insert or update or delete on biohub.system_role for each row execute procedure tr_journal_trigger(); - create trigger journal_webform_draft after insert or update or delete on biohub.webform_draft for each row execute procedure tr_journal_trigger(); + create trigger journal_system_user_role after insert or update or delete on biohub.system_user_role for each row execute procedure tr_journal_trigger(); create trigger journal_user_identity_source after insert or update or delete on biohub.user_identity_source for each row execute procedure tr_journal_trigger(); + create trigger journal_webform_draft after insert or update or delete on biohub.webform_draft for each row execute procedure tr_journal_trigger(); create trigger journal_system_user after insert or update or delete on biohub.system_user for each row execute procedure tr_journal_trigger(); - create trigger journal_investment_action_category after insert or update or delete on biohub.investment_action_category for each row execute procedure tr_journal_trigger(); create trigger journal_iucn_conservation_action_level_2_subclassification after insert or update or delete on biohub.iucn_conservation_action_level_2_subclassification for each row execute procedure tr_journal_trigger(); + create trigger journal_occurrence_submission after insert or update or delete on biohub.occurrence_submission for each row execute procedure tr_journal_trigger(); create trigger journal_project after insert or update or delete on biohub.project for each row execute procedure tr_journal_trigger(); - create trigger journal_project_type after insert or update or delete on biohub.project_type for each row execute procedure tr_journal_trigger(); - create trigger journal_submission_status after insert or update or delete on biohub.submission_status for each row execute procedure tr_journal_trigger(); - create trigger journal_submission_message after insert or update or delete on biohub.submission_message for each row execute procedure tr_journal_trigger(); + create trigger journal_permit after insert or update or delete on biohub.permit for each row execute procedure tr_journal_trigger(); diff --git a/database/src/migrations/release.0.21/smoketest_release.sql b/database/src/migrations/release.0.22/smoketest_release.sql similarity index 84% rename from database/src/migrations/release.0.21/smoketest_release.sql rename to database/src/migrations/release.0.22/smoketest_release.sql index c3b39faa68..583750057b 100644 --- a/database/src/migrations/release.0.21/smoketest_release.sql +++ b/database/src/migrations/release.0.22/smoketest_release.sql @@ -1,16 +1,23 @@ -- smoketest_release.sql -- run as db super user \c biohub +set role postgres; +set search_path=biohub; do $$ declare _count integer = 0; - _system_user_id biohub.system_user.system_user_id%type; + _system_user system_user%rowtype; + _system_user_id system_user.system_user_id%type; begin - set role postgres; - set search_path=biohub; - - delete from system_user where user_identifier = 'myIDIR'; + select * into _system_user from system_user where user_identifier = 'myIDIR'; + if _system_user.system_user_id is not null then + delete from permit where system_user_id = _system_user.system_user_id; + delete from administrative_activity where reported_system_user_id = _system_user.system_user_id; + delete from administrative_activity where assigned_system_user_id = _system_user.system_user_id; + delete from system_user_role where system_user_id = _system_user.system_user_id; + delete from system_user where system_user_id = _system_user.system_user_id; + end if; insert into system_user (user_identity_source_id, user_identifier, record_effective_date) values ((select user_identity_source_id from user_identity_source where name = 'IDIR' and record_end_date is null), 'myIDIR', now()) returning system_user_id into _system_user_id; insert into system_user_role (system_user_id, system_role_id) values (_system_user_id, (select system_role_id from system_role where name = 'System Administrator')); @@ -27,6 +34,8 @@ begin end $$; +set role biohub_api; +set search_path to biohub_dapi_v1, biohub, public, topology; do $$ declare _project_id project.project_id%type; @@ -39,15 +48,13 @@ declare _survey_status_query text := 'select project_id, survey_id, survey_status from survey_status'; _survey_status_rec survey_status%rowtype; _geography project.geography%type; + _project_funding_source_id project_funding_source.project_funding_source_id%type; begin - set role biohub_api; - set search_path to biohub_dapi_v1, biohub, public, topology; - -- set security context select api_set_context('myIDIR', 'IDIR') into _system_user_id; --select api_set_context('biohub_api', 'DATABASE') into _system_user_id; - select st_GeomFromEWKT('SRID=4326;POLYGON((-123.920288 48.592142,-123.667603 48.645205,-123.539886 48.536204,-123.583832 48.46978,-123.728027 48.460674,-123.868103 48.467959,-123.940887 48.5262,-123.920288 48.592142))') into _geography; + select st_GeomFromEWKT('SRID=4326;POLYGON((-123.920288 48.592142,-123.667603 48.645205,-123.539886 48.536204,-123.583832 48.46978,-123.728027 48.460674,-123.868103 48.467959,-123.940887 48.5262,-123.920288 48.592142), (-103.920288 38.592142,-103.667603 38.645205,-103.539886 38.536204,-103.583832 38.46978,-103.728027 38.460674,-103.868103 38.467959,-103.940887 38.5262,-103.920288 38.592142))') into _geography; insert into project (project_type_id , name @@ -67,7 +74,7 @@ begin , now()+interval '1 day' , 'coordinator_first_name' , 'coordinator_last_name' - , 'coordinator_email_address' + , 'coordinator_email_address@nowhere.com' , 'coordinator_agency_name' , TRUE , _geography @@ -77,7 +84,7 @@ begin insert into project_activity (project_id, activity_id) values (_project_id, (select activity_id from activity where name = 'Monitoring')); insert into project_climate_initiative (project_id, climate_change_initiative_id) values (_project_id, (select climate_change_initiative_id from climate_change_initiative where name = 'Monitoring')); insert into project_management_actions (project_id, management_action_type_id) values (_project_id, (select management_action_type_id from management_action_type where name = 'Recovery Action')); - insert into project_funding_source (project_id, investment_action_category_id, funding_amount, funding_start_date, funding_end_date, funding_source_project_id) values (_project_id, (select investment_action_category_id from investment_action_category where name = 'Action 1'), '$1,000.00', now(), now(), 'test'); + insert into project_funding_source (project_id, investment_action_category_id, funding_amount, funding_start_date, funding_end_date, funding_source_project_id) values (_project_id, (select investment_action_category_id from investment_action_category where name = 'Action 1'), '$1,000.00', now(), now(), 'test') returning project_funding_source_id into _project_funding_source_id; --insert into project_funding_source (project_id, investment_action_category_id, funding_amount, funding_start_date, funding_end_date) values (_project_id, 43, '$1,000.00', now(), now()); insert into project_iucn_action_classification (project_id, iucn_conservation_action_level_3_subclassification_id) values (_project_id, (select iucn_conservation_action_level_3_subclassification_id from iucn_conservation_action_level_3_subclassification where name = 'Primary education')); insert into project_attachment (project_id, file_name, title, key, file_size) values (_project_id, 'test_filename.txt', 'test filename', 'projects/'||_project_id::text, 10000); @@ -118,6 +125,9 @@ begin insert into study_species (survey_id, wldtaxonomic_units_id, is_focal) values (_survey_id, (select wldtaxonomic_units_id from wldtaxonomic_units where CODE = 'AMARALB'), true); select count(1) into _count from study_species; assert _count = 1, 'FAIL study_species'; + insert into survey_funding_source (survey_id, project_funding_source_id) values (_survey_id, _project_funding_source_id); + select count(1) into _count from survey_funding_source; + assert _count = 1, 'FAIL survey_funding_source'; -- occurrence -- occurrence submission 1 @@ -131,7 +141,7 @@ begin insert into submission_message (submission_status_id, submission_message_type_id, event_timestamp, message) values (_submission_status_id, (select submission_message_type_id from submission_message_type where name = 'Notice'), now()-interval '1 day', 'A notice message at stage submitted.'); -- transpose comments on next three lines to test deletion of published surveys by system administrator insert into submission_status (occurrence_submission_id, submission_status_type_id, event_timestamp) values (_occurrence_submission_id, (select submission_status_type_id from submission_status_type where name = 'Awaiting Curration'), now()-interval '1 day') returning submission_status_id into _submission_status_id; - --insert into submission_status (occurrence_submission_id, submission_status_type_id, event_timestamp) values (_occurrence_submission_id, (select submission_status_type_id from submission_status_type where name = 'Published'), now()-interval '1 day') returning id into _submission_status_id; + insert into submission_status (occurrence_submission_id, submission_status_type_id, event_timestamp) values (_occurrence_submission_id, (select submission_status_type_id from submission_status_type where name = 'Published'), now()-interval '1 day') returning submission_status_id into _submission_status_id; --insert into system_user_role (system_user_id, system_role_id) values (_system_user_id, (select system_role_id from system_role where name = 'System Administrator')); insert into submission_message (submission_status_id, submission_message_type_id, event_timestamp, message) values (_submission_status_id, (select submission_message_type_id from submission_message_type where name = 'Notice'), now()-interval '1 day', 'A notice message at stage published.'); @@ -147,14 +157,14 @@ begin insert into submission_status (occurrence_submission_id, submission_status_type_id, event_timestamp) values (_occurrence_submission_id, (select submission_status_type_id from submission_status_type where name = 'Rejected'), now()) returning submission_status_id into _submission_status_id; insert into submission_message (submission_status_id, submission_message_type_id, event_timestamp, message) values (_submission_status_id, (select submission_message_type_id from submission_message_type where name = 'Notice'), now(), 'A notice message at stage published.'); select count(1) into _count from submission_status; - assert _count = 4, 'FAIL submission_status'; + assert _count = 5, 'FAIL submission_status'; select count(1) into _count from submission_message; assert _count = 4, 'FAIL submission_message'; - raise notice 'survey status (project_id, survey_id, survey_status):'; - for _survey_status_rec in execute _survey_status_query loop - raise notice 'survey status results are % % %', _survey_status_rec.project_id, _survey_status_rec.survey_id, _survey_status_rec.survey_status; - end loop; +-- raise notice 'survey status (project_id, survey_id, survey_status):'; +-- for _survey_status_rec in execute _survey_status_query loop +-- raise notice 'survey status results are % % % %', _survey_status_rec.project_id, _survey_status_rec.survey_id, _survey_status_rec.occurrence_id, _survey_status_rec.survey_status; +-- end loop; -- test ancillary data delete from webform_draft; @@ -181,11 +191,11 @@ begin insert into permit (system_user_id, number, type, issue_date, end_date, coordinator_first_name, coordinator_last_name, coordinator_email_address, coordinator_agency_name) values (_system_user_id, '8377261', 'permit type', now(), now()+interval '1 day', 'first', 'last', 'nobody@nowhere.com', 'agency'); -- delete project + raise notice 'deleting data.'; call api_delete_project(_project_id); raise notice 'smoketest_release(2): PASS'; end $$; -delete from administrative_activity; delete from permit; \ No newline at end of file diff --git a/database/src/migrations/release.0.21/tr_audit_trigger.sql b/database/src/migrations/release.0.22/tr_audit_trigger.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_audit_trigger.sql rename to database/src/migrations/release.0.22/tr_audit_trigger.sql diff --git a/database/src/migrations/release.0.21/tr_journal_trigger.sql b/database/src/migrations/release.0.22/tr_journal_trigger.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_journal_trigger.sql rename to database/src/migrations/release.0.22/tr_journal_trigger.sql diff --git a/database/src/migrations/release.0.22/tr_occurrence_submission.sql b/database/src/migrations/release.0.22/tr_occurrence_submission.sql new file mode 100644 index 0000000000..1fb3d932b4 --- /dev/null +++ b/database/src/migrations/release.0.22/tr_occurrence_submission.sql @@ -0,0 +1,30 @@ +-- tr_occurrence_submission.sql +create or replace function tr_occurrence_submission() returns trigger +language plpgsql +security invoker +as +$$ +-- ******************************************************************* +-- Procedure: tr_occurrence_submission +-- Purpose: performs specific data validation +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-06-29 initial release +-- ******************************************************************* +declare + _data_package_id data_package.data_package_id%type; +begin + -- ensure that submission has submission level data package identifier + insert into data_package default values returning data_package_id into _data_package_id; + + insert into occurrence_submission_data_package (occurrence_submission_id, data_package_id) values (new.occurrence_submission_id, _data_package_id); + + return new; +end; +$$; + +drop trigger if exists occurrence_submission_val on biohub.occurrence_submission; +create trigger occurrence_submission_val after insert on biohub.occurrence_submission for each row execute procedure tr_occurrence_submission(); \ No newline at end of file diff --git a/database/src/migrations/release.0.21/tr_permit.sql b/database/src/migrations/release.0.22/tr_permit.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_permit.sql rename to database/src/migrations/release.0.22/tr_permit.sql diff --git a/database/src/migrations/release.0.21/tr_project.sql b/database/src/migrations/release.0.22/tr_project.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_project.sql rename to database/src/migrations/release.0.22/tr_project.sql diff --git a/database/src/migrations/release.0.21/tr_project_funding_source.sql b/database/src/migrations/release.0.22/tr_project_funding_source.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_project_funding_source.sql rename to database/src/migrations/release.0.22/tr_project_funding_source.sql diff --git a/database/src/migrations/release.0.21/tr_survey.sql b/database/src/migrations/release.0.22/tr_survey.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_survey.sql rename to database/src/migrations/release.0.22/tr_survey.sql diff --git a/database/src/migrations/release.0.21/tr_survey_proprietor.sql b/database/src/migrations/release.0.22/tr_survey_proprietor.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_survey_proprietor.sql rename to database/src/migrations/release.0.22/tr_survey_proprietor.sql diff --git a/database/src/migrations/release.0.21/vw_survey_status.sql b/database/src/migrations/release.0.22/vw_survey_status.sql similarity index 88% rename from database/src/migrations/release.0.21/vw_survey_status.sql rename to database/src/migrations/release.0.22/vw_survey_status.sql index cde4061cd2..6e092304df 100644 --- a/database/src/migrations/release.0.21/vw_survey_status.sql +++ b/database/src/migrations/release.0.22/vw_survey_status.sql @@ -6,12 +6,12 @@ with not_published as (select os.survey_id, max(ss.submission_status_id) as subm where os2.survey_id = os2.survey_id and ss2.occurrence_submission_id = os2.occurrence_submission_id and sst.submission_status_type_id = ss2.submission_status_type_id - and sst.name = api_get_character_system_constant('SURVEY_STATE_PUBLISHED') + and sst.name = api_get_character_system_constant('OCCURRENCE_SUBMISSION_STATE_PUBLISHED') and sst.record_end_date is null) group by os.survey_id), published as (select os.survey_id, max(ss.submission_status_id) as submission_status_id from occurrence_submission os, submission_status ss, submission_status_type sst where ss.submission_status_type_id = sst.submission_status_type_id - and sst.name = api_get_character_system_constant('SURVEY_STATE_PUBLISHED') + and sst.name = api_get_character_system_constant('OCCURRENCE_SUBMISSION_STATE_PUBLISHED') and sst.record_end_date is null group by os.survey_id) select s.project_id project_id, np.survey_id survey_id, sst.name survey_status, ss3.event_timestamp status_event_timestamp from not_published np, submission_status ss3, submission_status_type sst, survey s From 4b9dadcedc1208e86733c1684fe28989f0d1e452 Mon Sep 17 00:00:00 2001 From: charlie garrett-jones Date: Thu, 5 Aug 2021 14:40:05 -0700 Subject: [PATCH 3/6] BHBC-1249 - collapsed model changes into model mainline - implementation of api_get_eml_data_package for eml creation --- ...ts.ts => 20210715170003_secured_objects.ts | 0 .../20210225205948_biohub_release.ts | 10 +- ...15350_occurrence_submission_addFilename.ts | 52 -- ...005_adjust_procedure_api_delete_project.ts | 98 --- .../20210803170006_remove_project_region.ts | 73 -- .../release.0.21/api_delete_project.sql | 45 -- .../release.0.21/populate_system_constant.sql | 6 - .../api_delete_occurrence_submission.sql | 4 +- .../release.0.22/api_delete_project.sql | 44 ++ .../api_delete_survey.sql | 0 .../api_get_context_system_user_role_id.sql | 0 .../api_get_context_user_id.sql | 0 .../release.0.22/api_get_eml_data_package.sql | 729 ++++++++++++++++++ .../api_get_system_constant.sql | 0 .../api_get_system_metadata_constant.sql | 58 ++ .../api_set_context.sql | 0 .../api_user_is_administrator.sql | 0 .../release.0.22/api_xml_string_replace.sql | 22 + .../{release.0.21 => release.0.22}/biohub.sql | 217 +++--- .../create_spatial_extensions.psql | 0 .../dapi_custom_views.sql | 0 .../db_setup_up.sql | 4 + .../populate_activity.sql | 0 ...te_administrative_activity_status_type.sql | 0 .../populate_administrative_activity_type.sql | 0 .../populate_climate_change_initiatives.sql | 0 .../populate_first_nations.sql | 0 .../populate_funding_source.sql | 0 .../populate_investment_action_category.sql | 0 .../populate_iucn_classifications.sql | 0 .../populate_management_action_type.sql | 0 .../populate_project_role.sql | 0 .../populate_project_type.sql | 0 .../populate_proprietor_type.sql | 0 .../populate_submission_message_type.sql | 0 .../populate_submission_status_type.sql | 0 .../release.0.22/populate_system_constant.sql | 11 + .../populate_system_metadata_constant.sql | 4 +- .../populate_system_role.sql | 0 .../populate_user_identity_source.sql | 0 .../populate_wldtaxonomic_units.sql | 0 .../project_audit_triggers.sql | 26 +- .../project_dapi_views.sql | 2 +- .../project_journal_triggers.sql | 26 +- .../smoketest_release.sql | 46 +- .../tr_audit_trigger.sql | 0 .../tr_journal_trigger.sql | 0 .../release.0.22/tr_occurrence_submission.sql | 30 + .../tr_permit.sql | 0 .../tr_project.sql | 0 .../tr_project_funding_source.sql | 0 .../tr_survey.sql | 0 .../tr_survey_proprietor.sql | 0 .../vw_survey_status.sql | 4 +- 54 files changed, 1086 insertions(+), 425 deletions(-) rename database/src/migrations/20210715170003_secured_objects.ts => 20210715170003_secured_objects.ts (100%) delete mode 100644 database/src/migrations/20210726115350_occurrence_submission_addFilename.ts delete mode 100644 database/src/migrations/20210803170005_adjust_procedure_api_delete_project.ts delete mode 100644 database/src/migrations/20210803170006_remove_project_region.ts delete mode 100644 database/src/migrations/release.0.21/api_delete_project.sql delete mode 100644 database/src/migrations/release.0.21/populate_system_constant.sql rename database/src/migrations/{release.0.21 => release.0.22}/api_delete_occurrence_submission.sql (83%) create mode 100644 database/src/migrations/release.0.22/api_delete_project.sql rename database/src/migrations/{release.0.21 => release.0.22}/api_delete_survey.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/api_get_context_system_user_role_id.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/api_get_context_user_id.sql (100%) create mode 100644 database/src/migrations/release.0.22/api_get_eml_data_package.sql rename database/src/migrations/{release.0.21 => release.0.22}/api_get_system_constant.sql (100%) create mode 100644 database/src/migrations/release.0.22/api_get_system_metadata_constant.sql rename database/src/migrations/{release.0.21 => release.0.22}/api_set_context.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/api_user_is_administrator.sql (100%) create mode 100644 database/src/migrations/release.0.22/api_xml_string_replace.sql rename database/src/migrations/{release.0.21 => release.0.22}/biohub.sql (96%) rename database/src/migrations/{release.0.21 => release.0.22}/create_spatial_extensions.psql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/dapi_custom_views.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/db_setup_up.sql (92%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_activity.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_administrative_activity_status_type.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_administrative_activity_type.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_climate_change_initiatives.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_first_nations.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_funding_source.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_investment_action_category.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_iucn_classifications.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_management_action_type.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_project_role.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_project_type.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_proprietor_type.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_submission_message_type.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_submission_status_type.sql (100%) create mode 100644 database/src/migrations/release.0.22/populate_system_constant.sql rename database/src/migrations/{release.0.21 => release.0.22}/populate_system_metadata_constant.sql (81%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_system_role.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_user_identity_source.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/populate_wldtaxonomic_units.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/project_audit_triggers.sql (97%) rename database/src/migrations/{release.0.21 => release.0.22}/project_dapi_views.sql (96%) rename database/src/migrations/{release.0.21 => release.0.22}/project_journal_triggers.sql (97%) rename database/src/migrations/{release.0.21 => release.0.22}/smoketest_release.sql (84%) rename database/src/migrations/{release.0.21 => release.0.22}/tr_audit_trigger.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/tr_journal_trigger.sql (100%) create mode 100644 database/src/migrations/release.0.22/tr_occurrence_submission.sql rename database/src/migrations/{release.0.21 => release.0.22}/tr_permit.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/tr_project.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/tr_project_funding_source.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/tr_survey.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/tr_survey_proprietor.sql (100%) rename database/src/migrations/{release.0.21 => release.0.22}/vw_survey_status.sql (88%) diff --git a/database/src/migrations/20210715170003_secured_objects.ts b/20210715170003_secured_objects.ts similarity index 100% rename from database/src/migrations/20210715170003_secured_objects.ts rename to 20210715170003_secured_objects.ts diff --git a/database/src/migrations/20210225205948_biohub_release.ts b/database/src/migrations/20210225205948_biohub_release.ts index b0a91b66d6..a14b1c1e7a 100644 --- a/database/src/migrations/20210225205948_biohub_release.ts +++ b/database/src/migrations/20210225205948_biohub_release.ts @@ -5,7 +5,7 @@ import path from 'path'; const DB_USER_API_PASS = process.env.DB_USER_API_PASS; const DB_USER_API = process.env.DB_USER_API; -const DB_RELEASE = 'release.0.21'; +const DB_RELEASE = 'release.0.22'; /** * Apply biohub release changes. @@ -38,6 +38,9 @@ export async function up(knex: Knex): Promise { const tr_survey = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'tr_survey.sql')); const tr_permit = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'tr_permit.sql')); const api_get_system_constant = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_get_system_constant.sql')); + const api_get_system_metadata_constant = fs.readFileSync( + path.join(__dirname, DB_RELEASE, 'api_get_system_metadata_constant.sql') + ); const vw_survey_status = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'vw_survey_status.sql')); const api_delete_occurrence_submission = fs.readFileSync( @@ -45,6 +48,8 @@ export async function up(knex: Knex): Promise { ); const api_delete_survey = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_delete_survey.sql')); const api_delete_project = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_delete_project.sql')); + const api_xml_string_replace = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_xml_string_replace.sql')); + const api_get_eml_data_package = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_get_eml_data_package.sql')); const populate_system_constants = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'populate_system_constant.sql')); const populate_first_nations = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'populate_first_nations.sql')); @@ -134,11 +139,14 @@ export async function up(knex: Knex): Promise { ${tr_survey} ${tr_permit} ${api_get_system_constant} + ${api_get_system_metadata_constant} ${vw_survey_status} ${api_delete_occurrence_submission} ${api_delete_survey} ${api_delete_project} + ${api_xml_string_replace} + ${api_get_eml_data_package} -- populate look up tables set search_path = biohub; diff --git a/database/src/migrations/20210726115350_occurrence_submission_addFilename.ts b/database/src/migrations/20210726115350_occurrence_submission_addFilename.ts deleted file mode 100644 index 4e05ec9b09..0000000000 --- a/database/src/migrations/20210726115350_occurrence_submission_addFilename.ts +++ /dev/null @@ -1,52 +0,0 @@ -import Knex from 'knex'; - -const DB_SCHEMA = process.env.DB_SCHEMA; - -export async function up(knex: Knex): Promise { - await knex.raw(` - - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - --- --- TABLE: occurrence_submission --- - -ALTER TABLE ${DB_SCHEMA}.occurrence_submission ADD file_name varchar(300) -; - -COMMENT ON COLUMN occurrence_submission.file_name IS 'The name of the file submitted.' -; - -set search_path = biohub_dapi_v1; -set role biohub_api; - -create or replace view occurrence_submission as select * from biohub.occurrence_submission; - -set role postgres; - - `); -} - -/** - * Drop the `file_name` column in the `occurrence_submission` table. - * - * @export - * @param {Knex} knex - * @return {*} {Promise} - */ -export async function down(knex: Knex): Promise { - await knex.raw(` - SET SCHEMA '${DB_SCHEMA}'; - SET SEARCH_PATH = ${DB_SCHEMA},public, biohub_dapi_v1; - - ALTER TABLE occurrence_submission DROP COLUMN file_name; - - set role biohub_api; - - create or replace view occurrence_submission as select * from biohub.occurrence_submission; - - set role postgres; - - `); -} diff --git a/database/src/migrations/20210803170005_adjust_procedure_api_delete_project.ts b/database/src/migrations/20210803170005_adjust_procedure_api_delete_project.ts deleted file mode 100644 index bbdb07f8c7..0000000000 --- a/database/src/migrations/20210803170005_adjust_procedure_api_delete_project.ts +++ /dev/null @@ -1,98 +0,0 @@ -import * as Knex from 'knex'; - -const DB_SCHEMA = process.env.DB_SCHEMA; - -export async function up(knex: Knex): Promise { - await knex.raw(` - - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - - drop procedure if exists api_delete_project; - - create or replace procedure api_delete_project(p_project_id project.project_id%type) - language plpgsql - security definer - as - $$ - - declare - _survey_id survey.survey_id%type; - begin - for _survey_id in (select survey_id from survey where project_id = p_project_id) loop - call api_delete_survey(_survey_id); - end loop; - - delete from permit where project_id = p_project_id; - delete from survey where project_id = p_project_id; - delete from stakeholder_partnership where project_id = p_project_id; - delete from project_activity where project_id = p_project_id; - delete from project_climate_initiative where project_id = p_project_id; - delete from project_management_actions where project_id = p_project_id; - delete from project_funding_source where project_id = p_project_id; - delete from project_iucn_action_classification where project_id = p_project_id; - delete from project_attachment where project_id = p_project_id; - delete from project_first_nation where project_id = p_project_id; - delete from project_participation where project_id = p_project_id; - delete from project where project_id = p_project_id; - - exception - when others THEN - raise; - end; - $$; - - `); -} - -export async function down(knex: Knex): Promise { - await knex.raw(` - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - drop procedure if exists api_delete_project; - - create or replace procedure api_delete_project(p_project_id project.project_id%type) - language plpgsql - security definer - as - $$ - -- ******************************************************************* - -- Procedure: api_delete_project - -- Purpose: deletes a project and dependencies - -- - -- MODIFICATION HISTORY - -- Person Date Comments - -- ---------------- ----------- -------------------------------------- - -- charlie.garrettjones@quartech.com - -- 2021-04-19 initial release - -- 2021-06-21 added delete survey - -- ******************************************************************* - declare - _survey_id survey.survey_id%type; - begin - for _survey_id in (select survey_id from survey where project_id = p_project_id) loop - call api_delete_survey(_survey_id); - end loop; - - delete from permit where project_id = p_project_id; - delete from survey where project_id = p_project_id; - delete from stakeholder_partnership where project_id = p_project_id; - delete from project_activity where project_id = p_project_id; - delete from project_climate_initiative where project_id = p_project_id; - delete from project_region where project_id = p_project_id; - delete from project_management_actions where project_id = p_project_id; - delete from project_funding_source where project_id = p_project_id; - delete from project_iucn_action_classification where project_id = p_project_id; - delete from project_attachment where project_id = p_project_id; - delete from project_first_nation where project_id = p_project_id; - delete from project_participation where project_id = p_project_id; - delete from project where project_id = p_project_id; - - exception - when others THEN - raise; - end; - $$; - - `); -} diff --git a/database/src/migrations/20210803170006_remove_project_region.ts b/database/src/migrations/20210803170006_remove_project_region.ts deleted file mode 100644 index 1c3284ef8a..0000000000 --- a/database/src/migrations/20210803170006_remove_project_region.ts +++ /dev/null @@ -1,73 +0,0 @@ -import * as Knex from 'knex'; - -const DB_SCHEMA = process.env.DB_SCHEMA; - -export async function up(knex: Knex): Promise { - await knex.raw(` - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - - DROP VIEW if exists biohub_dapi_v1.project_region; - - set role postgres; - - DROP TRIGGER if exists audit_project_region on project_region; - DROP TRIGGER if exists journal_project_region on project_region; - DROP TABLE if exists project_region; - - `); -} - -export async function down(knex: Knex): Promise { - await knex.raw(` - set schema '${DB_SCHEMA}'; - set search_path = ${DB_SCHEMA},public; - - - CREATE TABLE project_region( - project_region_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - project_id integer NOT NULL, - name varchar(200) 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 project_region_pk PRIMARY KEY (project_region_id) - ); - - COMMENT ON COLUMN project_region.project_region_id IS 'System generated surrogate primary key identifier.' - ; - COMMENT ON COLUMN project_region.project_id IS 'System generated surrogate primary key identifier.' - ; - COMMENT ON COLUMN project_region.name IS 'The region name.' - ; - COMMENT ON COLUMN project_region.create_date IS 'The datetime the record was created.' - ; - COMMENT ON COLUMN project_region.create_user IS 'The id of the user who created the record as identified in the system user table.' - ; - COMMENT ON COLUMN project_region.update_date IS 'The datetime the record was updated.' - ; - COMMENT ON COLUMN project_region.update_user IS 'The id of the user who updated the record as identified in the system user table.' - ; - COMMENT ON COLUMN project_region.revision_count IS 'Revision count used for concurrency control.' - ; - COMMENT ON TABLE project_region IS 'The region of a project.' - ; - - ALTER TABLE project_region ADD CONSTRAINT "Refproject131" - FOREIGN KEY (project_id) - REFERENCES project(project_id) - ; - - create trigger audit_project_region before insert or update or delete on project_region for each row execute procedure tr_audit_trigger(); - create trigger journal_project_region after insert or update or delete on project_region for each row execute procedure tr_journal_trigger(); - - set search_path = ${DB_SCHEMA}_dapi_v1; - set role ${DB_SCHEMA}_api; - create or replace view project_region as select * from ${DB_SCHEMA}.project_region; - - set role postgres; - set search_path = ${DB_SCHEMA},public; - `); -} diff --git a/database/src/migrations/release.0.21/api_delete_project.sql b/database/src/migrations/release.0.21/api_delete_project.sql deleted file mode 100644 index 389c4cedfa..0000000000 --- a/database/src/migrations/release.0.21/api_delete_project.sql +++ /dev/null @@ -1,45 +0,0 @@ --- api_delete_project.sql -drop procedure if exists api_delete_project; - -create or replace procedure api_delete_project(p_project_id project.project_id%type) -language plpgsql -security definer -as -$$ --- ******************************************************************* --- Procedure: api_delete_project --- Purpose: deletes a project and dependencies --- --- MODIFICATION HISTORY --- Person Date Comments --- ---------------- ----------- -------------------------------------- --- charlie.garrettjones@quartech.com --- 2021-04-19 initial release --- 2021-06-21 added delete survey --- ******************************************************************* -declare - _survey_id survey.survey_id%type; -begin - for _survey_id in (select survey_id from survey where project_id = p_project_id) loop - call api_delete_survey(_survey_id); - end loop; - - delete from permit where project_id = p_project_id; - delete from survey where project_id = p_project_id; - delete from stakeholder_partnership where project_id = p_project_id; - delete from project_activity where project_id = p_project_id; - delete from project_climate_initiative where project_id = p_project_id; - delete from project_region where project_id = p_project_id; - delete from project_management_actions where project_id = p_project_id; - delete from project_funding_source where project_id = p_project_id; - delete from project_iucn_action_classification where project_id = p_project_id; - delete from project_attachment where project_id = p_project_id; - delete from project_first_nation where project_id = p_project_id; - delete from project_participation where project_id = p_project_id; - delete from project where project_id = p_project_id; - -exception - when others THEN - raise; -end; -$$; diff --git a/database/src/migrations/release.0.21/populate_system_constant.sql b/database/src/migrations/release.0.21/populate_system_constant.sql deleted file mode 100644 index 37cf1ac89f..0000000000 --- a/database/src/migrations/release.0.21/populate_system_constant.sql +++ /dev/null @@ -1,6 +0,0 @@ --- populate_system_constant.sql - --- survey states -insert into system_constant (constant_name, character_value, description) values ('SURVEY_STATE_PUBLISHED', 'Published', 'The survey state name that indicates that the data has been published and is discoverable.'); --- system roles -insert into system_constant (constant_name, character_value, description) values ('SYSTEM_ROLES_SYSTEM_ADMINISTRATOR', 'System Administrator', 'The system role name that defines a system administrator role.'); \ No newline at end of file diff --git a/database/src/migrations/release.0.21/api_delete_occurrence_submission.sql b/database/src/migrations/release.0.22/api_delete_occurrence_submission.sql similarity index 83% rename from database/src/migrations/release.0.21/api_delete_occurrence_submission.sql rename to database/src/migrations/release.0.22/api_delete_occurrence_submission.sql index 6e9ea0650b..2a9e731f36 100644 --- a/database/src/migrations/release.0.21/api_delete_occurrence_submission.sql +++ b/database/src/migrations/release.0.22/api_delete_occurrence_submission.sql @@ -23,7 +23,7 @@ begin select exists into _is_published (select 1 from survey_status ss, occurrence_submission os where os.occurrence_submission_id = _occurrence_submission_id and ss.survey_id = os.survey_id - and ss.survey_status = (select api_get_character_system_constant('SURVEY_STATE_PUBLISHED'))); + and ss.survey_status = (select api_get_character_system_constant('OCCURRENCE_SUBMISSION_STATE_PUBLISHED'))); if _is_published then select api_user_is_administrator() into _is_system_administrator; @@ -36,6 +36,8 @@ begin delete from submission_message where submission_status_id in (select submission_status_id from submission_status where occurrence_submission_id = _occurrence_submission_id); delete from submission_status where occurrence_submission_id = _occurrence_submission_id; delete from occurrence where occurrence_submission_id = _occurrence_submission_id; + delete from occurrence_submission_data_package where occurrence_submission_id = _occurrence_submission_id; + delete from data_package where data_package_id in (select data_package_id from occurrence_submission_data_package where occurrence_submission_id = _occurrence_submission_id); delete from occurrence_submission where occurrence_submission_id = _occurrence_submission_id; exception diff --git a/database/src/migrations/release.0.22/api_delete_project.sql b/database/src/migrations/release.0.22/api_delete_project.sql new file mode 100644 index 0000000000..4ce7ab1584 --- /dev/null +++ b/database/src/migrations/release.0.22/api_delete_project.sql @@ -0,0 +1,44 @@ +-- api_delete_project.sql +drop procedure if exists api_delete_project; + +create or replace procedure api_delete_project(p_project_id project.project_id%type) +language plpgsql +security definer +as +$$ +-- ******************************************************************* +-- Procedure: api_delete_project +-- Purpose: deletes a project and dependencies +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-04-19 initial release +-- 2021-06-21 added delete survey +-- ******************************************************************* +declare + _survey_id survey.survey_id%type; + begin + for _survey_id in (select survey_id from survey where project_id = p_project_id) loop + call api_delete_survey(_survey_id); + end loop; + + delete from permit where project_id = p_project_id; + delete from survey where project_id = p_project_id; + delete from stakeholder_partnership where project_id = p_project_id; + delete from project_activity where project_id = p_project_id; + delete from project_climate_initiative where project_id = p_project_id; + delete from project_management_actions where project_id = p_project_id; + delete from project_funding_source where project_id = p_project_id; + delete from project_iucn_action_classification where project_id = p_project_id; + delete from project_attachment where project_id = p_project_id; + delete from project_first_nation where project_id = p_project_id; + delete from project_participation where project_id = p_project_id; + delete from project where project_id = p_project_id; + +exception + when others THEN + raise; +end; +$$; diff --git a/database/src/migrations/release.0.21/api_delete_survey.sql b/database/src/migrations/release.0.22/api_delete_survey.sql similarity index 100% rename from database/src/migrations/release.0.21/api_delete_survey.sql rename to database/src/migrations/release.0.22/api_delete_survey.sql diff --git a/database/src/migrations/release.0.21/api_get_context_system_user_role_id.sql b/database/src/migrations/release.0.22/api_get_context_system_user_role_id.sql similarity index 100% rename from database/src/migrations/release.0.21/api_get_context_system_user_role_id.sql rename to database/src/migrations/release.0.22/api_get_context_system_user_role_id.sql diff --git a/database/src/migrations/release.0.21/api_get_context_user_id.sql b/database/src/migrations/release.0.22/api_get_context_user_id.sql similarity index 100% rename from database/src/migrations/release.0.21/api_get_context_user_id.sql rename to database/src/migrations/release.0.22/api_get_context_user_id.sql diff --git a/database/src/migrations/release.0.22/api_get_eml_data_package.sql b/database/src/migrations/release.0.22/api_get_eml_data_package.sql new file mode 100644 index 0000000000..7aeed96d1a --- /dev/null +++ b/database/src/migrations/release.0.22/api_get_eml_data_package.sql @@ -0,0 +1,729 @@ +-- api_get_eml_data_package.sql + +drop function if exists api_get_eml_data_package; + +create or replace function api_get_eml_data_package(p_data_package_id data_package.data_package_id%type, p_supplied_title varchar) returns xml +language plpgsql +security definer +stable +as +$$ +-- ******************************************************************* +-- Procedure: api_get_eml_data_package +-- Purpose: returns eml xml of a data package. +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-07-29 initial release +-- ******************************************************************* +declare + _BIOHUB_EML_VERSION constant varchar := '1.0'; + _eml_xml_text varchar; + + _BIOHUB_PROVIDER_URL constant system_metadata_constant.character_value%type := api_xml_string_replace(api_get_character_system_metadata_constant('BIOHUB_PROVIDER_URL')); + _SECURITY_PROVIDER_URL constant system_metadata_constant.character_value%type := api_xml_string_replace(api_get_character_system_metadata_constant('SECURITY_PROVIDER_URL')); + _ORGANIZATION_NAME_FULL constant system_metadata_constant.character_value%type := api_xml_string_replace(api_get_character_system_metadata_constant('ORGANIZATION_NAME_FULL')); + _ORGANIZATION_URL constant system_metadata_constant.character_value%type := api_xml_string_replace(api_get_character_system_metadata_constant('ORGANIZATION_URL')); + _INTELLECTUAL_RIGHTS constant system_metadata_constant.character_value%type := api_xml_string_replace(api_get_character_system_metadata_constant('INTELLECTUAL_RIGHTS')); + _TAXONOMIC_PROVIDER_URL constant system_metadata_constant.character_value%type := api_xml_string_replace(api_get_character_system_metadata_constant('TAXONOMIC_PROVIDER_URL')); + + _r_data_package data_package%rowtype; + _r_occurrence_submission occurrence_submission%rowtype; + _r_survey survey%rowtype; + _r_project project%rowtype; + + _exists boolean := false; + _record record; + _record2 record; + _string varchar; +begin + select * into strict _r_data_package from data_package + where data_package_id = p_data_package_id; + + select a.* into strict _r_occurrence_submission from occurrence_submission a, occurrence_submission_data_package b, data_package c + where c.data_package_id = _r_data_package.data_package_id + and b.data_package_id = c.data_package_id + and a.occurrence_submission_id = b.occurrence_submission_id; + + + _eml_xml_text := format(' + + + public + read + + + + %4$s + + %5$s + + + %5$s + %6$s + ' + , _r_data_package.uuid + , _BIOHUB_PROVIDER_URL + , _SECURITY_PROVIDER_URL + , api_xml_string_replace(p_supplied_title) + , _ORGANIZATION_NAME_FULL + , _ORGANIZATION_URL + ); + + _eml_xml_text := _eml_xml_text||format('%1$s' + , (select to_char(ss.event_timestamp, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE')) from submission_status ss, submission_status_type sst + where ss.submission_status_id = (select max(submission_status_id) from submission_status ss2 + where ss2.occurrence_submission_id = _r_occurrence_submission.occurrence_submission_id) + and ss.submission_status_type_id = sst.submission_status_type_id + and sst.name = api_get_character_system_constant('OCCURRENCE_SUBMISSION_STATE_PUBLISHED') + and sst.record_end_date is null)); + + _eml_xml_text := _eml_xml_text||format('english + + %1$s + ' + , _INTELLECTUAL_RIGHTS); + + -- TODO: handle arbitrary sets of occurrence records + if _r_occurrence_submission.survey_id is not null then + -- occurrence submission is associated with survey + select * into strict _r_survey from survey where survey_id = _r_occurrence_submission.survey_id; + select * into strict _r_project from project where project_id = _r_survey.project_id; + + _eml_xml_text := _eml_xml_text||''; + if _r_project.coordinator_public then + _eml_xml_text := _eml_xml_text||format(' + + %1$s + %2$s + + %3$s + %4$s' + , api_xml_string_replace(_r_project.coordinator_first_name) + , api_xml_string_replace(_r_project.coordinator_last_name) + , api_xml_string_replace(_r_project.coordinator_agency_name) + , api_xml_string_replace(_r_project.coordinator_email_address)); + else + _eml_xml_text := _eml_xml_text||format(' + %1$s + %2$s' + , _ORGANIZATION_NAME_FULL + , _ORGANIZATION_URL); + end if; + _eml_xml_text := _eml_xml_text||''; + + _eml_xml_text := _eml_xml_text||format(' + + %3$s + ' + , _r_survey.UUID + , _BIOHUB_PROVIDER_URL + , api_xml_string_replace(_r_survey.name)); + + if _r_project.coordinator_public then + _eml_xml_text := _eml_xml_text||format(' + + %1$s + %2$s + + %3$s + pointOfContact' + , api_xml_string_replace(_r_survey.lead_first_name) + , api_xml_string_replace(_r_survey.lead_last_name) + , api_xml_string_replace(_r_project.coordinator_agency_name)); + else + _eml_xml_text := _eml_xml_text||format(' + %1$s + %2$s + custodianSteward' + , _ORGANIZATION_NAME_FULL + , _ORGANIZATION_URL); + end if; + _eml_xml_text := _eml_xml_text||''; + + _eml_xml_text := _eml_xml_text||format(' + +
+ Objectives + %1$s +
+
' + , api_xml_string_replace(_r_survey.objectives)); + + select true into _exists from project_funding_source + where exists (select project_funding_source_id from survey_funding_source where survey_id = _r_survey.survey_id); + + if _exists then + _eml_xml_text := _eml_xml_text||' + +
+ Funding Source'; + + for _record in (select a.*, b.name investment_action_category_name, c.name funding_source_name from project_funding_source a, investment_action_category b, funding_source c + where project_funding_source_id in (select project_funding_source_id from survey_funding_source where survey_id = _r_survey.survey_id) + and b.investment_action_category_id = a.investment_action_category_id + and c.funding_source_id = b.funding_source_id) loop + + _eml_xml_text := _eml_xml_text||format(' + %1$s +
+ Investment Action Category + %2$s +
+ Funding Source Project ID + %3$s +
+
+ Funding Amount + %4$s +
+
+ Funding Start Date + %5$s +
+
+ Funding Start Date + %6$s +
+
' + , api_xml_string_replace(_record.funding_source_name) + , api_xml_string_replace(_record.investment_action_category_name) + , _record.project_funding_source_id + , _record.funding_amount + , to_char(_record.funding_start_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE')) + , to_char(_record.funding_end_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE'))); + end loop; + + _eml_xml_text := _eml_xml_text||' +
+
'; + end if; + _exists := false; + + -- TODO: this only provides us with the bounding box of the first polygon + with envelope as (select ST_Envelope(geography::geometry) geom from survey s where survey_id = _r_survey.survey_id) + select st_xmax(geom), st_ymax(geom), st_xmin(geom), st_ymin(geom) into _record from envelope; + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + %2$s + %3$s + %4$s + %5$s + ' +, case when _r_survey.location_description is not null then api_xml_string_replace(_r_survey.location_name||' - '||_r_survey.location_description) + else api_xml_string_replace(_r_survey.location_name) end +-- , api_xml_string_replace(_r_survey.location_name||' - '||_r_survey.location_description) + , _record.st_xmin + , _record.st_xmax + , _record.st_ymax + , _record.st_ymin); + + for _record in (with polygons as (select (st_dumppoints(g.geom)).* from (select geography::geometry as geom from survey where survey_id = 1) as g) + select distinct(path[1]) polygon from polygons) loop + _eml_xml_text := _eml_xml_text||' + + '; + + for _record2 in (with polygons as (select (st_dumppoints(g.geom)).* from (select geography::geometry as geom from survey where survey_id = 1) as g) + , points as (select geom from polygons where path[1] = _record.polygon) + select st_x(geom) x, st_y(geom) y from points) loop + _eml_xml_text := _eml_xml_text||format(' + + %1$s + %2$s + ' + , _record2.y + , _record2.x); + end loop; + + _eml_xml_text := _eml_xml_text||' + + '; + end loop; + _eml_xml_text := _eml_xml_text||''; + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + %2$s + + + ' + , to_char(_r_survey.start_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE')) + , to_char(_r_survey.end_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE'))); + + _eml_xml_text := _eml_xml_text||' + + '; + + for _record in (select a.* from wldtaxonomic_units a, study_species b + where a.wldtaxonomic_units_id = b.wldtaxonomic_units_id + and b.survey_id = _r_survey.survey_id + and b.is_focal) loop + _eml_xml_text := _eml_xml_text||format(' + %1$s + %2$s + %3$s + %5$s' + , api_xml_string_replace(_record.tty_name) + , api_xml_string_replace(_record.unit_name1||' '||_record.unit_name2) + , api_xml_string_replace(_record.english_name) + , _TAXONOMIC_PROVIDER_URL + , api_xml_string_replace(_record.code)); + end loop; + for _record in (select a.* from wldtaxonomic_units a, study_species b + where a.wldtaxonomic_units_id = b.wldtaxonomic_units_id + and b.survey_id = _r_survey.survey_id + and not b.is_focal) loop + _eml_xml_text := _eml_xml_text||format(' + + %1$s + %2$s + %3$s + %5$s + ' + , api_xml_string_replace(_record.tty_name) + , api_xml_string_replace(_record.unit_name1||' '||_record.unit_name2) + , api_xml_string_replace(_record.english_name) + , _TAXONOMIC_PROVIDER_URL + , api_xml_string_replace(_record.code)); + end loop; + _eml_xml_text := _eml_xml_text||' + + '; + _eml_xml_text := _eml_xml_text||' + + '; + + _eml_xml_text := _eml_xml_text||format(' + + %3$s + ' + , _r_project.UUID + , _BIOHUB_PROVIDER_URL + , api_xml_string_replace(_r_project.name)); + + if _r_project.coordinator_public then + _eml_xml_text := _eml_xml_text||format(' + + %1$s + %2$s + + %3$s + %4$s + pointOfContact' + , api_xml_string_replace(_r_project.coordinator_first_name) + , api_xml_string_replace(_r_project.coordinator_last_name) + , api_xml_string_replace(_r_project.coordinator_agency_name) + , api_xml_string_replace(_r_project.coordinator_email_address)); + else + _eml_xml_text := _eml_xml_text||format(' + %1$s + %2$s + custodianSteward' + , _ORGANIZATION_NAME_FULL + , _ORGANIZATION_URL); + end if; + _eml_xml_text := _eml_xml_text||''; + + _eml_xml_text := _eml_xml_text||format(' + +
+ Objectives + %1$s +
+
+ Caveates + %2$s +
+
+ Comments + %3$s +
+
' + , api_xml_string_replace(_r_project.objectives) + , api_xml_string_replace(_r_project.caveats) + , api_xml_string_replace(_r_project.comments)); + + select true into _exists from project_funding_source + where exists (select project_funding_source_id from project_funding_source where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||' + +
+ Funding Source'; + + for _record in (select a.*, b.name investment_action_category_name, c.name funding_source_name from project_funding_source a, investment_action_category b, funding_source c + where project_funding_source_id in (select project_funding_source_id from project_funding_source where project_id = _r_project.project_id) + and b.investment_action_category_id = a.investment_action_category_id + and c.funding_source_id = b.funding_source_id) loop + + _eml_xml_text := _eml_xml_text||format(' + %1$s +
+ Investment Action Category + %2$s +
+ Funding Source Project ID + %3$s +
+
+ Funding Amount + %4$s +
+
+ Funding Start Date + %5$s +
+
+ Funding Start Date + %6$s +
+
' + , api_xml_string_replace(_record.funding_source_name) + , api_xml_string_replace(_record.investment_action_category_name) + , _record.project_funding_source_id + , _record.funding_amount + , to_char(_record.funding_start_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE')) + , to_char(_record.funding_end_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE'))); + end loop; + + _eml_xml_text := _eml_xml_text||' +
+
'; + end if; + _exists := false; + + -- TODO: this only provides us with the bounding box of the first polygon + with envelope as (select ST_Envelope(geography::geometry) geom from project where project_id = _r_project.project_id) + select st_xmax(geom), st_ymax(geom), st_xmin(geom), st_ymin(geom) into _record from envelope; + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + %2$s + %3$s + %4$s + %5$s + ' + , coalesce(api_xml_string_replace(_r_project.location_description), api_get_character_system_constant('DATA_NOT_PROVIDED_MESSAGE')) + , _record.st_xmin + , _record.st_xmax + , _record.st_ymax + , _record.st_ymin); + + for _record in (with polygons as (select (st_dumppoints(g.geom)).* from (select geography::geometry as geom from project where project_id = _r_project.project_id) as g) + select distinct(path[1]) polygon from polygons) loop + _eml_xml_text := _eml_xml_text||' + + '; + + for _record2 in (with polygons as (select (st_dumppoints(g.geom)).* from (select geography::geometry as geom from project where project_id = _r_project.project_id) as g) + , points as (select geom from polygons where path[1] = _record.polygon) + select st_x(geom) x, st_y(geom) y from points) loop + _eml_xml_text := _eml_xml_text||format(' + + %1$s + %2$s + ' + , _record2.y + , _record2.x); + end loop; + + _eml_xml_text := _eml_xml_text||' + + '; + end loop; + _eml_xml_text := _eml_xml_text||''; + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + %2$s + + + ' + , to_char(_r_project.start_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE')) + , to_char(_r_project.end_date, api_get_character_system_constant('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE'))); + + _eml_xml_text := _eml_xml_text||' + + '; + _eml_xml_text := _eml_xml_text||'
'; + _eml_xml_text := _eml_xml_text||'
'; + _eml_xml_text := _eml_xml_text||'
'; + + select true into _exists from project_iucn_action_classification + where exists (select project_id from project_iucn_action_classification where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name level_1_name, b.name level_2_name, c.name level_3_name from iucn_conservation_action_level_1_classification a + , iucn_conservation_action_level_2_subclassification b, iucn_conservation_action_level_3_subclassification c, project_iucn_action_classification d + where d.project_id = _r_project.project_id + and c.iucn_conservation_action_level_3_subclassification_id = d.iucn_conservation_action_level_3_subclassification_id + and b.iucn_conservation_action_level_2_subclassification_id = c.iucn_conservation_action_level_2_subclassification_id + and a.iucn_conservation_action_level_1_classification_id = b.iucn_conservation_action_level_1_classification_id) loop + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + %1$s + %1$s + + + ' + , api_xml_string_replace(_record.level_1_name) + , api_xml_string_replace(_record.level_2_name) + , api_xml_string_replace(_record.level_3_name)); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + select true into _exists from stakeholder_partnership + where exists (select project_id from stakeholder_partnership where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name from stakeholder_partnership a + where a.project_id = _r_project.project_id) loop + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + ' + , api_xml_string_replace(_record.name)); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + select true into _exists from project_activity + where exists (select project_id from project_activity where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name from activity a, project_activity b + where b.project_id = _r_project.project_id + and a.activity_id = b.activity_id) loop + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + ' + , api_xml_string_replace(_record.name)); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + select true into _exists from project_climate_initiative + where exists (select project_id from project_climate_initiative where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name from climate_change_initiative a, project_climate_initiative b + where b.project_id = _r_project.project_id + and a.climate_change_initiative_id = b.climate_change_initiative_id) loop + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + ' + , api_xml_string_replace(_record.name)); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + select true into _exists from project_first_nation + where exists (select project_id from project_first_nation where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name from first_nations a, project_first_nation b + where b.project_id = _r_project.project_id + and a.first_nations_id = b.first_nations_id) loop + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + ' + , api_xml_string_replace(_record.name)); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + select true into _exists from project_management_actions + where exists (select project_id from project_management_actions where project_id = _r_project.project_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name from management_action_type a, project_management_actions b + where b.project_id = _r_project.project_id + and a.management_action_type_id = b.management_action_type_id) loop + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + + + ' + , api_xml_string_replace(_record.name)); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + select true into _exists from survey_proprietor + where exists (select survey_id from survey_proprietor where survey_id = _r_survey.survey_id); + + if _exists then + _eml_xml_text := _eml_xml_text||format(' + + %1$s' + , _r_project.UUID); + + for _record in (select a.name proprietor_type_name, b.name first_nations_name, c.* from proprietor_type a, first_nations b, survey_proprietor c + where c.survey_id = _r_survey.survey_id + and b.first_nations_id = c.first_nations_id + and a.proprietor_type_id = c.proprietor_type_id) loop + + if _record.disa_required then + _string := 'Yes'; + else + _string := 'No'; + end if; + + _eml_xml_text := _eml_xml_text||format(' + + + + %1$s + %2$s + %3$s + %4$s + %5$s + + + ' + , api_xml_string_replace(_record.first_nations_name) + , api_xml_string_replace(_record.proprietor_type_name) + , api_xml_string_replace(_record.rationale) + , api_xml_string_replace(_record.proprietor_name) + , _string + ); + + end loop; + _eml_xml_text := _eml_xml_text||' + '; + end if; + _exists := false; + + _eml_xml_text := _eml_xml_text||format(' + + %1$s + + + survey + %2$s + + + ' + , _r_data_package.UUID + , _BIOHUB_EML_VERSION); + + -- end occurrence submission associated with survey + end if; + + _eml_xml_text := _eml_xml_text||'
'; + return xmlparse(DOCUMENT _eml_xml_text); + +exception + when others then + raise; +end; +$$; + +grant execute on function api_get_eml_data_package to biohub_api; diff --git a/database/src/migrations/release.0.21/api_get_system_constant.sql b/database/src/migrations/release.0.22/api_get_system_constant.sql similarity index 100% rename from database/src/migrations/release.0.21/api_get_system_constant.sql rename to database/src/migrations/release.0.22/api_get_system_constant.sql diff --git a/database/src/migrations/release.0.22/api_get_system_metadata_constant.sql b/database/src/migrations/release.0.22/api_get_system_metadata_constant.sql new file mode 100644 index 0000000000..8916e5d5e7 --- /dev/null +++ b/database/src/migrations/release.0.22/api_get_system_metadata_constant.sql @@ -0,0 +1,58 @@ +-- api_get_system_metadata_constant.sql +drop function if exists api_get_character_system_metadata_constant; + +create or replace function api_get_character_system_metadata_constant(_constant_name system_metadata_constant.constant_name%type) returns system_metadata_constant.character_value%type +language plpgsql +security definer +stable +as +$$ +-- ******************************************************************* +-- Procedure: api_get_character_system_metadata_constant +-- Purpose: returns a text value from the system constants table +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-06-29 initial release +-- ******************************************************************* +begin + return (select character_value from system_metadata_constant where constant_name = _constant_name); + +exception + when others then + raise; +end; +$$; + +grant execute on function api_get_character_system_metadata_constant to biohub_api; + +drop function if exists api_get_numeric_system_metadata_constant; + +create or replace function api_get_numeric_system_metadata_constant(_constant_name system_metadata_constant.constant_name%type) returns system_metadata_constant.numeric_value%type +language plpgsql +security definer +stable +as +$$ +-- ******************************************************************* +-- Procedure: api_get_numeric_system_metadata_constant +-- Purpose: returns a numeric value from the system constants table +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-06-29 initial release +-- ******************************************************************* +begin + return (select numeric_value from system_metadata_constant where constant_name = _constant_name); + +exception + when others then + raise; +end; +$$; + +grant execute on function api_get_numeric_system_metadata_constant to biohub_api; diff --git a/database/src/migrations/release.0.21/api_set_context.sql b/database/src/migrations/release.0.22/api_set_context.sql similarity index 100% rename from database/src/migrations/release.0.21/api_set_context.sql rename to database/src/migrations/release.0.22/api_set_context.sql diff --git a/database/src/migrations/release.0.21/api_user_is_administrator.sql b/database/src/migrations/release.0.22/api_user_is_administrator.sql similarity index 100% rename from database/src/migrations/release.0.21/api_user_is_administrator.sql rename to database/src/migrations/release.0.22/api_user_is_administrator.sql diff --git a/database/src/migrations/release.0.22/api_xml_string_replace.sql b/database/src/migrations/release.0.22/api_xml_string_replace.sql new file mode 100644 index 0000000000..aaed2b8ad3 --- /dev/null +++ b/database/src/migrations/release.0.22/api_xml_string_replace.sql @@ -0,0 +1,22 @@ +-- api_xml_string_replace.sql +create or replace function api_xml_string_replace(p_string varchar) returns varchar +language plpgsql +security invoker +stable +as +$$ +-- ******************************************************************* +-- Procedure: api_xml_string_replace +-- Purpose: returns an string with replacments for <,> and & +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-01-03 initial release +-- ******************************************************************* +begin + + return replace(replace(replace(p_string, '&', '&'), '<', '<'), '>', '>'); +end; +$$; \ No newline at end of file diff --git a/database/src/migrations/release.0.21/biohub.sql b/database/src/migrations/release.0.22/biohub.sql similarity index 96% rename from database/src/migrations/release.0.21/biohub.sql rename to database/src/migrations/release.0.22/biohub.sql index 93af576fec..897c503c17 100644 --- a/database/src/migrations/release.0.21/biohub.sql +++ b/database/src/migrations/release.0.22/biohub.sql @@ -2,7 +2,7 @@ -- ER/Studio Data Architect SQL Code Generation -- Project : BioHub.DM1 -- --- Date Created : Wednesday, July 21, 2021 15:25:27 +-- Date Created : Thursday, August 05, 2021 14:02:54 -- Target DBMS : PostgreSQL 10.x-12.x -- @@ -290,7 +290,7 @@ CREATE TABLE data_package( COMMENT ON COLUMN data_package.data_package_id IS 'System generated surrogate primary key identifier.' ; -COMMENT ON COLUMN data_package.uuid IS 'System generated UUID data package identifier.' +COMMENT ON COLUMN data_package.uuid IS 'The universally unique identifier for the record.' ; COMMENT ON COLUMN data_package.create_date IS 'The datetime the record was created.' ; @@ -691,6 +691,44 @@ COMMENT ON COLUMN occurrence.revision_count IS 'Revision count used for concurre COMMENT ON TABLE occurrence IS 'Occurrence records that have been ingested from submissions sources.' ; +-- +-- TABLE: occurrence_data_package +-- + +CREATE TABLE occurrence_data_package( + occurrence_data_package_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + data_package_id integer NOT NULL, + occurrence_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 occurrence_data_package_pk PRIMARY KEY (occurrence_data_package_id) +) +; + + + +COMMENT ON COLUMN occurrence_data_package.occurrence_data_package_id IS 'System generated surrogate primary key identifier.' +; +COMMENT ON COLUMN occurrence_data_package.data_package_id IS 'System generated surrogate primary key identifier.' +; +COMMENT ON COLUMN occurrence_data_package.occurrence_id IS 'System generated surrogate primary key identifier.' +; +COMMENT ON COLUMN occurrence_data_package.create_date IS 'The datetime the record was created.' +; +COMMENT ON COLUMN occurrence_data_package.create_user IS 'The id of the user who created the record as identified in the system user table.' +; +COMMENT ON COLUMN occurrence_data_package.update_date IS 'The datetime the record was updated.' +; +COMMENT ON COLUMN occurrence_data_package.update_user IS 'The id of the user who updated the record as identified in the system user table.' +; +COMMENT ON COLUMN occurrence_data_package.revision_count IS 'Revision count used for concurrency control.' +; +COMMENT ON TABLE occurrence_data_package IS 'An associative entity that joins data package identifiers and occurrences.' +; + -- -- TABLE: occurrence_submission -- @@ -701,6 +739,7 @@ CREATE TABLE occurrence_submission( source varchar(300) NOT NULL, event_timestamp TIMESTAMPTZ NOT NULL, key varchar(1000), + file_name varchar(300), create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -722,6 +761,8 @@ COMMENT ON COLUMN occurrence_submission.event_timestamp IS 'The timestamp of the ; COMMENT ON COLUMN occurrence_submission.key IS 'The identifying key to the file in the storage system.' ; +COMMENT ON COLUMN occurrence_submission.file_name IS 'The name of the file submitted.' +; COMMENT ON COLUMN occurrence_submission.create_date IS 'The datetime the record was created.' ; COMMENT ON COLUMN occurrence_submission.create_user IS 'The id of the user who created the record as identified in the system user table.' @@ -741,8 +782,8 @@ COMMENT ON TABLE occurrence_submission IS 'Provides a historical listing of publ CREATE TABLE occurrence_submission_data_package( occurrence_submission_data_package_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - occurrence_submission_id integer NOT NULL, data_package_id integer NOT NULL, + occurrence_submission_id integer NOT NULL, create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -756,10 +797,10 @@ CREATE TABLE occurrence_submission_data_package( COMMENT ON COLUMN occurrence_submission_data_package.occurrence_submission_data_package_id IS 'System generated surrogate primary key identifier.' ; -COMMENT ON COLUMN occurrence_submission_data_package.occurrence_submission_id IS 'System generated surrogate primary key identifier.' -; COMMENT ON COLUMN occurrence_submission_data_package.data_package_id IS 'System generated surrogate primary key identifier.' ; +COMMENT ON COLUMN occurrence_submission_data_package.occurrence_submission_id IS 'System generated surrogate primary key identifier.' +; COMMENT ON COLUMN occurrence_submission_data_package.create_date IS 'The datetime the record was created.' ; COMMENT ON COLUMN occurrence_submission_data_package.create_user IS 'The id of the user who created the record as identified in the system user table.' @@ -852,29 +893,29 @@ NOTE: there are conceptual problems with associating permits to projects early i -- CREATE TABLE project( - project_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - project_type_id integer NOT NULL, - name varchar(50) NOT NULL, - objectives varchar(3000) NOT NULL, - management_recovery_action character(1), - location_description varchar(3000), - start_date date NOT NULL, - end_date date, - caveats varchar(3000), - comments varchar(3000), - coordinator_first_name varchar(50) NOT NULL, - coordinator_last_name varchar(50) NOT NULL, - coordinator_email_address varchar(500) NOT NULL, - coordinator_agency_name varchar(300) NOT NULL, - coordinator_public boolean NOT NULL, - publish_timestamp TIMESTAMPTZ, - geometry geometry(geometry, 3005), - geography geography(geometry), - 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, + project_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + project_type_id integer NOT NULL, + uuid uuid DEFAULT public.gen_random_uuid(), + name varchar(50) NOT NULL, + objectives varchar(3000) NOT NULL, + location_description varchar(3000), + start_date date NOT NULL, + end_date date, + caveats varchar(3000), + comments varchar(3000), + coordinator_first_name varchar(50) NOT NULL, + coordinator_last_name varchar(50) NOT NULL, + coordinator_email_address varchar(500) NOT NULL, + coordinator_agency_name varchar(300) NOT NULL, + coordinator_public boolean NOT NULL, + publish_timestamp TIMESTAMPTZ, + geometry geometry(geometry, 3005), + geography geography(geometry), + 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 project_pk PRIMARY KEY (project_id) ) ; @@ -885,12 +926,12 @@ COMMENT ON COLUMN project.project_id IS 'System generated surrogate primary key ; COMMENT ON COLUMN project.project_type_id IS 'System generated surrogate primary key identifier.' ; +COMMENT ON COLUMN project.uuid IS 'The universally unique identifier for the record.' +; COMMENT ON COLUMN project.name IS 'Name given to a project.' ; COMMENT ON COLUMN project.objectives IS 'The objectives for the project.' ; -COMMENT ON COLUMN project.management_recovery_action IS 'Identifies if the project addresses a management or recovery action.' -; COMMENT ON COLUMN project.location_description IS 'The location description.' ; COMMENT ON COLUMN project.start_date IS 'The start date of the project.' @@ -1264,44 +1305,6 @@ COMMENT ON COLUMN project_participation.revision_count IS 'Revision count used f COMMENT ON TABLE project_participation IS 'A associative entity that joins projects, system users and project role types.' ; --- --- TABLE: project_region --- - -CREATE TABLE project_region( - project_region_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - project_id integer NOT NULL, - name varchar(200) 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 project_region_pk PRIMARY KEY (project_region_id) -) -; - - - -COMMENT ON COLUMN project_region.project_region_id IS 'System generated surrogate primary key identifier.' -; -COMMENT ON COLUMN project_region.project_id IS 'System generated surrogate primary key identifier.' -; -COMMENT ON COLUMN project_region.name IS 'The region name.' -; -COMMENT ON COLUMN project_region.create_date IS 'The datetime the record was created.' -; -COMMENT ON COLUMN project_region.create_user IS 'The id of the user who created the record as identified in the system user table.' -; -COMMENT ON COLUMN project_region.update_date IS 'The datetime the record was updated.' -; -COMMENT ON COLUMN project_region.update_user IS 'The id of the user who updated the record as identified in the system user table.' -; -COMMENT ON COLUMN project_region.revision_count IS 'Revision count used for concurrency control.' -; -COMMENT ON TABLE project_region IS 'The region of a project.' -; - -- -- TABLE: project_role -- @@ -1699,6 +1702,7 @@ COMMENT ON TABLE submission_status_type IS 'The status types of submissions. Typ CREATE TABLE survey( survey_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), project_id integer NOT NULL, + uuid uuid DEFAULT public.gen_random_uuid(), name varchar(300), objectives varchar(3000) NOT NULL, start_date date NOT NULL, @@ -1725,6 +1729,8 @@ COMMENT ON COLUMN survey.survey_id IS 'System generated surrogate primary key id ; COMMENT ON COLUMN survey.project_id IS 'System generated surrogate primary key identifier.' ; +COMMENT ON COLUMN survey.uuid IS 'The universally unique identifier for the record.' +; COMMENT ON COLUMN survey.name IS 'Name given to a survey.' ; COMMENT ON COLUMN survey.objectives IS 'The objectives for the survey.' @@ -2396,22 +2402,40 @@ CREATE UNIQUE INDEX management_action_type_nuk1 ON management_action_type(name, CREATE INDEX "Ref165161" ON occurrence(occurrence_submission_id) ; -- +-- INDEX: "Ref185170" +-- + +CREATE INDEX "Ref185170" ON occurrence_data_package(data_package_id) +; +-- +-- INDEX: "Ref169174" +-- + +CREATE INDEX "Ref169174" ON occurrence_data_package(occurrence_id) +; +-- -- INDEX: "Ref153160" -- CREATE INDEX "Ref153160" ON occurrence_submission(survey_id) ; -- --- INDEX: "Ref165169" +-- INDEX: occurrence_submission_data_package_uk1 -- -CREATE INDEX "Ref165169" ON occurrence_submission_data_package(occurrence_submission_id) +CREATE UNIQUE INDEX occurrence_submission_data_package_uk1 ON occurrence_submission_data_package(data_package_id, occurrence_submission_id) ; -- --- INDEX: "Ref185170" +-- INDEX: "Ref185175" -- -CREATE INDEX "Ref185170" ON occurrence_submission_data_package(data_package_id) +CREATE INDEX "Ref185175" ON occurrence_submission_data_package(data_package_id) +; +-- +-- INDEX: "Ref165176" +-- + +CREATE INDEX "Ref165176" ON occurrence_submission_data_package(occurrence_submission_id) ; -- -- INDEX: permit_uk1 @@ -2588,18 +2612,6 @@ CREATE INDEX "Ref78149" ON project_participation(system_user_id) CREATE INDEX "Ref100150" ON project_participation(project_role_id) ; -- --- INDEX: project_region_uk1 --- - -CREATE UNIQUE INDEX project_region_uk1 ON project_region(name, project_id) -; --- --- INDEX: "Ref45131" --- - -CREATE INDEX "Ref45131" ON project_region(project_id) -; --- -- INDEX: project_role_nuk1 -- @@ -2856,6 +2868,21 @@ ALTER TABLE occurrence ADD CONSTRAINT "Refoccurrence_submission161" ; +-- +-- TABLE: occurrence_data_package +-- + +ALTER TABLE occurrence_data_package ADD CONSTRAINT "Refdata_package170" + FOREIGN KEY (data_package_id) + REFERENCES data_package(data_package_id) +; + +ALTER TABLE occurrence_data_package ADD CONSTRAINT "Refoccurrence174" + FOREIGN KEY (occurrence_id) + REFERENCES occurrence(occurrence_id) +; + + -- -- TABLE: occurrence_submission -- @@ -2870,16 +2897,16 @@ ALTER TABLE occurrence_submission ADD CONSTRAINT "Refsurvey160" -- TABLE: occurrence_submission_data_package -- -ALTER TABLE occurrence_submission_data_package ADD CONSTRAINT "Refoccurrence_submission169" - FOREIGN KEY (occurrence_submission_id) - REFERENCES occurrence_submission(occurrence_submission_id) -; - -ALTER TABLE occurrence_submission_data_package ADD CONSTRAINT "Refdata_package170" +ALTER TABLE occurrence_submission_data_package ADD CONSTRAINT "Refdata_package175" FOREIGN KEY (data_package_id) REFERENCES data_package(data_package_id) ; +ALTER TABLE occurrence_submission_data_package ADD CONSTRAINT "Refoccurrence_submission176" + FOREIGN KEY (occurrence_submission_id) + REFERENCES occurrence_submission(occurrence_submission_id) +; + -- -- TABLE: permit @@ -3031,16 +3058,6 @@ ALTER TABLE project_participation ADD CONSTRAINT "Refproject_role150" ; --- --- TABLE: project_region --- - -ALTER TABLE project_region ADD CONSTRAINT "Refproject131" - FOREIGN KEY (project_id) - REFERENCES project(project_id) -; - - -- -- TABLE: stakeholder_partnership -- diff --git a/database/src/migrations/release.0.21/create_spatial_extensions.psql b/database/src/migrations/release.0.22/create_spatial_extensions.psql similarity index 100% rename from database/src/migrations/release.0.21/create_spatial_extensions.psql rename to database/src/migrations/release.0.22/create_spatial_extensions.psql diff --git a/database/src/migrations/release.0.21/dapi_custom_views.sql b/database/src/migrations/release.0.22/dapi_custom_views.sql similarity index 100% rename from database/src/migrations/release.0.21/dapi_custom_views.sql rename to database/src/migrations/release.0.22/dapi_custom_views.sql diff --git a/database/src/migrations/release.0.21/db_setup_up.sql b/database/src/migrations/release.0.22/db_setup_up.sql similarity index 92% rename from database/src/migrations/release.0.21/db_setup_up.sql rename to database/src/migrations/release.0.22/db_setup_up.sql index dd6056571e..01ad66b13f 100644 --- a/database/src/migrations/release.0.21/db_setup_up.sql +++ b/database/src/migrations/release.0.22/db_setup_up.sql @@ -55,12 +55,16 @@ alter role biohub_api set search_path to biohub_dapi_v1, biohub, public, topolog \i tr_project.sql \i tr_survey.sql \i tr_permit.sql +\i tr_occurrence_submission.sql \i api_get_system_constant.sql +\i api_get_system_metadata_constant.sql \i vw_survey_status.sql \i api_delete_occurrence_submission.sql \i api_delete_survey.sql \i api_delete_project.sql +\i api_xml_string_replace.sql +\i api_get_eml_data_package.sql -- populate look up tables \set QUIET on diff --git a/database/src/migrations/release.0.21/populate_activity.sql b/database/src/migrations/release.0.22/populate_activity.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_activity.sql rename to database/src/migrations/release.0.22/populate_activity.sql diff --git a/database/src/migrations/release.0.21/populate_administrative_activity_status_type.sql b/database/src/migrations/release.0.22/populate_administrative_activity_status_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_administrative_activity_status_type.sql rename to database/src/migrations/release.0.22/populate_administrative_activity_status_type.sql diff --git a/database/src/migrations/release.0.21/populate_administrative_activity_type.sql b/database/src/migrations/release.0.22/populate_administrative_activity_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_administrative_activity_type.sql rename to database/src/migrations/release.0.22/populate_administrative_activity_type.sql diff --git a/database/src/migrations/release.0.21/populate_climate_change_initiatives.sql b/database/src/migrations/release.0.22/populate_climate_change_initiatives.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_climate_change_initiatives.sql rename to database/src/migrations/release.0.22/populate_climate_change_initiatives.sql diff --git a/database/src/migrations/release.0.21/populate_first_nations.sql b/database/src/migrations/release.0.22/populate_first_nations.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_first_nations.sql rename to database/src/migrations/release.0.22/populate_first_nations.sql diff --git a/database/src/migrations/release.0.21/populate_funding_source.sql b/database/src/migrations/release.0.22/populate_funding_source.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_funding_source.sql rename to database/src/migrations/release.0.22/populate_funding_source.sql diff --git a/database/src/migrations/release.0.21/populate_investment_action_category.sql b/database/src/migrations/release.0.22/populate_investment_action_category.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_investment_action_category.sql rename to database/src/migrations/release.0.22/populate_investment_action_category.sql diff --git a/database/src/migrations/release.0.21/populate_iucn_classifications.sql b/database/src/migrations/release.0.22/populate_iucn_classifications.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_iucn_classifications.sql rename to database/src/migrations/release.0.22/populate_iucn_classifications.sql diff --git a/database/src/migrations/release.0.21/populate_management_action_type.sql b/database/src/migrations/release.0.22/populate_management_action_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_management_action_type.sql rename to database/src/migrations/release.0.22/populate_management_action_type.sql diff --git a/database/src/migrations/release.0.21/populate_project_role.sql b/database/src/migrations/release.0.22/populate_project_role.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_project_role.sql rename to database/src/migrations/release.0.22/populate_project_role.sql diff --git a/database/src/migrations/release.0.21/populate_project_type.sql b/database/src/migrations/release.0.22/populate_project_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_project_type.sql rename to database/src/migrations/release.0.22/populate_project_type.sql diff --git a/database/src/migrations/release.0.21/populate_proprietor_type.sql b/database/src/migrations/release.0.22/populate_proprietor_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_proprietor_type.sql rename to database/src/migrations/release.0.22/populate_proprietor_type.sql diff --git a/database/src/migrations/release.0.21/populate_submission_message_type.sql b/database/src/migrations/release.0.22/populate_submission_message_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_submission_message_type.sql rename to database/src/migrations/release.0.22/populate_submission_message_type.sql diff --git a/database/src/migrations/release.0.21/populate_submission_status_type.sql b/database/src/migrations/release.0.22/populate_submission_status_type.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_submission_status_type.sql rename to database/src/migrations/release.0.22/populate_submission_status_type.sql diff --git a/database/src/migrations/release.0.22/populate_system_constant.sql b/database/src/migrations/release.0.22/populate_system_constant.sql new file mode 100644 index 0000000000..8124f3f4c2 --- /dev/null +++ b/database/src/migrations/release.0.22/populate_system_constant.sql @@ -0,0 +1,11 @@ +-- populate_system_constant.sql + +-- common constants +insert into system_constant (constant_name, character_value, description) values ('DATA_NOT_PROVIDED_MESSAGE', 'Not provided', 'A message to insert as appropriate where some data standard defines the data as required but that data is not available.'); +-- ISO 8601 date format strings +insert into system_constant (constant_name, character_value, description) values ('ISO_8601_DATE_FORMAT_WITH_TIMEZONE', 'YYYY-MM-DD"T"HH24:MI:SS"Z"', 'The ISO 8601 dae format string for timezone.'); +insert into system_constant (constant_name, character_value, description) values ('ISO_8601_DATE_FORMAT_WITHOUT_TIME_TIMEZONE', 'YYYY-MM-DD', 'The ISO 8601 dae format string without time or timezone.'); +-- survey states +insert into system_constant (constant_name, character_value, description) values ('OCCURRENCE_SUBMISSION_STATE_PUBLISHED', 'Published', 'The occurrence submission state name that indicates that the data has been published and is discoverable.'); +-- system roles +insert into system_constant (constant_name, character_value, description) values ('SYSTEM_ROLES_SYSTEM_ADMINISTRATOR', 'System Administrator', 'The system role name that defines a system administrator role.'); \ No newline at end of file diff --git a/database/src/migrations/release.0.21/populate_system_metadata_constant.sql b/database/src/migrations/release.0.22/populate_system_metadata_constant.sql similarity index 81% rename from database/src/migrations/release.0.21/populate_system_metadata_constant.sql rename to database/src/migrations/release.0.22/populate_system_metadata_constant.sql index febce6ed0a..1b63866465 100644 --- a/database/src/migrations/release.0.21/populate_system_metadata_constant.sql +++ b/database/src/migrations/release.0.22/populate_system_metadata_constant.sql @@ -1,9 +1,9 @@ -- populate_system_metadata_constant.sql -- system metadata tombstone data -insert into system_metadata_constant (constant_name, character_value, description) values ('BIOHUB_PROVIDER_URL', 'https://biohub.bc.ca', 'The system URL. This value is used in the production of published ecological metadata language files.'); +insert into system_metadata_constant (constant_name, character_value, description) values ('BIOHUB_PROVIDER_URL', 'https://biohub.gov.bc.ca', 'The system URL. This value is used in the production of published ecological metadata language files.'); insert into system_metadata_constant (constant_name, character_value, description) values ('SECURITY_PROVIDER_URL', 'https://biohub.bc.ca', 'The security provider URL. This value is used in the production of published ecological metadata language files.'); -insert into system_metadata_constant (constant_name, character_value, description) values ('ORGANIZATION_NAME_FULL', 'Knowledge Management Branch, Ministry of Enivronment, Government of British Columbia', 'The organizations full name. This value is used in the production of published ecological metadata language files.'); +insert into system_metadata_constant (constant_name, character_value, description) values ('ORGANIZATION_NAME_FULL', 'Knowledge Management Branch, Ministry of Enivronment and Climate Change Strategy, Government of British Columbia', 'The organizations full name. This value is used in the production of published ecological metadata language files.'); insert into system_metadata_constant (constant_name, character_value, description) values ('ORGANIZATION_URL', 'https://www2.gov.bc.ca/gov/content/governments/organizational-structure/ministries-organizations/ministries/environment-climate-change', 'The organizations public facing URL. This value is used in the production of published ecological metadata language files.'); insert into system_metadata_constant (constant_name, character_value, description) values ('INTELLECTUAL_RIGHTS', 'Intellectual rights example.', 'Intellectual rights verbiage for published data. This value is used in the production of published ecological metadata language files.'); insert into system_metadata_constant (constant_name, character_value, description) values ('TAXONOMIC_PROVIDER_URL', 'https://biohub.bc.ca', 'The taxonomic system URL. This value is used in the production of published ecological metadata language files.'); \ No newline at end of file diff --git a/database/src/migrations/release.0.21/populate_system_role.sql b/database/src/migrations/release.0.22/populate_system_role.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_system_role.sql rename to database/src/migrations/release.0.22/populate_system_role.sql diff --git a/database/src/migrations/release.0.21/populate_user_identity_source.sql b/database/src/migrations/release.0.22/populate_user_identity_source.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_user_identity_source.sql rename to database/src/migrations/release.0.22/populate_user_identity_source.sql diff --git a/database/src/migrations/release.0.21/populate_wldtaxonomic_units.sql b/database/src/migrations/release.0.22/populate_wldtaxonomic_units.sql similarity index 100% rename from database/src/migrations/release.0.21/populate_wldtaxonomic_units.sql rename to database/src/migrations/release.0.22/populate_wldtaxonomic_units.sql diff --git a/database/src/migrations/release.0.21/project_audit_triggers.sql b/database/src/migrations/release.0.22/project_audit_triggers.sql similarity index 97% rename from database/src/migrations/release.0.21/project_audit_triggers.sql rename to database/src/migrations/release.0.22/project_audit_triggers.sql index 70cd581b32..607facdcf6 100644 --- a/database/src/migrations/release.0.21/project_audit_triggers.sql +++ b/database/src/migrations/release.0.22/project_audit_triggers.sql @@ -7,42 +7,42 @@ create trigger audit_climate_change_initiative before insert or update or delete on biohub.climate_change_initiative for each row execute procedure tr_audit_trigger(); create trigger audit_first_nations before insert or update or delete on biohub.first_nations for each row execute procedure tr_audit_trigger(); create trigger audit_iucn_conservation_action_level_3_subclassification before insert or update or delete on biohub.iucn_conservation_action_level_3_subclassification for each row execute procedure tr_audit_trigger(); - create trigger audit_occurrence_submission before insert or update or delete on biohub.occurrence_submission for each row execute procedure tr_audit_trigger(); create trigger audit_occurrence before insert or update or delete on biohub.occurrence for each row execute procedure tr_audit_trigger(); - create trigger audit_occurrence_submission_data_package before insert or update or delete on biohub.occurrence_submission_data_package for each row execute procedure tr_audit_trigger(); + create trigger audit_occurrence_data_package before insert or update or delete on biohub.occurrence_data_package for each row execute procedure tr_audit_trigger(); create trigger audit_management_action_type before insert or update or delete on biohub.management_action_type for each row execute procedure tr_audit_trigger(); + create trigger audit_investment_action_category before insert or update or delete on biohub.investment_action_category for each row execute procedure tr_audit_trigger(); create trigger audit_iucn_conservation_action_level_1_classification before insert or update or delete on biohub.iucn_conservation_action_level_1_classification for each row execute procedure tr_audit_trigger(); - create trigger audit_permit before insert or update or delete on biohub.permit for each row execute procedure tr_audit_trigger(); + create trigger audit_occurrence_submission_data_package before insert or update or delete on biohub.occurrence_submission_data_package for each row execute procedure tr_audit_trigger(); create trigger audit_project_activity before insert or update or delete on biohub.project_activity for each row execute procedure tr_audit_trigger(); create trigger audit_project_climate_initiative before insert or update or delete on biohub.project_climate_initiative for each row execute procedure tr_audit_trigger(); create trigger audit_project_attachment before insert or update or delete on biohub.project_attachment for each row execute procedure tr_audit_trigger(); + create trigger audit_stakeholder_partnership before insert or update or delete on biohub.stakeholder_partnership for each row execute procedure tr_audit_trigger(); + create trigger audit_submission_message_type before insert or update or delete on biohub.submission_message_type for each row execute procedure tr_audit_trigger(); + create trigger audit_project_type before insert or update or delete on biohub.project_type for each row execute procedure tr_audit_trigger(); create trigger audit_project_first_nation before insert or update or delete on biohub.project_first_nation for each row execute procedure tr_audit_trigger(); create trigger audit_project_funding_source before insert or update or delete on biohub.project_funding_source for each row execute procedure tr_audit_trigger(); - create trigger audit_project_region before insert or update or delete on biohub.project_region for each row execute procedure tr_audit_trigger(); - create trigger audit_submission_message_type before insert or update or delete on biohub.submission_message_type for each row execute procedure tr_audit_trigger(); create trigger audit_project_iucn_action_classification before insert or update or delete on biohub.project_iucn_action_classification for each row execute procedure tr_audit_trigger(); create trigger audit_project_management_actions before insert or update or delete on biohub.project_management_actions for each row execute procedure tr_audit_trigger(); create trigger audit_project_participation before insert or update or delete on biohub.project_participation for each row execute procedure tr_audit_trigger(); create trigger audit_project_role before insert or update or delete on biohub.project_role for each row execute procedure tr_audit_trigger(); - create trigger audit_stakeholder_partnership before insert or update or delete on biohub.stakeholder_partnership for each row execute procedure tr_audit_trigger(); create trigger audit_study_species before insert or update or delete on biohub.study_species for each row execute procedure tr_audit_trigger(); + create trigger audit_submission_message before insert or update or delete on biohub.submission_message for each row execute procedure tr_audit_trigger(); create trigger audit_proprietor_type before insert or update or delete on biohub.proprietor_type for each row execute procedure tr_audit_trigger(); create trigger audit_submission_status_type before insert or update or delete on biohub.submission_status_type for each row execute procedure tr_audit_trigger(); create trigger audit_survey_funding_source before insert or update or delete on biohub.survey_funding_source for each row execute procedure tr_audit_trigger(); - create trigger audit_system_user_role before insert or update or delete on biohub.system_user_role for each row execute procedure tr_audit_trigger(); + create trigger audit_system_role before insert or update or delete on biohub.system_role for each row execute procedure tr_audit_trigger(); create trigger audit_system_constant before insert or update or delete on biohub.system_constant for each row execute procedure tr_audit_trigger(); create trigger audit_system_metadata_constant before insert or update or delete on biohub.system_metadata_constant for each row execute procedure tr_audit_trigger(); create trigger audit_survey before insert or update or delete on biohub.survey for each row execute procedure tr_audit_trigger(); + create trigger audit_submission_status before insert or update or delete on biohub.submission_status for each row execute procedure tr_audit_trigger(); create trigger audit_survey_attachment before insert or update or delete on biohub.survey_attachment for each row execute procedure tr_audit_trigger(); create trigger audit_survey_proprietor before insert or update or delete on biohub.survey_proprietor for each row execute procedure tr_audit_trigger(); - create trigger audit_system_role before insert or update or delete on biohub.system_role for each row execute procedure tr_audit_trigger(); - create trigger audit_webform_draft before insert or update or delete on biohub.webform_draft for each row execute procedure tr_audit_trigger(); + create trigger audit_system_user_role before insert or update or delete on biohub.system_user_role for each row execute procedure tr_audit_trigger(); create trigger audit_user_identity_source before insert or update or delete on biohub.user_identity_source for each row execute procedure tr_audit_trigger(); + create trigger audit_webform_draft before insert or update or delete on biohub.webform_draft for each row execute procedure tr_audit_trigger(); create trigger audit_system_user before insert or update or delete on biohub.system_user for each row execute procedure tr_audit_trigger(); - create trigger audit_investment_action_category before insert or update or delete on biohub.investment_action_category for each row execute procedure tr_audit_trigger(); create trigger audit_iucn_conservation_action_level_2_subclassification before insert or update or delete on biohub.iucn_conservation_action_level_2_subclassification for each row execute procedure tr_audit_trigger(); + create trigger audit_occurrence_submission before insert or update or delete on biohub.occurrence_submission for each row execute procedure tr_audit_trigger(); create trigger audit_project before insert or update or delete on biohub.project for each row execute procedure tr_audit_trigger(); - create trigger audit_project_type before insert or update or delete on biohub.project_type for each row execute procedure tr_audit_trigger(); - create trigger audit_submission_status before insert or update or delete on biohub.submission_status for each row execute procedure tr_audit_trigger(); - create trigger audit_submission_message before insert or update or delete on biohub.submission_message for each row execute procedure tr_audit_trigger(); + create trigger audit_permit before insert or update or delete on biohub.permit for each row execute procedure tr_audit_trigger(); diff --git a/database/src/migrations/release.0.21/project_dapi_views.sql b/database/src/migrations/release.0.22/project_dapi_views.sql similarity index 96% rename from database/src/migrations/release.0.21/project_dapi_views.sql rename to database/src/migrations/release.0.22/project_dapi_views.sql index f05b19519a..87569cd827 100644 --- a/database/src/migrations/release.0.21/project_dapi_views.sql +++ b/database/src/migrations/release.0.22/project_dapi_views.sql @@ -12,6 +12,7 @@ create or replace view iucn_conservation_action_level_3_subclassification as select * from biohub.iucn_conservation_action_level_3_subclassification; create or replace view management_action_type as select * from biohub.management_action_type; create or replace view occurrence as select * from biohub.occurrence; + create or replace view occurrence_data_package as select * from biohub.occurrence_data_package; create or replace view occurrence_submission as select * from biohub.occurrence_submission; create or replace view occurrence_submission_data_package as select * from biohub.occurrence_submission_data_package; create or replace view permit as select * from biohub.permit; @@ -24,7 +25,6 @@ create or replace view project_iucn_action_classification as select * from biohub.project_iucn_action_classification; create or replace view project_management_actions as select * from biohub.project_management_actions; create or replace view project_participation as select * from biohub.project_participation; - create or replace view project_region as select * from biohub.project_region; create or replace view project_role as select * from biohub.project_role; create or replace view project_type as select * from biohub.project_type; create or replace view proprietor_type as select * from biohub.proprietor_type; diff --git a/database/src/migrations/release.0.21/project_journal_triggers.sql b/database/src/migrations/release.0.22/project_journal_triggers.sql similarity index 97% rename from database/src/migrations/release.0.21/project_journal_triggers.sql rename to database/src/migrations/release.0.22/project_journal_triggers.sql index 9cddcc56f8..a210bc544c 100644 --- a/database/src/migrations/release.0.21/project_journal_triggers.sql +++ b/database/src/migrations/release.0.22/project_journal_triggers.sql @@ -7,42 +7,42 @@ create trigger journal_climate_change_initiative after insert or update or delete on biohub.climate_change_initiative for each row execute procedure tr_journal_trigger(); create trigger journal_first_nations after insert or update or delete on biohub.first_nations for each row execute procedure tr_journal_trigger(); create trigger journal_iucn_conservation_action_level_3_subclassification after insert or update or delete on biohub.iucn_conservation_action_level_3_subclassification for each row execute procedure tr_journal_trigger(); - create trigger journal_occurrence_submission after insert or update or delete on biohub.occurrence_submission for each row execute procedure tr_journal_trigger(); create trigger journal_occurrence after insert or update or delete on biohub.occurrence for each row execute procedure tr_journal_trigger(); - create trigger journal_occurrence_submission_data_package after insert or update or delete on biohub.occurrence_submission_data_package for each row execute procedure tr_journal_trigger(); + create trigger journal_occurrence_data_package after insert or update or delete on biohub.occurrence_data_package for each row execute procedure tr_journal_trigger(); create trigger journal_management_action_type after insert or update or delete on biohub.management_action_type for each row execute procedure tr_journal_trigger(); + create trigger journal_investment_action_category after insert or update or delete on biohub.investment_action_category for each row execute procedure tr_journal_trigger(); create trigger journal_iucn_conservation_action_level_1_classification after insert or update or delete on biohub.iucn_conservation_action_level_1_classification for each row execute procedure tr_journal_trigger(); - create trigger journal_permit after insert or update or delete on biohub.permit for each row execute procedure tr_journal_trigger(); + create trigger journal_occurrence_submission_data_package after insert or update or delete on biohub.occurrence_submission_data_package for each row execute procedure tr_journal_trigger(); create trigger journal_project_activity after insert or update or delete on biohub.project_activity for each row execute procedure tr_journal_trigger(); create trigger journal_project_climate_initiative after insert or update or delete on biohub.project_climate_initiative for each row execute procedure tr_journal_trigger(); create trigger journal_project_attachment after insert or update or delete on biohub.project_attachment for each row execute procedure tr_journal_trigger(); + create trigger journal_stakeholder_partnership after insert or update or delete on biohub.stakeholder_partnership for each row execute procedure tr_journal_trigger(); + create trigger journal_submission_message_type after insert or update or delete on biohub.submission_message_type for each row execute procedure tr_journal_trigger(); + create trigger journal_project_type after insert or update or delete on biohub.project_type for each row execute procedure tr_journal_trigger(); create trigger journal_project_first_nation after insert or update or delete on biohub.project_first_nation for each row execute procedure tr_journal_trigger(); create trigger journal_project_funding_source after insert or update or delete on biohub.project_funding_source for each row execute procedure tr_journal_trigger(); - create trigger journal_project_region after insert or update or delete on biohub.project_region for each row execute procedure tr_journal_trigger(); - create trigger journal_submission_message_type after insert or update or delete on biohub.submission_message_type for each row execute procedure tr_journal_trigger(); create trigger journal_project_iucn_action_classification after insert or update or delete on biohub.project_iucn_action_classification for each row execute procedure tr_journal_trigger(); create trigger journal_project_management_actions after insert or update or delete on biohub.project_management_actions for each row execute procedure tr_journal_trigger(); create trigger journal_project_participation after insert or update or delete on biohub.project_participation for each row execute procedure tr_journal_trigger(); create trigger journal_project_role after insert or update or delete on biohub.project_role for each row execute procedure tr_journal_trigger(); - create trigger journal_stakeholder_partnership after insert or update or delete on biohub.stakeholder_partnership for each row execute procedure tr_journal_trigger(); create trigger journal_study_species after insert or update or delete on biohub.study_species for each row execute procedure tr_journal_trigger(); + create trigger journal_submission_message after insert or update or delete on biohub.submission_message for each row execute procedure tr_journal_trigger(); create trigger journal_proprietor_type after insert or update or delete on biohub.proprietor_type for each row execute procedure tr_journal_trigger(); create trigger journal_submission_status_type after insert or update or delete on biohub.submission_status_type for each row execute procedure tr_journal_trigger(); create trigger journal_survey_funding_source after insert or update or delete on biohub.survey_funding_source for each row execute procedure tr_journal_trigger(); - create trigger journal_system_user_role after insert or update or delete on biohub.system_user_role for each row execute procedure tr_journal_trigger(); + create trigger journal_system_role after insert or update or delete on biohub.system_role for each row execute procedure tr_journal_trigger(); create trigger journal_system_constant after insert or update or delete on biohub.system_constant for each row execute procedure tr_journal_trigger(); create trigger journal_system_metadata_constant after insert or update or delete on biohub.system_metadata_constant for each row execute procedure tr_journal_trigger(); create trigger journal_survey after insert or update or delete on biohub.survey for each row execute procedure tr_journal_trigger(); + create trigger journal_submission_status after insert or update or delete on biohub.submission_status for each row execute procedure tr_journal_trigger(); create trigger journal_survey_attachment after insert or update or delete on biohub.survey_attachment for each row execute procedure tr_journal_trigger(); create trigger journal_survey_proprietor after insert or update or delete on biohub.survey_proprietor for each row execute procedure tr_journal_trigger(); - create trigger journal_system_role after insert or update or delete on biohub.system_role for each row execute procedure tr_journal_trigger(); - create trigger journal_webform_draft after insert or update or delete on biohub.webform_draft for each row execute procedure tr_journal_trigger(); + create trigger journal_system_user_role after insert or update or delete on biohub.system_user_role for each row execute procedure tr_journal_trigger(); create trigger journal_user_identity_source after insert or update or delete on biohub.user_identity_source for each row execute procedure tr_journal_trigger(); + create trigger journal_webform_draft after insert or update or delete on biohub.webform_draft for each row execute procedure tr_journal_trigger(); create trigger journal_system_user after insert or update or delete on biohub.system_user for each row execute procedure tr_journal_trigger(); - create trigger journal_investment_action_category after insert or update or delete on biohub.investment_action_category for each row execute procedure tr_journal_trigger(); create trigger journal_iucn_conservation_action_level_2_subclassification after insert or update or delete on biohub.iucn_conservation_action_level_2_subclassification for each row execute procedure tr_journal_trigger(); + create trigger journal_occurrence_submission after insert or update or delete on biohub.occurrence_submission for each row execute procedure tr_journal_trigger(); create trigger journal_project after insert or update or delete on biohub.project for each row execute procedure tr_journal_trigger(); - create trigger journal_project_type after insert or update or delete on biohub.project_type for each row execute procedure tr_journal_trigger(); - create trigger journal_submission_status after insert or update or delete on biohub.submission_status for each row execute procedure tr_journal_trigger(); - create trigger journal_submission_message after insert or update or delete on biohub.submission_message for each row execute procedure tr_journal_trigger(); + create trigger journal_permit after insert or update or delete on biohub.permit for each row execute procedure tr_journal_trigger(); diff --git a/database/src/migrations/release.0.21/smoketest_release.sql b/database/src/migrations/release.0.22/smoketest_release.sql similarity index 84% rename from database/src/migrations/release.0.21/smoketest_release.sql rename to database/src/migrations/release.0.22/smoketest_release.sql index c3b39faa68..583750057b 100644 --- a/database/src/migrations/release.0.21/smoketest_release.sql +++ b/database/src/migrations/release.0.22/smoketest_release.sql @@ -1,16 +1,23 @@ -- smoketest_release.sql -- run as db super user \c biohub +set role postgres; +set search_path=biohub; do $$ declare _count integer = 0; - _system_user_id biohub.system_user.system_user_id%type; + _system_user system_user%rowtype; + _system_user_id system_user.system_user_id%type; begin - set role postgres; - set search_path=biohub; - - delete from system_user where user_identifier = 'myIDIR'; + select * into _system_user from system_user where user_identifier = 'myIDIR'; + if _system_user.system_user_id is not null then + delete from permit where system_user_id = _system_user.system_user_id; + delete from administrative_activity where reported_system_user_id = _system_user.system_user_id; + delete from administrative_activity where assigned_system_user_id = _system_user.system_user_id; + delete from system_user_role where system_user_id = _system_user.system_user_id; + delete from system_user where system_user_id = _system_user.system_user_id; + end if; insert into system_user (user_identity_source_id, user_identifier, record_effective_date) values ((select user_identity_source_id from user_identity_source where name = 'IDIR' and record_end_date is null), 'myIDIR', now()) returning system_user_id into _system_user_id; insert into system_user_role (system_user_id, system_role_id) values (_system_user_id, (select system_role_id from system_role where name = 'System Administrator')); @@ -27,6 +34,8 @@ begin end $$; +set role biohub_api; +set search_path to biohub_dapi_v1, biohub, public, topology; do $$ declare _project_id project.project_id%type; @@ -39,15 +48,13 @@ declare _survey_status_query text := 'select project_id, survey_id, survey_status from survey_status'; _survey_status_rec survey_status%rowtype; _geography project.geography%type; + _project_funding_source_id project_funding_source.project_funding_source_id%type; begin - set role biohub_api; - set search_path to biohub_dapi_v1, biohub, public, topology; - -- set security context select api_set_context('myIDIR', 'IDIR') into _system_user_id; --select api_set_context('biohub_api', 'DATABASE') into _system_user_id; - select st_GeomFromEWKT('SRID=4326;POLYGON((-123.920288 48.592142,-123.667603 48.645205,-123.539886 48.536204,-123.583832 48.46978,-123.728027 48.460674,-123.868103 48.467959,-123.940887 48.5262,-123.920288 48.592142))') into _geography; + select st_GeomFromEWKT('SRID=4326;POLYGON((-123.920288 48.592142,-123.667603 48.645205,-123.539886 48.536204,-123.583832 48.46978,-123.728027 48.460674,-123.868103 48.467959,-123.940887 48.5262,-123.920288 48.592142), (-103.920288 38.592142,-103.667603 38.645205,-103.539886 38.536204,-103.583832 38.46978,-103.728027 38.460674,-103.868103 38.467959,-103.940887 38.5262,-103.920288 38.592142))') into _geography; insert into project (project_type_id , name @@ -67,7 +74,7 @@ begin , now()+interval '1 day' , 'coordinator_first_name' , 'coordinator_last_name' - , 'coordinator_email_address' + , 'coordinator_email_address@nowhere.com' , 'coordinator_agency_name' , TRUE , _geography @@ -77,7 +84,7 @@ begin insert into project_activity (project_id, activity_id) values (_project_id, (select activity_id from activity where name = 'Monitoring')); insert into project_climate_initiative (project_id, climate_change_initiative_id) values (_project_id, (select climate_change_initiative_id from climate_change_initiative where name = 'Monitoring')); insert into project_management_actions (project_id, management_action_type_id) values (_project_id, (select management_action_type_id from management_action_type where name = 'Recovery Action')); - insert into project_funding_source (project_id, investment_action_category_id, funding_amount, funding_start_date, funding_end_date, funding_source_project_id) values (_project_id, (select investment_action_category_id from investment_action_category where name = 'Action 1'), '$1,000.00', now(), now(), 'test'); + insert into project_funding_source (project_id, investment_action_category_id, funding_amount, funding_start_date, funding_end_date, funding_source_project_id) values (_project_id, (select investment_action_category_id from investment_action_category where name = 'Action 1'), '$1,000.00', now(), now(), 'test') returning project_funding_source_id into _project_funding_source_id; --insert into project_funding_source (project_id, investment_action_category_id, funding_amount, funding_start_date, funding_end_date) values (_project_id, 43, '$1,000.00', now(), now()); insert into project_iucn_action_classification (project_id, iucn_conservation_action_level_3_subclassification_id) values (_project_id, (select iucn_conservation_action_level_3_subclassification_id from iucn_conservation_action_level_3_subclassification where name = 'Primary education')); insert into project_attachment (project_id, file_name, title, key, file_size) values (_project_id, 'test_filename.txt', 'test filename', 'projects/'||_project_id::text, 10000); @@ -118,6 +125,9 @@ begin insert into study_species (survey_id, wldtaxonomic_units_id, is_focal) values (_survey_id, (select wldtaxonomic_units_id from wldtaxonomic_units where CODE = 'AMARALB'), true); select count(1) into _count from study_species; assert _count = 1, 'FAIL study_species'; + insert into survey_funding_source (survey_id, project_funding_source_id) values (_survey_id, _project_funding_source_id); + select count(1) into _count from survey_funding_source; + assert _count = 1, 'FAIL survey_funding_source'; -- occurrence -- occurrence submission 1 @@ -131,7 +141,7 @@ begin insert into submission_message (submission_status_id, submission_message_type_id, event_timestamp, message) values (_submission_status_id, (select submission_message_type_id from submission_message_type where name = 'Notice'), now()-interval '1 day', 'A notice message at stage submitted.'); -- transpose comments on next three lines to test deletion of published surveys by system administrator insert into submission_status (occurrence_submission_id, submission_status_type_id, event_timestamp) values (_occurrence_submission_id, (select submission_status_type_id from submission_status_type where name = 'Awaiting Curration'), now()-interval '1 day') returning submission_status_id into _submission_status_id; - --insert into submission_status (occurrence_submission_id, submission_status_type_id, event_timestamp) values (_occurrence_submission_id, (select submission_status_type_id from submission_status_type where name = 'Published'), now()-interval '1 day') returning id into _submission_status_id; + insert into submission_status (occurrence_submission_id, submission_status_type_id, event_timestamp) values (_occurrence_submission_id, (select submission_status_type_id from submission_status_type where name = 'Published'), now()-interval '1 day') returning submission_status_id into _submission_status_id; --insert into system_user_role (system_user_id, system_role_id) values (_system_user_id, (select system_role_id from system_role where name = 'System Administrator')); insert into submission_message (submission_status_id, submission_message_type_id, event_timestamp, message) values (_submission_status_id, (select submission_message_type_id from submission_message_type where name = 'Notice'), now()-interval '1 day', 'A notice message at stage published.'); @@ -147,14 +157,14 @@ begin insert into submission_status (occurrence_submission_id, submission_status_type_id, event_timestamp) values (_occurrence_submission_id, (select submission_status_type_id from submission_status_type where name = 'Rejected'), now()) returning submission_status_id into _submission_status_id; insert into submission_message (submission_status_id, submission_message_type_id, event_timestamp, message) values (_submission_status_id, (select submission_message_type_id from submission_message_type where name = 'Notice'), now(), 'A notice message at stage published.'); select count(1) into _count from submission_status; - assert _count = 4, 'FAIL submission_status'; + assert _count = 5, 'FAIL submission_status'; select count(1) into _count from submission_message; assert _count = 4, 'FAIL submission_message'; - raise notice 'survey status (project_id, survey_id, survey_status):'; - for _survey_status_rec in execute _survey_status_query loop - raise notice 'survey status results are % % %', _survey_status_rec.project_id, _survey_status_rec.survey_id, _survey_status_rec.survey_status; - end loop; +-- raise notice 'survey status (project_id, survey_id, survey_status):'; +-- for _survey_status_rec in execute _survey_status_query loop +-- raise notice 'survey status results are % % % %', _survey_status_rec.project_id, _survey_status_rec.survey_id, _survey_status_rec.occurrence_id, _survey_status_rec.survey_status; +-- end loop; -- test ancillary data delete from webform_draft; @@ -181,11 +191,11 @@ begin insert into permit (system_user_id, number, type, issue_date, end_date, coordinator_first_name, coordinator_last_name, coordinator_email_address, coordinator_agency_name) values (_system_user_id, '8377261', 'permit type', now(), now()+interval '1 day', 'first', 'last', 'nobody@nowhere.com', 'agency'); -- delete project + raise notice 'deleting data.'; call api_delete_project(_project_id); raise notice 'smoketest_release(2): PASS'; end $$; -delete from administrative_activity; delete from permit; \ No newline at end of file diff --git a/database/src/migrations/release.0.21/tr_audit_trigger.sql b/database/src/migrations/release.0.22/tr_audit_trigger.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_audit_trigger.sql rename to database/src/migrations/release.0.22/tr_audit_trigger.sql diff --git a/database/src/migrations/release.0.21/tr_journal_trigger.sql b/database/src/migrations/release.0.22/tr_journal_trigger.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_journal_trigger.sql rename to database/src/migrations/release.0.22/tr_journal_trigger.sql diff --git a/database/src/migrations/release.0.22/tr_occurrence_submission.sql b/database/src/migrations/release.0.22/tr_occurrence_submission.sql new file mode 100644 index 0000000000..1fb3d932b4 --- /dev/null +++ b/database/src/migrations/release.0.22/tr_occurrence_submission.sql @@ -0,0 +1,30 @@ +-- tr_occurrence_submission.sql +create or replace function tr_occurrence_submission() returns trigger +language plpgsql +security invoker +as +$$ +-- ******************************************************************* +-- Procedure: tr_occurrence_submission +-- Purpose: performs specific data validation +-- +-- MODIFICATION HISTORY +-- Person Date Comments +-- ---------------- ----------- -------------------------------------- +-- charlie.garrettjones@quartech.com +-- 2021-06-29 initial release +-- ******************************************************************* +declare + _data_package_id data_package.data_package_id%type; +begin + -- ensure that submission has submission level data package identifier + insert into data_package default values returning data_package_id into _data_package_id; + + insert into occurrence_submission_data_package (occurrence_submission_id, data_package_id) values (new.occurrence_submission_id, _data_package_id); + + return new; +end; +$$; + +drop trigger if exists occurrence_submission_val on biohub.occurrence_submission; +create trigger occurrence_submission_val after insert on biohub.occurrence_submission for each row execute procedure tr_occurrence_submission(); \ No newline at end of file diff --git a/database/src/migrations/release.0.21/tr_permit.sql b/database/src/migrations/release.0.22/tr_permit.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_permit.sql rename to database/src/migrations/release.0.22/tr_permit.sql diff --git a/database/src/migrations/release.0.21/tr_project.sql b/database/src/migrations/release.0.22/tr_project.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_project.sql rename to database/src/migrations/release.0.22/tr_project.sql diff --git a/database/src/migrations/release.0.21/tr_project_funding_source.sql b/database/src/migrations/release.0.22/tr_project_funding_source.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_project_funding_source.sql rename to database/src/migrations/release.0.22/tr_project_funding_source.sql diff --git a/database/src/migrations/release.0.21/tr_survey.sql b/database/src/migrations/release.0.22/tr_survey.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_survey.sql rename to database/src/migrations/release.0.22/tr_survey.sql diff --git a/database/src/migrations/release.0.21/tr_survey_proprietor.sql b/database/src/migrations/release.0.22/tr_survey_proprietor.sql similarity index 100% rename from database/src/migrations/release.0.21/tr_survey_proprietor.sql rename to database/src/migrations/release.0.22/tr_survey_proprietor.sql diff --git a/database/src/migrations/release.0.21/vw_survey_status.sql b/database/src/migrations/release.0.22/vw_survey_status.sql similarity index 88% rename from database/src/migrations/release.0.21/vw_survey_status.sql rename to database/src/migrations/release.0.22/vw_survey_status.sql index cde4061cd2..6e092304df 100644 --- a/database/src/migrations/release.0.21/vw_survey_status.sql +++ b/database/src/migrations/release.0.22/vw_survey_status.sql @@ -6,12 +6,12 @@ with not_published as (select os.survey_id, max(ss.submission_status_id) as subm where os2.survey_id = os2.survey_id and ss2.occurrence_submission_id = os2.occurrence_submission_id and sst.submission_status_type_id = ss2.submission_status_type_id - and sst.name = api_get_character_system_constant('SURVEY_STATE_PUBLISHED') + and sst.name = api_get_character_system_constant('OCCURRENCE_SUBMISSION_STATE_PUBLISHED') and sst.record_end_date is null) group by os.survey_id), published as (select os.survey_id, max(ss.submission_status_id) as submission_status_id from occurrence_submission os, submission_status ss, submission_status_type sst where ss.submission_status_type_id = sst.submission_status_type_id - and sst.name = api_get_character_system_constant('SURVEY_STATE_PUBLISHED') + and sst.name = api_get_character_system_constant('OCCURRENCE_SUBMISSION_STATE_PUBLISHED') and sst.record_end_date is null group by os.survey_id) select s.project_id project_id, np.survey_id survey_id, sst.name survey_status, ss3.event_timestamp status_event_timestamp from not_published np, submission_status ss3, submission_status_type sst, survey s From ab9f7c9d128634d3daeae1e6ab218bd9cae95809 Mon Sep 17 00:00:00 2001 From: charlie garrett-jones Date: Thu, 5 Aug 2021 15:17:13 -0700 Subject: [PATCH 4/6] - minor fix to migration mainline --- database/src/migrations/20210225205948_biohub_release.ts | 2 ++ 1 file changed, 2 insertions(+) diff --git a/database/src/migrations/20210225205948_biohub_release.ts b/database/src/migrations/20210225205948_biohub_release.ts index a14b1c1e7a..871ee561d5 100644 --- a/database/src/migrations/20210225205948_biohub_release.ts +++ b/database/src/migrations/20210225205948_biohub_release.ts @@ -37,6 +37,7 @@ export async function up(knex: Knex): Promise { const tr_project = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'tr_project.sql')); const tr_survey = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'tr_survey.sql')); const tr_permit = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'tr_permit.sql')); + const tr_occurrence_submission = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'tr_occurrence_submission.sql')); const api_get_system_constant = fs.readFileSync(path.join(__dirname, DB_RELEASE, 'api_get_system_constant.sql')); const api_get_system_metadata_constant = fs.readFileSync( path.join(__dirname, DB_RELEASE, 'api_get_system_metadata_constant.sql') @@ -138,6 +139,7 @@ export async function up(knex: Knex): Promise { ${tr_project} ${tr_survey} ${tr_permit} + ${tr_occurrence_submission} ${api_get_system_constant} ${api_get_system_metadata_constant} ${vw_survey_status} From 5f3006a72bf606d2a853b4f5c74fe346e5263f39 Mon Sep 17 00:00:00 2001 From: charlie garrett-jones Date: Thu, 5 Aug 2021 15:56:55 -0700 Subject: [PATCH 5/6] - problems with passing xml types back to api. sticking with character based return for now. --- .../src/migrations/release.0.22/api_get_eml_data_package.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/database/src/migrations/release.0.22/api_get_eml_data_package.sql b/database/src/migrations/release.0.22/api_get_eml_data_package.sql index 7aeed96d1a..93fbfda716 100644 --- a/database/src/migrations/release.0.22/api_get_eml_data_package.sql +++ b/database/src/migrations/release.0.22/api_get_eml_data_package.sql @@ -2,7 +2,7 @@ drop function if exists api_get_eml_data_package; -create or replace function api_get_eml_data_package(p_data_package_id data_package.data_package_id%type, p_supplied_title varchar) returns xml +create or replace function api_get_eml_data_package(p_data_package_id data_package.data_package_id%type, p_supplied_title varchar) returns varchar language plpgsql security definer stable @@ -718,7 +718,7 @@ begin end if; _eml_xml_text := _eml_xml_text||''; - return xmlparse(DOCUMENT _eml_xml_text); + return _eml_xml_text; exception when others then From f86e7beca317f24bf770c34f148cf9b39daba773 Mon Sep 17 00:00:00 2001 From: charlie garrett-jones Date: Fri, 6 Aug 2021 11:13:50 -0700 Subject: [PATCH 6/6] - fixed problem with icun levels not reporting properly --- .../src/migrations/release.0.22/api_get_eml_data_package.sql | 4 ++-- .../src/migrations/release.0.22/api_xml_string_replace.sql | 2 +- database/src/migrations/release.0.22/smoketest_release.sql | 4 ++-- 3 files changed, 5 insertions(+), 5 deletions(-) diff --git a/database/src/migrations/release.0.22/api_get_eml_data_package.sql b/database/src/migrations/release.0.22/api_get_eml_data_package.sql index 93fbfda716..cee427807b 100644 --- a/database/src/migrations/release.0.22/api_get_eml_data_package.sql +++ b/database/src/migrations/release.0.22/api_get_eml_data_package.sql @@ -497,8 +497,8 @@ begin %1$s - %1$s - %1$s + %2$s + %3$s ' diff --git a/database/src/migrations/release.0.22/api_xml_string_replace.sql b/database/src/migrations/release.0.22/api_xml_string_replace.sql index aaed2b8ad3..54f02e0330 100644 --- a/database/src/migrations/release.0.22/api_xml_string_replace.sql +++ b/database/src/migrations/release.0.22/api_xml_string_replace.sql @@ -19,4 +19,4 @@ begin return replace(replace(replace(p_string, '&', '&'), '<', '<'), '>', '>'); end; -$$; \ No newline at end of file +$$; diff --git a/database/src/migrations/release.0.22/smoketest_release.sql b/database/src/migrations/release.0.22/smoketest_release.sql index 583750057b..8afa5480c0 100644 --- a/database/src/migrations/release.0.22/smoketest_release.sql +++ b/database/src/migrations/release.0.22/smoketest_release.sql @@ -192,10 +192,10 @@ begin -- delete project raise notice 'deleting data.'; - call api_delete_project(_project_id); + --call api_delete_project(_project_id); raise notice 'smoketest_release(2): PASS'; end $$; -delete from permit; \ No newline at end of file +--delete from permit;