diff --git a/openbis/source/sql/postgresql/075/function-075.sql b/openbis/source/sql/postgresql/075/function-075.sql index 170393d9dcb62ef78c54072ccdf515c36e160366..ed1382ad132fa87814b88cc37a46450d0f17e534 100644 --- a/openbis/source/sql/postgresql/075/function-075.sql +++ b/openbis/source/sql/postgresql/075/function-075.sql @@ -271,4 +271,181 @@ 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(); \ No newline at end of file + FOR EACH ROW EXECUTE PROCEDURE DATA_SET_PROPERTY_WITH_MATERIAL_DATA_TYPE_CHECK(); + +--------------------------------------------------------------------------------------------------- +-- Purpose: Create DEFERRED triggers for checking consistency of deletion state. +---------------------------------------------------------------------------------------------------- +-- 1. forbid modifications of deleted entities +-- NOTE: we don't check for creation of deleted entities as it it not possible from the client side +-- and would reduce performance of bulk insert. + +CREATE OR REPLACE FUNCTION entity_name(entity_table_name NAME) RETURNS varchar AS $$ +BEGIN + CASE entity_table_name + WHEN 'data' THEN RETURN 'Data Set'; + WHEN 'samples' THEN RETURN 'Sample'; + WHEN 'experiments' THEN RETURN 'Experiment'; + WHEN 'materials' THEN RETURN 'Material'; + ELSE RAISE EXCEPTION '"%" is not an entity table', entity_table_name; + END CASE; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION forbid_deleted_entity_modification() RETURNS trigger AS $$ +BEGIN + RAISE NOTICE 'Check % (Code: %) ', entity_name(TG_TABLE_NAME), NEW.code; + IF (OLD.del_id IS NOT NULL AND NEW.del_id IS NOT NULL) THEN + RAISE EXCEPTION 'Update of a deleted % (Code: %) failed because deleted entities can''t be modified.', entity_name(TG_TABLE_NAME), NEW.code; + END IF; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER forbid_deleted_entity_modification + BEFORE UPDATE ON data + FOR EACH ROW EXECUTE PROCEDURE forbid_deleted_entity_modification(); + +CREATE TRIGGER forbid_deleted_entity_modification + BEFORE UPDATE ON samples + FOR EACH ROW EXECUTE PROCEDURE forbid_deleted_entity_modification(); + +CREATE TRIGGER forbid_deleted_entity_modification + BEFORE UPDATE ON experiments + FOR EACH ROW EXECUTE PROCEDURE forbid_deleted_entity_modification(); + +---------------------------------------------------------------------------------------------------- +-- 2. 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 + -- 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 'Insert/Update of Data Set (Code: %) failed because it cannot be connected to a deleted Sample (Code: %).', NEW.code, owner_code; + 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 'Insert/Update of Data Set (Code: %) failed because it cannot be connected to a deleted Experiment (Code: %).', NEW.code, owner_code; + 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 + DEFERRABLE INITIALLY DEFERRED + FOR EACH ROW WHEN (NEW.del_id IS NULL) + EXECUTE PROCEDURE check_created_or_modified_data_set_owner_is_alive(); + +---------------------------------------------------------------------------------------------------- +-- 3. 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 + -- 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.samp_id; + IF (owner_del_id IS NOT NULL) THEN + RAISE EXCEPTION 'Insert/Update of Sample (Code: %) failed because it cannot be connected to a deleted Experiment (Code: %).', NEW.code, owner_code; + 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 + DEFERRABLE INITIALLY DEFERRED + FOR EACH ROW WHEN (NEW.del_id IS NULL) + 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 + -- 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 is 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 is not deleted.', NEW.code; + END IF; + -- all children need to be deleted + SELECT count(*) INTO counter + FROM sample_relationships sr, samples sc + WHERE sample_id_parent = NEW.id AND sc.id = sr.sample_id_child AND sc.del_id IS NULL; + IF (counter > 0) THEN + RAISE EXCEPTION 'Sample (Code: %) deletion failed because at least one of its child samples is not deleted.', NEW.code; + END IF; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE CONSTRAINT TRIGGER check_deletion_consistency_on_sample_deletion + AFTER UPDATE ON samples + DEFERRABLE INITIALLY DEFERRED + FOR EACH ROW + WHEN (OLD.del_id IS NULL AND NEW.del_id IS NOT NULL) + EXECUTE PROCEDURE check_deletion_consistency_on_sample_deletion(); + +---------------------------------------------------------------------------------------------------- +-- 4. 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 + -- 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 is 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 is not deleted.', NEW.code; + END IF; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE CONSTRAINT TRIGGER check_deletion_consistency_on_experiment_deletion + AFTER UPDATE ON experiments + DEFERRABLE INITIALLY DEFERRED + FOR EACH ROW + WHEN (OLD.del_id IS NULL AND NEW.del_id IS NOT NULL) + EXECUTE PROCEDURE check_deletion_consistency_on_experiment_deletion(); \ No newline at end of file diff --git a/openbis/source/sql/postgresql/migration/migration-074-075.sql b/openbis/source/sql/postgresql/migration/migration-074-075.sql index ee37c9eadfe8aeb7a4dcfcd2e6213a95863de6ce..a06e6eca7075eb512a7148d74bf2e12589a5b4ab 100644 --- a/openbis/source/sql/postgresql/migration/migration-074-075.sql +++ b/openbis/source/sql/postgresql/migration/migration-074-075.sql @@ -1,8 +1,8 @@ -- Migration from 074 to 075 -------------------------------------- --- Rename invalidation to deletion -- -------------------------------------- +---------------------------------------------- +-- Purpose: Rename invalidation to deletion -- +---------------------------------------------- -- renamings: -- table INVALIDATIONS -> DELETIONS ALTER TABLE invalidations RENAME TO deletions; @@ -47,4 +47,181 @@ ALTER TABLE deletions -- DELETE FROM events WHERE event_type = 'INVALIDATION'; ALTER DOMAIN event_type DROP CONSTRAINT event_type_check; -ALTER DOMAIN event_type ADD CONSTRAINT event_type_check CHECK (VALUE IN ('DELETION', 'MOVEMENT')); \ No newline at end of file +ALTER DOMAIN event_type ADD CONSTRAINT event_type_check CHECK (VALUE IN ('DELETION', 'MOVEMENT')); + +--------------------------------------------------------------------------------------------------- +-- Purpose: Create DEFERRED triggers for checking consistency of deletion state. +---------------------------------------------------------------------------------------------------- +-- 1. forbid modifications of deleted entities +-- NOTE: we don't check for creation of deleted entities as it is not possible from the client side +-- and would reduce performance of bulk insert. + +CREATE OR REPLACE FUNCTION entity_name(entity_table_name NAME) RETURNS varchar AS $$ +BEGIN + CASE entity_table_name + WHEN 'data' THEN RETURN 'Data Set'; + WHEN 'samples' THEN RETURN 'Sample'; + WHEN 'experiments' THEN RETURN 'Experiment'; + WHEN 'materials' THEN RETURN 'Material'; + ELSE RAISE EXCEPTION '"%" is not an entity table', entity_table_name; + END CASE; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION forbid_deleted_entity_modification() RETURNS trigger AS $$ +BEGIN + RAISE NOTICE 'Check % (Code: %) ', entity_name(TG_TABLE_NAME), NEW.code; + IF (OLD.del_id IS NOT NULL AND NEW.del_id IS NOT NULL) THEN + RAISE EXCEPTION 'Update of a deleted % (Code: %) failed because deleted entities can''t be modified.', entity_name(TG_TABLE_NAME), NEW.code; + END IF; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE TRIGGER forbid_deleted_entity_modification + BEFORE UPDATE ON data + FOR EACH ROW EXECUTE PROCEDURE forbid_deleted_entity_modification(); + +CREATE TRIGGER forbid_deleted_entity_modification + BEFORE UPDATE ON samples + FOR EACH ROW EXECUTE PROCEDURE forbid_deleted_entity_modification(); + +CREATE TRIGGER forbid_deleted_entity_modification + BEFORE UPDATE ON experiments + FOR EACH ROW EXECUTE PROCEDURE forbid_deleted_entity_modification(); + +---------------------------------------------------------------------------------------------------- +-- 2. 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 + -- 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 'Insert/Update of Data Set (Code: %) failed because it cannot be connected to a deleted Sample (Code: %).', NEW.code, owner_code; + 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 'Insert/Update of Data Set (Code: %) failed because it cannot be connected to a deleted Experiment (Code: %).', NEW.code, owner_code; + 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 + DEFERRABLE INITIALLY DEFERRED + FOR EACH ROW WHEN (NEW.del_id IS NULL) + EXECUTE PROCEDURE check_created_or_modified_data_set_owner_is_alive(); + +---------------------------------------------------------------------------------------------------- +-- 3. 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 + -- 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.samp_id; + IF (owner_del_id IS NOT NULL) THEN + RAISE EXCEPTION 'Insert/Update of Sample (Code: %) failed because it cannot be connected to a deleted Experiment (Code: %).', NEW.code, owner_code; + 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 + DEFERRABLE INITIALLY DEFERRED + FOR EACH ROW WHEN (NEW.del_id IS NULL) + 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 + -- 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 is 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 is not deleted.', NEW.code; + END IF; + -- all children need to be deleted + SELECT count(*) INTO counter + FROM sample_relationships sr, samples sc + WHERE sample_id_parent = NEW.id AND sc.id = sr.sample_id_child AND sc.del_id IS NULL; + IF (counter > 0) THEN + RAISE EXCEPTION 'Sample (Code: %) deletion failed because at least one of its child samples is not deleted.', NEW.code; + END IF; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE CONSTRAINT TRIGGER check_deletion_consistency_on_sample_deletion + AFTER UPDATE ON samples + DEFERRABLE INITIALLY DEFERRED + FOR EACH ROW + WHEN (OLD.del_id IS NULL AND NEW.del_id IS NOT NULL) + EXECUTE PROCEDURE check_deletion_consistency_on_sample_deletion(); + +---------------------------------------------------------------------------------------------------- +-- 4. 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 + -- 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 is 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 is not deleted.', NEW.code; + END IF; + RETURN NEW; +END; +$$ LANGUAGE 'plpgsql'; + +CREATE CONSTRAINT TRIGGER check_deletion_consistency_on_experiment_deletion + AFTER UPDATE ON experiments + DEFERRABLE INITIALLY DEFERRED + FOR EACH ROW + WHEN (OLD.del_id IS NULL AND NEW.del_id IS NOT NULL) + EXECUTE PROCEDURE check_deletion_consistency_on_experiment_deletion(); \ No newline at end of file