From 80b85cca3bdc9871d4cd6103eab925b935af3a43 Mon Sep 17 00:00:00 2001 From: felmer <felmer> Date: Mon, 20 Aug 2012 09:40:42 +0000 Subject: [PATCH] SP-242, BIS-154: missing stuff for new database version 119 SVN: 26396 --- .../source/sql/postgresql/119/domains-119.sql | 30 + .../sql/postgresql/119/function-119.sql | 1963 +++++++++++++++++ .../source/sql/postgresql/119/grants-119.sql | 116 + 3 files changed, 2109 insertions(+) create mode 100644 openbis/source/sql/postgresql/119/domains-119.sql create mode 100644 openbis/source/sql/postgresql/119/function-119.sql create mode 100644 openbis/source/sql/postgresql/119/grants-119.sql diff --git a/openbis/source/sql/postgresql/119/domains-119.sql b/openbis/source/sql/postgresql/119/domains-119.sql new file mode 100644 index 00000000000..c6fffb75a11 --- /dev/null +++ b/openbis/source/sql/postgresql/119/domains-119.sql @@ -0,0 +1,30 @@ +-- Creating domains + +CREATE DOMAIN AUTHORIZATION_ROLE AS VARCHAR(40) CHECK (VALUE IN ('ADMIN', 'POWER_USER', 'USER', 'OBSERVER', 'ETL_SERVER')); +CREATE DOMAIN BOOLEAN_CHAR AS BOOLEAN DEFAULT FALSE; +CREATE DOMAIN BOOLEAN_CHAR_OR_UNKNOWN AS CHAR(1) DEFAULT 'U' CHECK (VALUE IN ('F', 'T', 'U')); +CREATE DOMAIN CODE AS VARCHAR(60); +CREATE DOMAIN COLUMN_LABEL AS VARCHAR(128); +CREATE DOMAIN DATA_STORE_SERVICE_KIND AS VARCHAR(40) CHECK (VALUE IN ('PROCESSING', 'QUERIES')); +CREATE DOMAIN DATA_STORE_SERVICE_REPORTING_PLUGIN_TYPE AS VARCHAR(40) CHECK (VALUE IN ('TABLE_MODEL', 'DSS_LINK', 'AGGREGATION_TABLE_MODEL')); +CREATE DOMAIN EVENT_TYPE AS VARCHAR(40) CHECK (VALUE IN ('DELETION', 'MOVEMENT')); +CREATE DOMAIN FILE AS BYTEA; +CREATE DOMAIN FILE_NAME AS VARCHAR(100); +CREATE DOMAIN TEXT_VALUE AS TEXT; +CREATE DOMAIN OBJECT_NAME AS VARCHAR(50); +CREATE DOMAIN REAL_VALUE AS REAL; +CREATE DOMAIN TECH_ID AS BIGINT; +CREATE DOMAIN TIME_STAMP AS TIMESTAMP WITH TIME ZONE; +CREATE DOMAIN TIME_STAMP_DFL AS TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP; +CREATE DOMAIN USER_ID AS VARCHAR(50); +CREATE DOMAIN TITLE_100 AS VARCHAR(100); +CREATE DOMAIN GRID_EXPRESSION AS VARCHAR(2000); +CREATE DOMAIN GRID_ID AS VARCHAR(200); +CREATE DOMAIN ORDINAL_INT AS BIGINT CHECK (VALUE > 0); +CREATE DOMAIN DESCRIPTION_2000 AS VARCHAR(2000); +CREATE DOMAIN ARCHIVING_STATUS AS VARCHAR(100) CHECK (VALUE IN ('LOCKED', 'AVAILABLE', 'ARCHIVED', 'ARCHIVE_PENDING', 'UNARCHIVE_PENDING', 'BACKUP_PENDING')); +CREATE DOMAIN QUERY_TYPE AS VARCHAR(40) CHECK (VALUE IN ('GENERIC', 'EXPERIMENT', 'SAMPLE', 'DATA_SET', 'MATERIAL')); +CREATE DOMAIN ENTITY_KIND AS VARCHAR(40) CHECK (VALUE IN ('SAMPLE', 'EXPERIMENT', 'DATA_SET', 'MATERIAL')); +CREATE DOMAIN SCRIPT_TYPE AS VARCHAR(40) CHECK (VALUE IN ('DYNAMIC_PROPERTY', 'MANAGED_PROPERTY', 'ENTITY_VALIDATION')); +CREATE DOMAIN IDENTIFIER AS VARCHAR(200); +CREATE DOMAIN DATA_SET_KIND AS VARCHAR(40) CHECK (VALUE IN ('PHYSICAL', 'LINK', 'CONTAINER')); diff --git a/openbis/source/sql/postgresql/119/function-119.sql b/openbis/source/sql/postgresql/119/function-119.sql new file mode 100644 index 00000000000..d481f0e631b --- /dev/null +++ b/openbis/source/sql/postgresql/119/function-119.sql @@ -0,0 +1,1963 @@ +-- Creating Functions + +------------------------------------------------------------------------------------ +-- Purpose: Create function RENAME_SEQUENCE() that is required for renaming the sequences belonging to tables +------------------------------------------------------------------------------------ +CREATE FUNCTION RENAME_SEQUENCE(OLD_NAME VARCHAR, NEW_NAME VARCHAR) RETURNS INTEGER AS $$ +DECLARE + CURR_SEQ_VAL INTEGER; +BEGIN + SELECT INTO CURR_SEQ_VAL NEXTVAL(OLD_NAME); + EXECUTE 'CREATE SEQUENCE ' || NEW_NAME || ' START WITH ' || CURR_SEQ_VAL; + EXECUTE 'DROP SEQUENCE ' || OLD_NAME; + RETURN CURR_SEQ_VAL; +END; +$$ LANGUAGE 'plpgsql'; + + +------------------------------------------------------------------------------------ +-- Purpose: Create trigger CONTROLLED_VOCABULARY_CHECK +------------------------------------------------------------------------------------ + +CREATE OR REPLACE FUNCTION CONTROLLED_VOCABULARY_CHECK() RETURNS trigger AS $$ +DECLARE + v_code CODE; +BEGIN + + select code into v_code from data_types where id = NEW.daty_id; + + -- Check if the data is of type "CONTROLLEDVOCABULARY" + if v_code = 'CONTROLLEDVOCABULARY' then + if NEW.covo_id IS NULL then + RAISE EXCEPTION 'Insert/Update of Property Type (Code: %) failed, as its Data Type is CONTROLLEDVOCABULARY, but it is not linked to a Controlled Vocabulary.', NEW.code; + end if; + end if; + + RETURN NEW; + +END; +$$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER CONTROLLED_VOCABULARY_CHECK BEFORE INSERT OR UPDATE ON PROPERTY_TYPES + FOR EACH ROW EXECUTE PROCEDURE CONTROLLED_VOCABULARY_CHECK(); + + +------------------------------------------------------------------------------------ +-- Purpose: Create trigger EXTERNAL_DATA_STORAGE_FORMAT_CHECK +------------------------------------------------------------------------------------ + +CREATE OR REPLACE FUNCTION EXTERNAL_DATA_STORAGE_FORMAT_CHECK() RETURNS trigger AS $$ +DECLARE + v_covo_code CODE; + data_code CODE; +BEGIN + + select code into v_covo_code from controlled_vocabularies + where is_internal_namespace = true and + id = (select covo_id from controlled_vocabulary_terms where id = NEW.cvte_id_stor_fmt); + -- Check if the data storage format is a term of the controlled vocabulary "STORAGE_FORMAT" + if v_covo_code != 'STORAGE_FORMAT' then + select code into data_code from data_all where id = NEW.data_id; + RAISE EXCEPTION 'Insert/Update of Data (Code: %) failed, as its Storage Format is %, but is required to be STORAGE_FORMAT.', data_code, v_covo_code; + end if; + + RETURN NEW; + +END; +$$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER EXTERNAL_DATA_STORAGE_FORMAT_CHECK BEFORE INSERT OR UPDATE ON EXTERNAL_DATA + FOR EACH ROW EXECUTE PROCEDURE EXTERNAL_DATA_STORAGE_FORMAT_CHECK(); + + +------------------------------------------------------------------------------------ +-- Purpose: Create triggers for checking sample code uniqueness +------------------------------------------------------------------------------------ + +CREATE OR REPLACE FUNCTION SAMPLE_CODE_UNIQUENESS_CHECK() RETURNS trigger AS $$ +DECLARE + counter INTEGER; +BEGIN + LOCK TABLE samples_all IN EXCLUSIVE MODE; + + IF (NEW.samp_id_part_of is NULL) THEN + IF (NEW.dbin_id is not NULL) THEN + SELECT count(*) into counter FROM samples_all + where id != NEW.id and code = NEW.code and samp_id_part_of is NULL and dbin_id = NEW.dbin_id; + IF (counter > 0) THEN + RAISE EXCEPTION 'Insert/Update of Sample (Code: %) failed because database instance sample with the same code already exists.', NEW.code; + END IF; + ELSIF (NEW.space_id is not NULL) THEN + SELECT count(*) into counter FROM samples_all + where id != NEW.id and code = NEW.code and samp_id_part_of is NULL and space_id = NEW.space_id; + IF (counter > 0) THEN + RAISE EXCEPTION 'Insert/Update of Sample (Code: %) failed because space sample with the same code already exists.', NEW.code; + END IF; + END IF; + ELSE + IF (NEW.dbin_id is not NULL) THEN + SELECT count(*) into counter FROM samples_all + where id != NEW.id and code = NEW.code and samp_id_part_of = NEW.samp_id_part_of and dbin_id = NEW.dbin_id; + IF (counter > 0) THEN + RAISE EXCEPTION 'Insert/Update of Sample (Code: %) failed because database instance sample with the same code and being the part of the same container already exists.', NEW.code; + END IF; + ELSIF (NEW.space_id is not NULL) THEN + SELECT count(*) into counter FROM samples_all + where id != NEW.id and code = NEW.code and samp_id_part_of = NEW.samp_id_part_of and space_id = NEW.space_id; + IF (counter > 0) THEN + RAISE EXCEPTION 'Insert/Update of Sample (Code: %) failed because space sample with the same code and being the part of the same container already exists.', NEW.code; + END IF; + END IF; + END IF; + + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER SAMPLE_CODE_UNIQUENESS_CHECK BEFORE INSERT OR UPDATE ON SAMPLES_ALL + FOR EACH ROW EXECUTE PROCEDURE SAMPLE_CODE_UNIQUENESS_CHECK(); + + +CREATE OR REPLACE FUNCTION SAMPLE_SUBCODE_UNIQUENESS_CHECK() RETURNS trigger AS $$ +DECLARE + counter INTEGER; + unique_subcode BOOLEAN_CHAR; +BEGIN + LOCK TABLE samples_all IN EXCLUSIVE MODE; + + SELECT is_subcode_unique into unique_subcode FROM sample_types WHERE id = NEW.saty_id; + + IF (unique_subcode) THEN + IF (NEW.dbin_id is not NULL) THEN + SELECT count(*) into counter FROM samples_all + where id != NEW.id and code = NEW.code and saty_id = NEW.saty_id and dbin_id = NEW.dbin_id; + IF (counter > 0) THEN + RAISE EXCEPTION 'Insert/Update of Sample (Code: %) failed because database instance sample of the same type with the same subcode already exists.', NEW.code; + END IF; + ELSIF (NEW.space_id is not NULL) THEN + SELECT count(*) into counter FROM samples_all + where id != NEW.id and code = NEW.code and saty_id = NEW.saty_id and space_id = NEW.space_id; + IF (counter > 0) THEN + RAISE EXCEPTION 'Insert/Update of Sample (Code: %) failed because space sample of the same type with the same subcode already exists.', NEW.code; + END IF; + END IF; + END IF; + + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER SAMPLE_SUBCODE_UNIQUENESS_CHECK BEFORE INSERT OR UPDATE ON SAMPLES_ALL + FOR EACH ROW EXECUTE PROCEDURE SAMPLE_SUBCODE_UNIQUENESS_CHECK(); + +------------------------------------------------------------------------------------ +-- Purpose: Create trigger MATERIAL/SAMPLE/EXPERIMENT/DATA_SET _PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK +-- It checks that if material property value is assigned to the entity, +-- then the material type is equal to the one described by property type. +------------------------------------------------------------------------------------ + +CREATE OR REPLACE FUNCTION MATERIAL_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK() RETURNS trigger AS $$ +DECLARE + v_type_id CODE; + v_type_id_prop CODE; +BEGIN + if NEW.mate_prop_id IS NOT NULL then + -- find material type id of the property type + select pt.maty_prop_id into v_type_id_prop + from material_type_property_types etpt, property_types pt + where NEW.mtpt_id = etpt.id AND etpt.prty_id = pt.id; + + if v_type_id_prop IS NOT NULL then + -- find material type id of the material which consists the entity's property value + select entity.maty_id into v_type_id + from materials entity + where NEW.mate_prop_id = entity.id; + if v_type_id != v_type_id_prop then + RAISE EXCEPTION 'Insert/Update of property value referencing material (id: %) failed, as referenced material type is different than expected (id %, expected id: %).', + NEW.mate_prop_id, v_type_id, v_type_id_prop; + end if; + end if; + end if; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER MATERIAL_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK BEFORE INSERT OR UPDATE ON material_properties + FOR EACH ROW EXECUTE PROCEDURE MATERIAL_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK(); + +CREATE OR REPLACE FUNCTION SAMPLE_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK() RETURNS trigger AS $$ +DECLARE + v_type_id CODE; + v_type_id_prop CODE; +BEGIN + if NEW.mate_prop_id IS NOT NULL then + -- find material type id of the property type + select pt.maty_prop_id into v_type_id_prop + from sample_type_property_types etpt, property_types pt + where NEW.stpt_id = etpt.id AND etpt.prty_id = pt.id; + + if v_type_id_prop IS NOT NULL then + -- find material type id of the material which consists the entity's property value + select entity.maty_id into v_type_id + from materials entity + where NEW.mate_prop_id = entity.id; + if v_type_id != v_type_id_prop then + RAISE EXCEPTION 'Insert/Update of property value referencing material (id: %) failed, as referenced material type is different than expected (id %, expected id: %).', + NEW.mate_prop_id, v_type_id, v_type_id_prop; + end if; + end if; + end if; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER SAMPLE_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK BEFORE INSERT OR UPDATE ON sample_properties + FOR EACH ROW EXECUTE PROCEDURE SAMPLE_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK(); + +CREATE OR REPLACE FUNCTION EXPERIMENT_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK() RETURNS trigger AS $$ +DECLARE + v_type_id CODE; + v_type_id_prop CODE; +BEGIN + if NEW.mate_prop_id IS NOT NULL then + -- find material type id of the property type + select pt.maty_prop_id into v_type_id_prop + from experiment_type_property_types etpt, property_types pt + where NEW.etpt_id = etpt.id AND etpt.prty_id = pt.id; + + if v_type_id_prop IS NOT NULL then + -- find material type id of the material which consists the entity's property value + select entity.maty_id into v_type_id + from materials entity + where NEW.mate_prop_id = entity.id; + if v_type_id != v_type_id_prop then + RAISE EXCEPTION 'Insert/Update of property value referencing material (id: %) failed, as referenced material type is different than expected (id %, expected id: %).', + NEW.mate_prop_id, v_type_id, v_type_id_prop; + end if; + end if; + end if; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER EXPERIMENT_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK BEFORE INSERT OR UPDATE ON experiment_properties + FOR EACH ROW EXECUTE PROCEDURE EXPERIMENT_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK(); + + -- data set +CREATE OR REPLACE FUNCTION DATA_SET_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK() RETURNS trigger AS $$ +DECLARE + v_type_id CODE; + v_type_id_prop CODE; +BEGIN + if NEW.mate_prop_id IS NOT NULL then + -- find material type id of the property type + select pt.maty_prop_id into v_type_id_prop + from data_set_type_property_types dstpt, property_types pt + where NEW.dstpt_id = dstpt.id AND dstpt.prty_id = pt.id; + + if v_type_id_prop IS NOT NULL then + -- find material type id of the material which consists the entity's property value + select entity.maty_id into v_type_id + from materials entity + where NEW.mate_prop_id = entity.id; + if v_type_id != v_type_id_prop then + RAISE EXCEPTION 'Insert/Update of property value referencing material (id: %) failed, as referenced material type is different than expected (id %, expected id: %).', + NEW.mate_prop_id, v_type_id, v_type_id_prop; + end if; + end if; + end if; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER DATA_SET_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK BEFORE INSERT OR UPDATE ON data_set_properties + FOR EACH ROW EXECUTE PROCEDURE DATA_SET_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK(); + +---------------------------------------------------------------------------------------------------- +-- Purpose: Create DEFERRED triggers for checking consistency of deletion state. +---------------------------------------------------------------------------------------------------- +-- utility function describing a deletion + +CREATE OR REPLACE FUNCTION deletion_description(del_id TECH_ID) RETURNS VARCHAR AS $$ +DECLARE + del_person VARCHAR; + del_date VARCHAR; + del_reason VARCHAR; +BEGIN + SELECT p.last_name || ' ' || p.first_name || ' (' || p.email || ')', + to_char(d.registration_timestamp, 'YYYY-MM-DD HH:MM:SS'), d.reason + INTO del_person, del_date, del_reason FROM deletions d, persons p + WHERE d.pers_id_registerer = p.id AND d.id = del_id; + RETURN 'deleted by ' || del_person || ' on ' || del_date || ' with reason: "' || del_reason || '"'; +END; +$$ LANGUAGE 'plpgsql'; + +---------------------------------------------------------------------------------------------------- +-- 1. data set +--- on insert/update - experiment, sample can't be deleted unless the data set is delete +--- - parents/children relationship stays unchanged + +CREATE OR REPLACE FUNCTION check_created_or_modified_data_set_owner_is_alive() RETURNS trigger AS $$ +DECLARE + owner_code CODE; + owner_del_id TECH_ID; +BEGIN + IF (NEW.del_id IS NOT NULL) THEN + RETURN NEW; + END IF; + + -- check sample + IF (NEW.samp_id IS NOT NULL) THEN + SELECT del_id, code INTO owner_del_id, owner_code + FROM samples + WHERE id = NEW.samp_id; + IF (owner_del_id IS NOT NULL) THEN + RAISE EXCEPTION 'Data Set (Code: %) cannot be connected to a Sample (Code: %) %.', + NEW.code, owner_code, deletion_description(owner_del_id); + END IF; + END IF; + -- check experiment + SELECT del_id, code INTO owner_del_id, owner_code + FROM experiments + WHERE id = NEW.expe_id; + IF (owner_del_id IS NOT NULL) THEN + RAISE EXCEPTION 'Data Set (Code: %) cannot be connected to an Experiment (Code: %) %.', + NEW.code, owner_code, deletion_description(owner_del_id); + END IF; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE CONSTRAINT TRIGGER check_created_or_modified_data_set_owner_is_alive + AFTER INSERT OR UPDATE ON data_all + DEFERRABLE INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE check_created_or_modified_data_set_owner_is_alive(); + +---------------------------------------------------------------------------------------------------- +-- 2. sample +--- on insert/update -> experiment can't be deleted unless the sample is deleted +--- deletion +----> all directly connected data sets need to be deleted +----> all components and children need to be deleted + +CREATE OR REPLACE FUNCTION check_created_or_modified_sample_owner_is_alive() RETURNS trigger AS $$ +DECLARE + owner_code CODE; + owner_del_id TECH_ID; +BEGIN + IF (NEW.del_id IS NOT NULL) THEN + RETURN NEW; + END IF; + + -- check experiment (can't be deleted) + IF (NEW.expe_id IS NOT NULL) THEN + SELECT del_id, code INTO owner_del_id, owner_code + FROM experiments + WHERE id = NEW.expe_id; + IF (owner_del_id IS NOT NULL) THEN + RAISE EXCEPTION 'Sample (Code: %) cannot be connected to an Experiment (Code: %) %.', + NEW.code, owner_code, deletion_description(owner_del_id); + END IF; + END IF; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE CONSTRAINT TRIGGER check_created_or_modified_sample_owner_is_alive + AFTER INSERT OR UPDATE ON samples_all + DEFERRABLE INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE check_created_or_modified_sample_owner_is_alive(); + +CREATE OR REPLACE FUNCTION check_deletion_consistency_on_sample_deletion() RETURNS trigger AS $$ +DECLARE + counter INTEGER; +BEGIN + IF (OLD.del_id IS NOT NULL OR NEW.del_id IS NULL) THEN + RETURN NEW; + END IF; + + -- all directly connected data sets need to be deleted + -- check datasets + SELECT count(*) INTO counter + FROM data + WHERE data.samp_id = NEW.id AND data.del_id IS NULL; + IF (counter > 0) THEN + RAISE EXCEPTION 'Sample (Code: %) deletion failed because at least one of its data sets was not deleted.', NEW.code; + END IF; + -- all components need to be deleted + SELECT count(*) INTO counter + FROM samples + WHERE samples.samp_id_part_of = NEW.id AND samples.del_id IS NULL; + IF (counter > 0) THEN + RAISE EXCEPTION 'Sample (Code: %) deletion failed because at least one of its component samples was not deleted.', NEW.code; + END IF; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE CONSTRAINT TRIGGER check_deletion_consistency_on_sample_deletion + AFTER UPDATE ON samples_all + DEFERRABLE INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE check_deletion_consistency_on_sample_deletion(); + +----------------------------------------- +-- update sample relationships on revert +----------------------------------------- + +CREATE OR REPLACE FUNCTION preserve_deletion_consistency_on_sample_relationships() RETURNS trigger AS $$ +DECLARE + delid TECH_ID; +BEGIN + IF (NEW.del_id IS NOT NULL OR OLD.del_id IS NULL) THEN + RETURN NEW; + END IF; + SELECT del_id INTO delid + FROM SAMPLES_ALL where id = NEW.sample_id_parent; + IF (delid IS NOT NULL) THEN + NEW.del_id = delid; + END IF; + SELECT del_id INTO delid + FROM SAMPLES_ALL where id = NEW.sample_id_child; + IF (delid IS NOT NULL) THEN + NEW.del_id = delid; + END IF; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER preserve_deletion_consistency_on_sample_relationships + BEFORE UPDATE ON sample_relationships_all + FOR EACH ROW + EXECUTE PROCEDURE preserve_deletion_consistency_on_sample_relationships(); + +----------------------------------------- +-- update dataset relationships on revert +----------------------------------------- +CREATE OR REPLACE FUNCTION preserve_deletion_consistency_on_data_set_relationships() RETURNS trigger AS $$ +DECLARE + delid TECH_ID; +BEGIN + IF (NEW.del_id IS NOT NULL OR OLD.del_id IS NULL) THEN + RETURN NEW; + END IF; + SELECT del_id INTO delid + FROM DATA_ALL where id = NEW.data_id_parent; + IF (delid IS NOT NULL) THEN + NEW.del_id = delid; + END IF; + SELECT del_id INTO delid + FROM DATA_ALL where id = NEW.data_id_child; + IF (delid IS NOT NULL) THEN + NEW.del_id = delid; + END IF; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER preserve_deletion_consistency_on_data_set_relationships + BEFORE UPDATE ON data_set_relationships_all + FOR EACH ROW + EXECUTE PROCEDURE preserve_deletion_consistency_on_data_set_relationships(); + +---------------------------------------------------------------------------------------------------- +-- 3. experiment +--- deletion -> all directly connected samples and data sets need to be deleted + +CREATE OR REPLACE FUNCTION check_deletion_consistency_on_experiment_deletion() RETURNS trigger AS $$ +DECLARE + counter INTEGER; +BEGIN + IF (OLD.del_id IS NOT NULL OR NEW.del_id IS NULL) THEN + RETURN NEW; + END IF; + + -- check datasets + SELECT count(*) INTO counter + FROM data + WHERE data.expe_id = NEW.id AND data.del_id IS NULL; + IF (counter > 0) THEN + RAISE EXCEPTION 'Experiment (Code: %) deletion failed because at least one of its data sets was not deleted.', NEW.code; + END IF; + -- check samples + SELECT count(*) INTO counter + FROM samples + WHERE samples.expe_id = NEW.id AND samples.del_id IS NULL; + IF (counter > 0) THEN + RAISE EXCEPTION 'Experiment (Code: %) deletion failed because at least one of its samples was not deleted.', NEW.code; + END IF; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE CONSTRAINT TRIGGER check_deletion_consistency_on_experiment_deletion + AFTER UPDATE ON experiments_all + DEFERRABLE INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE check_deletion_consistency_on_experiment_deletion(); + +---------------------------------------------------------------------------------------------------- +-- Rules for views +---------------------------------------------------------------------------------------------------- + +CREATE OR REPLACE RULE sample_insert AS + ON INSERT TO samples DO INSTEAD + INSERT INTO samples_all ( + id, + code, + dbin_id, + del_id, + expe_id, + modification_timestamp, + perm_id, + pers_id_registerer, + pers_id_modifier, + registration_timestamp, + samp_id_part_of, + saty_id, + space_id + ) VALUES ( + NEW.id, + NEW.code, + NEW.dbin_id, + NEW.del_id, + NEW.expe_id, + NEW.modification_timestamp, + NEW.perm_id, + NEW.pers_id_registerer, + NEW.pers_id_modifier, + NEW.registration_timestamp, + NEW.samp_id_part_of, + NEW.saty_id, + NEW.space_id + ); + +CREATE OR REPLACE RULE sample_update AS + ON UPDATE TO samples DO INSTEAD + UPDATE samples_all + SET code = NEW.code, + dbin_id = NEW.dbin_id, + del_id = NEW.del_id, + expe_id = NEW.expe_id, + modification_timestamp = NEW.modification_timestamp, + perm_id = NEW.perm_id, + pers_id_registerer = NEW.pers_id_registerer, + pers_id_modifier = NEW.pers_id_modifier, + registration_timestamp = NEW.registration_timestamp, + samp_id_part_of = NEW.samp_id_part_of, + saty_id = NEW.saty_id, + space_id = NEW.space_id + WHERE id = NEW.id; + +CREATE OR REPLACE RULE sample_delete AS + ON DELETE TO samples DO INSTEAD + DELETE FROM samples_all + WHERE id = OLD.id; + +CREATE OR REPLACE RULE sample_deleted_update AS + ON UPDATE TO samples_deleted DO INSTEAD + UPDATE samples_all + SET del_id = NEW.del_id, + modification_timestamp = NEW.modification_timestamp + WHERE id = NEW.id; + +CREATE OR REPLACE RULE sample_deleted_delete AS + ON DELETE TO samples_deleted DO INSTEAD + DELETE FROM samples_all + WHERE id = OLD.id; + +---------------- +-- experiment -- +---------------- + +CREATE OR REPLACE RULE experiment_insert AS + ON INSERT TO experiments DO INSTEAD + INSERT INTO experiments_all ( + id, + code, + del_id, + exty_id, + is_public, + modification_timestamp, + perm_id, + pers_id_registerer, + pers_id_modifier, + proj_id, + registration_timestamp + ) VALUES ( + NEW.id, + NEW.code, + NEW.del_id, + NEW.exty_id, + NEW.is_public, + NEW.modification_timestamp, + NEW.perm_id, + NEW.pers_id_registerer, + NEW.pers_id_modifier, + NEW.proj_id, + NEW.registration_timestamp + ); + +CREATE OR REPLACE RULE experiment_update AS + ON UPDATE TO experiments DO INSTEAD + UPDATE experiments_all + SET code = NEW.code, + del_id = NEW.del_id, + exty_id = NEW.exty_id, + is_public = NEW.is_public, + modification_timestamp = NEW.modification_timestamp, + perm_id = NEW.perm_id, + pers_id_registerer = NEW.pers_id_registerer, + pers_id_modifier = NEW.pers_id_modifier, + proj_id = NEW.proj_id, + registration_timestamp = NEW.registration_timestamp + WHERE id = NEW.id; + +CREATE OR REPLACE RULE experiment_delete AS + ON DELETE TO experiments DO INSTEAD + DELETE FROM experiments_all + WHERE id = OLD.id; + +CREATE OR REPLACE RULE experiments_deleted_update AS + ON UPDATE TO experiments_deleted DO INSTEAD + UPDATE experiments_all + SET del_id = NEW.del_id, + modification_timestamp = NEW.modification_timestamp + WHERE id = NEW.id; + +CREATE OR REPLACE RULE experiments_deleted_delete AS + ON DELETE TO experiments_deleted DO INSTEAD + DELETE FROM experiments_all + WHERE id = OLD.id; + +---------- +-- data -- +---------- + +CREATE OR REPLACE RULE data_insert AS + ON INSERT TO data DO INSTEAD + INSERT INTO data_all ( + id, + code, + ctnr_id, + ctnr_order, + del_id, + expe_id, + dast_id, + data_producer_code, + dsty_id, + is_derived, + is_placeholder, + is_valid, + modification_timestamp, + pers_id_registerer, + pers_id_modifier, + production_timestamp, + registration_timestamp, + samp_id + ) VALUES ( + NEW.id, + NEW.code, + NEW.ctnr_id, + NEW.ctnr_order, + NEW.del_id, + NEW.expe_id, + NEW.dast_id, + NEW.data_producer_code, + NEW.dsty_id, + NEW.is_derived, + NEW.is_placeholder, + NEW.is_valid, + NEW.modification_timestamp, + NEW.pers_id_registerer, + NEW.pers_id_modifier, + NEW.production_timestamp, + NEW.registration_timestamp, + NEW.samp_id + ); + +CREATE OR REPLACE RULE data_update AS + ON UPDATE TO data DO INSTEAD + UPDATE data_all + SET code = NEW.code, + ctnr_id = NEW.ctnr_id, + ctnr_order = NEW.ctnr_order, + del_id = NEW.del_id, + expe_id = NEW.expe_id, + dast_id = NEW.dast_id, + data_producer_code = NEW.data_producer_code, + dsty_id = NEW.dsty_id, + is_derived = NEW.is_derived, + is_placeholder = NEW.is_placeholder, + is_valid = NEW.is_valid, + modification_timestamp = NEW.modification_timestamp, + pers_id_registerer = NEW.pers_id_registerer, + pers_id_modifier = NEW.pers_id_modifier, + production_timestamp = NEW.production_timestamp, + registration_timestamp = NEW.registration_timestamp, + samp_id = NEW.samp_id + WHERE id = NEW.id; + +CREATE OR REPLACE RULE data_all AS + ON DELETE TO data DO INSTEAD + DELETE FROM data_all + WHERE id = OLD.id; + +CREATE OR REPLACE RULE data_deleted_update AS + ON UPDATE TO data_deleted DO INSTEAD + UPDATE data_all + SET del_id = NEW.del_id, + modification_timestamp = NEW.modification_timestamp + WHERE id = NEW.id; + +CREATE OR REPLACE RULE data_deleted_delete AS + ON DELETE TO data_deleted DO INSTEAD + DELETE FROM data_all + WHERE id = OLD.id; + + +---------------------------------------------------------------------------------------------------- +-- Rules for properties history +---------------------------------------------------------------------------------------------------- + +-- Material Properties -- + +CREATE OR REPLACE RULE material_properties_update AS + ON UPDATE TO material_properties + WHERE (OLD.VALUE IS NOT NULL AND decode(substring(OLD.value from 1 for 1), 'escape') != E'\\xefbfbd' AND OLD.VALUE != NEW.VALUE) + OR (OLD.CVTE_ID IS NOT NULL AND OLD.CVTE_ID != NEW.CVTE_ID) + OR (OLD.MATE_PROP_ID IS NOT NULL AND OLD.MATE_PROP_ID != NEW.MATE_PROP_ID) + DO ALSO + INSERT INTO material_properties_history ( + ID, + MATE_ID, + MTPT_ID, + VALUE, + VOCABULARY_TERM, + MATERIAL, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP, + VALID_UNTIL_TIMESTAMP + ) VALUES ( + nextval('MATERIAL_PROPERTY_ID_SEQ'), + OLD.MATE_ID, + OLD.MTPT_ID, + OLD.VALUE, + (select (t.code || ' [' || v.code || ']') from controlled_vocabulary_terms as t join controlled_vocabularies as v on t.covo_id = v.id where t.id = OLD.CVTE_ID), + (select (m.code || ' [' || mt.code || ']') from materials as m join material_types as mt on m.maty_id = mt.id where m.id = OLD.MATE_PROP_ID), + OLD.PERS_ID_AUTHOR, + OLD.MODIFICATION_TIMESTAMP, + current_timestamp + ); + +CREATE OR REPLACE RULE material_properties_delete AS + ON DELETE TO material_properties + WHERE (OLD.VALUE IS NOT NULL AND decode(substring(OLD.value from 1 for 1), 'escape') != E'\\xefbfbd') + OR OLD.CVTE_ID IS NOT NULL + OR OLD.MATE_PROP_ID IS NOT NULL + DO ALSO + INSERT INTO material_properties_history ( + ID, + MATE_ID, + MTPT_ID, + VALUE, + VOCABULARY_TERM, + MATERIAL, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP, + VALID_UNTIL_TIMESTAMP + ) VALUES ( + nextval('MATERIAL_PROPERTY_ID_SEQ'), + OLD.MATE_ID, + OLD.MTPT_ID, + OLD.VALUE, + (select (t.code || ' [' || v.code || ']') from controlled_vocabulary_terms as t join controlled_vocabularies as v on t.covo_id = v.id where t.id = OLD.CVTE_ID), + (select (m.code || ' [' || mt.code || ']') from materials as m join material_types as mt on m.maty_id = mt.id where m.id = OLD.MATE_PROP_ID), + OLD.PERS_ID_AUTHOR, + OLD.MODIFICATION_TIMESTAMP, + current_timestamp + ); + +-- Experiment Properties -- + +CREATE OR REPLACE RULE experiment_properties_update AS + ON UPDATE TO experiment_properties + WHERE (OLD.VALUE IS NOT NULL AND decode(substring(OLD.value from 1 for 1), 'escape') != E'\\xefbfbd' AND OLD.VALUE != NEW.VALUE) + OR (OLD.CVTE_ID IS NOT NULL AND OLD.CVTE_ID != NEW.CVTE_ID) + OR (OLD.MATE_PROP_ID IS NOT NULL AND OLD.MATE_PROP_ID != NEW.MATE_PROP_ID) + DO ALSO + INSERT INTO experiment_properties_history ( + ID, + EXPE_ID, + ETPT_ID, + VALUE, + VOCABULARY_TERM, + MATERIAL, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP, + VALID_UNTIL_TIMESTAMP + ) VALUES ( + nextval('EXPERIMENT_PROPERTY_ID_SEQ'), + OLD.EXPE_ID, + OLD.ETPT_ID, + OLD.VALUE, + (select (t.code || ' [' || v.code || ']') from controlled_vocabulary_terms as t join controlled_vocabularies as v on t.covo_id = v.id where t.id = OLD.CVTE_ID), + (select (m.code || ' [' || mt.code || ']') from materials as m join material_types as mt on m.maty_id = mt.id where m.id = OLD.MATE_PROP_ID), + OLD.PERS_ID_AUTHOR, + OLD.MODIFICATION_TIMESTAMP, + current_timestamp + ); + +CREATE OR REPLACE RULE experiment_properties_delete AS + ON DELETE TO experiment_properties + WHERE (OLD.VALUE IS NOT NULL AND decode(substring(OLD.value from 1 for 1), 'escape') != E'\\xefbfbd') + OR OLD.CVTE_ID IS NOT NULL + OR OLD.MATE_PROP_ID IS NOT NULL + DO ALSO + INSERT INTO experiment_properties_history ( + ID, + EXPE_ID, + ETPT_ID, + VALUE, + VOCABULARY_TERM, + MATERIAL, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP, + VALID_UNTIL_TIMESTAMP + ) VALUES ( + nextval('EXPERIMENT_PROPERTY_ID_SEQ'), + OLD.EXPE_ID, + OLD.ETPT_ID, + OLD.VALUE, + (select (t.code || ' [' || v.code || ']') from controlled_vocabulary_terms as t join controlled_vocabularies as v on t.covo_id = v.id where t.id = OLD.CVTE_ID), + (select (m.code || ' [' || mt.code || ']') from materials as m join material_types as mt on m.maty_id = mt.id where m.id = OLD.MATE_PROP_ID), + OLD.PERS_ID_AUTHOR, + OLD.MODIFICATION_TIMESTAMP, + current_timestamp + ); + +-- Sample Properties -- + +CREATE OR REPLACE RULE sample_properties_update AS + ON UPDATE TO sample_properties + WHERE (OLD.VALUE IS NOT NULL AND decode(substring(OLD.value from 1 for 1), 'escape') != E'\\xefbfbd' AND OLD.VALUE != NEW.VALUE) + OR (OLD.CVTE_ID IS NOT NULL AND OLD.CVTE_ID != NEW.CVTE_ID) + OR (OLD.MATE_PROP_ID IS NOT NULL AND OLD.MATE_PROP_ID != NEW.MATE_PROP_ID) + DO ALSO + INSERT INTO sample_properties_history ( + ID, + SAMP_ID, + STPT_ID, + VALUE, + VOCABULARY_TERM, + MATERIAL, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP, + VALID_UNTIL_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_PROPERTY_ID_SEQ'), + OLD.SAMP_ID, + OLD.STPT_ID, + OLD.VALUE, + (select (t.code || ' [' || v.code || ']') from controlled_vocabulary_terms as t join controlled_vocabularies as v on t.covo_id = v.id where t.id = OLD.CVTE_ID), + (select (m.code || ' [' || mt.code || ']') from materials as m join material_types as mt on m.maty_id = mt.id where m.id = OLD.MATE_PROP_ID), + OLD.PERS_ID_AUTHOR, + OLD.MODIFICATION_TIMESTAMP, + current_timestamp + ); + +CREATE OR REPLACE RULE sample_properties_delete AS + ON DELETE TO sample_properties + WHERE (OLD.VALUE IS NOT NULL AND decode(substring(OLD.value from 1 for 1), 'escape') != E'\\xefbfbd') + OR OLD.CVTE_ID IS NOT NULL + OR OLD.MATE_PROP_ID IS NOT NULL + DO ALSO + INSERT INTO sample_properties_history ( + ID, + SAMP_ID, + STPT_ID, + VALUE, + VOCABULARY_TERM, + MATERIAL, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP, + VALID_UNTIL_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_PROPERTY_ID_SEQ'), + OLD.SAMP_ID, + OLD.STPT_ID, + OLD.VALUE, + (select (t.code || ' [' || v.code || ']') from controlled_vocabulary_terms as t join controlled_vocabularies as v on t.covo_id = v.id where t.id = OLD.CVTE_ID), + (select (m.code || ' [' || mt.code || ']') from materials as m join material_types as mt on m.maty_id = mt.id where m.id = OLD.MATE_PROP_ID), + OLD.PERS_ID_AUTHOR, + OLD.MODIFICATION_TIMESTAMP, + current_timestamp + ); + +-- Data Set Properties -- + +CREATE OR REPLACE RULE data_set_properties_update AS + ON UPDATE TO data_set_properties + WHERE (OLD.VALUE IS NOT NULL AND decode(substring(OLD.value from 1 for 1), 'escape') != E'\\xefbfbd' AND OLD.VALUE != NEW.VALUE) + OR (OLD.CVTE_ID IS NOT NULL AND OLD.CVTE_ID != NEW.CVTE_ID) + OR (OLD.MATE_PROP_ID IS NOT NULL AND OLD.MATE_PROP_ID != NEW.MATE_PROP_ID) + DO ALSO + INSERT INTO data_set_properties_history ( + ID, + DS_ID, + DSTPT_ID, + VALUE, + VOCABULARY_TERM, + MATERIAL, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP, + VALID_UNTIL_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_PROPERTY_ID_SEQ'), + OLD.DS_ID, + OLD.DSTPT_ID, + OLD.VALUE, + (select (t.code || ' [' || v.code || ']') from controlled_vocabulary_terms as t join controlled_vocabularies as v on t.covo_id = v.id where t.id = OLD.CVTE_ID), + (select (m.code || ' [' || mt.code || ']') from materials as m join material_types as mt on m.maty_id = mt.id where m.id = OLD.MATE_PROP_ID), + OLD.PERS_ID_AUTHOR, + OLD.MODIFICATION_TIMESTAMP, + current_timestamp + ); + +CREATE OR REPLACE RULE data_set_properties_delete AS + ON DELETE TO data_set_properties + WHERE (OLD.VALUE IS NOT NULL AND decode(substring(OLD.value from 1 for 1), 'escape') != E'\\xefbfbd') + OR OLD.CVTE_ID IS NOT NULL + OR OLD.MATE_PROP_ID IS NOT NULL + DO ALSO + INSERT INTO data_set_properties_history ( + ID, + DS_ID, + DSTPT_ID, + VALUE, + VOCABULARY_TERM, + MATERIAL, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP, + VALID_UNTIL_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_PROPERTY_ID_SEQ'), + OLD.DS_ID, + OLD.DSTPT_ID, + OLD.VALUE, + (select (t.code || ' [' || v.code || ']') from controlled_vocabulary_terms as t join controlled_vocabularies as v on t.covo_id = v.id where t.id = OLD.CVTE_ID), + (select (m.code || ' [' || mt.code || ']') from materials as m join material_types as mt on m.maty_id = mt.id where m.id = OLD.MATE_PROP_ID), + OLD.PERS_ID_AUTHOR, + OLD.MODIFICATION_TIMESTAMP, + current_timestamp + ); + +-- End of rules for properties history + +CREATE OR REPLACE RULE data_set_relationships_insert AS + ON INSERT TO data_set_relationships DO INSTEAD + INSERT INTO data_set_relationships_all ( + data_id_parent, + data_id_child, + pers_id_author, + registration_timestamp, + modification_timestamp + ) VALUES ( + NEW.data_id_parent, + NEW.data_id_child, + NEW.pers_id_author, + NEW.registration_timestamp, + NEW.modification_timestamp + ); + +CREATE OR REPLACE RULE data_set_relationships_update AS + ON UPDATE TO data_set_relationships DO INSTEAD + UPDATE data_set_relationships_all + SET + data_id_parent = NEW.data_id_parent, + data_id_child = NEW.data_id_child, + del_id = NEW.del_id, + pers_id_author = NEW.pers_id_author, + registration_timestamp = NEW.registration_timestamp, + modification_timestamp = NEW.modification_timestamp + WHERE data_id_parent = NEW.data_id_parent and data_id_child = NEW.data_id_child; + +CREATE OR REPLACE RULE data_set_relationships_delete AS + ON DELETE TO data_set_relationships DO INSTEAD + DELETE FROM data_set_relationships_all + WHERE data_id_parent = OLD.data_id_parent and data_id_child = OLD.data_id_child; + +CREATE OR REPLACE RULE sample_relationships_insert AS + ON INSERT TO sample_relationships DO INSTEAD + INSERT INTO sample_relationships_all ( + id, + sample_id_parent, + relationship_id, + sample_id_child, + pers_id_author, + registration_timestamp, + modification_timestamp + ) VALUES ( + NEW.id, + NEW.sample_id_parent, + NEW.relationship_id, + NEW.sample_id_child, + NEW.pers_id_author, + NEW.registration_timestamp, + NEW.modification_timestamp + ); + +CREATE OR REPLACE RULE sample_relationships_update AS + ON UPDATE TO sample_relationships DO INSTEAD + UPDATE sample_relationships_all + SET + sample_id_parent = NEW.sample_id_parent, + relationship_id = NEW.relationship_id, + sample_id_child = NEW.sample_id_child, + del_id = NEW.del_id, + pers_id_author = NEW.pers_id_author, + registration_timestamp = NEW.registration_timestamp, + modification_timestamp = NEW.modification_timestamp + WHERE id = NEW.id; + +CREATE OR REPLACE RULE sample_relationships_delete AS + ON DELETE TO sample_relationships DO INSTEAD + DELETE FROM sample_relationships_all + WHERE id = OLD.id; + +---------------------------------------------------------------------------------------------------- +-- Rules for relationships history +---------------------------------------------------------------------------------------------------- + +-- sample -> experiment + +CREATE OR REPLACE RULE sample_experiment_update AS + ON UPDATE TO samples_all + WHERE (OLD.EXPE_ID != NEW.EXPE_ID OR OLD.EXPE_ID IS NULL) AND NEW.EXPE_ID IS NOT NULL + DO ALSO ( + UPDATE EXPERIMENT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_EXPE_ID = OLD.EXPE_ID AND SAMP_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL; + INSERT INTO EXPERIMENT_RELATIONSHIPS_HISTORY ( + ID, + MAIN_EXPE_ID, + RELATION_TYPE, + SAMP_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('EXPERIMENT_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.EXPE_ID, + 'OWNER', + NEW.ID, + NEW.PERM_ID, + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + UPDATE SAMPLE_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_SAMP_ID = OLD.ID AND EXPE_ID = OLD.EXPE_ID AND VALID_UNTIL_TIMESTAMP IS NULL; + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + EXPE_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'OWNED', + NEW.EXPE_ID, + (SELECT PERM_ID FROM EXPERIMENTS_ALL WHERE ID = NEW.EXPE_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE sample_experiment_remove_update AS + ON UPDATE TO samples_all + WHERE OLD.EXPE_ID IS NOT NULL AND NEW.EXPE_ID IS NULL + DO ALSO ( + UPDATE EXPERIMENT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_EXPE_ID = OLD.EXPE_ID AND SAMP_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL; + UPDATE SAMPLE_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_SAMP_ID = OLD.ID AND EXPE_ID = OLD.EXPE_ID AND VALID_UNTIL_TIMESTAMP IS NULL; + ); + +CREATE OR REPLACE RULE sample_experiment_insert AS + ON INSERT TO samples_all + WHERE NEW.EXPE_ID IS NOT NULL + DO ALSO ( + INSERT INTO EXPERIMENT_RELATIONSHIPS_HISTORY ( + ID, + MAIN_EXPE_ID, + RELATION_TYPE, + SAMP_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('EXPERIMENT_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.EXPE_ID, + 'OWNER', + NEW.ID, + NEW.PERM_ID, + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + EXPE_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'OWNED', + NEW.EXPE_ID, + (SELECT PERM_ID FROM EXPERIMENTS_ALL WHERE ID = NEW.EXPE_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE sample_experiment_delete AS + ON DELETE TO samples_all + WHERE OLD.EXPE_ID IS NOT NULL + DO ALSO + UPDATE EXPERIMENT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = current_timestamp + WHERE MAIN_EXPE_ID = OLD.EXPE_ID AND SAMP_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL; + +-- container samples + +CREATE OR REPLACE RULE sample_container_update AS + ON UPDATE TO samples_all + WHERE (OLD.SAMP_ID_PART_OF != NEW.SAMP_ID_PART_OF OR OLD.SAMP_ID_PART_OF IS NULL) AND NEW.SAMP_ID_PART_OF IS NOT NULL + DO ALSO ( + UPDATE SAMPLE_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE (MAIN_SAMP_ID = OLD.SAMP_ID_PART_OF AND SAMP_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL AND RELATION_TYPE = 'CONTAINER') + OR (MAIN_SAMP_ID = OLD.ID AND SAMP_ID = OLD.SAMP_ID_PART_OF AND VALID_UNTIL_TIMESTAMP IS NULL AND RELATION_TYPE = 'CONTAINED'); + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + SAMP_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.SAMP_ID_PART_OF, + 'CONTAINER', + NEW.ID, + NEW.PERM_ID, + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + SAMP_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'CONTAINED', + NEW.SAMP_ID_PART_OF, + (SELECT PERM_ID FROM SAMPLES_ALL WHERE ID = NEW.SAMP_ID_PART_OF), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE sample_container_remove_update AS + ON UPDATE TO samples_all + WHERE OLD.SAMP_ID_PART_OF IS NOT NULL AND NEW.SAMP_ID_PART_OF IS NULL + DO ALSO ( + UPDATE SAMPLE_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE (MAIN_SAMP_ID = OLD.SAMP_ID_PART_OF AND SAMP_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL AND RELATION_TYPE = 'CONTAINER') + OR (MAIN_SAMP_ID = OLD.ID AND SAMP_ID = OLD.SAMP_ID_PART_OF AND VALID_UNTIL_TIMESTAMP IS NULL AND RELATION_TYPE = 'CONTAINED'); + ); + +CREATE OR REPLACE RULE sample_container_insert AS + ON INSERT TO samples_all + WHERE NEW.SAMP_ID_PART_OF IS NOT NULL + DO ALSO ( + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + SAMP_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.SAMP_ID_PART_OF, + 'CONTAINER', + NEW.ID, + NEW.PERM_ID, + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + SAMP_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'CONTAINED', + NEW.SAMP_ID_PART_OF, + (SELECT PERM_ID FROM SAMPLES_ALL WHERE ID = NEW.SAMP_ID_PART_OF), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE sample_container_delete AS + ON DELETE TO samples_all + WHERE OLD.SAMP_ID_PART_OF IS NOT NULL + DO ALSO + UPDATE SAMPLE_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = current_timestamp + WHERE MAIN_SAMP_ID = OLD.SAMP_ID_PART_OF AND SAMP_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL AND RELATION_TYPE = 'CONTAINER'; + +-- dataset -> eperiment + +CREATE OR REPLACE RULE dataset_experiment_update AS + ON UPDATE TO data_all + WHERE (OLD.EXPE_ID != NEW.EXPE_ID OR OLD.SAMP_ID IS NOT NULL) AND NEW.SAMP_ID IS NULL + DO ALSO ( + UPDATE EXPERIMENT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_EXPE_ID = OLD.EXPE_ID AND DATA_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL; + INSERT INTO EXPERIMENT_RELATIONSHIPS_HISTORY ( + ID, + MAIN_EXPE_ID, + RELATION_TYPE, + DATA_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('EXPERIMENT_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.EXPE_ID, + 'OWNER', + NEW.ID, + NEW.CODE, + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + UPDATE DATA_SET_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE (MAIN_DATA_ID = OLD.ID AND EXPE_ID = OLD.EXPE_ID AND VALID_UNTIL_TIMESTAMP IS NULL); + INSERT INTO DATA_SET_RELATIONSHIPS_HISTORY ( + ID, + MAIN_DATA_ID, + RELATION_TYPE, + EXPE_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'OWNED', + NEW.EXPE_ID, + (SELECT PERM_ID FROM EXPERIMENTS_ALL WHERE ID = NEW.EXPE_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE dataset_experiment_remove_update AS + ON UPDATE TO data_all + WHERE OLD.SAMP_ID IS NULL AND NEW.SAMP_ID IS NOT NULL + DO ALSO ( + UPDATE EXPERIMENT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_EXPE_ID = OLD.EXPE_ID AND DATA_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL; + UPDATE DATA_SET_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_DATA_ID = OLD.ID AND EXPE_ID = OLD.EXPE_ID AND VALID_UNTIL_TIMESTAMP IS NULL; + ); + +CREATE OR REPLACE RULE dataset_experiment_insert AS + ON INSERT TO data_all + WHERE NEW.EXPE_ID IS NOT NULL AND NEW.SAMP_ID IS NULL + DO ALSO ( + INSERT INTO EXPERIMENT_RELATIONSHIPS_HISTORY ( + ID, + MAIN_EXPE_ID, + RELATION_TYPE, + DATA_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('EXPERIMENT_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.EXPE_ID, + 'OWNER', + NEW.ID, + NEW.CODE, + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + INSERT INTO DATA_SET_RELATIONSHIPS_HISTORY ( + ID, + MAIN_DATA_ID, + RELATION_TYPE, + EXPE_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'OWNED', + NEW.EXPE_ID, + (SELECT PERM_ID FROM EXPERIMENTS_ALL WHERE ID = NEW.EXPE_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE dataset_experiment_delete AS + ON DELETE TO data_all + WHERE OLD.EXPE_ID IS NOT NULL AND OLD.SAMP_ID IS NULL + DO ALSO + UPDATE EXPERIMENT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = current_timestamp + WHERE MAIN_EXPE_ID = OLD.EXPE_ID AND DATA_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL; + +-- dataset -> sample + +CREATE OR REPLACE RULE dataset_sample_update AS + ON UPDATE TO data_all + WHERE (OLD.SAMP_ID != NEW.SAMP_ID OR OLD.SAMP_ID IS NULL) AND NEW.SAMP_ID IS NOT NULL + DO ALSO ( + UPDATE SAMPLE_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_SAMP_ID = OLD.SAMP_ID AND DATA_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL; + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + DATA_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.SAMP_ID, + 'OWNER', + NEW.ID, + NEW.CODE, + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + UPDATE DATA_SET_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE (MAIN_DATA_ID = OLD.ID AND SAMP_ID = OLD.SAMP_ID AND VALID_UNTIL_TIMESTAMP IS NULL); + INSERT INTO DATA_SET_RELATIONSHIPS_HISTORY ( + ID, + MAIN_DATA_ID, + RELATION_TYPE, + SAMP_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'OWNED', + NEW.SAMP_ID, + (SELECT PERM_ID FROM SAMPLES_ALL WHERE ID = NEW.SAMP_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE dataset_sample_remove_update AS + ON UPDATE TO data_all + WHERE OLD.SAMP_ID IS NOT NULL AND NEW.SAMP_ID IS NULL + DO ALSO ( + UPDATE SAMPLE_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_SAMP_ID = OLD.SAMP_ID AND DATA_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL; + UPDATE DATA_SET_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_DATA_ID = OLD.ID AND SAMP_ID = OLD.SAMP_ID AND VALID_UNTIL_TIMESTAMP IS NULL; + ); + +CREATE OR REPLACE RULE dataset_sample_insert AS + ON INSERT TO data_all + WHERE NEW.SAMP_ID IS NOT NULL + DO ALSO ( + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + DATA_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.SAMP_ID, + 'OWNER', + NEW.ID, + NEW.CODE, + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + INSERT INTO DATA_SET_RELATIONSHIPS_HISTORY ( + ID, + MAIN_DATA_ID, + RELATION_TYPE, + SAMP_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'OWNED', + NEW.SAMP_ID, + (SELECT PERM_ID FROM SAMPLES_ALL WHERE ID = NEW.SAMP_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE dataset_sample_delete AS + ON DELETE TO data_all + WHERE OLD.SAMP_ID IS NOT NULL + DO ALSO + UPDATE SAMPLE_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = current_timestamp + WHERE MAIN_SAMP_ID = OLD.SAMP_ID AND DATA_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL; + +-- dataset container + +CREATE OR REPLACE RULE dataset_container_update AS + ON UPDATE TO data_all + WHERE (OLD.CTNR_ID != NEW.CTNR_ID OR OLD.CTNR_ID IS NULL) AND NEW.CTNR_ID IS NOT NULL + DO ALSO ( + UPDATE DATA_SET_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE (MAIN_DATA_ID = OLD.CTNR_ID AND DATA_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL AND RELATION_TYPE = 'CONTAINER') + OR (MAIN_DATA_ID = OLD.ID AND DATA_ID = OLD.CTNR_ID AND VALID_UNTIL_TIMESTAMP IS NULL AND RELATION_TYPE = 'CONTAINED'); + INSERT INTO DATA_SET_RELATIONSHIPS_HISTORY ( + ID, + MAIN_DATA_ID, + RELATION_TYPE, + DATA_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.CTNR_ID, + 'CONTAINER', + NEW.ID, + NEW.CODE, + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + INSERT INTO DATA_SET_RELATIONSHIPS_HISTORY ( + ID, + MAIN_DATA_ID, + RELATION_TYPE, + DATA_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'CONTAINED', + NEW.CTNR_ID, + (SELECT CODE FROM data_all WHERE ID = NEW.CTNR_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE data_container_remove_update AS + ON UPDATE TO data_all + WHERE OLD.CTNR_ID IS NOT NULL AND NEW.CTNR_ID IS NULL + DO ALSO ( + UPDATE DATA_SET_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE (MAIN_DATA_ID = OLD.CTNR_ID AND DATA_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL AND RELATION_TYPE = 'CONTAINER') + OR (MAIN_DATA_ID = OLD.ID AND DATA_ID = OLD.CTNR_ID AND VALID_UNTIL_TIMESTAMP IS NULL AND RELATION_TYPE = 'CONTAINED'); + ); + +CREATE OR REPLACE RULE data_container_insert AS + ON INSERT TO data_all + WHERE NEW.CTNR_ID IS NOT NULL + DO ALSO ( + INSERT INTO DATA_SET_RELATIONSHIPS_HISTORY ( + ID, + MAIN_DATA_ID, + RELATION_TYPE, + DATA_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.CTNR_ID, + 'CONTAINER', + NEW.ID, + NEW.CODE, + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + INSERT INTO DATA_SET_RELATIONSHIPS_HISTORY ( + ID, + MAIN_DATA_ID, + RELATION_TYPE, + DATA_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'CONTAINED', + NEW.CTNR_ID, + (SELECT CODE FROM data_all WHERE ID = NEW.CTNR_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE data_container_delete AS + ON DELETE TO data_all + WHERE OLD.CTNR_ID IS NOT NULL + DO ALSO + UPDATE DATA_SET_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = current_timestamp + WHERE MAIN_DATA_ID = OLD.CTNR_ID AND DATA_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL AND RELATION_TYPE = 'CONTAINER'; + +-- dataset parent-child relationship + +CREATE OR REPLACE RULE data_parent_child_insert AS + ON INSERT TO data_set_relationships_all + WHERE NEW.DEL_ID IS NULL + DO ALSO ( + INSERT INTO DATA_SET_RELATIONSHIPS_HISTORY ( + ID, + MAIN_DATA_ID, + RELATION_TYPE, + DATA_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.DATA_ID_PARENT, + 'PARENT', + NEW.DATA_ID_CHILD, + (SELECT CODE FROM data_all WHERE ID = NEW.DATA_ID_CHILD), + NEW.PERS_ID_AUTHOR, + NEW.MODIFICATION_TIMESTAMP + ); + INSERT INTO DATA_SET_RELATIONSHIPS_HISTORY ( + ID, + MAIN_DATA_ID, + RELATION_TYPE, + DATA_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.DATA_ID_CHILD, + 'CHILD', + NEW.DATA_ID_PARENT, + (SELECT CODE FROM data_all WHERE ID = NEW.DATA_ID_PARENT), + NEW.PERS_ID_AUTHOR, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE data_parent_child_delete AS + ON DELETE TO data_set_relationships_all + WHERE OLD.DEL_ID IS NULL + DO ALSO ( + UPDATE DATA_SET_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = current_timestamp + WHERE (MAIN_DATA_ID = OLD.DATA_ID_PARENT AND DATA_ID = OLD.DATA_ID_CHILD AND VALID_UNTIL_TIMESTAMP IS NULL) + OR (MAIN_DATA_ID = OLD.DATA_ID_CHILD AND DATA_ID = OLD.DATA_ID_PARENT AND VALID_UNTIL_TIMESTAMP IS NULL); + ); + +CREATE OR REPLACE RULE data_parent_child_update AS + ON UPDATE TO data_set_relationships_all + WHERE NEW.DEL_ID IS NOT NULL AND OLD.DEL_ID IS NULL + DO ALSO ( + UPDATE DATA_SET_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = current_timestamp + WHERE (MAIN_DATA_ID = OLD.DATA_ID_PARENT AND DATA_ID = OLD.DATA_ID_CHILD AND VALID_UNTIL_TIMESTAMP IS NULL) + OR (MAIN_DATA_ID = OLD.DATA_ID_CHILD AND DATA_ID = OLD.DATA_ID_PARENT AND VALID_UNTIL_TIMESTAMP IS NULL); + ); + +CREATE OR REPLACE RULE data_parent_child_revert_update AS + ON UPDATE TO data_set_relationships_all + WHERE OLD.DEL_ID IS NOT NULL AND NEW.DEL_ID IS NULL + DO ALSO ( + INSERT INTO DATA_SET_RELATIONSHIPS_HISTORY ( + ID, + MAIN_DATA_ID, + RELATION_TYPE, + DATA_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.DATA_ID_PARENT, + 'PARENT', + NEW.DATA_ID_CHILD, + (SELECT CODE FROM data_all WHERE ID = NEW.DATA_ID_CHILD), + NEW.PERS_ID_AUTHOR, + NEW.MODIFICATION_TIMESTAMP + ); + INSERT INTO DATA_SET_RELATIONSHIPS_HISTORY ( + ID, + MAIN_DATA_ID, + RELATION_TYPE, + DATA_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.DATA_ID_CHILD, + 'CHILD', + NEW.DATA_ID_PARENT, + (SELECT CODE FROM data_all WHERE ID = NEW.DATA_ID_PARENT), + NEW.PERS_ID_AUTHOR, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +-- samples parent-child relationship + +CREATE OR REPLACE RULE sample_parent_child_insert AS + ON INSERT TO sample_relationships_all + WHERE NEW.DEL_ID IS NULL + DO ALSO ( + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + SAMP_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.SAMPLE_ID_PARENT, + 'PARENT', + NEW.SAMPLE_ID_CHILD, + (SELECT PERM_ID FROM samples_all WHERE ID = NEW.SAMPLE_ID_CHILD), + NEW.PERS_ID_AUTHOR, + NEW.MODIFICATION_TIMESTAMP + ); + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + SAMP_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.SAMPLE_ID_CHILD, + 'CHILD', + NEW.SAMPLE_ID_PARENT, + (SELECT PERM_ID FROM samples_all WHERE ID = NEW.SAMPLE_ID_PARENT), + NEW.PERS_ID_AUTHOR, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE sample_parent_child_delete AS + ON DELETE TO sample_relationships_all + WHERE OLD.DEL_ID IS NULL + DO ALSO ( + UPDATE SAMPLE_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = current_timestamp + WHERE (MAIN_SAMP_ID = OLD.SAMPLE_ID_PARENT AND SAMP_ID = OLD.SAMPLE_ID_CHILD AND VALID_UNTIL_TIMESTAMP IS NULL) + OR (MAIN_SAMP_ID = OLD.SAMPLE_ID_CHILD AND SAMP_ID = OLD.SAMPLE_ID_PARENT AND VALID_UNTIL_TIMESTAMP IS NULL); + ); + +CREATE OR REPLACE RULE sample_parent_child_update AS + ON UPDATE TO sample_relationships_all + WHERE NEW.DEL_ID IS NOT NULL AND OLD.DEL_ID IS NULL + DO ALSO ( + UPDATE SAMPLE_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = current_timestamp + WHERE (MAIN_SAMP_ID = OLD.SAMPLE_ID_PARENT AND SAMP_ID = OLD.SAMPLE_ID_CHILD AND VALID_UNTIL_TIMESTAMP IS NULL) + OR (MAIN_SAMP_ID = OLD.SAMPLE_ID_CHILD AND SAMP_ID = OLD.SAMPLE_ID_PARENT AND VALID_UNTIL_TIMESTAMP IS NULL); + ); + +CREATE OR REPLACE RULE sample_parent_child_revert_update AS + ON UPDATE TO sample_relationships_all + WHERE NEW.DEL_ID IS NULL AND OLD.DEL_ID IS NOT NULL + DO ALSO ( + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + SAMP_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.SAMPLE_ID_PARENT, + 'PARENT', + NEW.SAMPLE_ID_CHILD, + (SELECT PERM_ID FROM samples_all WHERE ID = NEW.SAMPLE_ID_CHILD), + NEW.PERS_ID_AUTHOR, + NEW.MODIFICATION_TIMESTAMP + ); + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + SAMP_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.SAMPLE_ID_CHILD, + 'CHILD', + NEW.SAMPLE_ID_PARENT, + (SELECT PERM_ID FROM samples_all WHERE ID = NEW.SAMPLE_ID_PARENT), + NEW.PERS_ID_AUTHOR, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +-- experiment -> project + +CREATE OR REPLACE RULE experiment_project_update AS + ON UPDATE TO experiments_all + WHERE (OLD.PROJ_ID != NEW.PROJ_ID OR OLD.PROJ_ID IS NULL) AND NEW.PROJ_ID IS NOT NULL + DO ALSO ( + UPDATE PROJECT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_PROJ_ID = OLD.PROJ_ID AND EXPE_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL; + INSERT INTO PROJECT_RELATIONSHIPS_HISTORY ( + ID, + MAIN_PROJ_ID, + RELATION_TYPE, + EXPE_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('PROJECT_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.PROJ_ID, + 'OWNER', + NEW.ID, + NEW.PERM_ID, + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + UPDATE EXPERIMENT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_EXPE_ID = OLD.ID AND PROJ_ID = OLD.PROJ_ID AND VALID_UNTIL_TIMESTAMP IS NULL; + INSERT INTO EXPERIMENT_RELATIONSHIPS_HISTORY ( + ID, + MAIN_EXPE_ID, + RELATION_TYPE, + PROJ_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('EXPERIMENT_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'OWNED', + NEW.PROJ_ID, + (SELECT CODE FROM PROJECTS WHERE ID = NEW.PROJ_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE experiment_project_remove_update AS + ON UPDATE TO experiments_all + WHERE OLD.PROJ_ID IS NOT NULL AND NEW.PROJ_ID IS NULL + DO ALSO ( + UPDATE PROJECT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_PROJ_ID = OLD.PROJ_ID AND EXPE_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL; + UPDATE EXPERIMENT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_EXPE_ID = OLD.ID AND PROJ_ID = OLD.PROJ_ID AND VALID_UNTIL_TIMESTAMP IS NULL; + ); + +CREATE OR REPLACE RULE experiment_project_insert AS + ON INSERT TO experiments_all + WHERE NEW.PROJ_ID IS NOT NULL + DO ALSO ( + INSERT INTO PROJECT_RELATIONSHIPS_HISTORY ( + ID, + MAIN_PROJ_ID, + RELATION_TYPE, + EXPE_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('PROJECT_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.PROJ_ID, + 'OWNER', + NEW.ID, + NEW.PERM_ID, + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + INSERT INTO EXPERIMENT_RELATIONSHIPS_HISTORY ( + ID, + MAIN_EXPE_ID, + RELATION_TYPE, + PROJ_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('EXPERIMENT_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'OWNED', + NEW.PROJ_ID, + (SELECT CODE FROM PROJECTS WHERE ID = NEW.PROJ_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE experiment_project_delete AS + ON DELETE TO experiments_all + WHERE OLD.PROJ_ID IS NOT NULL + DO ALSO + UPDATE PROJECT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = current_timestamp + WHERE MAIN_PROJ_ID = OLD.PROJ_ID AND EXPE_ID = OLD.ID AND VALID_UNTIL_TIMESTAMP IS NULL; + +-- project -> space + +CREATE OR REPLACE RULE project_space_update AS + ON UPDATE TO projects + WHERE (OLD.SPACE_ID != NEW.SPACE_ID OR OLD.SPACE_ID IS NULL) AND NEW.SPACE_ID IS NOT NULL + DO ALSO ( + UPDATE PROJECT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_PROJ_ID = OLD.ID AND SPACE_ID = OLD.SPACE_ID AND VALID_UNTIL_TIMESTAMP IS NULL; + INSERT INTO PROJECT_RELATIONSHIPS_HISTORY ( + ID, + MAIN_PROJ_ID, + RELATION_TYPE, + SPACE_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('PROJECT_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'OWNED', + NEW.SPACE_ID, + (SELECT CODE FROM SPACES WHERE ID = NEW.SPACE_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE project_space_remove_update AS + ON UPDATE TO projects + WHERE OLD.SPACE_ID IS NOT NULL AND NEW.SPACE_ID IS NULL + DO ALSO ( + UPDATE PROJECT_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_PROJ_ID = OLD.ID AND SPACE_ID = OLD.SPACE_ID AND VALID_UNTIL_TIMESTAMP IS NULL; + ); + +CREATE OR REPLACE RULE project_space_insert AS + ON INSERT TO projects + WHERE NEW.SPACE_ID IS NOT NULL + DO ALSO ( + INSERT INTO PROJECT_RELATIONSHIPS_HISTORY ( + ID, + MAIN_PROJ_ID, + RELATION_TYPE, + SPACE_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('PROJECT_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'OWNED', + NEW.SPACE_ID, + (SELECT CODE FROM SPACES WHERE ID = NEW.SPACE_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +-- sample -> space + +CREATE OR REPLACE RULE sample_space_update AS + ON UPDATE TO samples_all + WHERE (OLD.SPACE_ID != NEW.SPACE_ID OR OLD.SPACE_ID IS NULL OR OLD.EXPE_ID IS NOT NULL) AND NEW.SPACE_ID IS NOT NULL AND NEW.EXPE_ID IS NULL + DO ALSO ( + UPDATE SAMPLE_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_SAMP_ID = OLD.ID AND SPACE_ID = OLD.SPACE_ID AND VALID_UNTIL_TIMESTAMP IS NULL; + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + SPACE_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'OWNED', + NEW.SPACE_ID, + (SELECT CODE FROM SPACES WHERE ID = NEW.SPACE_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); + +CREATE OR REPLACE RULE sample_space_remove_update AS + ON UPDATE TO samples_all + WHERE OLD.SPACE_ID IS NOT NULL AND (NEW.SPACE_ID IS NULL OR (OLD.EXPE_ID IS NULL AND NEW.EXPE_ID IS NOT NULL)) + DO ALSO ( + UPDATE SAMPLE_RELATIONSHIPS_HISTORY SET VALID_UNTIL_TIMESTAMP = NEW.MODIFICATION_TIMESTAMP + WHERE MAIN_SAMP_ID = OLD.ID AND SPACE_ID = OLD.SPACE_ID AND VALID_UNTIL_TIMESTAMP IS NULL; + ); + +CREATE OR REPLACE RULE sample_space_insert AS + ON INSERT TO samples_all + WHERE NEW.EXPE_ID IS NULL AND NEW.SPACE_ID IS NOT NULL + DO ALSO ( + INSERT INTO SAMPLE_RELATIONSHIPS_HISTORY ( + ID, + MAIN_SAMP_ID, + RELATION_TYPE, + SPACE_ID, + ENTITY_PERM_ID, + PERS_ID_AUTHOR, + VALID_FROM_TIMESTAMP + ) VALUES ( + nextval('SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ'), + NEW.ID, + 'OWNED', + NEW.SPACE_ID, + (SELECT CODE FROM SPACES WHERE ID = NEW.SPACE_ID), + NEW.PERS_ID_MODIFIER, + NEW.MODIFICATION_TIMESTAMP + ); + ); +-- end of rules for relationships history \ No newline at end of file diff --git a/openbis/source/sql/postgresql/119/grants-119.sql b/openbis/source/sql/postgresql/119/grants-119.sql new file mode 100644 index 00000000000..15b45931cf4 --- /dev/null +++ b/openbis/source/sql/postgresql/119/grants-119.sql @@ -0,0 +1,116 @@ +-- Granting SELECT privilege to group OPENBIS_READONLY + +GRANT SELECT ON SEQUENCE attachment_content_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE attachment_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE code_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE controlled_vocabulary_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE core_plugin_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE cvte_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE data_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE data_set_property_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE data_set_relationship_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE data_set_type_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE data_store_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE DATA_STORE_SERVICES_ID_SEQ TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE data_type_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE database_instance_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE dstpt_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE etpt_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE event_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE experiment_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE experiment_property_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE experiment_type_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE file_format_type_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE space_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE deletion_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE locator_type_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE material_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE material_property_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE material_type_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE mtpt_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE perm_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE person_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE project_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE property_type_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE role_assignment_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE sample_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE sample_property_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE sample_type_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE stpt_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE authorization_group_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE filter_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE query_id_seq TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE POST_REGISTRATION_DATASET_QUEUE_ID_SEQ TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE ENTITY_OPERATIONS_LOG_ID_SEQ TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE EXPERIMENT_RELATIONSHIPS_HISTORY_ID_SEQ TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE SAMPLE_RELATIONSHIPS_HISTORY_ID_SEQ TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE DATA_SET_RELATIONSHIPS_HISTORY_ID_SEQ TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE PROJECT_RELATIONSHIPS_HISTORY_ID_SEQ TO GROUP OPENBIS_READONLY; +GRANT SELECT ON SEQUENCE EXTERNAL_DATA_MANAGEMENT_SYSTEM_ID_SEQ TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE attachment_contents TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE attachments TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE controlled_vocabularies TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE controlled_vocabulary_terms TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE core_plugins TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE data_all TO GROUP OPENBIS_READONLY; +GRANT SELECT ON data TO GROUP OPENBIS_READONLY; +GRANT SELECT ON data_deleted TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE data_set_properties TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE data_set_properties_history TO GROUP OPENBIS_READONLY; +GRANT SELECT ON data_set_relationships TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE data_set_relationships_all TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE data_set_type_property_types TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE data_set_types TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE data_stores TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE data_types TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE DATA_STORE_SERVICES TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE DATA_STORE_SERVICE_DATA_SET_TYPES TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE database_instances TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE database_version_logs TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE events TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE experiment_properties TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE experiment_properties_history TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE experiment_type_property_types TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE experiment_types TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE experiments_all TO GROUP OPENBIS_READONLY; +GRANT SELECT ON experiments TO GROUP OPENBIS_READONLY; +GRANT SELECT ON experiments_deleted TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE external_data TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE file_format_types TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE spaces TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE deletions TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE locator_types TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE material_properties TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE material_properties_history TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE material_type_property_types TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE material_types TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE materials TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE persons TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE projects TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE property_types TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE role_assignments TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE sample_properties TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE sample_properties_history TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE sample_type_property_types TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE sample_types TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE samples_all TO GROUP OPENBIS_READONLY; +GRANT SELECT ON samples TO GROUP OPENBIS_READONLY; +GRANT SELECT ON samples_deleted TO GROUP OPENBIS_READONLY; +GRANT SELECT ON sample_relationships TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE sample_relationships_all TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE authorization_groups TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE authorization_group_persons TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE filters TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE queries TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE scripts TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE POST_REGISTRATION_DATASET_QUEUE TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE ENTITY_OPERATIONS_LOG TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE EXPERIMENT_RELATIONSHIPS_HISTORY TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE SAMPLE_RELATIONSHIPS_HISTORY TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE DATA_SET_RELATIONSHIPS_HISTORY TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE PROJECT_RELATIONSHIPS_HISTORY TO GROUP OPENBIS_READONLY; +GRANT SELECT ON sample_history_view TO GROUP OPENBIS_READONLY; +GRANT SELECT ON data_set_history_view TO GROUP OPENBIS_READONLY; +GRANT SELECT ON experiment_history_view TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE EXTERNAL_DATA_MANAGEMENT_SYSTEMS TO GROUP OPENBIS_READONLY; +GRANT SELECT ON TABLE LINK_DATA TO GROUP OPENBIS_READONLY; -- GitLab