diff --git a/api/src/openapi/schemas/biohub-data-submission.ts b/api/src/openapi/schemas/biohub-data-submission.ts new file mode 100644 index 000000000..8e48b422c --- /dev/null +++ b/api/src/openapi/schemas/biohub-data-submission.ts @@ -0,0 +1,53 @@ +export const BioHubFeatureCollection = { + title: 'BioHub Data Submission', + type: 'object', + required: ['id', 'type', 'features'], + properties: { + id: { + title: 'Unique id of the submission', + type: 'string' + }, + type: { + type: 'string', + enum: ['Submission'] + }, + features: { + type: 'array', + items: { + $ref: '#/$defs/Feature' + } + } + }, + $defs: { + Feature: { + title: 'BioHub Data Submission Feature', + type: 'object', + required: ['id', 'type', 'properties', 'features'], + properties: { + id: { + title: 'Unique id of the feature', + type: 'string' + }, + type: { + title: 'Feature type', + type: 'string' + }, + properties: { + title: 'Feature properties', + type: 'object', + properties: {} + }, + features: { + title: 'Feature child features', + type: 'array', + items: { + $ref: '#/$defs/Feature' + } + } + }, + additionalProperties: false + }, + additionalProperties: false + }, + additionalProperties: false +}; diff --git a/database/src/migrations/20231109000001_feature_tables.ts b/database/src/migrations/20231109000001_feature_tables.ts index 85a028bb8..ec6a6f296 100644 --- a/database/src/migrations/20231109000001_feature_tables.ts +++ b/database/src/migrations/20231109000001_feature_tables.ts @@ -17,7 +17,7 @@ export async function up(knex: Knex): Promise { ---------------------------------------------------------------------------------------- -- Create tables ---------------------------------------------------------------------------------------- - set search_path=biohub,public; + set search_path=biohub,public; CREATE TABLE submission_feature( submission_feature_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), @@ -34,7 +34,7 @@ export async function up(knex: Knex): Promise { revision_count integer DEFAULT 0 NOT NULL, CONSTRAINT submission_feature_pk PRIMARY KEY (submission_feature_id) ); - + COMMENT ON COLUMN submission_feature.submission_feature_id IS 'System generated surrogate primary key identifier.'; COMMENT ON COLUMN submission_feature.submission_id IS 'Foreign key to the submission table.'; COMMENT ON COLUMN submission_feature.feature_type_id IS 'Foreign key to the feature_type table.'; @@ -48,14 +48,14 @@ export async function up(knex: Knex): Promise { COMMENT ON COLUMN submission_feature.update_user IS 'The id of the user who updated the record as identified in the system user table.'; COMMENT ON COLUMN submission_feature.revision_count IS 'Revision count used for concurrency control.'; COMMENT ON TABLE submission_feature IS 'A set of data for a specific feature of a submission.'; - + ---------------------------------------------------------------------------------------- CREATE TABLE feature_type( feature_type_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), - name varchar(50) NOT NULL, + name varchar(100) NOT NULL, display_name varchar(100) NOT NULL, - description varchar(3000), + description varchar(500), record_effective_date date NOT NULL, record_end_date date, create_date timestamptz(6) DEFAULT now() NOT NULL, @@ -78,7 +78,7 @@ export async function up(knex: Knex): Promise { COMMENT ON COLUMN feature_type.update_user IS 'The id of the user who updated the record as identified in the system user table.'; COMMENT ON COLUMN feature_type.revision_count IS 'Revision count used for concurrency control.'; COMMENT ON TABLE feature_type IS 'Defines feature types.'; - + ---------------------------------------------------------------------------------------- CREATE TABLE feature_type_property( @@ -106,15 +106,15 @@ export async function up(knex: Knex): Promise { COMMENT ON COLUMN feature_type_property.update_user IS 'The id of the user who updated the record as identified in the system user table.'; COMMENT ON COLUMN feature_type_property.revision_count IS 'Revision count used for concurrency control.'; COMMENT ON TABLE feature_type_property IS 'A join table on feature type and feature_property. Defines which properties can be used by a given feature type.'; - + ---------------------------------------------------------------------------------------- CREATE TABLE feature_property( feature_property_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), feature_property_type_id integer NOT NULL, - name varchar(50) NOT NULL, + name varchar(100) NOT NULL, display_name varchar(100) NOT NULL, - description varchar(3000), + description varchar(500), parent_feature_property_id integer, record_effective_date date NOT NULL, record_end_date date, @@ -146,7 +146,7 @@ export async function up(knex: Knex): Promise { CREATE TABLE feature_property_type( feature_property_type_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), name varchar(100) NOT NULL, - description varchar(3000), + description varchar(500), record_effective_date date NOT NULL, record_end_date date, create_date timestamptz(6) DEFAULT now() NOT NULL, diff --git a/database/src/migrations/20231109000002_search_tables.ts b/database/src/migrations/20231109000002_search_tables.ts index a45cd6c43..353cac421 100644 --- a/database/src/migrations/20231109000002_search_tables.ts +++ b/database/src/migrations/20231109000002_search_tables.ts @@ -25,8 +25,6 @@ export async function up(knex: Knex): Promise { submission_feature_id integer NOT NULL, feature_property_id integer NOT NULL, value varchar(250) NOT NULL, --- record_effective_date date NOT NULL, --- record_end_date date, create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -34,20 +32,18 @@ export async function up(knex: Knex): Promise { revision_count integer DEFAULT 0 NOT NULL, CONSTRAINT search_string_pk PRIMARY KEY (search_string_id) ); - + COMMENT ON COLUMN search_string.search_string_id IS 'System generated surrogate primary key identifier.'; COMMENT ON COLUMN search_string.submission_feature_id IS 'Foreign key to the submission_feature table.'; COMMENT ON COLUMN search_string.feature_property_id IS 'Foreign key to the feature_property table.'; COMMENT ON COLUMN search_string.value IS 'The search value of the record.'; --- COMMENT ON COLUMN search_string.record_effective_date IS 'Record level effective date.'; --- COMMENT ON COLUMN search_string.record_end_date IS 'Record level end date.'; COMMENT ON COLUMN search_string.create_date IS 'The datetime the record was created.'; COMMENT ON COLUMN search_string.create_user IS 'The id of the user who created the record as identified in the system user table.'; COMMENT ON COLUMN search_string.update_date IS 'The datetime the record was updated.'; COMMENT ON COLUMN search_string.update_user IS 'The id of the user who updated the record as identified in the system user table.'; COMMENT ON COLUMN search_string.revision_count IS 'Revision count used for concurrency control.'; COMMENT ON TABLE search_string IS 'String search values'; - + ---------------------------------------------------------------------------------------- CREATE TABLE search_number( @@ -55,8 +51,6 @@ export async function up(knex: Knex): Promise { submission_feature_id integer NOT NULL, feature_property_id integer NOT NULL, value numeric NOT NULL, --- record_effective_date date NOT NULL, --- record_end_date date, create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -64,13 +58,11 @@ export async function up(knex: Knex): Promise { revision_count integer DEFAULT 0 NOT NULL, CONSTRAINT search_number_pk PRIMARY KEY (search_number_id) ); - + COMMENT ON COLUMN search_number.search_number_id IS 'System generated surrogate primary key identifier.'; COMMENT ON COLUMN search_number.submission_feature_id IS 'Foreign key to the submission_feature table.'; COMMENT ON COLUMN search_number.feature_property_id IS 'Foreign key to the feature_property table.'; COMMENT ON COLUMN search_number.value IS 'The search value of the record.'; --- COMMENT ON COLUMN search_number.record_effective_date IS 'Record level effective date.'; --- COMMENT ON COLUMN search_number.record_end_date IS 'Record level end date.'; COMMENT ON COLUMN search_number.create_date IS 'The datetime the record was created.'; COMMENT ON COLUMN search_number.create_user IS 'The id of the user who created the record as identified in the system user table.'; COMMENT ON COLUMN search_number.update_date IS 'The datetime the record was updated.'; @@ -85,8 +77,6 @@ export async function up(knex: Knex): Promise { submission_feature_id integer NOT NULL, feature_property_id integer NOT NULL, value timestamptz(6) NOT NULL, --- record_effective_date date NOT NULL, --- record_end_date date, create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -94,13 +84,11 @@ export async function up(knex: Knex): Promise { revision_count integer DEFAULT 0 NOT NULL, CONSTRAINT search_datetime_pk PRIMARY KEY (search_datetime_id) ); - + COMMENT ON COLUMN search_datetime.search_datetime_id IS 'System generated surrogate primary key identifier.'; COMMENT ON COLUMN search_datetime.submission_feature_id IS 'Foreign key to the submission_feature table.'; COMMENT ON COLUMN search_datetime.feature_property_id IS 'Foreign key to the feature_property table.'; COMMENT ON COLUMN search_datetime.value IS 'The search value of the record.'; --- COMMENT ON COLUMN search_datetime.record_effective_date IS 'Record level effective date.'; --- COMMENT ON COLUMN search_datetime.record_end_date IS 'Record level end date.'; COMMENT ON COLUMN search_datetime.create_date IS 'The datetime the record was created.'; COMMENT ON COLUMN search_datetime.create_user IS 'The id of the user who created the record as identified in the system user table.'; COMMENT ON COLUMN search_datetime.update_date IS 'The datetime the record was updated.'; @@ -115,8 +103,6 @@ export async function up(knex: Knex): Promise { submission_feature_id integer NOT NULL, feature_property_id integer NOT NULL, value geometry NOT NULL, --- record_effective_date date NOT NULL, --- record_end_date date, create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -124,13 +110,11 @@ export async function up(knex: Knex): Promise { revision_count integer DEFAULT 0 NOT NULL, CONSTRAINT search_spatial_pk PRIMARY KEY (search_spatial_id) ); - + COMMENT ON COLUMN search_spatial.search_spatial_id IS 'System generated surrogate primary key identifier.'; COMMENT ON COLUMN search_spatial.submission_feature_id IS 'Foreign key to the submission_feature table.'; COMMENT ON COLUMN search_spatial.feature_property_id IS 'Foreign key to the feature_property table.'; COMMENT ON COLUMN search_spatial.value IS 'The search value of the record.'; --- COMMENT ON COLUMN search_spatial.record_effective_date IS 'Record level effective date.'; --- COMMENT ON COLUMN search_spatial.record_end_date IS 'Record level end date.'; COMMENT ON COLUMN search_spatial.create_date IS 'The spatial the record was created.'; COMMENT ON COLUMN search_spatial.create_user IS 'The id of the user who created the record as identified in the system user table.'; COMMENT ON COLUMN search_spatial.update_date IS 'The spatial the record was updated.'; @@ -145,8 +129,6 @@ export async function up(knex: Knex): Promise { submission_feature_id integer NOT NULL, feature_property_id integer NOT NULL, value numeric NOT NULL, --- record_effective_date date NOT NULL, --- record_end_date date, create_date timestamptz(6) DEFAULT now() NOT NULL, create_user integer NOT NULL, update_date timestamptz(6), @@ -154,13 +136,11 @@ export async function up(knex: Knex): Promise { revision_count integer DEFAULT 0 NOT NULL, CONSTRAINT search_taxonomy_pk PRIMARY KEY (search_taxonomy_id) ); - + COMMENT ON COLUMN search_taxonomy.search_taxonomy_id IS 'System generated surrogate primary key identifier.'; COMMENT ON COLUMN search_taxonomy.submission_feature_id IS 'Foreign key to the submission_feature table.'; COMMENT ON COLUMN search_taxonomy.feature_property_id IS 'Foreign key to the feature_property table.'; COMMENT ON COLUMN search_taxonomy.value IS 'The search value of the record.'; --- COMMENT ON COLUMN search_taxonomy.record_effective_date IS 'Record level effective date.'; --- COMMENT ON COLUMN search_taxonomy.record_end_date IS 'Record level end date.'; COMMENT ON COLUMN search_taxonomy.create_date IS 'The taxonomy the record was created.'; COMMENT ON COLUMN search_taxonomy.create_user IS 'The id of the user who created the record as identified in the system user table.'; COMMENT ON COLUMN search_taxonomy.update_date IS 'The taxonomy the record was updated.'; diff --git a/database/src/migrations/20231109000003_populate_feature_lookup_tables.ts b/database/src/migrations/20231109000003_populate_feature_lookup_tables.ts index b5b1f75ed..b00afd514 100644 --- a/database/src/migrations/20231109000003_populate_feature_lookup_tables.ts +++ b/database/src/migrations/20231109000003_populate_feature_lookup_tables.ts @@ -45,7 +45,7 @@ export async function up(knex: Knex): Promise { insert into feature_type (name, display_name, description, record_effective_date) values ('sample_period', 'Sample Period', 'A datetime period in which data was collected', now()); insert into feature_type (name, display_name, description, record_effective_date) values ('observation', 'Observation', 'An observation record', now()); insert into feature_type (name, display_name, description, record_effective_date) values ('animal', 'Animal', 'An individual animal record', now()); - insert into feature_type (name, display_name, description, record_effective_date) values ('telemetry', 'Telemetry', 'A telemetry record', now()); + insert into feature_type (name, display_name, description, record_effective_date) values ('telemetry', 'Telemetry', 'A telemetry record', now()); -- populate feature_type_property table -- feature_type: dataset @@ -56,21 +56,21 @@ export async function up(knex: Knex): Promise { insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'dataset'), (select feature_property_id from feature_property where name = 'start_date'), now()); insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'dataset'), (select feature_property_id from feature_property where name = 'end_date'), now()); insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'dataset'), (select feature_property_id from feature_property where name = 'geometry'), now()); - + -- feature_type: sample_site insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'sample_site'), (select feature_property_id from feature_property where name = 'name'), now()); insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'sample_site'), (select feature_property_id from feature_property where name = 'description'), now()); insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'sample_site'), (select feature_property_id from feature_property where name = 'geometry'), now()); - + -- feature_type: sample_method insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'sample_method'), (select feature_property_id from feature_property where name = 'name'), now()); insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'sample_method'), (select feature_property_id from feature_property where name = 'description'), now()); - + -- feature_type: sample_period insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'sample_period'), (select feature_property_id from feature_property where name = 'date_range'), now()); insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'sample_period'), (select feature_property_id from feature_property where name = 'start_date'), now()); insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'sample_period'), (select feature_property_id from feature_property where name = 'end_date'), now()); - + -- feature_type: observation insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'observation'), (select feature_property_id from feature_property where name = 'taxonomy'), now()); insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'observation'), (select feature_property_id from feature_property where name = 'date_range'), now()); @@ -78,10 +78,10 @@ export async function up(knex: Knex): Promise { insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'observation'), (select feature_property_id from feature_property where name = 'end_date'), now()); insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'observation'), (select feature_property_id from feature_property where name = 'geometry'), now()); insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'observation'), (select feature_property_id from feature_property where name = 'count'), now()); - + -- feature_type: animal - insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'animal'), (select feature_property_id from feature_property where name = 'taxonomy'), now()); - + insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'animal'), (select feature_property_id from feature_property where name = 'taxonomy'), now()); + -- feature_type: telemetry insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'telemetry'), (select feature_property_id from feature_property where name = 'date_range'), now()); insert into feature_type_property (feature_type_id, feature_property_id, record_effective_date) values ((select feature_type_id from feature_type where name = 'telemetry'), (select feature_property_id from feature_property where name = 'start_date'), now()); diff --git a/database/src/migrations/20231709000001_security_tables.ts b/database/src/migrations/20231709000001_security_tables.ts new file mode 100644 index 000000000..dd43485d2 --- /dev/null +++ b/database/src/migrations/20231709000001_security_tables.ts @@ -0,0 +1,274 @@ +import { Knex } from 'knex'; + +/** + * Add tables: + * - submission_feature + * - feature_type + * - feature_type_property + * - feature_property + * - feature_property_type + * + * @export + * @param {Knex} knex + * @return {*} {Promise} + */ +export async function up(knex: Knex): Promise { + await knex.raw(` + ---------------------------------------------------------------------------------------- + -- Create tables + ---------------------------------------------------------------------------------------- + set search_path=biohub,public; + + CREATE TABLE security_rule( + security_rule_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + name varchar(100) NOT NULL, + description varchar(500), + record_effective_date date 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 security_rule_pk PRIMARY KEY (security_rule_id) + ); + + COMMENT ON COLUMN security_rule.security_rule_id IS 'System generated surrogate primary key identifier.'; + COMMENT ON COLUMN security_rule.name IS 'The name of the security_rule record.'; + COMMENT ON COLUMN security_rule.description IS 'The description of the security_rule record.'; + COMMENT ON COLUMN security_rule.record_effective_date IS 'Record level effective date.'; + COMMENT ON COLUMN security_rule.record_end_date IS 'Record level end date.'; + 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 'A security rule.'; + + ---------------------------------------------------------------------------------------- + + CREATE TABLE security_string( + security_string_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + security_rule_id integer NOT NULL, + name varchar(100) NOT NULL, + description varchar(500), + feature_property_id integer NOT NULL, + value varchar(250) NOT NULL, + comparator varchar(50) NOT NULL, + record_effective_date date 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 security_string_pk PRIMARY KEY (security_string_id) + ); + + COMMENT ON COLUMN security_string.security_string_id IS 'System generated surrogate primary key identifier.'; + COMMENT ON COLUMN security_string.security_rule_id IS 'Foreign key to the security_string table.'; + COMMENT ON COLUMN security_string.name IS 'The name of the security_string record.'; + COMMENT ON COLUMN security_string.description IS 'The description of the security_string record.'; + COMMENT ON COLUMN security_string.feature_property_id IS 'Foreign key to the feature_property table.'; + COMMENT ON COLUMN security_string.value IS 'The search value of the record.'; + COMMENT ON COLUMN security_string.comparator IS 'The comparison template.'; + COMMENT ON COLUMN security_string.create_date IS 'The datetime the record was created.'; + COMMENT ON COLUMN security_string.create_user IS 'The id of the user who created the record as identified in the system user table.'; + COMMENT ON COLUMN security_string.update_date IS 'The datetime the record was updated.'; + COMMENT ON COLUMN security_string.update_user IS 'The id of the user who updated the record as identified in the system user table.'; + COMMENT ON COLUMN security_string.revision_count IS 'Revision count used for concurrency control.'; + COMMENT ON TABLE security_string IS 'String search values'; + + ---------------------------------------------------------------------------------------- + + CREATE TABLE security_number( + security_number_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + security_rule_id integer NOT NULL, + name varchar(100) NOT NULL, + description varchar(500), + feature_property_id integer NOT NULL, + value numeric NOT NULL, + comparator varchar(50) NOT NULL, + record_effective_date date 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 security_number_pk PRIMARY KEY (security_number_id) + ); + + COMMENT ON COLUMN security_number.security_number_id IS 'System generated surrogate primary key identifier.'; + COMMENT ON COLUMN security_number.security_rule_id IS 'Foreign key to the security_number table.'; + COMMENT ON COLUMN security_number.name IS 'The name of the security_number record.'; + COMMENT ON COLUMN security_number.description IS 'The description of the security_number record.'; + COMMENT ON COLUMN security_number.feature_property_id IS 'Foreign key to the feature_property table.'; + COMMENT ON COLUMN security_number.value IS 'The search value of the record.'; + COMMENT ON COLUMN security_number.comparator IS 'The comparison template.'; + COMMENT ON COLUMN security_number.create_date IS 'The datetime the record was created.'; + COMMENT ON COLUMN security_number.create_user IS 'The id of the user who created the record as identified in the system user table.'; + COMMENT ON COLUMN security_number.update_date IS 'The datetime the record was updated.'; + COMMENT ON COLUMN security_number.update_user IS 'The id of the user who updated the record as identified in the system user table.'; + COMMENT ON COLUMN security_number.revision_count IS 'Revision count used for concurrency control.'; + COMMENT ON TABLE security_number IS 'Numeric search values'; + + ---------------------------------------------------------------------------------------- + + CREATE TABLE security_datetime( + security_datetime_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + security_rule_id integer NOT NULL, + name varchar(100) NOT NULL, + description varchar(500), + feature_property_id integer NOT NULL, + value timestamptz(6) NOT NULL, + comparator varchar(50) NOT NULL, + record_effective_date date 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 security_datetime_pk PRIMARY KEY (security_datetime_id) + ); + + COMMENT ON COLUMN security_datetime.security_datetime_id IS 'System generated surrogate primary key identifier.'; + COMMENT ON COLUMN security_datetime.security_rule_id IS 'Foreign key to the security_datetime table.'; + COMMENT ON COLUMN security_datetime.name IS 'The name of the security_datetime record.'; + COMMENT ON COLUMN security_datetime.description IS 'The description of the security_datetime record.'; + COMMENT ON COLUMN security_datetime.feature_property_id IS 'Foreign key to the feature_property table.'; + COMMENT ON COLUMN security_datetime.value IS 'The search value of the record.'; + COMMENT ON COLUMN security_datetime.comparator IS 'The comparison template.'; + COMMENT ON COLUMN security_datetime.create_date IS 'The datetime the record was created.'; + COMMENT ON COLUMN security_datetime.create_user IS 'The id of the user who created the record as identified in the system user table.'; + COMMENT ON COLUMN security_datetime.update_date IS 'The datetime the record was updated.'; + COMMENT ON COLUMN security_datetime.update_user IS 'The id of the user who updated the record as identified in the system user table.'; + COMMENT ON COLUMN security_datetime.revision_count IS 'Revision count used for concurrency control.'; + COMMENT ON TABLE security_datetime IS 'Numeric search values'; + + ---------------------------------------------------------------------------------------- + + CREATE TABLE security_spatial( + security_spatial_id integer GENERATED ALWAYS AS IDENTITY (START WITH 1 INCREMENT BY 1), + security_rule_id integer NOT NULL, + name varchar(100) NOT NULL, + description varchar(500), + feature_property_id integer NOT NULL, + value geometry NOT NULL, + comparator varchar(50) NOT NULL, + record_effective_date date 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 security_spatial_pk PRIMARY KEY (security_spatial_id) + ); + + COMMENT ON COLUMN security_spatial.security_spatial_id IS 'System generated surrogate primary key identifier.'; + COMMENT ON COLUMN security_spatial.security_rule_id IS 'Foreign key to the security_spatial table.'; + COMMENT ON COLUMN security_spatial.name IS 'The name of the security_spatial record.'; + COMMENT ON COLUMN security_spatial.description IS 'The description of the security_spatial record.'; + COMMENT ON COLUMN security_spatial.feature_property_id IS 'Foreign key to the feature_property table.'; + COMMENT ON COLUMN security_spatial.value IS 'The search value of the record.'; + COMMENT ON COLUMN security_spatial.comparator IS 'The comparison template.'; + COMMENT ON COLUMN security_spatial.create_date IS 'The spatial the record was created.'; + COMMENT ON COLUMN security_spatial.create_user IS 'The id of the user who created the record as identified in the system user table.'; + COMMENT ON COLUMN security_spatial.update_date IS 'The spatial the record was updated.'; + COMMENT ON COLUMN security_spatial.update_user IS 'The id of the user who updated the record as identified in the system user table.'; + COMMENT ON COLUMN security_spatial.revision_count IS 'Revision count used for concurrency control.'; + COMMENT ON TABLE security_spatial IS 'Numeric search values'; + + ---------------------------------------------------------------------------------------- + -- Create Indexes and Constraints for table: security_rule + ---------------------------------------------------------------------------------------- + + -- Add unique end-date key constraint (don't allow 2 records with the same name and a NULL record_end_date) + CREATE UNIQUE INDEX security_rule_nuk1 ON security_rule(name, (record_end_date is NULL)) where record_end_date is null; + + ---------------------------------------------------------------------------------------- + -- Create Indexes and Constraints for table: security_string + ---------------------------------------------------------------------------------------- + + -- Add unique end-date key constraint (don't allow 2 records with the same name and a NULL record_end_date) + CREATE UNIQUE INDEX security_string_nuk1 ON security_string(name, (record_end_date is NULL)) where record_end_date is null; + + -- Add foreign key constraint + ALTER TABLE security_string ADD CONSTRAINT security_string_fk1 + FOREIGN KEY (security_rule_id) + REFERENCES security_rule(security_rule_id); + + -- add indexes for foreign keys + CREATE INDEX security_string_idx1 ON security_string(security_rule_id); + + ---------------------------------------------------------------------------------------- + -- Create Indexes and Constraints for table: security_number + ---------------------------------------------------------------------------------------- + + -- Add unique end-date key constraint (don't allow 2 records with the same name and a NULL record_end_date) + CREATE UNIQUE INDEX security_number_nuk1 ON security_number(name, (record_end_date is NULL)) where record_end_date is null; + + -- Add foreign key constraint + ALTER TABLE security_number ADD CONSTRAINT security_number_fk1 + FOREIGN KEY (security_rule_id) + REFERENCES security_rule(security_rule_id); + + -- add indexes for foreign keys + CREATE INDEX security_number_idx1 ON security_number(security_rule_id); + + ---------------------------------------------------------------------------------------- + -- Create Indexes and Constraints for table: security_datetime + ---------------------------------------------------------------------------------------- + + -- Add unique end-date key constraint (don't allow 2 records with the same name and a NULL record_end_date) + CREATE UNIQUE INDEX security_datetime_nuk1 ON security_datetime(name, (record_end_date is NULL)) where record_end_date is null; + + -- Add foreign key constraint + ALTER TABLE security_datetime ADD CONSTRAINT security_datetime_fk1 + FOREIGN KEY (security_rule_id) + REFERENCES security_rule(security_rule_id); + + -- add indexes for foreign keys + CREATE INDEX security_datetime_idx1 ON security_datetime(security_rule_id); + + ---------------------------------------------------------------------------------------- + -- Create Indexes and Constraints for table: security_spatial + ---------------------------------------------------------------------------------------- + + -- Add unique end-date key constraint (don't allow 2 records with the same name and a NULL record_end_date) + CREATE UNIQUE INDEX security_spatial_nuk1 ON security_spatial(name, (record_end_date is NULL)) where record_end_date is null; + + -- Add foreign key constraint + ALTER TABLE security_spatial ADD CONSTRAINT security_spatial_fk1 + FOREIGN KEY (security_rule_id) + REFERENCES security_rule(security_rule_id); + + -- add indexes for foreign keys + CREATE INDEX security_spatial_idx1 ON security_spatial(security_rule_id); + + ---------------------------------------------------------------------------------------- + -- Create audit and journal triggers + ---------------------------------------------------------------------------------------- + + create trigger audit_security_rule before insert or update or delete on security_rule for each row execute procedure tr_audit_trigger(); + create trigger journal_security_rule after insert or update or delete on security_rule for each row execute procedure tr_journal_trigger(); + + create trigger audit_security_string before insert or update or delete on security_string for each row execute procedure tr_audit_trigger(); + create trigger journal_security_string after insert or update or delete on security_string for each row execute procedure tr_journal_trigger(); + + create trigger audit_security_number before insert or update or delete on security_number for each row execute procedure tr_audit_trigger(); + create trigger journal_security_number after insert or update or delete on security_number for each row execute procedure tr_journal_trigger(); + + create trigger audit_security_datetime before insert or update or delete on security_datetime for each row execute procedure tr_audit_trigger(); + create trigger journal_security_datetime after insert or update or delete on security_datetime for each row execute procedure tr_journal_trigger(); + + create trigger audit_security_spatial before insert or update or delete on security_spatial for each row execute procedure tr_audit_trigger(); + create trigger journal_security_spatial after insert or update or delete on security_spatial for each row execute procedure tr_journal_trigger(); + `); +} + +export async function down(knex: Knex): Promise { + await knex.raw(``); +} diff --git a/database/src/migrations/20231709000002_security_functions.ts b/database/src/migrations/20231709000002_security_functions.ts new file mode 100644 index 000000000..ae00ec191 --- /dev/null +++ b/database/src/migrations/20231709000002_security_functions.ts @@ -0,0 +1,118 @@ +import { Knex } from 'knex'; + +/** + * Add functions: + * - evaluate_security_string_condition + * - evaluate_security_number_condition + * - evaluate_security_rule + * + * @export + * @param {Knex} knex + * @return {*} {Promise} + */ +export async function up(knex: Knex): Promise { + await knex.raw(` + ---------------------------------------------------------------------------------------- + -- Create functions + ---------------------------------------------------------------------------------------- + set search_path=biohub,public; + + -- Executes a single security_string condition against the provided submission_feature_id + -- Note: Returns true if the condition hit (applied). + CREATE OR REPLACE FUNCTION evaluate_security_string_condition(rule_name VARCHAR, submission_feature_id integer) + RETURNS TABLE (result boolean) + language plpgsql + SET client_min_messages = warning + AS $$ + DECLARE + comp TEXT; + val text; + BEGIN + SELECT security_string.comparator, security_string.value INTO comp, val FROM security_string WHERE name = evaluate_security_string_condition.rule_name; + + RETURN QUERY EXECUTE format('SELECT CASE WHEN EXISTS (SELECT 1 FROM search_string WHERE submission_feature_id = %s AND value %s ''%s'') THEN TRUE ELSE FALSE END', evaluate_security_string_condition.submission_feature_id, comp, val); + END; + $$; + + -- Executes a single security_number condition against the provided submission_feature_id + -- Note: Returns true if the condition hit (applied). + CREATE OR REPLACE FUNCTION evaluate_security_number_condition(rule_name VARCHAR, submission_feature_id integer) + RETURNS TABLE (result boolean) + language plpgsql + SET client_min_messages = warning + AS $$ + DECLARE + comparator TEXT; + value numeric; + BEGIN + SELECT security_number.comparator, security_number.value INTO comparator, value FROM security_number WHERE name = evaluate_security_number_condition.rule_name; + + RETURN QUERY EXECUTE format('SELECT CASE WHEN EXISTS (SELECT 1 FROM search_number WHERE submission_feature_id = %s AND value %s %s) THEN TRUE ELSE FALSE END', evaluate_security_number_condition.submission_feature_id, comparator, value); + END; + $$; + + -- Executes a single security_spatial condition against the provided submission_feature_id + -- Note: Returns true if the condition hit (applied). + -- Note: SRID of both geometries must be the same (prefer 4326) + CREATE OR REPLACE FUNCTION evaluate_security_spatial_condition(rule_name VARCHAR, submission_feature_id integer) + RETURNS TABLE (result BOOLEAN) + language plpgsql + set client_min_messages = warning + AS $$ + DECLARE + comparator TEXT; + value geometry; + BEGIN + SELECT security_spatial.comparator, security_spatial.value INTO comparator, value FROM security_spatial WHERE name = evaluate_security_spatial_condition.rule_name; + + RETURN QUERY EXECUTE FORMAT('SELECT CASE WHEN EXISTS (SELECT 1 FROM search_spatial WHERE submission_feature_id = %s AND ST_Intersects(value, ''%s'')) THEN TRUE ELSE FALSE END', evaluate_security_spatial_condition.submission_feature_id, value); + END; + $$; + + -- Executes all security rules against the provided submission_feature_id + -- Note: Returns a list of security rules and a boolean indicating if ALL conditions under that rule hit (applied). + CREATE OR REPLACE FUNCTION evaluate_security_rule(submission_feature_id integer) + RETURNS TABLE (result boolean, security_rule_id integer) + language plpgsql + set client_min_messages = warning + AS $$ + begin + return QUERY ( + select bool_and(r1.result) result, r1.security_rule_id from ( + (select bool_and(ex1.result) result, s1.security_rule_id from security_string s1, lateral evaluate_security_string_condition(s1.name, evaluate_security_rule.submission_feature_id) ex1 group by s1.security_rule_id) + union ALL + (select bool_and(ex2.result) result, s2.security_rule_id from security_number s2, lateral evaluate_security_number_condition(s2.name, evaluate_security_rule.submission_feature_id) ex2 group by s2.security_rule_id) + union ALL + (select bool_and(ex3.result) result, s3.security_rule_id from security_datetime s3, lateral evaluate_security_datetime_condition(s3.name, evaluate_security_rule.submission_feature_id) ex3 group by s3.security_rule_id) + union ALL + (select bool_and(ex3.result) result, s3.security_rule_id from security_spatial s3, lateral evaluate_security_spatial_condition(s3.name, evaluate_security_rule.submission_feature_id) ex3 group by s3.security_rule_id) + ) r1 group by r1.security_rule_id + ); + END; + $$; + + -- Executes all security rules against the provided submission_feature_id + -- Note: This is an alternate version to 'evaluate_security_rule' that includes the names of the conditions that hit/missed (applied/didn't apply). + CREATE OR REPLACE FUNCTION evaluate_security_rule_2(submission_feature_id integer) + RETURNS TABLE (result boolean, security_rule_id integer, security_condition_name varchar) + language plpgsql + set client_min_messages = warning + AS $$ + begin + return QUERY ( + (select bool_and(ex1.result) result, s1.security_rule_id, s1.name security_condition_name from security_string s1, lateral evaluate_security_string_condition(s1.name, evaluate_security_rule_2.submission_feature_id) ex1 group by s1.security_rule_id, s1.name) + union ALL + (select bool_and(ex2.result) result, s2.security_rule_id, s2.name security_condition_name from security_number s2, lateral evaluate_security_number_condition(s2.name, evaluate_security_rule_2.submission_feature_id) ex2 group by s2.security_rule_id, s2.name) + union ALL + (select bool_and(ex3.result) result, s3.security_rule_id, s3.name security_condition_name from security_datetime s3, lateral evaluate_security_datetime_condition(s3.name, evaluate_security_rule_2.submission_feature_id) ex3 group by s3.security_rule_id, s3.name) + union ALL + (select bool_and(ex3.result) result, s3.security_rule_id, s3.name security_condition_name from security_spatial s3, lateral evaluate_security_spatial_condition(s3.name, evaluate_security_rule_2.submission_feature_id) ex3 group by s3.security_rule_id, s3.name) + ); + END; + $$; + `); +} + +export async function down(knex: Knex): Promise { + await knex.raw(``); +}