From 372b4049839fbda94b4762cb45168defc3322c30 Mon Sep 17 00:00:00 2001 From: Mac Deluca Date: Fri, 19 Jan 2024 16:36:27 -0800 Subject: [PATCH 1/7] created migration for taxon table --- .../20240119000000_taxonomy_tables.ts | 63 +++++++++++++++++++ 1 file changed, 63 insertions(+) create mode 100644 database/src/migrations/20240119000000_taxonomy_tables.ts diff --git a/database/src/migrations/20240119000000_taxonomy_tables.ts b/database/src/migrations/20240119000000_taxonomy_tables.ts new file mode 100644 index 00000000..d08e8a5f --- /dev/null +++ b/database/src/migrations/20240119000000_taxonomy_tables.ts @@ -0,0 +1,63 @@ +import { Knex } from 'knex'; + +/** + * Add tables: + * - taxon + * + * @export + * @param {Knex} knex + * @return {*} {Promise} + */ + +export async function up(knex: Knex): Promise { + await knex.raw(`--sql + ---------------------------------------------------------------------------------------- + -- Create table + ---------------------------------------------------------------------------------------- + set search_path=biohub,public; + + CREATE TABLE taxon ( + taxon_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + bc_taxon_code varchar(10), + itis_tsn integer NOT NULL, + scientific_name varchar(50) NOT NULL, + common_name varchar(50), + itis_data jsonb NOT NULL, + itis_update_date timestamptz(6) NOT NULL, + record_effective_date date DEFAULT now() NOT NULL, + record_end_date date, + create_date timestamptz(6) DEFAULT now() NOT NULL, + create_user integer NOT NULL, + update_date timestamptz(6), + update_user integer, + revision_count integer DEFAULT 0 NOT NULL, + CONSTRAINT taxon_pk PRIMARY KEY (taxon_id) + ); + + COMMENT ON COLUMN taxon.taxon_id IS 'System generated surrogate primary key identifier.'; + COMMENT ON COLUMN taxon.bc_taxon_code IS 'British Columbia standard Taxon identifier.'; + COMMENT ON COLUMN taxon.itis_tsn IS 'ITIS primary key identifier, populated from ITIS response. ITIS (Integrated Taxonomic Information System), TSN (Taxonomic Serial Number). https://itis.gov/pdf/faq_itis_tsn.pdf'; + COMMENT ON COLUMN taxon.scientific_name IS 'Taxon scientific name, initially populated from ITIS response.'; + COMMENT ON COLUMN taxon.common_name IS 'Taxon common name, initially populated from ITIS response.'; + COMMENT ON COLUMN taxon.itis_data IS 'Raw ITIS payload, populated from ITIS response.'; + COMMENT ON COLUMN taxon.itis_update_date IS 'The datetime the ITIS taxon was updated, populated from ITIS response.'; + COMMENT ON COLUMN taxon.record_effective_date IS 'Record level effective date.'; + COMMENT ON COLUMN taxon.record_end_date IS 'Record level end date.'; + COMMENT ON COLUMN taxon.create_date IS 'The datetime the record was created.'; + COMMENT ON COLUMN taxon.create_user IS 'The id of the user who created the record as identified in the system user table.'; + COMMENT ON COLUMN taxon.update_date IS 'The datetime the record was updated.'; + COMMENT ON COLUMN taxon.update_user IS 'The id of the user who updated the record as identified in the system user table.'; + COMMENT ON COLUMN taxon.revision_count IS 'Revision count used for concurrency control.'; + COMMENT ON TABLE taxon IS 'ITIS taxon cache table.'; + + ---------------------------------------------------------------------------------------- + -- Create table triggers + ---------------------------------------------------------------------------------------- + create trigger audit_region_lookup before insert or update or delete on taxon for each row execute procedure tr_audit_trigger(); + create trigger journal_region_lookup after insert or update or delete on taxon for each row execute procedure tr_journal_trigger(); + `); +} + +export async function down(knex: Knex): Promise { + await knex.raw(``); +} From edecb20ae4d48519ba35281a04126514c8380edf Mon Sep 17 00:00:00 2001 From: Mac Deluca Date: Mon, 22 Jan 2024 11:29:18 -0800 Subject: [PATCH 2/7] added taxon_alias table --- .../20240119000000_taxonomy_tables.ts | 53 ++++++++++++++++--- 1 file changed, 46 insertions(+), 7 deletions(-) diff --git a/database/src/migrations/20240119000000_taxonomy_tables.ts b/database/src/migrations/20240119000000_taxonomy_tables.ts index d08e8a5f..9021ab02 100644 --- a/database/src/migrations/20240119000000_taxonomy_tables.ts +++ b/database/src/migrations/20240119000000_taxonomy_tables.ts @@ -12,14 +12,14 @@ import { Knex } from 'knex'; export async function up(knex: Knex): Promise { await knex.raw(`--sql ---------------------------------------------------------------------------------------- - -- Create table + -- Create tables ---------------------------------------------------------------------------------------- set search_path=biohub,public; CREATE TABLE taxon ( taxon_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - bc_taxon_code varchar(10), itis_tsn integer NOT NULL, + bc_taxon_code varchar(10), scientific_name varchar(50) NOT NULL, common_name varchar(50), itis_data jsonb NOT NULL, @@ -31,12 +31,13 @@ export async function up(knex: Knex): Promise { update_date timestamptz(6), update_user integer, revision_count integer DEFAULT 0 NOT NULL, - CONSTRAINT taxon_pk PRIMARY KEY (taxon_id) + + CONSTRAINT taxon_pk PRIMARY KEY (taxon_id) ); COMMENT ON COLUMN taxon.taxon_id IS 'System generated surrogate primary key identifier.'; - COMMENT ON COLUMN taxon.bc_taxon_code IS 'British Columbia standard Taxon identifier.'; COMMENT ON COLUMN taxon.itis_tsn IS 'ITIS primary key identifier, populated from ITIS response. ITIS (Integrated Taxonomic Information System), TSN (Taxonomic Serial Number). https://itis.gov/pdf/faq_itis_tsn.pdf'; + COMMENT ON COLUMN taxon.bc_taxon_code IS 'British Columbia standard taxon identifier.'; COMMENT ON COLUMN taxon.scientific_name IS 'Taxon scientific name, initially populated from ITIS response.'; COMMENT ON COLUMN taxon.common_name IS 'Taxon common name, initially populated from ITIS response.'; COMMENT ON COLUMN taxon.itis_data IS 'Raw ITIS payload, populated from ITIS response.'; @@ -48,13 +49,51 @@ export async function up(knex: Knex): Promise { COMMENT ON COLUMN taxon.update_date IS 'The datetime the record was updated.'; COMMENT ON COLUMN taxon.update_user IS 'The id of the user who updated the record as identified in the system user table.'; COMMENT ON COLUMN taxon.revision_count IS 'Revision count used for concurrency control.'; - COMMENT ON TABLE taxon IS 'ITIS taxon cache table.'; + COMMENT ON TABLE taxon IS 'Taxon cache table, extending ITIS webservice response.'; + + CREATE TABLE taxon_alias ( + taxon_alias_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + taxon_id integer NOT NULL, + alias varchar(50) 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 taxon_alias_pk PRIMARY KEY (taxon_alias_id) + ); + + COMMENT ON COLUMN taxon_alias.taxon_alias_id IS 'System generated surrogate primary key identifier.'; + COMMENT ON COLUMN taxon_alias.taxon_id IS 'A foreign key that points to a taxon.'; + COMMENT ON COLUMN taxon_alias.alias IS 'A taxon alias.'; + COMMENT ON COLUMN taxon_alias.create_date IS 'The datetime the record was created.'; + COMMENT ON COLUMN taxon_alias.create_user IS 'The id of the user who created the record as identified in the system user table.'; + COMMENT ON COLUMN taxon_alias.update_date IS 'The datetime the record was updated.'; + COMMENT ON COLUMN taxon_alias.update_user IS 'The id of the user who updated the record as identified in the system user table.'; + COMMENT ON COLUMN taxon_alias.revision_count IS 'Revision count used for concurrency control.'; + COMMENT ON TABLE taxon_alias IS 'Taxon alias table, for assigning additional alias names to taxons'; + + ---------------------------------------------------------------------------------------- + -- Create table indexes and constraints + ---------------------------------------------------------------------------------------- + ALTER TABLE taxon_alias ADD CONSTRAINT taxon_alias_fk1 FOREIGN KEY (taxon_id) REFERENCES taxon(taxon_id); + + CREATE INDEX taxon_alias_fk1 ON taxon_alias(taxon_id); + + -- Add unique end-date key constraints + CREATE UNIQUE INDEX taxon_nuk1 ON taxon(scientific_name, (record_end_date is NULL)) where record_end_date is null; + CREATE UNIQUE INDEX taxon_nuk2 ON taxon(bc_taxon_code, (record_end_date is NULL)) where record_end_date is null; + CREATE UNIQUE INDEX taxon_nuk3 ON taxon(itis_tsn, (record_end_date is NULL)) where record_end_date is null; ---------------------------------------------------------------------------------------- -- Create table triggers ---------------------------------------------------------------------------------------- - create trigger audit_region_lookup before insert or update or delete on taxon for each row execute procedure tr_audit_trigger(); - create trigger journal_region_lookup after insert or update or delete on taxon for each row execute procedure tr_journal_trigger(); + create trigger audit_taxon before insert or update or delete on taxon for each row execute procedure tr_audit_trigger(); + create trigger journal_taxon after insert or update or delete on taxon for each row execute procedure tr_journal_trigger(); + + create trigger audit_taxon_alias before insert or update or delete on taxon_alias for each row execute procedure tr_audit_trigger(); + create trigger journal_taxon_alias after insert or update or delete on taxon_alias for each row execute procedure tr_journal_trigger(); `); } From 8166b39f0e306acd83367f52dd3fca13033cecca Mon Sep 17 00:00:00 2001 From: Mac Deluca Date: Mon, 22 Jan 2024 15:12:42 -0800 Subject: [PATCH 3/7] missing taxon_alias in top comment --- database/src/migrations/20240119000000_taxonomy_tables.ts | 1 + 1 file changed, 1 insertion(+) diff --git a/database/src/migrations/20240119000000_taxonomy_tables.ts b/database/src/migrations/20240119000000_taxonomy_tables.ts index 9021ab02..e9a52274 100644 --- a/database/src/migrations/20240119000000_taxonomy_tables.ts +++ b/database/src/migrations/20240119000000_taxonomy_tables.ts @@ -3,6 +3,7 @@ import { Knex } from 'knex'; /** * Add tables: * - taxon + * - taxon_alias * * @export * @param {Knex} knex From 94892676834bc4d7fccbf6ad7ad36de815df45cf Mon Sep 17 00:00:00 2001 From: Mac Deluca Date: Mon, 22 Jan 2024 17:20:45 -0800 Subject: [PATCH 4/7] added additional lookup tables --- .../20240119000000_taxonomy_tables.ts | 137 ++++++++++++------ 1 file changed, 95 insertions(+), 42 deletions(-) diff --git a/database/src/migrations/20240119000000_taxonomy_tables.ts b/database/src/migrations/20240119000000_taxonomy_tables.ts index e9a52274..efb91e75 100644 --- a/database/src/migrations/20240119000000_taxonomy_tables.ts +++ b/database/src/migrations/20240119000000_taxonomy_tables.ts @@ -18,74 +18,127 @@ export async function up(knex: Knex): Promise { set search_path=biohub,public; CREATE TABLE taxon ( - taxon_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - itis_tsn integer NOT NULL, - bc_taxon_code varchar(10), - scientific_name varchar(50) NOT NULL, + taxon_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + itis_tsn integer NOT NULL, + bc_taxon_code varchar(50), + itis_scientific_name varchar(300) NOT NULL, common_name varchar(50), - itis_data jsonb NOT NULL, - itis_update_date timestamptz(6) NOT NULL, - record_effective_date date DEFAULT now() NOT NULL, + itis_data jsonb NOT NULL, + itis_update_date timestamptz(6) NOT NULL, + record_effective_date date DEFAULT now() NOT NULL, record_end_date date, - create_date timestamptz(6) DEFAULT now() NOT NULL, - create_user 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, + revision_count integer DEFAULT 0 NOT NULL, - CONSTRAINT taxon_pk PRIMARY KEY (taxon_id) + CONSTRAINT taxon_pk PRIMARY KEY (taxon_id) ); - COMMENT ON COLUMN taxon.taxon_id IS 'System generated surrogate primary key identifier.'; - COMMENT ON COLUMN taxon.itis_tsn IS 'ITIS primary key identifier, populated from ITIS response. ITIS (Integrated Taxonomic Information System), TSN (Taxonomic Serial Number). https://itis.gov/pdf/faq_itis_tsn.pdf'; - COMMENT ON COLUMN taxon.bc_taxon_code IS 'British Columbia standard taxon identifier.'; - COMMENT ON COLUMN taxon.scientific_name IS 'Taxon scientific name, initially populated from ITIS response.'; - COMMENT ON COLUMN taxon.common_name IS 'Taxon common name, initially populated from ITIS response.'; - COMMENT ON COLUMN taxon.itis_data IS 'Raw ITIS payload, populated from ITIS response.'; - COMMENT ON COLUMN taxon.itis_update_date IS 'The datetime the ITIS taxon was updated, populated from ITIS response.'; - COMMENT ON COLUMN taxon.record_effective_date IS 'Record level effective date.'; - COMMENT ON COLUMN taxon.record_end_date IS 'Record level end date.'; - COMMENT ON COLUMN taxon.create_date IS 'The datetime the record was created.'; - COMMENT ON COLUMN taxon.create_user IS 'The id of the user who created the record as identified in the system user table.'; - COMMENT ON COLUMN taxon.update_date IS 'The datetime the record was updated.'; - COMMENT ON COLUMN taxon.update_user IS 'The id of the user who updated the record as identified in the system user table.'; - COMMENT ON COLUMN taxon.revision_count IS 'Revision count used for concurrency control.'; - COMMENT ON TABLE taxon IS 'Taxon cache table, extending ITIS webservice response.'; + COMMENT ON COLUMN taxon.taxon_id IS 'System generated surrogate primary key identifier.'; + COMMENT ON COLUMN taxon.itis_tsn IS 'ITIS primary key identifier, populated from ITIS response. ITIS (Integrated Taxonomic Information System), TSN (Taxonomic Serial Number). https://itis.gov/pdf/faq_itis_tsn.pdf'; + COMMENT ON COLUMN taxon.bc_taxon_code IS 'British Columbia standard taxon identifier.'; + COMMENT ON COLUMN taxon.scientific_name IS 'Taxon scientific name, initially populated from ITIS response.'; + COMMENT ON COLUMN taxon.common_name IS 'Taxon common name, initially populated from ITIS response.'; + COMMENT ON COLUMN taxon.itis_data IS 'Raw ITIS payload, populated from ITIS response.'; + COMMENT ON COLUMN taxon.itis_update_date IS 'The datetime the ITIS taxon was updated, populated from ITIS response.'; + COMMENT ON COLUMN taxon.record_effective_date IS 'Record level effective date.'; + COMMENT ON COLUMN taxon.record_end_date IS 'Record level end date.'; + COMMENT ON COLUMN taxon.create_date IS 'The datetime the record was created.'; + COMMENT ON COLUMN taxon.create_user IS 'The id of the user who created the record as identified in the system user table.'; + COMMENT ON COLUMN taxon.update_date IS 'The datetime the record was updated.'; + COMMENT ON COLUMN taxon.update_user IS 'The id of the user who updated the record as identified in the system user table.'; + COMMENT ON COLUMN taxon.revision_count IS 'Revision count used for concurrency control.'; + COMMENT ON TABLE taxon IS 'Taxon cache table, extending ITIS webservice response.'; CREATE TABLE taxon_alias ( - taxon_alias_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - taxon_id integer NOT NULL, - alias varchar(50) NOT NULL, - create_date timestamptz(6) DEFAULT now() NOT NULL, - create_user integer NOT NULL, + taxon_alias_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + taxon_id integer NOT NULL, + language_id integer NOT NULL, + taxon_alias_origin_id integer NOT NULL, + alias varchar(300) NOT NULL, + record_effective_date date DEFAULT now() NOT NULL, + record_end_date date, + create_date timestamptz(6) DEFAULT now() NOT NULL, + create_user integer NOT NULL, + update_date timestamptz(6), + update_user integer, + revision_count integer DEFAULT 0 NOT NULL, + + CONSTRAINT taxon_alias_pk PRIMARY KEY (taxon_alias_id) + ); + + COMMENT ON COLUMN taxon_alias.taxon_alias_id IS 'System generated surrogate primary key identifier.'; + COMMENT ON COLUMN taxon_alias.taxon_id IS 'A foreign key that points to a taxon.'; + COMMENT ON COLUMN taxon_alias.alias IS 'A taxon alias.'; + COMMENT ON COLUMN taxon_alias.record_effective_date IS 'Record level effective date.'; + COMMENT ON COLUMN taxon_alias.record_end_date IS 'Record level end date.'; + COMMENT ON COLUMN taxon_alias.create_date IS 'The datetime the record was created.'; + COMMENT ON COLUMN taxon_alias.create_user IS 'The id of the user who created the record as identified in the system user table.'; + COMMENT ON COLUMN taxon_alias.update_date IS 'The datetime the record was updated.'; + COMMENT ON COLUMN taxon_alias.update_user IS 'The id of the user who updated the record as identified in the system user table.'; + COMMENT ON COLUMN taxon_alias.revision_count IS 'Revision count used for concurrency control.'; + COMMENT ON TABLE taxon_alias IS 'Taxon alias table, for assigning additional alias names to taxons.'; + + CREATE TABLE language_lookup ( + language_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + language varchar(100) 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 language_lookup_pk PRIMARY KEY (language_lookup_id) + ); + + COMMENT ON COLUMN language_lookup.language_id IS 'System generated surrogate primary key identifier.'; + COMMENT ON COLUMN language_lookup.language IS 'The name of the language.'; + COMMENT ON COLUMN language_lookup.create_date IS 'The datetime the record was created.'; + COMMENT ON COLUMN language_lookup.create_user IS 'The id of the user who created the record as identified in the system user table.'; + COMMENT ON COLUMN language_lookup.update_date IS 'The datetime the record was updated.'; + COMMENT ON COLUMN language_lookup.update_user IS 'The id of the user who updated the record as identified in the system user table.'; + COMMENT ON COLUMN language_lookup.revision_count IS 'Revision count used for concurrency control.'; + COMMENT ON TABLE language_lookup IS 'Language lookup table.'; + + CREATE TABLE taxon_alias_origin ( + taxon_alias_origin_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + origin varchar(100) 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, + revision_count integer DEFAULT 0 NOT NULL, - CONSTRAINT taxon_alias_pk PRIMARY KEY (taxon_alias_id) + CONSTRAINT taxon_alias_origin_pk PRIMARY KEY (taxon_alias_origin_id) ); - COMMENT ON COLUMN taxon_alias.taxon_alias_id IS 'System generated surrogate primary key identifier.'; - COMMENT ON COLUMN taxon_alias.taxon_id IS 'A foreign key that points to a taxon.'; - COMMENT ON COLUMN taxon_alias.alias IS 'A taxon alias.'; - COMMENT ON COLUMN taxon_alias.create_date IS 'The datetime the record was created.'; - COMMENT ON COLUMN taxon_alias.create_user IS 'The id of the user who created the record as identified in the system user table.'; - COMMENT ON COLUMN taxon_alias.update_date IS 'The datetime the record was updated.'; - COMMENT ON COLUMN taxon_alias.update_user IS 'The id of the user who updated the record as identified in the system user table.'; - COMMENT ON COLUMN taxon_alias.revision_count IS 'Revision count used for concurrency control.'; - COMMENT ON TABLE taxon_alias IS 'Taxon alias table, for assigning additional alias names to taxons'; + COMMENT ON COLUMN taxon_alias_origin.taxon_alias_origin_id IS 'System generated surrogate primary key identifier.'; + COMMENT ON COLUMN taxon_alias_origin.origin IS 'The origin source of the taxon alias.'; + COMMENT ON COLUMN taxon_alias_origin.create_date IS 'The datetime the record was created.'; + COMMENT ON COLUMN taxon_alias_origin.create_user IS 'The id of the user who created the record as identified in the system user table.'; + COMMENT ON COLUMN taxon_alias_origin.update_date IS 'The datetime the record was updated.'; + COMMENT ON COLUMN taxon_alias_origin.update_user IS 'The id of the user who updated the record as identified in the system user table.'; + COMMENT ON COLUMN taxon_alias_origin.revision_count IS 'Revision count used for concurrency control.'; + COMMENT ON TABLE taxon_alias_origin IS 'Taxon alias origin lookup table.'; ---------------------------------------------------------------------------------------- -- Create table indexes and constraints ---------------------------------------------------------------------------------------- ALTER TABLE taxon_alias ADD CONSTRAINT taxon_alias_fk1 FOREIGN KEY (taxon_id) REFERENCES taxon(taxon_id); + ALTER TABLE taxon_alias ADD CONSTRAINT taxon_alias_fk2 FOREIGN KEY (language_id) REFERENCES language_lookup(language_id); + ALTER TABLE taxon_alias ADD CONSTRAINT taxon_alias_fk3 FOREIGN KEY (taxon_alias_origin_id) REFERENCES taxon_alias_origin(taxon_alias_origin_id); CREATE INDEX taxon_alias_fk1 ON taxon_alias(taxon_id); + CREATE INDEX taxon_alias_fk2 ON taxon_alias(language_id); + CREATE INDEX taxon_alias_fk3 ON taxon_alias(taxon_alias_origin_id); -- Add unique end-date key constraints CREATE UNIQUE INDEX taxon_nuk1 ON taxon(scientific_name, (record_end_date is NULL)) where record_end_date is null; CREATE UNIQUE INDEX taxon_nuk2 ON taxon(bc_taxon_code, (record_end_date is NULL)) where record_end_date is null; CREATE UNIQUE INDEX taxon_nuk3 ON taxon(itis_tsn, (record_end_date is NULL)) where record_end_date is null; + CREATE UNIQUE INDEX taxon_alias_nuk1 ON taxon_alias(taxon_id, alias, (record_end_date is NULL)) where record_end_date is null; ---------------------------------------------------------------------------------------- -- Create table triggers From 46073d051ed7cf3c1c679e3e24c89973943224fb Mon Sep 17 00:00:00 2001 From: Mac Deluca Date: Tue, 23 Jan 2024 10:46:08 -0800 Subject: [PATCH 5/7] cleaned up syntax --- .../20240119000000_taxonomy_tables.ts | 22 ++++++++++++++----- 1 file changed, 16 insertions(+), 6 deletions(-) diff --git a/database/src/migrations/20240119000000_taxonomy_tables.ts b/database/src/migrations/20240119000000_taxonomy_tables.ts index efb91e75..1848d057 100644 --- a/database/src/migrations/20240119000000_taxonomy_tables.ts +++ b/database/src/migrations/20240119000000_taxonomy_tables.ts @@ -4,6 +4,8 @@ import { Knex } from 'knex'; * Add tables: * - taxon * - taxon_alias + * - taxon_alias_origin + * - language_lookup * * @export * @param {Knex} knex @@ -39,7 +41,7 @@ export async function up(knex: Knex): Promise { COMMENT ON COLUMN taxon.taxon_id IS 'System generated surrogate primary key identifier.'; COMMENT ON COLUMN taxon.itis_tsn IS 'ITIS primary key identifier, populated from ITIS response. ITIS (Integrated Taxonomic Information System), TSN (Taxonomic Serial Number). https://itis.gov/pdf/faq_itis_tsn.pdf'; COMMENT ON COLUMN taxon.bc_taxon_code IS 'British Columbia standard taxon identifier.'; - COMMENT ON COLUMN taxon.scientific_name IS 'Taxon scientific name, initially populated from ITIS response.'; + COMMENT ON COLUMN taxon.itis_scientific_name IS 'ITIS taxon scientific name, populated from ITIS response.'; COMMENT ON COLUMN taxon.common_name IS 'Taxon common name, initially populated from ITIS response.'; COMMENT ON COLUMN taxon.itis_data IS 'Raw ITIS payload, populated from ITIS response.'; COMMENT ON COLUMN taxon.itis_update_date IS 'The datetime the ITIS taxon was updated, populated from ITIS response.'; @@ -90,7 +92,7 @@ export async function up(knex: Knex): Promise { update_user integer, revision_count integer DEFAULT 0 NOT NULL, - CONSTRAINT language_lookup_pk PRIMARY KEY (language_lookup_id) + CONSTRAINT language_lookup_pk PRIMARY KEY (language_id) ); COMMENT ON COLUMN language_lookup.language_id IS 'System generated surrogate primary key identifier.'; @@ -115,7 +117,7 @@ export async function up(knex: Knex): Promise { ); COMMENT ON COLUMN taxon_alias_origin.taxon_alias_origin_id IS 'System generated surrogate primary key identifier.'; - COMMENT ON COLUMN taxon_alias_origin.origin IS 'The origin source of the taxon alias.'; + COMMENT ON COLUMN taxon_alias_origin.origin IS 'The source origin of the taxon alias.'; COMMENT ON COLUMN taxon_alias_origin.create_date IS 'The datetime the record was created.'; COMMENT ON COLUMN taxon_alias_origin.create_user IS 'The id of the user who created the record as identified in the system user table.'; COMMENT ON COLUMN taxon_alias_origin.update_date IS 'The datetime the record was updated.'; @@ -134,11 +136,13 @@ export async function up(knex: Knex): Promise { CREATE INDEX taxon_alias_fk2 ON taxon_alias(language_id); CREATE INDEX taxon_alias_fk3 ON taxon_alias(taxon_alias_origin_id); - -- Add unique end-date key constraints - CREATE UNIQUE INDEX taxon_nuk1 ON taxon(scientific_name, (record_end_date is NULL)) where record_end_date is null; + -- Add unique end-date key constraints (taxon) + CREATE UNIQUE INDEX taxon_nuk1 ON taxon(itis_scientific_name, (record_end_date is NULL)) where record_end_date is null; CREATE UNIQUE INDEX taxon_nuk2 ON taxon(bc_taxon_code, (record_end_date is NULL)) where record_end_date is null; CREATE UNIQUE INDEX taxon_nuk3 ON taxon(itis_tsn, (record_end_date is NULL)) where record_end_date is null; - CREATE UNIQUE INDEX taxon_alias_nuk1 ON taxon_alias(taxon_id, alias, (record_end_date is NULL)) where record_end_date is null; + + -- Add unique end-date key constraints (taxon_alias) + CREATE UNIQUE INDEX taxon_alias_nuk1 ON taxon_alias(taxon_id, alias, language_id, taxon_alias_origin_id, (record_end_date is NULL)) where record_end_date is null; ---------------------------------------------------------------------------------------- -- Create table triggers @@ -148,6 +152,12 @@ export async function up(knex: Knex): Promise { create trigger audit_taxon_alias before insert or update or delete on taxon_alias for each row execute procedure tr_audit_trigger(); create trigger journal_taxon_alias after insert or update or delete on taxon_alias for each row execute procedure tr_journal_trigger(); + + create trigger audit_language_lookup before insert or update or delete on language_lookup for each row execute procedure tr_audit_trigger(); + create trigger journal_language_lookup after insert or update or delete on language_lookup for each row execute procedure tr_journal_trigger(); + + create trigger audit_taxon_alias_origin before insert or update or delete on taxon_alias_origin for each row execute procedure tr_audit_trigger(); + create trigger journal_taxon_alias_origin after insert or update or delete on taxon_alias_origin for each row execute procedure tr_journal_trigger(); `); } From 3c083281ba941cfac91be20a4f991cf9a7fec7a0 Mon Sep 17 00:00:00 2001 From: Mac Deluca Date: Wed, 24 Jan 2024 09:20:57 -0800 Subject: [PATCH 6/7] updated missing comments for taxon tables --- database/src/migrations/20240119000000_taxonomy_tables.ts | 2 ++ 1 file changed, 2 insertions(+) diff --git a/database/src/migrations/20240119000000_taxonomy_tables.ts b/database/src/migrations/20240119000000_taxonomy_tables.ts index 1848d057..2e269aa1 100644 --- a/database/src/migrations/20240119000000_taxonomy_tables.ts +++ b/database/src/migrations/20240119000000_taxonomy_tables.ts @@ -73,6 +73,8 @@ export async function up(knex: Knex): Promise { COMMENT ON COLUMN taxon_alias.taxon_alias_id IS 'System generated surrogate primary key identifier.'; COMMENT ON COLUMN taxon_alias.taxon_id IS 'A foreign key that points to a taxon.'; + COMMENT ON COLUMN taxon_alias.language_id IS 'A foreign key that points to a language.'; + COMMENT ON COLUMN taxon_alias.taxon_alias_origin_id IS 'A foreign key that points to a taxon alias origin.'; COMMENT ON COLUMN taxon_alias.alias IS 'A taxon alias.'; COMMENT ON COLUMN taxon_alias.record_effective_date IS 'Record level effective date.'; COMMENT ON COLUMN taxon_alias.record_end_date IS 'Record level end date.'; From 434856a47a9c25b8107155625e7b5f86d20cd2a1 Mon Sep 17 00:00:00 2001 From: Mac Deluca Date: Wed, 24 Jan 2024 13:36:13 -0800 Subject: [PATCH 7/7] ignore-skip --- database/src/migrations/20240119000000_taxonomy_tables.ts | 1 + 1 file changed, 1 insertion(+) diff --git a/database/src/migrations/20240119000000_taxonomy_tables.ts b/database/src/migrations/20240119000000_taxonomy_tables.ts index 2e269aa1..78a3fcea 100644 --- a/database/src/migrations/20240119000000_taxonomy_tables.ts +++ b/database/src/migrations/20240119000000_taxonomy_tables.ts @@ -160,6 +160,7 @@ export async function up(knex: Knex): Promise { create trigger audit_taxon_alias_origin before insert or update or delete on taxon_alias_origin for each row execute procedure tr_audit_trigger(); create trigger journal_taxon_alias_origin after insert or update or delete on taxon_alias_origin for each row execute procedure tr_journal_trigger(); + `); }