Skip to content
Snippets Groups Projects
Commit ee4f8844 authored by buczekp's avatar buczekp
Browse files

[LMS-2368] fixed incomplete migration (functions+triggers were missing in test DB) & fixed a test

SVN: 22079
parent 0d104065
No related branches found
No related tags found
No related merge requests found
......@@ -300,13 +300,18 @@ public class ExperimentDAOTest extends AbstractDAOTest
public final void testDeleteFailWithDataSets()
{
final IExperimentDAO experimentDAO = daoFactory.getExperimentDAO();
final ExperimentPE deletedExperiment = findExperiment("/CISD/DEFAULT/EXP-X");
// Deleted experiment should have data sets which prevent it from deletion.
// Other connections which also prevent sample deletion should be empty in this test.
// Other connections which also prevent experiment deletion should be empty in this test.
// Currently there is no such experiment in test DB so we first add a data set
// Currently there is no such experiment in test DB so we first create an experiment
// with no connections and then connect a data set to it.
// to an empty experiment (with no connections).
ExperimentPE experiment =
createExperiment("CISD", "CISD", "DEFAULT", "EXP-13", "SIRNA_HCS");
daoFactory.getExperimentDAO().createOrUpdateExperiment(experiment);
final ExperimentPE deletedExperiment = findExperiment("/CISD/DEFAULT/EXP-13");
final ExternalDataPE dataSet = findExternalData("20081105092158673-1");
dataSet.setExperiment(deletedExperiment);
daoFactory.getDataDAO().validateAndSaveUpdatedEntity(dataSet);
......
......@@ -269,10 +269,17 @@ CREATE INDEX space_pers_registered_by_fk_i ON spaces USING btree (pers_id_regist
CREATE INDEX stpt_pers_fk_i ON sample_type_property_types USING btree (pers_id_registerer);
CREATE INDEX stpt_prty_fk_i ON sample_type_property_types USING btree (prty_id);
CREATE INDEX stpt_saty_fk_i ON sample_type_property_types USING btree (saty_id);
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();
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 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();
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();
CREATE TRIGGER controlled_vocabulary_check BEFORE INSERT OR UPDATE ON property_types FOR EACH ROW EXECUTE PROCEDURE controlled_vocabulary_check();
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();
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();
CREATE TRIGGER external_data_storage_format_check BEFORE INSERT OR UPDATE ON external_data FOR EACH ROW EXECUTE PROCEDURE external_data_storage_format_check();
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();
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 TRIGGER sample_code_uniqueness_check BEFORE INSERT OR UPDATE ON samples FOR EACH ROW EXECUTE PROCEDURE sample_code_uniqueness_check();
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();
......
......@@ -40,6 +40,105 @@ CREATE DOMAIN time_stamp AS timestamp with time zone;
CREATE DOMAIN time_stamp_dfl AS timestamp with time zone NOT NULL DEFAULT now();
CREATE DOMAIN title_100 AS character varying(100);
CREATE DOMAIN user_id AS character varying(50);
CREATE FUNCTION check_created_or_modified_data_set_owner_is_alive() RETURNS trigger
LANGUAGE plpgsql
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;
$$;
CREATE FUNCTION check_created_or_modified_sample_owner_is_alive() RETURNS trigger
LANGUAGE plpgsql
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;
$$;
CREATE FUNCTION check_deletion_consistency_on_experiment_deletion() RETURNS trigger
LANGUAGE plpgsql
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;
$$;
CREATE FUNCTION check_deletion_consistency_on_sample_deletion() RETURNS trigger
LANGUAGE plpgsql
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;
$$;
CREATE FUNCTION controlled_vocabulary_check() RETURNS trigger
LANGUAGE plpgsql
AS $$
......@@ -83,6 +182,19 @@ BEGIN
RETURN NEW;
END;
$$;
CREATE FUNCTION entity_name(entity_table_name name) RETURNS character varying
LANGUAGE plpgsql
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;
$$;
CREATE FUNCTION experiment_property_with_material_data_type_check() RETURNS trigger
LANGUAGE plpgsql
AS $$
......@@ -128,6 +240,17 @@ BEGIN
RETURN NEW;
END;
$$;
CREATE FUNCTION forbid_deleted_entity_modification() RETURNS trigger
LANGUAGE plpgsql
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;
$$;
CREATE FUNCTION material_property_with_material_data_type_check() RETURNS trigger
LANGUAGE plpgsql
AS $$
......
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment