Skip to content

Commit

Permalink
new reference package
Browse files Browse the repository at this point in the history
  • Loading branch information
Timur committed Jan 22, 2020
1 parent f81ac7e commit 1c928f2
Show file tree
Hide file tree
Showing 4 changed files with 223 additions and 0 deletions.
92 changes: 92 additions & 0 deletions working/packages/reference_pack/AddNewConcept.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,92 @@
/*
Adds new concept
Usage:
DO $_$
BEGIN
PERFORM vocabulary_pack.AddNewConcept(
pConcept_name =>'test concept name',
pDomain_id =>'Drug',
pVocabulary_id =>'SNOMED',
pConcept_class_id =>'Ingredient',
pStandard_concept =>'S',
pConcept_code =>'123_test2'
);
END $_$;
OR (if you want to get the concept_id):
SELECT vocabulary_pack.AddNewConcept(
pConcept_name =>'test concept name',
pDomain_id =>'Drug',
pVocabulary_id =>'SNOMED',
pConcept_class_id =>'Ingredient',
pStandard_concept =>'S',
pConcept_code =>'123_test3'
);
*/

CREATE OR REPLACE FUNCTION vocabulary_pack.AddNewConcept (
pConcept_name concept.concept_name%TYPE,
pDomain_id concept.domain_id%TYPE,
pVocabulary_id concept.vocabulary_id%TYPE,
pConcept_class_id concept.concept_class_id%TYPE,
pStandard_concept concept.standard_concept%TYPE,
pConcept_code concept.concept_code%TYPE,
pValid_start_date concept.valid_start_date%TYPE = TO_DATE ('19700101', 'YYYYMMDD'),
pValid_end_date concept.valid_end_date%TYPE = TO_DATE ('20991231', 'YYYYMMDD'),
pInvalid_reason concept.invalid_reason%TYPE = NULL
)
RETURNS int4 AS
$BODY$
DECLARE
z INT;
ex INT;
BEGIN
IF COALESCE(pStandard_concept,'S') NOT IN ('S','C') THEN RAISE EXCEPTION 'Incorrect value for pStandard_concept: %', pStandard_concept; END IF;
IF pStandard_concept='S' AND pInvalid_reason IS NOT NULL THEN RAISE EXCEPTION 'pStandard_concept cannot be S (pInvalid_reason is not null)'; END IF;

pConcept_name:=REGEXP_REPLACE(pConcept_name, '[[:cntrl:]]+', ' ', 'g');
pConcept_name:=REGEXP_REPLACE(pConcept_name, ' {2,}', ' ', 'g');
pConcept_name:=TRIM(pConcept_name);
pConcept_name:=REPLACE(pConcept_name, '', '-');

pConcept_code:=REGEXP_REPLACE(pConcept_code, '[[:cntrl:]]+', ' ', 'g');
pConcept_code:=REGEXP_REPLACE(pConcept_code, ' {2,}', ' ', 'g');
pConcept_code:=TRIM(pConcept_code);
pConcept_code:=REPLACE(pConcept_code, '', '-');

DROP SEQUENCE IF EXISTS v5_concept;

SELECT MAX (concept_id) + 1 INTO ex FROM concept
WHERE concept_id >= 31967 AND concept_id < 72245;

EXECUTE 'CREATE SEQUENCE v5_concept INCREMENT BY 1 START WITH ' || ex || ' CACHE 20';

--insert the concept
SELECT nextval('v5_concept') INTO z;
INSERT INTO concept (concept_id, concept_name, domain_id, vocabulary_id, concept_class_id, standard_concept, concept_code, valid_start_date, valid_end_date, invalid_reason)
VALUES (z, pConcept_name, pDomain_id, pVocabulary_id, pConcept_class_id, pStandard_concept, pConcept_code, pValid_start_date, pValid_end_date, pInvalid_reason);

--insert the mapping
IF pStandard_concept='S' THEN
INSERT INTO concept_relationship (concept_id_1, concept_id_2, relationship_id, valid_start_date, valid_end_date, invalid_reason)
VALUES (z, z, 'Maps to', pValid_start_date, TO_DATE('20991231', 'YYYYMMDD'), NULL),
(z, z, 'Mapped from', pValid_start_date, TO_DATE('20991231', 'YYYYMMDD'), NULL);
END IF;

--insert the synonym (=pConcept_name)
INSERT INTO concept_synonym (concept_id, concept_synonym_name, language_concept_id)
VALUES (z, pConcept_name, 4180186 /*English*/);

DROP SEQUENCE v5_concept;

RETURN z;
END;
$BODY$
LANGUAGE 'plpgsql'
VOLATILE
CALLED ON NULL INPUT
SECURITY INVOKER
COST 100
SET client_min_messages = error;
73 changes: 73 additions & 0 deletions working/packages/reference_pack/AddNewRelationship.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,73 @@
/*
Adds new relationship
Usage:
DO $_$
BEGIN
PERFORM vocabulary_pack.AddNewRelationship(
pRelationship_name =>'Has system',
pRelationship_id =>'Has system',
pIs_hierarchical =>0,
pDefines_ancestry =>0,
pReverse_relationship_id =>'System of',
pRelationship_name_rev =>'System of',
pIs_hierarchical_rev =>0,
pDefines_ancestry_rev =>0
);
END $_$;
*/

CREATE OR REPLACE FUNCTION vocabulary_pack.AddNewRelationship (
pRelationship_name relationship.relationship_name%TYPE,
pRelationship_id relationship.relationship_id%TYPE,
pIs_hierarchical int,
pDefines_ancestry int,
pReverse_relationship_id relationship.reverse_relationship_id%TYPE,
pRelationship_name_rev relationship.relationship_name%TYPE,
pIs_hierarchical_rev int,
pDefines_ancestry_rev int
)
RETURNS void AS
$BODY$
DECLARE
z INT;
ex INT;
BEGIN
IF COALESCE(pIs_hierarchical,-1) NOT IN (0,1) THEN RAISE EXCEPTION 'Incorrect value for pIs_hierarchical: %', pIs_hierarchical; END IF;
IF COALESCE(pDefines_ancestry,-1) NOT IN (0,1) THEN RAISE EXCEPTION 'Incorrect value for pDefines_ancestry: %', pDefines_ancestry; END IF;
IF COALESCE(pIs_hierarchical_rev,-1) NOT IN (0,1) THEN RAISE EXCEPTION 'Incorrect value for pIs_hierarchical_rev: %', pIs_hierarchical_rev; END IF;
IF COALESCE(pDefines_ancestry_rev,-1) NOT IN (0,1) THEN RAISE EXCEPTION 'Incorrect value for pDefines_ancestry_rev: %', pDefines_ancestry_rev; END IF;
IF pDefines_ancestry=1 AND pDefines_ancestry_rev=1 THEN RAISE EXCEPTION 'pDefines_ancestry and pDefines_ancestry_rev are both equal to 1'; END IF;

DROP SEQUENCE IF EXISTS v5_concept;

SELECT MAX (concept_id) + 1 INTO ex FROM concept
WHERE concept_id >= 31967 AND concept_id < 72245;

EXECUTE 'CREATE SEQUENCE v5_concept INCREMENT BY 1 START WITH ' || ex || ' CACHE 20';
ALTER TABLE relationship DROP CONSTRAINT FPK_RELATIONSHIP_REVERSE;

--direct
SELECT nextval('v5_concept') INTO z;
INSERT INTO concept (concept_id, concept_name, domain_id, vocabulary_id, concept_class_id, standard_concept, concept_code, valid_start_date, valid_end_date, invalid_reason)
VALUES (z, pRelationship_name, 'Metadata', 'Relationship', 'Relationship', null, 'OMOP generated', TO_DATE ('19700101', 'YYYYMMDD'), TO_DATE ('20991231', 'YYYYMMDD'), null);
INSERT INTO relationship (relationship_id, relationship_name, is_hierarchical, defines_ancestry, reverse_relationship_id, relationship_concept_id)
VALUES (pRelationship_id, pRelationship_name, pIs_hierarchical, pDefines_ancestry, pReverse_relationship_id, z);

--reverse
SELECT nextval('v5_concept') INTO z;
INSERT INTO concept (concept_id, concept_name, domain_id, vocabulary_id, concept_class_id, standard_concept, concept_code, valid_start_date, valid_end_date, invalid_reason)
VALUES (z, pRelationship_name_rev, 'Metadata', 'Relationship', 'Relationship', null, 'OMOP generated', TO_DATE ('19700101', 'YYYYMMDD'), TO_DATE ('20991231', 'YYYYMMDD'), null);
INSERT INTO relationship (relationship_id, relationship_name, is_hierarchical, defines_ancestry, reverse_relationship_id, relationship_concept_id)
VALUES (pReverse_relationship_id, pRelationship_name_rev, pIs_hierarchical_rev, pDefines_ancestry_rev, pRelationship_id, z);

ALTER TABLE relationship ADD CONSTRAINT fpk_relationship_reverse FOREIGN KEY (reverse_relationship_id) REFERENCES relationship (relationship_id);
DROP SEQUENCE v5_concept;
END;
$BODY$
LANGUAGE 'plpgsql'
VOLATILE
CALLED ON NULL INPUT
SECURITY INVOKER
COST 100
SET client_min_messages = error;
58 changes: 58 additions & 0 deletions working/packages/reference_pack/AddNewSynonym.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,58 @@
/*
Adds new synonym
Usage:
DO $_$
BEGIN
PERFORM vocabulary_pack.AddNewSynonym(
pConcept_id =>123,
pSynonym_name =>'test synonym',
pLanguage_concept_id =>4180186
);
END $_$;
OR you can combine with the AddNewConcept:
DO $_$
BEGIN
PERFORM vocabulary_pack.AddNewSynonym(
pConcept_id =>vocabulary_pack.AddNewConcept(
pConcept_name =>'test concept name 5',
pDomain_id =>'Drug',
pVocabulary_id =>'SNOMED',
pConcept_class_id =>'Ingredient',
pStandard_concept =>'S',
pConcept_code =>'123_test5'
),
pSynonym_name =>'test synonym 5',
pLanguage_concept_id =>4180186
);
END $_$;
*/

CREATE OR REPLACE FUNCTION vocabulary_pack.AddNewSynonym (
pConcept_id concept_synonym.concept_id%TYPE,
pSynonym_name concept_synonym.concept_synonym_name%TYPE,
pLanguage_concept_id concept_synonym.language_concept_id%TYPE = 4180186 /*English*/
)
RETURNS void AS
$BODY$
DECLARE
z INT;
ex INT;
BEGIN
pSynonym_name:=REGEXP_REPLACE(pSynonym_name, '[[:cntrl:]]+', ' ', 'g');
pSynonym_name:=REGEXP_REPLACE(pSynonym_name, ' {2,}', ' ', 'g');
pSynonym_name:=TRIM(pSynonym_name);
pSynonym_name:=REPLACE(pSynonym_name, '', '-');

INSERT INTO concept_synonym (concept_id, concept_synonym_name, language_concept_id)
VALUES (pConcept_id, pSynonym_name, pLanguage_concept_id);
END;
$BODY$
LANGUAGE 'plpgsql'
VOLATILE
CALLED ON NULL INPUT
SECURITY INVOKER
COST 100
SET client_min_messages = error;

0 comments on commit 1c928f2

Please sign in to comment.