Skip to content
Snippets Groups Projects
Commit 06c8fdfe authored by felmer's avatar felmer
Browse files

LMS-835 new database schema 032

SVN: 10602
parent 946ae9d2
No related branches found
No related tags found
No related merge requests found
----------------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table DATABASE_INSTANCES
----------------------------------------------------------------------------
INSERT INTO database_instances(
id
, code
, uuid
, is_original_source)
VALUES ( nextval('DATABASE_INSTANCE_ID_SEQ')
, 'SYSTEM_DEFAULT'
, 'SYSTEM_DEFAULT'
, 'T');
----------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table DATA_STORES
----------------------------------------------------------------------
insert into data_stores
(id
,code
,download_url
,dbin_id)
values
(nextval('DATA_STORE_ID_SEQ')
,'STANDARD'
,''
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
update database_instances set dast_id = (select id from data_stores where code = 'STANDARD');
----------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table PERSONS
-----------------------------------------------------------------------
insert into persons
(id
,first_name
,last_name
,user_id
,email
,dbin_id)
values
(nextval('PERSON_ID_SEQ')
,''
,'System User'
,'system'
,''
,(select id from database_instances where code = 'SYSTEM_DEFAULT') );
-----------------------------------------------------------------------------------
-- Purpose: Create Controlled Vocabulary PLATE_GEOMETRY
-----------------------------------------------------------------------------------
insert into controlled_vocabularies
( id
, code
, is_internal_namespace
, description
, pers_id_registerer
, is_managed_internally
, dbin_id )
values (nextval('CONTROLLED_VOCABULARY_ID_SEQ')
, 'PLATE_GEOMETRY'
, true
, 'The geometry or dimensions of a plate'
, (select id from persons where user_id ='system')
, true
,(select id from database_instances where code = 'SYSTEM_DEFAULT'));
-----------------------------------------------------------------------------------
-- Purpose: Create Controlled Vocabulary Terms for PLATE_GEOMETRY
-----------------------------------------------------------------------------------
insert into controlled_vocabulary_terms
( id
, code
, covo_id
, pers_id_registerer)
values (nextval('CVTE_ID_SEQ')
, '96_WELLS_8X12'
, (select id from controlled_vocabularies where code = 'PLATE_GEOMETRY' and is_internal_namespace = true)
, (select id from persons where user_id ='system'));
insert into controlled_vocabulary_terms
( id
, code
, covo_id
, pers_id_registerer)
values (nextval('CVTE_ID_SEQ')
, '384_WELLS_16X24'
, (select id from controlled_vocabularies where code = 'PLATE_GEOMETRY' and is_internal_namespace = true)
, (select id from persons where user_id ='system'));
insert into controlled_vocabulary_terms
( id
, code
, covo_id
, pers_id_registerer)
values (nextval('CVTE_ID_SEQ')
, '1536_WELLS_32X48'
, (select id from controlled_vocabularies where code = 'PLATE_GEOMETRY' and is_internal_namespace = true)
, (select id from persons where user_id ='system'));
-----------------------------------------------------------------------------------
-- Purpose: Create Controlled Vocabulary STORAGE_FORMAT
-----------------------------------------------------------------------------------
insert into controlled_vocabularies
( id
, code
, is_internal_namespace
, description
, pers_id_registerer
, is_managed_internally
, dbin_id )
values (nextval('CONTROLLED_VOCABULARY_ID_SEQ')
, 'STORAGE_FORMAT'
, true
, 'The on-disk storage format of a data set'
, (select id from persons where user_id ='system')
, true
,(select id from database_instances where code = 'SYSTEM_DEFAULT'));
-----------------------------------------------------------------------------------
-- Purpose: Create Controlled Vocabulary Terms for STORAGE_FORMAT
-----------------------------------------------------------------------------------
insert into controlled_vocabulary_terms
( id
, code
, covo_id
, pers_id_registerer )
values (nextval('CVTE_ID_SEQ')
, 'PROPRIETARY'
, (select id from controlled_vocabularies where code = 'STORAGE_FORMAT' and is_internal_namespace = true)
, (select id from persons where user_id ='system'));
insert into controlled_vocabulary_terms
( id
, code
, covo_id
, pers_id_registerer )
values (nextval('CVTE_ID_SEQ')
, 'BDS_DIRECTORY'
, (select id from controlled_vocabularies where code = 'STORAGE_FORMAT' and is_internal_namespace = true)
, (select id from persons where user_id ='system'));
-------------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table EXPERIMENT_TYPES
--------------------------------------------------------------------------
insert into experiment_types
(id
,code
,description
,dbin_id)
values
(nextval('EXPERIMENT_TYPE_ID_SEQ')
,'SIRNA_HCS'
,'Small Interfering RNA High Content Screening'
,(select id from database_instances where code = 'SYSTEM_DEFAULT'));
insert into experiment_types
(id
,code
,description
,dbin_id)
values
(nextval('EXPERIMENT_TYPE_ID_SEQ')
,'COMPOUND_HCS'
,'Compound High Content Screening'
,(select id from database_instances where code = 'SYSTEM_DEFAULT'));
----------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table MATERIAL_TYPES
-----------------------------------------------------------------------
insert into material_types
(id
,code
,description
,dbin_id)
values
(nextval('MATERIAL_TYPE_ID_SEQ')
,'VIRUS'
,'Virus'
,(select id from database_instances where code = 'SYSTEM_DEFAULT'));
insert into material_types
(id
,code
,description
,dbin_id)
values
(nextval('MATERIAL_TYPE_ID_SEQ')
,'CELL_LINE'
,'Cell Line or Cell Culture. The growing of cells under controlled conditions.'
,(select id from database_instances where code = 'SYSTEM_DEFAULT'));
insert into material_types
(id
,code
,description
,dbin_id)
values
(nextval('MATERIAL_TYPE_ID_SEQ')
,'GENE'
,'Gene'
,(select id from database_instances where code = 'SYSTEM_DEFAULT'));
insert into material_types
(id
,code
,description
,dbin_id)
values
(nextval('MATERIAL_TYPE_ID_SEQ')
,'OLIGO'
,'Oligo nucleotide'
,(select id from database_instances where code = 'SYSTEM_DEFAULT'));
insert into material_types
(id
,code
,description
,dbin_id)
values
(nextval('MATERIAL_TYPE_ID_SEQ')
,'CONTROL'
,'Control of a control layout'
,(select id from database_instances where code = 'SYSTEM_DEFAULT'));
insert into material_types
(id
,code
,description
,dbin_id)
values
(nextval('MATERIAL_TYPE_ID_SEQ')
,'BACTERIUM'
,'Bacterium'
,(select id from database_instances where code = 'SYSTEM_DEFAULT'));
insert into material_types
(id
,code
,description
,dbin_id)
values
(nextval('MATERIAL_TYPE_ID_SEQ')
,'COMPOUND'
,'Compound'
,(select id from database_instances where code = 'SYSTEM_DEFAULT'));
------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table DATA_TYPES
------------------------------------------------------------------
insert into data_types
(id
,code
,description)
values
(nextval('DATA_TYPE_ID_SEQ')
,'VARCHAR'
,'Short text'
);
insert into data_types
(id
,code
,description)
values
(nextval('DATA_TYPE_ID_SEQ')
,'MULTILINE_VARCHAR'
,'Long text'
);
insert into data_types
(id
,code
,description)
values
(nextval('DATA_TYPE_ID_SEQ')
,'INTEGER'
,'Integer number'
);
insert into data_types
(id
,code
,description)
values
(nextval('DATA_TYPE_ID_SEQ')
,'REAL'
,'Real number, i.e. an inexact, variable-precision numeric type'
);
insert into data_types
(id
,code
,description)
values
(nextval('DATA_TYPE_ID_SEQ')
,'BOOLEAN'
,'True or False'
);
insert into data_types
(id
,code
,description)
values
(nextval('DATA_TYPE_ID_SEQ')
,'TIMESTAMP'
,'Both date and time. Format: yyyy-mm-dd hh:mm:ss'
);
insert into data_types
(id
,code
,description)
values
(nextval('DATA_TYPE_ID_SEQ')
,'CONTROLLEDVOCABULARY'
,'Controlled Vocabulary'
);
insert into data_types
(id
,code
,description)
values
(nextval('DATA_TYPE_ID_SEQ')
,'MATERIAL'
,'Reference to a material'
);
insert into data_types
(id
,code
,description)
values
(nextval('DATA_TYPE_ID_SEQ')
,'HYPERLINK'
,'Address of a web page'
);
----------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table PROPERTY_TYPES
-----------------------------------------------------------------------
insert into property_types
(id
,code
,description
,label
,daty_id
,pers_id_registerer
,dbin_id)
values
(nextval('PROPERTY_TYPE_ID_SEQ')
,'DESCRIPTION'
,'A Description'
,'Description'
,(select id from data_types where code ='VARCHAR')
,(select id from persons where user_id ='system')
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
insert into property_types
(id
,code
,description
,label
,daty_id
,pers_id_registerer
,dbin_id)
values
(nextval('PROPERTY_TYPE_ID_SEQ')
,'GENE_SYMBOL'
,'Gene Symbol, e.g. BMP15'
,'Gene Symbol'
,(select id from data_types where code ='VARCHAR')
,(select id from persons where user_id ='system')
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
insert into property_types
(id
,code
,description
,label
,daty_id
,pers_id_registerer
,dbin_id)
values
(nextval('PROPERTY_TYPE_ID_SEQ')
,'NUCLEOTIDE_SEQUENCE'
,'A sequence of nucleotides'
,'Nucleotide Sequence'
,(select id from data_types where code ='VARCHAR')
,(select id from persons where user_id ='system')
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
insert into property_types
(id
,code
,description
,label
,daty_id
,pers_id_registerer
,dbin_id)
values
(nextval('PROPERTY_TYPE_ID_SEQ')
,'REFSEQ'
,'NCBI Reference Sequence code, applicable to sequences of type: DNA, RNA, protein'
,'RefSeq'
,(select id from data_types where code ='VARCHAR')
,(select id from persons where user_id ='system')
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
insert into property_types
(id
,code
,description
,label
,daty_id
,pers_id_registerer
,dbin_id)
values
(nextval('PROPERTY_TYPE_ID_SEQ')
,'OFFSET'
,'Offset from the start of the sequence'
,'Offset'
,(select id from data_types where code ='INTEGER')
,(select id from persons where user_id ='system')
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
-----------------------------------------------------------------------------------
-- Purpose: Create property type PLATE_GEOMETRY
-----------------------------------------------------------------------------------
insert into property_types
(id
,code
,is_internal_namespace
,description
,label
,daty_id
,covo_id
,pers_id_registerer
, is_managed_internally
,dbin_id)
values
(nextval('PROPERTY_TYPE_ID_SEQ')
,'PLATE_GEOMETRY'
,true
,'Plate Geometry'
,'Plate Geometry'
,(select id from data_types where code ='CONTROLLEDVOCABULARY')
,(select id from controlled_vocabularies where code ='PLATE_GEOMETRY' and is_internal_namespace = true)
,(select id from persons where user_id ='system')
,true
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
----------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table SAMPLE_TYPES
----------------------------------------------------------------------
insert into sample_types
(id
,code
,description
,dbin_id)
values
(nextval('SAMPLE_TYPE_ID_SEQ')
,'MASTER_PLATE'
,'Master Plate'
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
insert into sample_types
(id
,code
,description
,dbin_id
,generated_from_depth)
values
(nextval('SAMPLE_TYPE_ID_SEQ')
,'DILUTION_PLATE'
,'Dilution Plate'
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
,1
);
insert into sample_types
(id
,code
,description
,dbin_id
,generated_from_depth)
values
(nextval('SAMPLE_TYPE_ID_SEQ')
,'CELL_PLATE'
,'Cell Plate'
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
,2
);
insert into sample_types
(id
,code
,description
,dbin_id
,generated_from_depth)
values
(nextval('SAMPLE_TYPE_ID_SEQ')
,'REINFECT_PLATE'
,'Re-infection Plate'
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
,3
);
insert into sample_types
(id
,code
,description
,dbin_id)
values
(nextval('SAMPLE_TYPE_ID_SEQ')
,'CONTROL_LAYOUT'
,'Control layout'
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
insert into sample_types
(id
,code
,description
,dbin_id
,is_listable
,generated_from_depth
,part_of_depth)
values
(nextval('SAMPLE_TYPE_ID_SEQ')
,'WELL'
,'Plate Well'
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
,'F'
,0
,1
);
------------------------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table EXPERIMENT_TYPE_PROPERTY_TYPES
------------------------------------------------------------------------------------
----
-- Note: we rely on DESCRIPTION to be present and internally_managed for all experiment types!
----
----------------------------------
-- Experiment Type SIRNA_HCS
----------------------------------
insert into experiment_type_property_types
( id
,exty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('ETPT_ID_SEQ')
,(select id from experiment_types where code = 'SIRNA_HCS')
,(select id from property_types where code = 'DESCRIPTION' and is_internal_namespace = false)
,true
,true
,(select id from persons where user_id ='system')
);
----------------------------------
-- Experiment Type COMPOUND_HCS
----------------------------------
insert into experiment_type_property_types
( id
,exty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('ETPT_ID_SEQ')
,(select id from experiment_types where code = 'COMPOUND_HCS')
,(select id from property_types where code = 'DESCRIPTION' and is_internal_namespace = false)
,true
,true
,(select id from persons where user_id ='system')
);
------------------------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table SAMPLE_TYPE_PROPERTY_TYPES
------------------------------------------------------------------------------------
---------------------------------
-- Sample Type MASTER_PLATE
-- Property Type PLATE_GEOMETRY
---------------------------------
insert into sample_type_property_types
( id
,saty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('STPT_ID_SEQ')
,(select id from sample_types where code = 'MASTER_PLATE')
,(select id from property_types where code = 'PLATE_GEOMETRY' and is_internal_namespace = true)
,true
,true
,(select id from persons where user_id ='system')
);
---------------------------------
-- Sample Type CONTROL_LAYOUT
-- Property Type PLATE_GEOMETRY
---------------------------------
insert into sample_type_property_types
( id
,saty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('STPT_ID_SEQ')
,(select id from sample_types where code = 'CONTROL_LAYOUT')
,(select id from property_types where code = 'PLATE_GEOMETRY' and is_internal_namespace = true)
,true
,true
,(select id from persons where user_id ='system')
);
------------------------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table MATERIAL_TYPE_PROPERTY_TYPES
------------------------------------------------------------------------------------
----
-- Note: we rely on DESCRIPTION to be present and internally_managed for all material types!
----
-----------------------
-- Material Type VIRUS
-----------------------
insert into material_type_property_types
( id
,maty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('MTPT_ID_SEQ')
,(select id from material_types where code = 'VIRUS')
,(select id from property_types where code = 'DESCRIPTION' and is_internal_namespace = false)
,true
,true
,(select id from persons where user_id ='system')
);
-----------------------
-- Material Type BACTERIUM
-----------------------
insert into material_type_property_types
( id
,maty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('MTPT_ID_SEQ')
,(select id from material_types where code = 'BACTERIUM')
,(select id from property_types where code = 'DESCRIPTION' and is_internal_namespace = false)
,true
,true
,(select id from persons where user_id ='system')
);
-----------------------
-- Material Type COMPOUND
-----------------------
insert into material_type_property_types
( id
,maty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('MTPT_ID_SEQ')
,(select id from material_types where code = 'COMPOUND')
,(select id from property_types where code = 'DESCRIPTION' and is_internal_namespace = false)
,true
,true
,(select id from persons where user_id ='system')
);
-----------------------
-- Material Type GENE
-----------------------
insert into material_type_property_types
( id
,maty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('MTPT_ID_SEQ')
,(select id from material_types where code = 'GENE')
,(select id from property_types where code = 'GENE_SYMBOL' and is_internal_namespace = false)
,true
,true
,(select id from persons where user_id ='system')
);
insert into material_type_property_types
( id
,maty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('MTPT_ID_SEQ')
,(select id from material_types where code = 'GENE')
,(select id from property_types where code = 'DESCRIPTION' and is_internal_namespace = false)
,false
,true
,(select id from persons where user_id ='system')
);
-----------------------
-- Material Type OLIGO
-----------------------
insert into material_type_property_types
( id
,maty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('MTPT_ID_SEQ')
,(select id from material_types where code = 'OLIGO')
,(select id from property_types where code = 'NUCLEOTIDE_SEQUENCE' and is_internal_namespace = false)
,true
,true
,(select id from persons where user_id ='system')
);
insert into material_type_property_types
( id
,maty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('MTPT_ID_SEQ')
,(select id from material_types where code = 'OLIGO')
,(select id from property_types where code = 'OFFSET' and is_internal_namespace = false)
,false
,true
,(select id from persons where user_id ='system')
);
insert into material_type_property_types
( id
,maty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('MTPT_ID_SEQ')
,(select id from material_types where code = 'OLIGO')
,(select id from property_types where code = 'DESCRIPTION' and is_internal_namespace = false)
,false
,true
,(select id from persons where user_id ='system')
);
-------------------------
-- Material Type CONTROL
-------------------------
insert into material_type_property_types
( id
,maty_id
,prty_id
,is_mandatory
,is_managed_internally
,pers_id_registerer
)
values
(nextval('MTPT_ID_SEQ')
,(select id from material_types where code = 'CONTROL')
,(select id from property_types where code = 'DESCRIPTION' and is_internal_namespace = false)
,false
,true
,(select id from persons where user_id ='system')
);
--------------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table DATA_SET_TYPES
--------------------------------------------------------------------------
insert into data_set_types
(id
,code
,description
,dbin_id)
values
(nextval('DATA_SET_TYPE_ID_SEQ')
,'UNKNOWN'
,'Unknown'
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
insert into data_set_types
(id
,code
,description
,dbin_id)
values
(nextval('DATA_SET_TYPE_ID_SEQ')
,'HCS_IMAGE'
,'High Content Screening Image'
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
insert into data_set_types
(id
,code
,description
,dbin_id)
values
(nextval('DATA_SET_TYPE_ID_SEQ')
,'HCS_IMAGE_ANALYSIS_DATA'
,'Data derived from analysis of HCS images'
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
-------------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table FILE_FORMAT_TYPES
-------------------------------------------------------------------------
insert into file_format_types
(id
,code
,description
,dbin_id)
values
(nextval('FILE_FORMAT_TYPE_ID_SEQ')
,'TIFF'
,'TIFF File'
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
insert into file_format_types
(id
,code
,description
,dbin_id)
values
(nextval('FILE_FORMAT_TYPE_ID_SEQ')
,'3VPROPRIETARY'
,'Data Analysis 3V proprietary format'
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
insert into file_format_types
(id
,code
,description
,dbin_id)
values
(nextval('FILE_FORMAT_TYPE_ID_SEQ')
,'PLKPROPRIETARY'
,'Data Analysis Pelkmans group proprietary format'
,(select id from database_instances where code = 'SYSTEM_DEFAULT')
);
---------------------------------------------------------------------
-- Purpose: Insert an initial data set into the table LOCATOR_TYPES
---------------------------------------------------------------------
insert into locator_types
(id
,code
,description)
values
(nextval('LOCATOR_TYPE_ID_SEQ')
,'RELATIVE_LOCATION'
,'Relative Location'
);
This diff is collapsed.
-- 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 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 trigger SAMPLE_CODE_UNIQUENESS_CHECK
------------------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION SAMPLE_CODE_UNIQUENESS_CHECK() RETURNS trigger AS $$
DECLARE
counter INTEGER;
BEGIN
IF (NEW.samp_id_part_of is NULL) THEN
IF (NEW.dbin_id is not NULL) THEN
SELECT count(*) into counter FROM samples
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.grou_id is not NULL) THEN
SELECT count(*) into counter FROM samples
where id != NEW.id and code = NEW.code and samp_id_part_of is NULL and grou_id = NEW.grou_id;
IF (counter > 0) THEN
RAISE EXCEPTION 'Insert/Update of Sample (Code: %) failed because group 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
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 parent already exists.', NEW.code;
END IF;
ELSIF (NEW.grou_id is not NULL) THEN
SELECT count(*) into counter FROM samples
where id != NEW.id and code = NEW.code and samp_id_part_of = NEW.samp_id_part_of and grou_id = NEW.grou_id;
IF (counter > 0) THEN
RAISE EXCEPTION 'Insert/Update of Sample (Code: %) failed because group sample with the same code and being the part of the same parent 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
FOR EACH ROW EXECUTE PROCEDURE SAMPLE_CODE_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();
\ No newline at end of file
-- -------
-- Modify MATERIAL_BATCHES
-- -------
ALTER TABLE material_batches
DROP COLUMN proc_id;
-- -------
-- Modify SAMPLES
-- -------
ALTER TABLE samples
ADD COLUMN expe_id tech_id;
ALTER TABLE samples
ADD CONSTRAINT samp_expe_fk FOREIGN KEY (expe_id) REFERENCES experiments(id);
CREATE INDEX samp_expe_fk_i ON samples USING btree (expe_id);
-- relink samples directly to experiments
UPDATE samples
SET expe_id = (SELECT e.id FROM experiments e, procedures p, sample_inputs si
WHERE si.samp_id = samples.id AND si.proc_id = p.id AND p.expe_id = e.id AND e.inva_id IS NULL);
-- -------
-- Modify DATA
-- -------
ALTER TABLE data
ADD COLUMN expe_id tech_id;
ALTER TABLE data
ADD CONSTRAINT data_expe_fk FOREIGN KEY (expe_id) REFERENCES experiments(id);
CREATE INDEX data_expe_fk_i ON data USING btree (expe_id);
UPDATE data
SET expe_id = (SELECT e.id FROM experiments e, procedures p
WHERE data.proc_id_produced_by = p.id AND p.expe_id = e.id);
ALTER TABLE data
ALTER COLUMN expe_id SET NOT NULL;
ALTER TABLE data
DROP COLUMN proc_id_produced_by;
-- -------
-- Drop PROCEDURES, PROCEDURE_TYPES, and SAMPLE_INPUTS
-- -------
DROP TABLE sample_inputs;
DROP TABLE procedures;
DROP TABLE procedure_types;
DROP SEQUENCE procedure_id_seq;
DROP SEQUENCE procedure_type_id_seq;
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