From 933d7fe9e01ca06132406cdb261b2801520d5245 Mon Sep 17 00:00:00 2001 From: AlaikseiKatyshou Date: Wed, 3 Apr 2024 16:31:47 +0300 Subject: [PATCH 01/18] Objects and instruction to prepare local environment --- .../DevV5_constraints_DDL.sql | 77 ++ .../local_environment/DevV5_tables_DDL.sql | 280 +++++ .../local_environment/GenericUpdate_LE.sql | 1095 +++++++++++++++++ working/local_environment/README.md | 154 +++ 4 files changed, 1606 insertions(+) create mode 100644 working/local_environment/DevV5_constraints_DDL.sql create mode 100644 working/local_environment/DevV5_tables_DDL.sql create mode 100644 working/local_environment/GenericUpdate_LE.sql create mode 100644 working/local_environment/README.md diff --git a/working/local_environment/DevV5_constraints_DDL.sql b/working/local_environment/DevV5_constraints_DDL.sql new file mode 100644 index 000000000..3f39ae428 --- /dev/null +++ b/working/local_environment/DevV5_constraints_DDL.sql @@ -0,0 +1,77 @@ + +--Create PKs +ALTER TABLE concept ADD CONSTRAINT xpk_concept PRIMARY KEY (concept_id); +ALTER TABLE vocabulary ADD CONSTRAINT xpk_vocabulary PRIMARY KEY (vocabulary_id); +ALTER TABLE domain ADD CONSTRAINT xpk_domain PRIMARY KEY (domain_id); +ALTER TABLE concept_class ADD CONSTRAINT xpk_concept_class PRIMARY KEY (concept_class_id); +ALTER TABLE concept_relationship ADD CONSTRAINT xpk_concept_relationship PRIMARY KEY (concept_id_1,concept_id_2,relationship_id); +ALTER TABLE relationship ADD CONSTRAINT xpk_relationship PRIMARY KEY (relationship_id); +ALTER TABLE concept_ancestor ADD CONSTRAINT xpkconcept_ancestor PRIMARY KEY (ancestor_concept_id,descendant_concept_id); +ALTER TABLE drug_strength ADD CONSTRAINT xpk_drug_strength PRIMARY KEY (drug_concept_id, ingredient_concept_id); + +--Create external keys +ALTER TABLE concept ADD CONSTRAINT fpk_concept_domain FOREIGN KEY (domain_id) REFERENCES domain (domain_id); +ALTER TABLE concept ADD CONSTRAINT fpk_concept_class FOREIGN KEY (concept_class_id) REFERENCES concept_class (concept_class_id); +ALTER TABLE concept ADD CONSTRAINT fpk_concept_vocabulary FOREIGN KEY (vocabulary_id) REFERENCES vocabulary (vocabulary_id); +ALTER TABLE vocabulary ADD CONSTRAINT fpk_vocabulary_concept FOREIGN KEY (vocabulary_concept_id) REFERENCES concept (concept_id); +ALTER TABLE domain ADD CONSTRAINT fpk_domain_concept FOREIGN KEY (domain_concept_id) REFERENCES concept (concept_id); +ALTER TABLE concept_class ADD CONSTRAINT fpk_concept_class_concept FOREIGN KEY (concept_class_concept_id) REFERENCES concept (concept_id); +ALTER TABLE concept_relationship ADD CONSTRAINT fpk_concept_relationship_c_1 FOREIGN KEY (concept_id_1) REFERENCES concept (concept_id); +ALTER TABLE concept_relationship ADD CONSTRAINT fpk_concept_relationship_c_2 FOREIGN KEY (concept_id_2) REFERENCES concept (concept_id); +ALTER TABLE concept_relationship ADD CONSTRAINT fpk_concept_relationship_id FOREIGN KEY (relationship_id) REFERENCES relationship (relationship_id); +ALTER TABLE relationship ADD CONSTRAINT fpk_relationship_concept FOREIGN KEY (relationship_concept_id) REFERENCES concept (concept_id); +ALTER TABLE relationship ADD CONSTRAINT fpk_relationship_reverse FOREIGN KEY (reverse_relationship_id) REFERENCES relationship (relationship_id); +ALTER TABLE concept_synonym ADD CONSTRAINT fpk_concept_synonym_concept FOREIGN KEY (concept_id) REFERENCES concept (concept_id); +ALTER TABLE concept_synonym ADD CONSTRAINT fpk_concept_synonym_language FOREIGN KEY (language_concept_id) REFERENCES concept (concept_id); +ALTER TABLE concept_synonym ADD CONSTRAINT unique_synonyms UNIQUE (concept_id,concept_synonym_name,language_concept_id); +ALTER TABLE drug_strength ADD CONSTRAINT fpk_drug_strength_concept_1 FOREIGN KEY (drug_concept_id) REFERENCES concept (concept_id); +ALTER TABLE drug_strength ADD CONSTRAINT fpk_drug_strength_concept_2 FOREIGN KEY (ingredient_concept_id) REFERENCES concept (concept_id); +ALTER TABLE drug_strength ADD CONSTRAINT fpk_drug_strength_unit_1 FOREIGN KEY (amount_unit_concept_id) REFERENCES concept (concept_id); +ALTER TABLE drug_strength ADD CONSTRAINT fpk_drug_strength_unit_2 FOREIGN KEY (numerator_unit_concept_id) REFERENCES concept (concept_id); +ALTER TABLE drug_strength ADD CONSTRAINT fpk_drug_strength_unit_3 FOREIGN KEY (denominator_unit_concept_id) REFERENCES concept (concept_id); +ALTER TABLE pack_content ADD CONSTRAINT fpk_pack_content_concept_1 FOREIGN KEY (pack_concept_id) REFERENCES concept (concept_id); +ALTER TABLE pack_content ADD CONSTRAINT fpk_pack_content_concept_2 FOREIGN KEY (drug_concept_id) REFERENCES concept (concept_id); +ALTER TABLE concept_relationship_manual ADD CONSTRAINT unique_manual_relationships UNIQUE (concept_code_1,concept_code_2,vocabulary_id_1,vocabulary_id_2,relationship_id); +ALTER TABLE concept_manual ADD CONSTRAINT unique_manual_concepts UNIQUE (vocabulary_id,concept_code); +ALTER TABLE concept_synonym_manual ADD CONSTRAINT unique_manual_synonyms UNIQUE (synonym_name,synonym_concept_code,synonym_vocabulary_id,language_concept_id); + +--Create indexes +CREATE UNIQUE INDEX idx_unique_concept_code ON concept (vocabulary_id, concept_code) WHERE vocabulary_id NOT IN ('DRG', 'SMQ') AND concept_code <> 'OMOP generated'; +/* + We need index listed below for queries like "SELECT * FROM concept WHERE vocabulary_id='xxx'". + Previous unique index only to support unique pairs of voabulary_id+concept_code with some exceptions +*/ +CREATE INDEX idx_vocab_concept_code ON concept (vocabulary_id varchar_pattern_ops, concept_code); +CREATE INDEX idx_concept_relationship_id_2 ON concept_relationship (concept_id_2); +CREATE INDEX idx_concept_synonym_id ON concept_synonym (concept_id); +CREATE INDEX idx_csyn_concept_syn_name ON concept_synonym (concept_synonym_name); +CREATE INDEX idx_drug_strength_id_1 ON drug_strength (drug_concept_id); +CREATE INDEX idx_drug_strength_id_2 ON drug_strength (ingredient_concept_id); +CREATE INDEX idx_pack_content_id_2 ON pack_content (drug_concept_id); +CREATE UNIQUE INDEX u_pack_content ON pack_content (pack_concept_id, drug_concept_id, COALESCE(amount,-1)); +ALTER TABLE concept_stage ADD CONSTRAINT idx_pk_cs PRIMARY KEY (concept_code,vocabulary_id); +CREATE INDEX idx_cs_concept_id ON concept_stage (concept_id); +ALTER TABLE concept_relationship_stage ADD CONSTRAINT idx_pk_crs PRIMARY KEY (concept_code_1,concept_code_2,vocabulary_id_1,vocabulary_id_2,relationship_id); +CREATE INDEX idx_concept_code_2 ON concept_relationship_stage (concept_code_2); +ALTER TABLE concept_synonym_stage ADD CONSTRAINT idx_pk_css PRIMARY KEY (synonym_vocabulary_id,synonym_name,synonym_concept_code,language_concept_id); +CREATE INDEX idx_dss_concept_code ON drug_strength_stage (drug_concept_code); +CREATE INDEX idx_ca_descendant ON concept_ancestor (descendant_concept_id); +CREATE UNIQUE INDEX xpk_vocab_conversion ON vocabulary_conversion (vocabulary_id_v5); +CREATE INDEX idx_base_crm_cid1 ON base_concept_relationship_manual (concept_id_1) WHERE concept_id_1=0; +CREATE INDEX idx_base_crm_cid2 ON base_concept_relationship_manual (concept_id_2) WHERE concept_id_2=0; +CREATE INDEX idx_base_cm_cid ON base_concept_manual (concept_id) WHERE concept_id=0; +CREATE INDEX idx_base_csm_cid ON base_concept_synonym_manual (concept_id) WHERE concept_id=0; + +--Create checks +ALTER TABLE concept ADD CONSTRAINT chk_c_concept_name CHECK (concept_name <> ''); +ALTER TABLE concept ADD CONSTRAINT chk_c_standard_concept CHECK (COALESCE(standard_concept,'C') in ('C','S')); +ALTER TABLE concept ADD CONSTRAINT chk_c_concept_code CHECK (concept_code <> ''); +ALTER TABLE concept ADD CONSTRAINT chk_c_invalid_reason CHECK (COALESCE(invalid_reason,'D') in ('D','U')); +ALTER TABLE concept_relationship ADD CONSTRAINT chk_cr_invalid_reason CHECK (COALESCE(invalid_reason,'D')='D'); +ALTER TABLE concept_synonym ADD CONSTRAINT chk_csyn_concept_synonym_name CHECK (concept_synonym_name <> ''); +ALTER TABLE concept_manual ADD CONSTRAINT chk_cmnl_concept_name CHECK (concept_name <> ''); +ALTER TABLE concept_manual ADD CONSTRAINT chk_cmnl_concept_code CHECK (concept_code <> ''); +ALTER TABLE concept_synonym_manual ADD CONSTRAINT chk_csynmnl_concept_synonym_name CHECK (synonym_name <> ''); +ALTER TABLE concept_relationship_manual ADD CONSTRAINT chk_crm_invalid_reason CHECK (COALESCE(invalid_reason,'D')='D'); +ALTER TABLE concept_relationship_manual ADD CONSTRAINT chk_crm_concept_code_1 CHECK (concept_code_1 <> ''); +ALTER TABLE concept_relationship_manual ADD CONSTRAINT chk_crm_concept_code_2 CHECK (concept_code_2 <> ''); \ No newline at end of file diff --git a/working/local_environment/DevV5_tables_DDL.sql b/working/local_environment/DevV5_tables_DDL.sql new file mode 100644 index 000000000..8a602bdb7 --- /dev/null +++ b/working/local_environment/DevV5_tables_DDL.sql @@ -0,0 +1,280 @@ +/************************************************************************** +* Copyright 2016 Observational Health Data Sciences and Informatics (OHDSI) +* +* Licensed under the Apache License, Version 2.0 (the License); +* you may not use this file except in compliance with the License. +* You may obtain a copy of the License at +* +* http://www.apache.org/licenses/LICENSE-2.0 +* +* Unless required by applicable law or agreed to in writing, software +* distributed under the License is distributed on an AS IS BASIS, +* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. +* See the License for the specific language governing permissions and +* limitations under the License. +* +* Authors: Timur Vakhitov +* Date: 2020 +**************************************************************************/ + +--Main DDL + +DROP TABLE IF EXISTS concept CASCADE; +CREATE TABLE concept ( + concept_id int4 NOT NULL, + concept_name VARCHAR (255) NOT NULL, + domain_id VARCHAR (20) NOT NULL, + vocabulary_id VARCHAR (20) NOT NULL, + concept_class_id VARCHAR (20) NOT NULL, + standard_concept VARCHAR (1), + concept_code VARCHAR (50) NOT NULL, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR (1) +); + +DROP TABLE IF EXISTS concept_relationship CASCADE; +CREATE TABLE concept_relationship ( + concept_id_1 int4 NOT NULL, + concept_id_2 int4 NOT NULL, + relationship_id VARCHAR (20) NOT NULL, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR (1) +); + +DROP TABLE IF EXISTS concept_synonym CASCADE; +CREATE TABLE concept_synonym ( + concept_id int4 NOT NULL, + concept_synonym_name VARCHAR (1000) NOT NULL, + language_concept_id int4 NOT NULL +); + +DROP TABLE IF EXISTS concept_ancestor CASCADE; +CREATE TABLE concept_ancestor ( + ancestor_concept_id int4 NOT NULL, + descendant_concept_id int4 NOT NULL, + min_levels_of_separation int4 NOT NULL, + max_levels_of_separation int4 NOT NULL +); + +DROP TABLE IF EXISTS relationship CASCADE; +CREATE TABLE relationship ( + relationship_id VARCHAR (20) NOT NULL, + relationship_name VARCHAR (255) NOT NULL UNIQUE, + is_hierarchical int NOT NULL, + defines_ancestry int2 NOT NULL, + reverse_relationship_id VARCHAR (20) NOT NULL, + relationship_concept_id int4 NOT NULL +); + +DROP TABLE IF EXISTS vocabulary CASCADE; +CREATE TABLE vocabulary ( + vocabulary_id VARCHAR (20) NOT NULL, + vocabulary_name VARCHAR (255) NOT NULL, + vocabulary_reference VARCHAR (255) NOT NULL, + vocabulary_version VARCHAR (255), + vocabulary_concept_id int4 NOT NULL, + latest_update DATE, --service field (new update date for using in load_stage/functions/generic_update) + dev_schema_name TEXT, --service field (the name of the schema where manual changes come from if the script is run in the devv5) + vocabulary_params JSONB --service field (for storing additional params) +); + +DROP TABLE IF EXISTS vocabulary_conversion CASCADE; +CREATE TABLE vocabulary_conversion ( + vocabulary_id_v4 int4 PRIMARY KEY, + vocabulary_id_v5 VARCHAR (20), + omop_req VARCHAR (1), + click_default VARCHAR (1), + available VARCHAR (25), + url VARCHAR (256), + click_disabled VARCHAR (1), + latest_update DATE +); + +DROP TABLE IF EXISTS relationship_conversion CASCADE; +CREATE TABLE relationship_conversion ( + relationship_id int2 NOT NULL, + relationship_id_new VARCHAR (20) NOT NULL +); + +DROP TABLE IF EXISTS concept_class_conversion CASCADE; +CREATE TABLE concept_class_conversion +( + concept_class VARCHAR (50) NOT NULL, + concept_class_id_new VARCHAR (20) NOT NULL +); + +DROP TABLE IF EXISTS concept_class CASCADE; +CREATE TABLE concept_class ( + concept_class_id VARCHAR (20) NOT NULL, + concept_class_name VARCHAR (255) NOT NULL, + concept_class_concept_id int4 NOT NULL +); + +DROP TABLE IF EXISTS domain CASCADE; +CREATE TABLE domain ( + domain_id VARCHAR (20) NOT NULL, + domain_name VARCHAR (255) NOT NULL, + domain_concept_id int4 NOT NULL +); + +DROP TABLE IF EXISTS drug_strength CASCADE; +CREATE TABLE drug_strength ( + drug_concept_id int4 NOT NULL, + ingredient_concept_id int4 NOT NULL, + amount_value NUMERIC, + amount_unit_concept_id int4, + numerator_value NUMERIC, + numerator_unit_concept_id int4, + denominator_value NUMERIC, + denominator_unit_concept_id int4, + box_size int2, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR (1) +); + +DROP TABLE IF EXISTS pack_content CASCADE; +CREATE TABLE pack_content ( + pack_concept_id int4 NOT NULL, + drug_concept_id int4 NOT NULL, + amount int2, + box_size int2 +); + +DROP TABLE IF EXISTS concept_stage; +CREATE TABLE concept_stage ( + concept_id int4, + concept_name VARCHAR (255), + domain_id VARCHAR (20), + vocabulary_id VARCHAR (20) NOT NULL, + concept_class_id VARCHAR (20), + standard_concept VARCHAR (1), + concept_code VARCHAR (50) NOT NULL, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR (1) +); + +DROP TABLE IF EXISTS concept_relationship_stage; +CREATE TABLE concept_relationship_stage ( + concept_id_1 int4, + concept_id_2 int4, + concept_code_1 VARCHAR (50) NOT NULL, + concept_code_2 VARCHAR (50) NOT NULL, + vocabulary_id_1 VARCHAR (20) NOT NULL, + vocabulary_id_2 VARCHAR (20) NOT NULL, + relationship_id VARCHAR (20) NOT NULL, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR (1) +); + +DROP TABLE IF EXISTS concept_synonym_stage; +CREATE TABLE concept_synonym_stage ( + synonym_concept_id int4, + synonym_name VARCHAR (1000) NOT NULL, + synonym_concept_code VARCHAR (50) NOT NULL, + synonym_vocabulary_id VARCHAR (20) NOT NULL, + language_concept_id int4 NOT NULL +); + +DROP TABLE IF EXISTS drug_strength_stage; +CREATE TABLE drug_strength_stage ( + drug_concept_code VARCHAR (20) NOT NULL, + vocabulary_id_1 VARCHAR (20) NOT NULL, + ingredient_concept_code VARCHAR (20) NOT NULL, + vocabulary_id_2 VARCHAR (20) NOT NULL, + amount_value NUMERIC, + amount_unit_concept_id int4, + numerator_value NUMERIC, + numerator_unit_concept_id int4, + denominator_value NUMERIC, + denominator_unit_concept_id int4, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR (1) +); + +DROP TABLE IF EXISTS pack_content_stage; +CREATE TABLE pack_content_stage ( + pack_concept_code VARCHAR (20) NOT NULL, + pack_vocabulary_id VARCHAR (20) NOT NULL, + drug_concept_code VARCHAR (20) NOT NULL, + drug_vocabulary_id VARCHAR (20) NOT NULL, + amount int2, + box_size int2 +); + +DROP TABLE IF EXISTS concept_relationship_manual; +CREATE TABLE concept_relationship_manual ( + concept_code_1 VARCHAR (50) NOT NULL, + concept_code_2 VARCHAR (50) NOT NULL, + vocabulary_id_1 VARCHAR (20) NOT NULL, + vocabulary_id_2 VARCHAR (20) NOT NULL, + relationship_id VARCHAR (20) NOT NULL, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR (1) +); + +DROP TABLE IF EXISTS concept_manual; +CREATE TABLE concept_manual ( + concept_name VARCHAR (255), + domain_id VARCHAR (20), + vocabulary_id VARCHAR (20) NOT NULL, + concept_class_id VARCHAR (20), + standard_concept VARCHAR (1), + concept_code VARCHAR (50) NOT NULL, + valid_start_date DATE, + valid_end_date DATE, + invalid_reason VARCHAR (1) +); + +DROP TABLE IF EXISTS concept_synonym_manual; +CREATE TABLE concept_synonym_manual ( + synonym_name VARCHAR (1000) NOT NULL, + synonym_concept_code VARCHAR (50) NOT NULL, + synonym_vocabulary_id VARCHAR (20) NOT NULL, + language_concept_id int4 NOT NULL +); + +--Create a base table for manual relationships, it stores all manual relationships from all vocabularies +DROP TABLE IF EXISTS base_concept_relationship_manual; +CREATE TABLE base_concept_relationship_manual ( + LIKE concept_relationship_manual, + concept_id_1 INT4 NOT NULL, + concept_id_2 INT4 NOT NULL, + CONSTRAINT idx_pk_base_crm PRIMARY KEY ( + concept_code_1, + concept_code_2, + vocabulary_id_1, + vocabulary_id_2, + relationship_id + ) + ); + +--Create a base table for manual concepts, it stores all manual concepts from all vocabularies +DROP TABLE IF EXISTS base_concept_manual CASCADE; +CREATE TABLE base_concept_manual ( + LIKE concept_manual, + concept_id INT4 NOT NULL, + CONSTRAINT idx_pk_base_cm PRIMARY KEY ( + concept_code, + vocabulary_id + ) + ); + +--Create a base table for manual synonyms, it stores all manual synonyms from all vocabularies +DROP TABLE IF EXISTS base_concept_synonym_manual CASCADE; +CREATE TABLE base_concept_synonym_manual ( + LIKE concept_synonym_manual, + concept_id INT4 NOT NULL, + CONSTRAINT idx_pk_base_csm PRIMARY KEY ( + synonym_vocabulary_id, + synonym_name, + synonym_concept_code, + language_concept_id + ) + ); diff --git a/working/local_environment/GenericUpdate_LE.sql b/working/local_environment/GenericUpdate_LE.sql new file mode 100644 index 000000000..01f452c21 --- /dev/null +++ b/working/local_environment/GenericUpdate_LE.sql @@ -0,0 +1,1095 @@ +-- DROP FUNCTION devv5.genericupdate(); + +CREATE OR REPLACE FUNCTION devv5.genericupdate() + RETURNS void + LANGUAGE plpgsql + SET client_min_messages TO 'error' +AS $function$ +BEGIN + --1. Prerequisites: + --1.1 Check vocabulary table, at least one vocabulary must have the latest_update field set + PERFORM FROM vocabulary WHERE latest_update IS NOT NULL LIMIT 1; + IF NOT FOUND THEN + RAISE EXCEPTION 'At least one vocabulary must have the latest_update field set' + USING HINT = 'Forgot to execute SetLatestUpdate?'; + END IF; + + --1.2 Check stage tables for incorrect rows + DO $$ + DECLARE + z TEXT; + crlf TEXT:=E'\r\n'; + BEGIN + SELECT STRING_AGG(error_text||' [rows_count='||rows_count||']', crlf) INTO z FROM qa_tests.Check_Stage_Tables(); + IF LENGTH(z)>10000 THEN + z:=SUBSTR(z,1,10000)||'... (cut)'; + END IF; + IF z IS NOT NULL THEN + z:=crlf||z||crlf||crlf||'NOTE: You can also run SELECT * FROM qa_tests.Check_Stage_Tables();'; + RAISE EXCEPTION '%', z; + END IF; + END $$; + + --1.3 Start logging manual work + /*PERFORM admin_pack.LogManualChanges();*/ + + --1.4 Clear concept_id's just in case + UPDATE concept_stage + SET concept_id = NULL + WHERE concept_id IS NOT NULL; + + UPDATE concept_relationship_stage + SET concept_id_1 = NULL, + concept_id_2 = NULL + WHERE COALESCE(concept_id_1, concept_id_2) IS NOT NULL; + + UPDATE concept_synonym_stage + SET synonym_concept_id = NULL + WHERE synonym_concept_id IS NOT NULL; + + --2. Make sure that invalid concepts are standard_concept = NULL + UPDATE concept_stage cs + SET standard_concept = NULL + WHERE cs.invalid_reason IS NOT NULL + AND cs.standard_concept IS NOT NULL; + + --3. Make sure invalid_reason = null if the valid_end_date is 31-Dec-2099 + UPDATE concept_stage cs + SET invalid_reason = NULL + WHERE cs.valid_end_date = TO_DATE ('20991231', 'YYYYMMDD') + AND cs.invalid_reason IS NOT NULL; + + --4. Update concept_id in concept_stage from concept for existing concepts + UPDATE concept_stage cs + SET concept_id = c.concept_id + FROM concept c + WHERE cs.concept_code = c.concept_code + AND cs.vocabulary_id = c.vocabulary_id; + + --5. Analyzing + ANALYZE concept_stage; + ANALYZE concept_relationship_stage; + + --6. Clearing the concept_name + --Remove double spaces, carriage return, newline, vertical tab, form feed, unicode spaces + UPDATE concept_stage + SET concept_name = TRIM(REGEXP_REPLACE(concept_name, '[[:cntrl:]\u00a0\u180e\u2007\u200b-\u200f\u202f\u2060\ufeff]+', ' ', 'g')) + WHERE concept_name ~ '[[:cntrl:]\u00a0\u180e\u2007\u200b-\u200f\u202f\u2060\ufeff]'; + + UPDATE concept_stage + SET concept_name = REGEXP_REPLACE(concept_name, ' {2,}', ' ', 'g') + WHERE concept_name ~ ' {2,}'; + + --Remove long dashes + UPDATE concept_stage + SET concept_name = REPLACE(concept_name, '–', '-') + WHERE concept_name LIKE '%–%'; + + --Remove trailing escape character (\) + UPDATE concept_stage + SET concept_name = RTRIM(concept_name, $c$\$c$) + WHERE concept_name LIKE '%\\'; + + --7. Clearing the synonym_name + --Remove double spaces, carriage return, newline, vertical tab and form feed + WITH del + AS ( + DELETE + FROM concept_synonym_stage + WHERE synonym_name ~ '[[:cntrl:]\u00a0\u180e\u2007\u200b-\u200f\u202f\u2060\ufeff]' + RETURNING * + ) + INSERT INTO concept_synonym_stage + SELECT d.synonym_concept_id, + TRIM(REGEXP_REPLACE(d.synonym_name, '[[:cntrl:]\u00a0\u180e\u2007\u200b-\u200f\u202f\u2060\ufeff]+', ' ', 'g')) AS synonym_name, + d.synonym_concept_code, + d.synonym_vocabulary_id, + d.language_concept_id + FROM del d + ON CONFLICT DO NOTHING; + + --Remove double spaces + WITH del + AS ( + DELETE + FROM concept_synonym_stage + WHERE synonym_name ~ ' {2,}' + RETURNING * + ) + INSERT INTO concept_synonym_stage + SELECT d.synonym_concept_id, + REGEXP_REPLACE(d.synonym_name, ' {2,}', ' ', 'g') AS synonym_name, + d.synonym_concept_code, + d.synonym_vocabulary_id, + d.language_concept_id + FROM del d + ON CONFLICT DO NOTHING; + + --Remove long dashes + WITH del + AS ( + DELETE + FROM concept_synonym_stage + WHERE synonym_name LIKE '%–%' + RETURNING * + ) + INSERT INTO concept_synonym_stage + SELECT d.synonym_concept_id, + REPLACE(d.synonym_name, '–', '-') AS synonym_name, + d.synonym_concept_code, + d.synonym_vocabulary_id, + d.language_concept_id + FROM del d + ON CONFLICT DO NOTHING; + + --Remove trailing escape character (\) + WITH del + AS ( + DELETE + FROM concept_synonym_stage + WHERE synonym_name LIKE '%\\' + RETURNING * + ) + INSERT INTO concept_synonym_stage + SELECT d.synonym_concept_id, + RTRIM(d.synonym_name, $c$\$c$) AS synonym_name, + d.synonym_concept_code, + d.synonym_vocabulary_id, + d.language_concept_id + FROM del d + ON CONFLICT DO NOTHING; + + /*************************** + * Update the concept table * + ****************************/ + + --8. Update existing concept details from concept_stage. + --All fields (concept_name, domain_id, concept_class_id, standard_concept, valid_start_date, valid_end_date, invalid_reason) are updated + UPDATE concept c + SET ( + concept_name, + domain_id, + concept_class_id, + standard_concept, + valid_start_date, + valid_end_date, + invalid_reason + ) = ( + cs.concept_name, + cs.domain_id, + cs.concept_class_id, + cs.standard_concept, + CASE + WHEN cs.valid_start_date <> v.latest_update --if we have a real date in the concept_stage, use it. If it is only the release date, use the existing + THEN cs.valid_start_date + ELSE c.valid_start_date + END, + cs.valid_end_date, + cs.invalid_reason + ) + FROM concept_stage cs + JOIN vocabulary v USING (vocabulary_id) + WHERE c.concept_id = cs.concept_id + AND ROW(c.concept_name, c.domain_id, c.concept_class_id, c.standard_concept, c.valid_start_date, c.valid_end_date, c.invalid_reason) + IS DISTINCT FROM + ROW(cs.concept_name, cs.domain_id, cs.concept_class_id, cs.standard_concept, cs.valid_start_date, cs.valid_end_date, cs.invalid_reason); + + --9. Deprecate concepts missing from concept_stage and are not already deprecated. + --This only works for vocabularies where we expect a full set of active concepts in concept_stage. + --If the vocabulary only provides changed concepts, this should not be run, and the update information is already dealt with in step 1. + --20180523: new rule for some vocabularies, see http://forums.ohdsi.org/t/proposal-to-keep-outdated-standard-concepts-active-and-standard/3695/22 and AVOF-981 + --20200730 added ICD10PCS + --9.1. Update the concept for 'regular' vocabularies + UPDATE concept c + SET invalid_reason = 'D', + standard_concept = NULL, + valid_end_date = v.latest_update - 1 + FROM vocabulary v + WHERE c.vocabulary_id = v.vocabulary_id + AND COALESCE(v.vocabulary_params ->> 'is_full', '0') = '1' --all vocabularies that give us a full list of active concepts at each release we can safely assume to deprecate missing ones (in default we will not deprecate) + AND NOT (COALESCE(v.vocabulary_params ->> 'special_deprecation', '0') = '1') + AND v.latest_update IS NOT NULL --only for current vocabularies + AND NOT EXISTS ( + SELECT 1 + FROM concept_stage cs + WHERE cs.concept_id = c.concept_id + AND cs.vocabulary_id = c.vocabulary_id + ) --if concept missing from concept_stage + AND c.invalid_reason IS NULL;--not already deprecated + + --9.2. Update the concept for 'special' vocabs + UPDATE concept c + SET valid_end_date = v.latest_update - 1 + FROM vocabulary v + WHERE c.vocabulary_id = v.vocabulary_id + AND v.vocabulary_params ->> 'special_deprecation' = '1' + AND v.latest_update IS NOT NULL --only for current vocabularies + AND NOT EXISTS ( + SELECT 1 + FROM concept_stage cs + WHERE cs.concept_id = c.concept_id + AND cs.vocabulary_id = c.vocabulary_id + ) --if concept missing from concept_stage + AND c.valid_end_date = TO_DATE('20991231', 'YYYYMMDD');--not already deprecated + + --10. Add new concepts from concept_stage + --Create sequence after last valid one + DO $$ + DECLARE + ex INTEGER; + BEGIN + --SELECT MAX(concept_id)+1 INTO ex FROM concept WHERE concept_id<500000000; -- Last valid below HOI concept_id + DROP SEQUENCE IF EXISTS v5_concept; + SELECT concept_id + 1 INTO ex FROM ( + SELECT concept_id, next_id, next_id - concept_id - 1 free_concept_ids + FROM ( + SELECT concept_id, LEAD (concept_id) OVER (ORDER BY concept_id) next_id FROM + ( + SELECT concept_id FROM concept + /*UNION ALL + SELECT concept_id FROM devv5.concept_blacklisted*/ --blacklisted concept_id's (AVOF-2395) + ) AS i + WHERE concept_id >= 581480 AND concept_id < 500000000 + ) AS t + WHERE concept_id <> next_id - 1 AND next_id - concept_id > (SELECT COUNT (*) FROM concept_stage WHERE concept_id IS NULL) + ORDER BY next_id - concept_id + LIMIT 1 + ) AS sq; + EXECUTE 'CREATE SEQUENCE v5_concept INCREMENT BY 1 START WITH ' || ex || ' NO CYCLE CACHE 20'; + END$$; + + --11. Insert new concepts + 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 + ) + SELECT NEXTVAL('v5_concept'), + cs.concept_name, + cs.domain_id, + cs.vocabulary_id, + cs.concept_class_id, + cs.standard_concept, + cs.concept_code, + cs.valid_start_date, + cs.valid_end_date, + cs.invalid_reason + FROM concept_stage cs + WHERE cs.concept_id IS NULL;-- new because no concept_id could be found for the concept_code/vocabulary_id combination + + DROP SEQUENCE v5_concept; + ANALYZE concept; + + --12. Update concept_id for new concepts + UPDATE concept_stage cs + SET concept_id = c.concept_id + FROM concept c + WHERE cs.concept_code = c.concept_code + AND cs.vocabulary_id = c.vocabulary_id + AND cs.concept_id IS NULL; + ANALYZE concept_stage; + + --13. Update concept_id_1 and concept_id_2 in concept_relationship_stage from concept_stage and concept + UPDATE concept_relationship_stage crs + SET concept_id_1 = c1.concept_id, + concept_id_2 = c2.concept_id + FROM concept_stage c1, + concept_stage c2 + WHERE c1.concept_code = crs.concept_code_1 + AND c1.vocabulary_id = crs.vocabulary_id_1 + AND c2.concept_code = crs.concept_code_2 + AND c2.vocabulary_id = crs.vocabulary_id_2; + + UPDATE concept_relationship_stage crs + SET concept_id_1 = c.concept_id + FROM concept c + WHERE c.concept_code = crs.concept_code_1 + AND c.vocabulary_id = crs.vocabulary_id_1 + AND crs.concept_id_1 IS NULL; + + UPDATE concept_relationship_stage crs + SET concept_id_2 = c.concept_id + FROM concept c + WHERE c.concept_code = crs.concept_code_2 + AND c.vocabulary_id = crs.vocabulary_id_2 + AND crs.concept_id_2 IS NULL; + + /**************************************** + * Update the concept_relationship table * + ****************************************/ + + --14. Turn all relationship records so they are symmetrical if necessary and create an index + INSERT INTO concept_relationship_stage ( + concept_id_1, + concept_id_2, + concept_code_1, + concept_code_2, + vocabulary_id_1, + vocabulary_id_2, + relationship_id, + valid_start_date, + valid_end_date, + invalid_reason + ) + SELECT crs.concept_id_2, + crs.concept_id_1, + crs.concept_code_2, + crs.concept_code_1, + crs.vocabulary_id_2, + crs.vocabulary_id_1, + r.reverse_relationship_id, + crs.valid_start_date, + crs.valid_end_date, + crs.invalid_reason + FROM concept_relationship_stage crs + JOIN relationship r USING (relationship_id) + ON CONFLICT DO NOTHING; + + CREATE INDEX idx_crs_ids_generic_temp ON concept_relationship_stage ( + concept_id_1, + concept_id_2, + relationship_id + ); + ANALYZE concept_relationship_stage; + + --15. Update all relationships existing in concept_relationship_stage, including undeprecation of formerly deprecated ones + UPDATE concept_relationship cr + SET valid_end_date = crs.valid_end_date, + invalid_reason = crs.invalid_reason + FROM concept_relationship_stage crs + WHERE crs.concept_id_1 = cr.concept_id_1 + AND crs.concept_id_2 = cr.concept_id_2 + AND crs.relationship_id = cr.relationship_id + AND crs.valid_end_date <> cr.valid_end_date; + + --16. Deprecate missing relationships, but only if the concepts are fresh. If relationships are missing because of deprecated concepts, leave them intact. + --Also, only relationships are considered missing if the combination of vocabulary_id_1, vocabulary_id_2 AND relationship_id is present in concept_relationship_stage + --The latter will prevent large-scale deprecations of relationships between vocabularies where the relationship is defined not here, but together with the other vocab + + --Do the deprecation + WITH relationships + AS ( + SELECT * + FROM UNNEST(ARRAY [ + 'Concept replaced by', + 'Concept same_as to', + 'Concept alt_to to', + 'Concept was_a to', + 'Maps to', + 'CPT4 - SNOMED cat', -- AVOC-4022 + 'CPT4 - SNOMED eq' -- AVOC-4022 + ]) AS relationship_id + ), + vocab_combinations + AS ( + --Create a list of vocab1, vocab2 and relationship_id existing in concept_relationship_stage, except 'Maps' to and replacement relationships + --Also excludes manual mappings from concept_relationship_manual + SELECT DISTINCT s0.vocabulary_id_1, + s0.vocabulary_id_2, + s0.relationship_id, + -- One of latest_update (if we have more than one vocabulary in concept_relationship_stage) may be NULL, therefore use GREATEST to get one non-null date + GREATEST(v1.latest_update, v2.latest_update) AS max_latest_update + FROM ( + SELECT concept_code_1, + concept_code_2, + vocabulary_id_1, + vocabulary_id_2, + relationship_id + FROM concept_relationship_stage + + EXCEPT + + ( + SELECT concept_code_1, + concept_code_2, + vocabulary_id_1, + vocabulary_id_2, + relationship_id + FROM concept_relationship_manual + + UNION ALL + + --Add reverse mappings for exclude + SELECT concept_code_2, + concept_code_1, + vocabulary_id_2, + vocabulary_id_1, + reverse_relationship_id + FROM concept_relationship_manual + JOIN relationship USING (relationship_id) + ) + ) AS s0 + JOIN vocabulary v1 ON v1.vocabulary_id = s0.vocabulary_id_1 + JOIN vocabulary v2 ON v2.vocabulary_id = s0.vocabulary_id_2 + WHERE s0.vocabulary_id_1 NOT IN ( + 'SPL', + 'RxNorm Extension', + 'CDM' + ) + AND s0.vocabulary_id_2 NOT IN ( + 'SPL', + 'RxNorm Extension', + 'CDM' + ) + AND s0.relationship_id NOT IN ( + SELECT relationship_id + FROM relationships + + UNION ALL + + SELECT reverse_relationship_id + FROM relationships + JOIN relationship USING (relationship_id) + ) + AND COALESCE(v1.latest_update, v2.latest_update) IS NOT NULL + ) + UPDATE concept_relationship d + SET valid_end_date = vc.max_latest_update - 1, + invalid_reason = 'D' + --Whether the combination of vocab1, vocab2 and relationship exists (in subquery) + --(intended to be covered by this particular vocab udpate) + --And both concepts exist (don't deprecate relationships of deprecated concepts) + FROM concept c1, + concept c2, + vocab_combinations vc + WHERE c1.concept_id = d.concept_id_1 + AND c2.concept_id = d.concept_id_2 + AND c1.valid_end_date = TO_DATE('20991231', 'YYYYMMDD') + AND c2.valid_end_date = TO_DATE('20991231', 'YYYYMMDD') + AND c1.vocabulary_id = vc.vocabulary_id_1 + AND c2.vocabulary_id = vc.vocabulary_id_2 + AND d.relationship_id = vc.relationship_id + --And the record is currently fresh and not already deprecated + AND d.invalid_reason IS NULL + --And it was started before or equal the release date + AND d.valid_start_date <= vc.max_latest_update + --And it is missing from the new concept_relationship_stage + AND NOT EXISTS ( + SELECT 1 + FROM concept_relationship_stage crs + WHERE crs.concept_id_1 = d.concept_id_1 + AND crs.concept_id_2 = d.concept_id_2 + AND crs.relationship_id = d.relationship_id + ); + + --17. Deprecate old 'Maps to', 'Maps to value' and replacement records, but only if we have a new one in concept_relationship_stage with the same source concept + --part 1 (direct mappings) + WITH relationships AS ( + SELECT relationship_id FROM relationship + WHERE relationship_id IN ( + 'Concept replaced by', + 'Concept same_as to', + 'Concept alt_to to', + 'Concept was_a to', + 'Maps to', + 'Maps to value', + 'Source - RxNorm eq', -- AVOF-2118 + 'CPT4 - SNOMED cat', -- AVOC-4022 + 'CPT4 - SNOMED eq' -- AVOC-4022 + ) + ) + UPDATE concept_relationship r + SET valid_end_date = + GREATEST(r.valid_start_date, (SELECT MAX(v.latest_update) -1 -- one of latest_update (if we have more than one vocabulary in concept_relationship_stage) may be NULL, therefore use aggregate function MAX() to get one non-null date + FROM vocabulary v + WHERE v.vocabulary_id IN (c1.vocabulary_id, c2.vocabulary_id) --take both concept ids to get proper latest_update + )), + invalid_reason = 'D' + FROM concept c1, concept c2, relationships rel + WHERE r.concept_id_1=c1.concept_id + AND r.concept_id_2=c2.concept_id + AND r.invalid_reason IS NULL + AND r.relationship_id=rel.relationship_id + AND r.concept_id_1<>r.concept_id_2 + AND EXISTS ( + SELECT 1 FROM concept_relationship_stage crs + WHERE crs.concept_id_1=r.concept_id_1 + AND crs.relationship_id=r.relationship_id + AND crs.invalid_reason IS NULL + AND ( + crs.vocabulary_id_2=c2.vocabulary_id + OR (/*AVOF-459*/ + crs.vocabulary_id_2 IN ('RxNorm','RxNorm Extension') AND c2.vocabulary_id IN ('RxNorm','RxNorm Extension') + ) + OR (/*AVOF-1439*/ + crs.vocabulary_id_2 IN ('SNOMED','SNOMED Veterinary') AND c2.vocabulary_id IN ('SNOMED','SNOMED Veterinary') + ) + ) + ) + AND NOT EXISTS ( + SELECT 1 FROM concept_relationship_stage crs + WHERE crs.concept_id_1=r.concept_id_1 + AND crs.concept_id_2=r.concept_id_2 + AND crs.relationship_id=r.relationship_id + AND crs.invalid_reason IS NULL + ); + + --part 2 (reverse mappings) + WITH relationships AS ( + SELECT reverse_relationship_id FROM relationship + WHERE relationship_id in ( + 'Concept replaced by', + 'Concept same_as to', + 'Concept alt_to to', + 'Concept was_a to', + 'Maps to', + 'Maps to value', + 'Source - RxNorm eq', -- AVOF-2118 + 'CPT4 - SNOMED cat', -- AVOC-4022 + 'CPT4 - SNOMED eq' -- AVOC-4022 + ) + ) + UPDATE concept_relationship r + SET valid_end_date = + GREATEST(r.valid_start_date, (SELECT MAX(v.latest_update) -1 -- one of latest_update (if we have more than one vocabulary in concept_relationship_stage) may be NULL, therefore use aggregate function MAX() to get one non-null date + FROM vocabulary v + WHERE v.vocabulary_id IN (c1.vocabulary_id, c2.vocabulary_id) --take both concept ids to get proper latest_update + )), + invalid_reason = 'D' + FROM concept c1, concept c2, relationships rel + WHERE r.concept_id_1=c1.concept_id + AND r.concept_id_2=c2.concept_id + AND r.invalid_reason IS NULL + AND r.relationship_id=rel.reverse_relationship_id + AND r.concept_id_1<>r.concept_id_2 + AND EXISTS ( + SELECT 1 FROM concept_relationship_stage crs + WHERE crs.concept_id_2=r.concept_id_2 + AND crs.relationship_id=r.relationship_id + AND crs.invalid_reason IS NULL + AND ( + crs.vocabulary_id_1=c1.vocabulary_id + OR (/*AVOF-459*/ + crs.vocabulary_id_1 IN ('RxNorm','RxNorm Extension') AND c1.vocabulary_id IN ('RxNorm','RxNorm Extension') + ) + OR (/*AVOF-1439*/ + crs.vocabulary_id_1 IN ('SNOMED','SNOMED Veterinary') AND c1.vocabulary_id IN ('SNOMED','SNOMED Veterinary') + ) + ) + ) + AND NOT EXISTS ( + SELECT 1 FROM concept_relationship_stage crs + WHERE crs.concept_id_1=r.concept_id_1 + AND crs.concept_id_2=r.concept_id_2 + AND crs.relationship_id=r.relationship_id + AND crs.invalid_reason IS NULL + ); + + --18. Insert new relationships if they don't already exist + INSERT INTO concept_relationship + SELECT crs.concept_id_1, + crs.concept_id_2, + crs.relationship_id, + crs.valid_start_date, + crs.valid_end_date, + crs.invalid_reason + FROM concept_relationship_stage crs + ON CONFLICT DO NOTHING; + + /********************************************************* + * Update the correct invalid reason in the concept table * + * This should rarely happen * + *********************************************************/ + + --19. Make sure invalid_reason = 'U' if we have an active replacement record in the concept_relationship table + UPDATE concept c + SET valid_end_date = LEAST(c.valid_end_date, v.latest_update - 1), -- day before release day + invalid_reason = 'U', + standard_concept = NULL + FROM concept_relationship cr, vocabulary v + WHERE c.vocabulary_id = v.vocabulary_id + AND cr.concept_id_1 = c.concept_id + AND cr.invalid_reason IS NULL + AND cr.relationship_id IN ( + 'Concept replaced by', + 'Concept same_as to', + 'Concept alt_to to', + 'Concept was_a to' + ) + AND v.latest_update IS NOT NULL -- only for current vocabularies + AND (c.invalid_reason IS NULL OR c.invalid_reason = 'D'); -- not already upgraded + + --20. Make sure invalid_reason = 'D' if we have no active replacement record in the concept_relationship table for upgraded concepts + UPDATE concept c + SET valid_end_date = LEAST(c.valid_end_date, v.latest_update - 1), + invalid_reason = 'D', + standard_concept = NULL + FROM vocabulary v + WHERE v.vocabulary_id = c.vocabulary_id + AND NOT EXISTS ( + SELECT 1 + FROM concept_relationship r + WHERE r.concept_id_1 = c.concept_id + AND r.invalid_reason IS NULL + AND r.relationship_id IN ( + 'Concept replaced by', + 'Concept same_as to', + 'Concept alt_to to', + 'Concept was_a to' + ) + ) + AND v.latest_update IS NOT NULL -- only for current vocabularies + AND c.invalid_reason = 'U';-- not already deprecated + + --The following are a bunch of rules for Maps to and Maps from relationships. + --Since they work outside the _stage tables, they will be restricted to the vocabularies worked on + + --21. 'Maps to' and 'Mapped from' relationships from concepts to self should exist for all concepts where standard_concept = 'S' + INSERT INTO concept_relationship AS cr + SELECT c.concept_id AS concept_id_1, + c.concept_id AS concept_id_2, + r.relationship_id, + v.latest_update AS valid_start_date, + TO_DATE('20991231', 'yyyymmdd') AS valid_end_date, + NULL AS invalid_reason + FROM concept c + JOIN vocabulary v ON v.vocabulary_id = c.vocabulary_id + AND v.latest_update IS NOT NULL + CROSS JOIN ( + SELECT 'Maps to' AS relationship_id + + UNION ALL + + SELECT 'Mapped from' + ) r + WHERE c.standard_concept = 'S' + AND c.invalid_reason IS NULL + ON CONFLICT ON CONSTRAINT xpk_concept_relationship + DO UPDATE + SET valid_end_date = excluded.valid_end_date, + invalid_reason = excluded.invalid_reason + WHERE cr.invalid_reason IS NOT NULL; + + --22. 'Maps to' or 'Maps to value' relationships should not exist where + --a) the source concept has standard_concept = 'S', unless it is to self + --b) the target concept has standard_concept = 'C' or NULL + --c) the target concept has invalid_reason='D' or 'U' + + UPDATE concept_relationship r + SET valid_end_date = GREATEST(r.valid_start_date, (SELECT MAX(v.latest_update)-1 FROM vocabulary v WHERE v.vocabulary_id=c1.vocabulary_id OR v.vocabulary_id=c2.vocabulary_id)), -- day before release day or valid_start_date + invalid_reason = 'D' + FROM concept c1, concept c2, vocabulary v + WHERE r.concept_id_1 = c1.concept_id + AND r.concept_id_2 = c2.concept_id + AND ( + (c1.standard_concept = 'S' AND c1.concept_id <> c2.concept_id) -- rule a) + OR COALESCE (c2.standard_concept, 'X') <> 'S' -- rule b) + OR c2.invalid_reason IN ('U', 'D') -- rule c) + ) + AND v.vocabulary_id IN (c1.vocabulary_id, c2.vocabulary_id) + AND v.latest_update IS NOT NULL -- only the current vocabularies + AND r.relationship_id IN ('Maps to','Maps to value') + AND r.invalid_reason IS NULL; + + --And reverse + UPDATE concept_relationship r + SET valid_end_date = GREATEST(r.valid_start_date, (SELECT MAX(v.latest_update)-1 FROM vocabulary v WHERE v.vocabulary_id=c1.vocabulary_id OR v.vocabulary_id=c2.vocabulary_id)), -- day before release day or valid_start_date + invalid_reason = 'D' + FROM concept c1, concept c2, vocabulary v + WHERE r.concept_id_1 = c1.concept_id + AND r.concept_id_2 = c2.concept_id + AND ( + (c2.standard_concept = 'S' AND c1.concept_id <> c2.concept_id) -- rule a) + OR COALESCE (c1.standard_concept, 'X') <> 'S' -- rule b) + OR c1.invalid_reason IN ('U', 'D') -- rule c) + ) + AND v.vocabulary_id IN (c1.vocabulary_id, c2.vocabulary_id) + AND v.latest_update IS NOT NULL -- only the current vocabularies + AND r.relationship_id IN ('Mapped from','Value mapped from') + AND r.invalid_reason IS NULL; + + --23. Post-processing (some concepts might be deprecated when they missed in source, so load_stage doesn't know about them and DO NOT deprecate relationships proper) + --Deprecate replacement records if target concept was deprecated + UPDATE concept_relationship cr + SET invalid_reason = 'D', + valid_end_date = (SELECT MAX (v.latest_update) FROM concept c JOIN vocabulary v ON c.vocabulary_id = v.vocabulary_id WHERE c.concept_id IN (cr.concept_id_1, cr.concept_id_2))-1 + FROM ( + WITH RECURSIVE hierarchy_concepts (concept_id_1, concept_id_2, relationship_id, full_path) AS + ( + SELECT concept_id_1, concept_id_2, relationship_id, ARRAY [concept_id_1] AS full_path + FROM upgraded_concepts + WHERE concept_id_2 IN (SELECT concept_id_2 FROM upgraded_concepts WHERE invalid_reason = 'D') + UNION ALL + SELECT c.concept_id_1, c.concept_id_2, c.relationship_id, hc.full_path || c.concept_id_1 AS full_path + FROM upgraded_concepts c + JOIN hierarchy_concepts hc on hc.concept_id_1=c.concept_id_2 + WHERE c.concept_id_1 <> ALL (full_path) + ), + upgraded_concepts AS ( + SELECT r.concept_id_1, + r.concept_id_2, + r.relationship_id, + c2.invalid_reason + FROM concept c1, concept c2, concept_relationship r + WHERE r.relationship_id IN ( + 'Concept replaced by', + 'Concept same_as to', + 'Concept alt_to to', + 'Concept was_a to' + ) + AND r.invalid_reason IS NULL + AND c1.concept_id = r.concept_id_1 + AND c2.concept_id = r.concept_id_2 + AND EXISTS (SELECT 1 FROM vocabulary WHERE latest_update IS NOT NULL AND vocabulary_id IN (c1.vocabulary_id,c2.vocabulary_id)) + AND c2.concept_code <> 'OMOP generated' + AND r.concept_id_1 <> r.concept_id_2 + ) + SELECT concept_id_1, concept_id_2, relationship_id FROM hierarchy_concepts + ) i + WHERE cr.concept_id_1 = i.concept_id_1 AND cr.concept_id_2 = i.concept_id_2 AND cr.relationship_id = i.relationship_id; + + --Deprecate concepts if we have no active replacement record in the concept_relationship + UPDATE concept c + SET valid_end_date = LEAST(c.valid_end_date, v.latest_update - 1), + invalid_reason = 'D', + standard_concept = NULL + FROM vocabulary v + WHERE v.vocabulary_id = c.vocabulary_id + AND NOT EXISTS ( + SELECT 1 + FROM concept_relationship r + WHERE r.concept_id_1 = c.concept_id + AND r.invalid_reason IS NULL + AND r.relationship_id IN ( + 'Concept replaced by', + 'Concept same_as to', + 'Concept alt_to to', + 'Concept was_a to' + ) + ) + AND v.latest_update IS NOT NULL -- only for current vocabularies + AND c.invalid_reason = 'U';-- not already deprecated + + --Deprecate 'Maps to' mappings to deprecated and upgraded concepts + UPDATE concept_relationship r + SET valid_end_date = ( + SELECT MAX(v.latest_update) + FROM concept c + JOIN vocabulary v ON c.vocabulary_id = v.vocabulary_id + WHERE c.concept_id IN ( + r.concept_id_1, + r.concept_id_2 + ) + ) - 1, + invalid_reason = 'D' + WHERE r.relationship_id = 'Maps to' + AND r.invalid_reason IS NULL + AND EXISTS ( + SELECT 1 + FROM concept c + WHERE c.concept_id = r.concept_id_2 + AND c.invalid_reason IN ( + 'U', + 'D' + ) + ) + AND EXISTS ( + SELECT 1 + FROM concept c + JOIN vocabulary v ON c.vocabulary_id = v.vocabulary_id + WHERE c.concept_id IN ( + r.concept_id_1, + r.concept_id_2 + ) + AND v.latest_update IS NOT NULL + ); + + --Reverse for deprecating + UPDATE concept_relationship r + SET invalid_reason = r1.invalid_reason, + valid_end_date = r1.valid_end_date + FROM concept_relationship r1 + JOIN relationship rel ON r1.relationship_id = rel.relationship_id + WHERE r1.relationship_id IN ( + 'Concept replaced by', + 'Concept same_as to', + 'Concept alt_to to', + 'Concept was_a to', + 'Maps to' + ) + AND EXISTS ( + SELECT 1 + FROM concept c + JOIN vocabulary v ON c.vocabulary_id = v.vocabulary_id + WHERE c.concept_id IN ( + r1.concept_id_1, + r1.concept_id_2 + ) + AND v.latest_update IS NOT NULL + ) + AND r.concept_id_1 = r1.concept_id_2 + AND r.concept_id_2 = r1.concept_id_1 + AND r.relationship_id = rel.reverse_relationship_id + AND r.valid_end_date <> r1.valid_end_date; + + /*********************************** + * Update the concept_synonym table * + ************************************/ + + --24. Remove duplicates from concept_synonym_stage that might appear after concept_name corrections + DELETE + FROM concept_synonym_stage css + WHERE EXISTS ( + SELECT 1 + FROM concept_synonym_stage css_int + WHERE css_int.synonym_name = css.synonym_name + AND css_int.synonym_concept_code = css.synonym_concept_code + AND css_int.synonym_vocabulary_id = css.synonym_vocabulary_id + AND css_int.language_concept_id = css.language_concept_id + AND css_int.ctid > css.ctid + ); + + --25. Remove synonyms from concept_synonym_stage if synonym_name alreay exists in concept_stage, but only for English + DELETE + FROM concept_synonym_stage css + WHERE EXISTS ( + SELECT 1 + FROM concept_stage cs + WHERE cs.concept_code = css.synonym_concept_code + AND cs.vocabulary_id = css.synonym_vocabulary_id + AND LOWER(cs.concept_name) = LOWER(css.synonym_name) + AND css.language_concept_id = 4180186 + ); + + --26. Update synonym_concept_id + UPDATE concept_synonym_stage css + SET synonym_concept_id = cs.concept_id + FROM concept_stage cs + WHERE cs.concept_code = css.synonym_concept_code + AND cs.vocabulary_id = css.synonym_vocabulary_id + AND css.synonym_concept_id IS NULL; + + --27. Remove all existing synonyms for concepts that are in concept_stage + --Synonyms are built from scratch each time, no life cycle + DELETE + FROM concept_synonym csyn + WHERE NOT EXISTS ( + SELECT 1 + FROM concept_synonym_stage css_int + WHERE css_int.synonym_concept_id = csyn.concept_id + AND css_int.synonym_name = csyn.concept_synonym_name + AND css_int.language_concept_id = csyn.language_concept_id + ) + AND EXISTS ( + SELECT 1 + FROM concept_stage c_int + WHERE c_int.concept_id = csyn.concept_id + ); + + --28. Add new synonyms + INSERT INTO concept_synonym ( + concept_id, + concept_synonym_name, + language_concept_id + ) + SELECT css.synonym_concept_id, + css.synonym_name, + css.language_concept_id + FROM concept_synonym_stage css + ON CONFLICT ON CONSTRAINT unique_synonyms DO NOTHING; + + --29. Fillig drug_strength + --Special rules for RxNorm Extension: same as 'Maps to' rules, but records from deprecated concepts will be deleted + DELETE + FROM drug_strength + WHERE drug_concept_id IN ( + SELECT c.concept_id + FROM concept c + JOIN vocabulary v ON c.vocabulary_id = v.vocabulary_id + WHERE latest_update IS NOT NULL + AND v.vocabulary_id <> 'RxNorm Extension' + ); + + --Replace with fresh records (only for 'RxNorm Extension') + DELETE + FROM drug_strength ds + WHERE EXISTS ( + SELECT 1 + FROM drug_strength_stage dss + JOIN concept c1 ON c1.concept_code = dss.drug_concept_code + AND c1.vocabulary_id = dss.vocabulary_id_1 + AND ds.drug_concept_id = c1.concept_id + JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id + WHERE v.latest_update IS NOT NULL + AND v.vocabulary_id = 'RxNorm Extension' + ); + + --Insert new records + INSERT INTO drug_strength ( + drug_concept_id, + ingredient_concept_id, + amount_value, + amount_unit_concept_id, + numerator_value, + numerator_unit_concept_id, + denominator_value, + denominator_unit_concept_id, + box_size, + valid_start_date, + valid_end_date, + invalid_reason + ) + SELECT c1.concept_id, + c2.concept_id, + ds.amount_value, + ds.amount_unit_concept_id, + ds.numerator_value, + ds.numerator_unit_concept_id, + ds.denominator_value, + ds.denominator_unit_concept_id, + REGEXP_REPLACE(bs.concept_name, '.+Box of ([0-9]+).*', '\1')::INT2 AS box_size, + ds.valid_start_date, + ds.valid_end_date, + ds.invalid_reason + FROM drug_strength_stage ds + JOIN concept c1 ON c1.concept_code = ds.drug_concept_code + AND c1.vocabulary_id = ds.vocabulary_id_1 + JOIN concept c2 ON c2.concept_code = ds.ingredient_concept_code + AND c2.vocabulary_id = ds.vocabulary_id_2 + JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id + LEFT JOIN concept bs ON bs.concept_id = c1.concept_id + AND bs.vocabulary_id = 'RxNorm Extension' + AND bs.concept_name LIKE '%Box of%' + WHERE v.latest_update IS NOT NULL; + + --Delete drug if concept is deprecated (only for 'RxNorm Extension') + DELETE + FROM drug_strength ds + WHERE EXISTS ( + SELECT 1 + FROM concept c1 + JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id + WHERE ds.drug_concept_id = c1.concept_id + AND v.latest_update IS NOT NULL + AND v.vocabulary_id = 'RxNorm Extension' + AND c1.invalid_reason IS NOT NULL + ); + + --30. Fillig pack_content + --Special rules for RxNorm Extension: same as 'Maps to' rules, but records from deprecated concepts will be deleted + DELETE + FROM pack_content + WHERE pack_concept_id IN ( + SELECT c.concept_id + FROM concept c + JOIN vocabulary v ON c.vocabulary_id = v.vocabulary_id + WHERE latest_update IS NOT NULL + AND v.vocabulary_id <> 'RxNorm Extension' + ); + + --Replace with fresh records (only for 'RxNorm Extension') + DELETE + FROM pack_content pc + WHERE EXISTS ( + SELECT 1 + FROM pack_content_stage pcs + JOIN concept c1 ON c1.concept_code = pcs.pack_concept_code + AND c1.vocabulary_id = pcs.pack_vocabulary_id + AND pc.pack_concept_id = c1.concept_id + JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id + WHERE v.latest_update IS NOT NULL + AND v.vocabulary_id = 'RxNorm Extension' + ); + + INSERT INTO pack_content ( + pack_concept_id, + drug_concept_id, + amount, + box_size + ) + SELECT c1.concept_id, + c2.concept_id, + ds.amount, + ds.box_size + FROM pack_content_stage ds + JOIN concept c1 ON c1.concept_code = ds.pack_concept_code + AND c1.vocabulary_id = ds.pack_vocabulary_id + JOIN concept c2 ON c2.concept_code = ds.drug_concept_code + AND c2.vocabulary_id = ds.drug_vocabulary_id + JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id + WHERE v.latest_update IS NOT NULL; + + --Delete if concept is deprecated (only for 'RxNorm Extension') + DELETE + FROM pack_content pc + WHERE EXISTS ( + SELECT 1 + FROM concept c1 + JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id + WHERE pc.pack_concept_id = c1.concept_id + AND v.latest_update IS NOT NULL + AND v.vocabulary_id = 'RxNorm Extension' + AND c1.invalid_reason IS NOT NULL + ); + + --31. Fix empty concept names, new rules [AVOF-2206] + UPDATE concept c + SET concept_name = i.concept_name + FROM ( + SELECT c1.concept_id, + vocabulary_pack.CutConceptName(CONCAT ( + 'No name provided', + ' - mapped to ' || STRING_AGG(c2.concept_name, ' | ' ORDER BY c2.concept_name) + )) AS concept_name + FROM concept c1 + JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id + LEFT JOIN concept_relationship cr ON cr.concept_id_1 = c1.concept_id + AND cr.relationship_id = 'Maps to' + AND cr.invalid_reason IS NULL + LEFT JOIN concept c2 ON c2.concept_id = cr.concept_id_2 + WHERE c1.vocabulary_id IN ( + 'Read', + 'GPI' + ) + AND c1.concept_name = ' ' + AND v.latest_update IS NOT NULL --only for current vocabularies + GROUP BY c1.concept_id + ) i + WHERE i.concept_id = c.concept_id; + + --32. Check if current vocabulary exists in vocabulary_conversion table + INSERT INTO vocabulary_conversion ( + vocabulary_id_v4, + vocabulary_id_v5 + ) + SELECT -1, + v.vocabulary_id + FROM vocabulary v + WHERE v.latest_update IS NOT NULL + ON CONFLICT DO NOTHING; + + --33. Update latest_update on vocabulary_conversion + UPDATE vocabulary_conversion vc + SET latest_update = v.latest_update + FROM vocabulary v + WHERE v.latest_update IS NOT NULL + AND v.vocabulary_id = vc.vocabulary_id_v5; + + --34. Clean up + UPDATE vocabulary + SET latest_update = NULL, + dev_schema_name = NULL + WHERE latest_update IS NOT NULL; + + DROP INDEX idx_crs_ids_generic_temp; + + --35. Final analysing for base tables + ANALYZE concept; + ANALYZE concept_relationship; + ANALYZE concept_synonym; + + --36. Update concept_id fields in the "basic" manual tables for storing in audit + /*PERFORM admin_pack.UpdateManualConceptID();*/ + + --QA (should return NULL) + --SELECT * FROM QA_TESTS.GET_CHECKS(); +END; +$function$ +; diff --git a/working/local_environment/README.md b/working/local_environment/README.md new file mode 100644 index 000000000..0a62a81b1 --- /dev/null +++ b/working/local_environment/README.md @@ -0,0 +1,154 @@ +# Preparing a Local Environment for the Vocabulary Development Process + +## Description + +This document describes the local database preparation that needs to be done for the vocabulary development process + +## Prerequisites + +PostgreSQL 14 or higher. + +## Creating Schemas + +>> create schema <**dev_schema_name**\>; +>> create schema **devv5**; +>> create schema **sources**; +>> create schema **qa_tests**; +>> create schema **vocabulary_pack**; +>> create schema **admin_pack**; + +## Creating Functions + +### devv5 + +- GenericUpdate() + [Vocabulary-v5.0/working/generic_update.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/generic_update.sql) + GenericUpdate_LE.sql +- FastRecreateSchema() + [Vocabulary-v5.0/working/fast_recreate_schema.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/fast_recreate_schema.sql) +- GetPrimaryRelationshipID() [Vocabulary-v5.0/working/packages/admin_pack/GetPrimaryRelationshipID.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/GetPrimaryRelationshipID.sql) +- Functions from + [Vocabulary-v5.0/working/packages/DevV5_additional_functions at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/tree/master/working/packages/DevV5_additional_functions) + +### vocabulary_pack + +- DropFKConstraints() + [Vocabulary-v5.0/working/packages/vocabulary_pack/DropFKConstraints.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DropFKConstraints.sql) +- SetLatestUpdate() + [Vocabulary-v5.0/working/packages/vocabulary_pack/SetLatestUpdate.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/SetLatestUpdate.sql) +- ProcessManualSynonyms() + [Vocabulary-v5.0/working/packages/vocabulary_pack/ProcessManualSynonyms.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/ProcessManualSynonyms.sql) +- CheckManualSynonyms() + [Vocabulary-v5.0/working/packages/vocabulary_pack/CheckManualSynonyms.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/CheckManualSynonyms.sql) +- ProcessManualRelationships() + [Vocabulary-v5.0/working/packages/vocabulary_pack/ProcessManualRelationships.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/ProcessManualRelationships.sql) +- CheckReplacementMappings() + [Vocabulary-v5.0/working/packages/vocabulary_pack/CheckReplacementMappings.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/CheckReplacementMappings.sql) +- AddFreshMAPSTO() + [Vocabulary-v5.0/working/packages/vocabulary_pack/AddFreshMAPSTO.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/AddFreshMAPSTO.sql) +- GetActualConceptInfo() [Vocabulary-v5.0/working/packages/vocabulary_pack/GetActualConceptInfo.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/GetActualConceptInfo.sql) +- DeprecateWrongMapsTo() [Vocabulary-v5.0/working/packages/vocabulary_pack/DeprecateWrongMapsTo.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DeprecateWrongMapsTo.sql) +- DeleteAmbiguousMapsTo() + +[Vocabulary-v5.0/working/packages/vocabulary_pack/DeleteAmbiguousMapsTo.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DeleteAmbiguousMapsTo.sql) + +### qa_tests + +- Functions from [Vocabulary-v5.0/working/packages/QA_TESTS at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/tree/master/working/packages/QA_TESTS) + +### admin_pack + +- Create extensions: + CREATE EXTENSION pgcrypto; + CREATE EXTENSION tablefunc; +- admin_pack_ddl.sql + [Vocabulary-v5.0/working/packages/admin_pack/admin_pack_ddl.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/admin_pack_ddl.sql) +- VirtualLogIn() + [Vocabulary-v5.0/working/packages/admin_pack/VirtualLogIn.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/VirtualLogIn.sql) +- CreateVirtualUser() + [Vocabulary-v5.0/working/packages/admin_pack/CreateVirtualUser.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CreateVirtualUser.sql) +- CheckUserPrivilege() + [Vocabulary-v5.0/working/packages/admin_pack/CheckUserPrivilege.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CheckUserPrivilege.sql) +- GetUserID() + [Vocabulary-v5.0/working/packages/admin_pack/GetUserID.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/GetUserID.sql) +- CheckEmailCharacters() + [Vocabulary-v5.0/working/packages/admin_pack/CheckEmailCharacters.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CheckEmailCharacters.sql) +- CheckLoginCharacters() + [Vocabulary-v5.0/working/packages/admin_pack/CheckLoginCharacters.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CheckLoginCharacters.sql) +- CheckPasswordStrength() + [Vocabulary-v5.0/working/packages/admin_pack/CheckPasswordStrength.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CheckPasswordStrength.sql) +- CheckPrivilegeCharacters() + [Vocabulary-v5.0/working/packages/admin_pack/CheckPrivilegeCharacters.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CheckPrivilegeCharacters.sql) +- CheckUserSpecificVocabulary() + [Vocabulary-v5.0/working/packages/admin_pack/CheckUserSpecificVocabulary.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CheckUserSpecificVocabulary.sql) +- CreatePrivilege() + [Vocabulary-v5.0/working/packages/admin_pack/CreatePrivilege.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CreatePrivilege.sql) + +## Creating Tables + +The next four columns are for internal use only, so they should be excluded from the DevV5_DDL script before execution (from **base_concept_relationship_manual**, **base_concept_manual**, **base_concept_synonym_manual** tables): + +- created +- created_by +- modified +- modified_by + +### Devv5 + +In case the table structure already exists in the database, this part can be skipped. + +When tables are created for the first time, everything should be executed from the DevV5_DDL.sql script except creating constraints and indexes so that they do not interfere with the import of vocabularies from Athena. + +- DevV5_DDL.sql +[Vocabulary-v5.0/working/DevV5_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) +Or just run this script [DevV5_tables_DDL.sql] (https://github.com/OHDSI/Vocabulary-v5.0/blob/master/local_environment/DevV5_tables_DDL.sql) +- Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) + +### dev_schema_name + +- DevV5_DDL.sql + [Vocabulary-v5.0/working/DevV5_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) +- Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) + +### Update Vocabulary table structure + +If the table structure was created before 03/04/2024, the following script should be run: + +- [2024-03-04.sql] +(https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/manual_changes/2024/2024-03-04.sql) + +## sources + +Creating source tables according to instructions for your vocabulary. + +## Import Vocabulary Data from Athena + +To initially fill out the vocabulary tables, it needs to download the necessary vocabularies from [Athena (ohdsi.org)](https://athena.ohdsi.org/vocabulary/list) and import them using the “copy” command. + +The data should be imported to the tables in devv5 schema. + +Before importing dictionaries from CSV files, the client encoding should be set to “UTF8”: + +SET client_encoding = ‘UTF8’; + +The “COPY” command to import data from CSV files in psql: + +>> \\COPY <table_name> FROM '<path_to_csv_file>\\DRUG_STRENGTH.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b' ; + +Additional inserts that may be needed before creating constraints are here (import languages to the concept table): +[Import_Languages.sql] (https://github.com/OHDSI/Vocabulary-v5.0/blob/master/local_environment/Import_Languages.sql) + +After all the data has been imported, it is necessary to create constraints and indexes from the DevV5_DDL.sql, mentioned above, or use this script: +[DevV5_constraints_DDL.sql] (https://github.com/OHDSI/Vocabulary-v5.0/blob/master/local_environment/DevV5_constraints_DDL.sql) + +## Import Source Data + +Filling out source tables according to instructions for a vocabulary. + +## Start the Vocabulary Development Process + +1. **devv5**.FastRecreateSchema() +2. Load_Stage in **dev_schema_name** +3. **qa_tests**.check_stage_tables() +4. **devv5**.GenericUpdate +5. **qa_tests**.get_\* functions \ No newline at end of file From 80f0936228eade4ece8a1fd18c932a6ed8f51b2e Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Wed, 3 Apr 2024 17:05:56 +0300 Subject: [PATCH 02/18] Fix README.md --- working/local_environment/README.md | 99 ++++++++++++++++------------- 1 file changed, 54 insertions(+), 45 deletions(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 0a62a81b1..e266797ec 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -1,36 +1,35 @@ -# Preparing a Local Environment for the Vocabulary Development Process +Preparing a Local Environment for the Vocabulary Development Process -## Description +# Description This document describes the local database preparation that needs to be done for the vocabulary development process -## Prerequisites +# Prerequisites PostgreSQL 14 or higher. -## Creating Schemas +# Creating Schemas +Create schemas: +>-- replace with an actual schema name: +>CREATE SCHEMA ; +>CREATE SCHEMA devv5; +>CREATE SCHEMA sources; +>CREATE SCHEMA qa_tests; +>CREATE SCHEMA vocabulary_pack; +>CREATE SCHEMA admin_pack; ->> create schema <**dev_schema_name**\>; ->> create schema **devv5**; ->> create schema **sources**; ->> create schema **qa_tests**; ->> create schema **vocabulary_pack**; ->> create schema **admin_pack**; +# Creating Functions -## Creating Functions +## devv5 -### devv5 - -- GenericUpdate() - [Vocabulary-v5.0/working/generic_update.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/generic_update.sql) - GenericUpdate_LE.sql +- GenericUpdate_LE.sql - FastRecreateSchema() [Vocabulary-v5.0/working/fast_recreate_schema.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/fast_recreate_schema.sql) - GetPrimaryRelationshipID() [Vocabulary-v5.0/working/packages/admin_pack/GetPrimaryRelationshipID.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/GetPrimaryRelationshipID.sql) - Functions from [Vocabulary-v5.0/working/packages/DevV5_additional_functions at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/tree/master/working/packages/DevV5_additional_functions) -### vocabulary_pack +## vocabulary_pack - DropFKConstraints() [Vocabulary-v5.0/working/packages/vocabulary_pack/DropFKConstraints.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DropFKConstraints.sql) @@ -52,15 +51,16 @@ PostgreSQL 14 or higher. [Vocabulary-v5.0/working/packages/vocabulary_pack/DeleteAmbiguousMapsTo.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DeleteAmbiguousMapsTo.sql) -### qa_tests +## qa_tests - Functions from [Vocabulary-v5.0/working/packages/QA_TESTS at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/tree/master/working/packages/QA_TESTS) -### admin_pack +## admin_pack + +Create extensions: +>CREATE EXTENSION pgcrypto; +>CREATE EXTENSION tablefunc; -- Create extensions: - CREATE EXTENSION pgcrypto; - CREATE EXTENSION tablefunc; - admin_pack_ddl.sql [Vocabulary-v5.0/working/packages/admin_pack/admin_pack_ddl.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/admin_pack_ddl.sql) - VirtualLogIn() @@ -84,71 +84,80 @@ PostgreSQL 14 or higher. - CreatePrivilege() [Vocabulary-v5.0/working/packages/admin_pack/CreatePrivilege.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CreatePrivilege.sql) -## Creating Tables +# Creating Tables The next four columns are for internal use only, so they should be excluded from the DevV5_DDL script before execution (from **base_concept_relationship_manual**, **base_concept_manual**, **base_concept_synonym_manual** tables): - - created - created_by - modified - modified_by -### Devv5 +## Devv5 In case the table structure already exists in the database, this part can be skipped. -When tables are created for the first time, everything should be executed from the DevV5_DDL.sql script except creating constraints and indexes so that they do not interfere with the import of vocabularies from Athena. +When tables are created for the first time, everything should be executed from the script except creating constraints and indexes so that they do not interfere with the import of vocabularies from Athena. - DevV5_DDL.sql -[Vocabulary-v5.0/working/DevV5_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) -Or just run this script [DevV5_tables_DDL.sql] (https://github.com/OHDSI/Vocabulary-v5.0/blob/master/local_environment/DevV5_tables_DDL.sql) + [Vocabulary-v5.0/working/DevV5_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) + Or just run this script \[DevV5_tables_DDL.sql\] () - Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) -### dev_schema_name +## dev_schema_name - DevV5_DDL.sql [Vocabulary-v5.0/working/DevV5_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) - Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) -### Update Vocabulary table structure +## Update Vocabulary table structure If the table structure was created before 03/04/2024, the following script should be run: -- [2024-03-04.sql] -(https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/manual_changes/2024/2024-03-04.sql) +- 2024-03-04.sql (working/manual_changes/2024/2024-03-04.sql) ## sources Creating source tables according to instructions for your vocabulary. -## Import Vocabulary Data from Athena +# Import Vocabulary Data from Athena -To initially fill out the vocabulary tables, it needs to download the necessary vocabularies from [Athena (ohdsi.org)](https://athena.ohdsi.org/vocabulary/list) and import them using the “copy” command. +To initially fill out the vocabulary tables, it needs to download the necessary vocabularies from [Athena (ohdsi.org)](https://athena.ohdsi.org/vocabulary/list) and import them using the “copy” command in psql. -The data should be imported to the tables in devv5 schema. +Also there is the video instruction how to do it using DBeaver: -Before importing dictionaries from CSV files, the client encoding should be set to “UTF8”: +[Demo: Getting Vocabularies Into My OMOP CDM (Michael Kallfelz • Nov. 9 OHDSI Community Call) (youtube.com)](https://www.youtube.com/watch?v=FCHxAQOBptE) -SET client_encoding = ‘UTF8’; +The data should be imported to the tables in **devv5** schema. -The “COPY” command to import data from CSV files in psql: +Before importing dictionaries from CSV files, the client encoding should be set to “UTF8” (psql): +>SET client_encoding = ‘UTF8’; ->> \\COPY <table_name> FROM '<path_to_csv_file>\\DRUG_STRENGTH.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b' ; -Additional inserts that may be needed before creating constraints are here (import languages to the concept table): -[Import_Languages.sql] (https://github.com/OHDSI/Vocabulary-v5.0/blob/master/local_environment/Import_Languages.sql) +The “COPY” command to import data from CSV files (psql): + +>COPY DRUG_STRENGTH FROM '<path_to_csv_file>\\DRUG_STRENGTH.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +>COPY CONCEPT FROM '<path_to_csv_file>\\CONCEPT.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +>COPY CONCEPT_RELATIONSHIP FROM '<path_to_csv_file>\\CONCEPT_RELATIONSHIP.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +>COPY CONCEPT_ANCESTOR FROM '<path_to_csv_file>\\CONCEPT_ANCESTOR.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +>COPY CONCEPT_SYNONYM FROM '<path_to_csv_file>\\CONCEPT_SYNONYM.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +>COPY VOCABULARY FROM '<path_to_csv_file>\\VOCABULARY.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +>COPY RELATIONSHIP FROM '<path_to_csv_file>\\RELATIONSHIP.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +>COPY CONCEPT_CLASS FROM '<path_to_csv_file>\\CONCEPT_CLASS.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +>COPY DOMAIN FROM '<path_to_csv_file>\\DOMAIN.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; After all the data has been imported, it is necessary to create constraints and indexes from the DevV5_DDL.sql, mentioned above, or use this script: -[DevV5_constraints_DDL.sql] (https://github.com/OHDSI/Vocabulary-v5.0/blob/master/local_environment/DevV5_constraints_DDL.sql) -## Import Source Data +**DevV5_constraints_DDL.sql +** + +# Import Source Data Filling out source tables according to instructions for a vocabulary. -## Start the Vocabulary Development Process +# Start the Vocabulary Development Process 1. **devv5**.FastRecreateSchema() 2. Load_Stage in **dev_schema_name** 3. **qa_tests**.check_stage_tables() 4. **devv5**.GenericUpdate -5. **qa_tests**.get_\* functions \ No newline at end of file +5. **qa_tests**.get_\* functions From f5c855cf11a348d675ce4a2d02a7e43e9f689e8b Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Wed, 3 Apr 2024 17:07:49 +0300 Subject: [PATCH 03/18] Fix README.md --- working/local_environment/README.md | 13 ++++++++++--- 1 file changed, 10 insertions(+), 3 deletions(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index e266797ec..387749e34 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -136,19 +136,26 @@ Before importing dictionaries from CSV files, the client encoding should be set The “COPY” command to import data from CSV files (psql): >COPY DRUG_STRENGTH FROM '<path_to_csv_file>\\DRUG_STRENGTH.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +> >COPY CONCEPT FROM '<path_to_csv_file>\\CONCEPT.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +> >COPY CONCEPT_RELATIONSHIP FROM '<path_to_csv_file>\\CONCEPT_RELATIONSHIP.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +> >COPY CONCEPT_ANCESTOR FROM '<path_to_csv_file>\\CONCEPT_ANCESTOR.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +> >COPY CONCEPT_SYNONYM FROM '<path_to_csv_file>\\CONCEPT_SYNONYM.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +> >COPY VOCABULARY FROM '<path_to_csv_file>\\VOCABULARY.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +> >COPY RELATIONSHIP FROM '<path_to_csv_file>\\RELATIONSHIP.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +> >COPY CONCEPT_CLASS FROM '<path_to_csv_file>\\CONCEPT_CLASS.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; +> >COPY DOMAIN FROM '<path_to_csv_file>\\DOMAIN.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; After all the data has been imported, it is necessary to create constraints and indexes from the DevV5_DDL.sql, mentioned above, or use this script: - -**DevV5_constraints_DDL.sql -** +**DevV5_constraints_DDL.sql** + # Import Source Data From 4d56aef91cd4480a299db6b94acd69465f1764b6 Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Wed, 3 Apr 2024 17:08:49 +0300 Subject: [PATCH 04/18] Update README.md --- working/local_environment/README.md | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 387749e34..a93f76140 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -11,11 +11,11 @@ PostgreSQL 14 or higher. # Creating Schemas Create schemas: >-- replace with an actual schema name: ->CREATE SCHEMA ; ->CREATE SCHEMA devv5; ->CREATE SCHEMA sources; ->CREATE SCHEMA qa_tests; ->CREATE SCHEMA vocabulary_pack; +>CREATE SCHEMA ; +>CREATE SCHEMA devv5; +>CREATE SCHEMA sources; +>CREATE SCHEMA qa_tests; +>CREATE SCHEMA vocabulary_pack; >CREATE SCHEMA admin_pack; # Creating Functions From 4ad9b3fe56368ed0def7beebc8db7511c4fce9a1 Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Thu, 4 Apr 2024 16:17:30 +0300 Subject: [PATCH 05/18] Update README.md --- working/local_environment/README.md | 27 +++++++++++++++++---------- 1 file changed, 17 insertions(+), 10 deletions(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index a93f76140..112ccdff7 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -9,7 +9,9 @@ This document describes the local database preparation that needs to be done for PostgreSQL 14 or higher. # Creating Schemas -Create schemas: + +As an initial step, it needs to create schemas in the database. +It is also necessary to give an appropriate name to a schema for the vocabulary development process (e.g. **dev_hemonc** for the HemOnc vocabulary). >-- replace with an actual schema name: >CREATE SCHEMA ; >CREATE SCHEMA devv5; @@ -20,9 +22,12 @@ Create schemas: # Creating Functions +This section describes the features and procedures that should be installed in the database in the appropriate schemas. + ## devv5 -- GenericUpdate_LE.sql +- GenericUpdate_LE.sql (a version of the GenericUpdate function for a local environment) + [Vocabulary-v5.0/working/local_environment/GenericUpdate_LE.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/local_environment/GenericUpdate_LE.sql) - FastRecreateSchema() [Vocabulary-v5.0/working/fast_recreate_schema.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/fast_recreate_schema.sql) - GetPrimaryRelationshipID() [Vocabulary-v5.0/working/packages/admin_pack/GetPrimaryRelationshipID.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/GetPrimaryRelationshipID.sql) @@ -57,6 +62,7 @@ Create schemas: ## admin_pack +Pgcrypto and Tablefunc extensions should be installed for some functions to work correctly. Create extensions: >CREATE EXTENSION pgcrypto; >CREATE EXTENSION tablefunc; @@ -98,21 +104,21 @@ In case the table structure already exists in the database, this part can be ski When tables are created for the first time, everything should be executed from the script except creating constraints and indexes so that they do not interfere with the import of vocabularies from Athena. -- DevV5_DDL.sql +- DevV5_DDL.sql without created, created_by, modified, modified_by fields [Vocabulary-v5.0/working/DevV5_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) - Or just run this script \[DevV5_tables_DDL.sql\] () + Or just run this script [Vocabulary-v5.0/working/local_environment/DevV5_tables_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)] (https://github.com/OHDSI/Vocabulary-v5.0/blob/master/local_environment/DevV5_tables_DDL.sql) - Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) -## dev_schema_name +## development schema -- DevV5_DDL.sql +- DevV5_DDL.sql without created, created_by, modified, modified_by fields [Vocabulary-v5.0/working/DevV5_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) + Or just run this script [Vocabulary-v5.0/working/local_environment/DevV5_tables_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)] (https://github.com/OHDSI/Vocabulary-v5.0/blob/master/local_environment/DevV5_tables_DDL.sql) - Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) ## Update Vocabulary table structure If the table structure was created before 03/04/2024, the following script should be run: - - 2024-03-04.sql (working/manual_changes/2024/2024-03-04.sql) ## sources @@ -123,8 +129,11 @@ Creating source tables according to instructions for your vocabulary. To initially fill out the vocabulary tables, it needs to download the necessary vocabularies from [Athena (ohdsi.org)](https://athena.ohdsi.org/vocabulary/list) and import them using the “copy” command in psql. -Also there is the video instruction how to do it using DBeaver: +The following vocabularies have to be installed: +- SNOMED +- (TBD) +Also there is the video instruction how to do it using DBeaver: [Demo: Getting Vocabularies Into My OMOP CDM (Michael Kallfelz • Nov. 9 OHDSI Community Call) (youtube.com)](https://www.youtube.com/watch?v=FCHxAQOBptE) The data should be imported to the tables in **devv5** schema. @@ -132,9 +141,7 @@ The data should be imported to the tables in **devv5** schema. Before importing dictionaries from CSV files, the client encoding should be set to “UTF8” (psql): >SET client_encoding = ‘UTF8’; - The “COPY” command to import data from CSV files (psql): - >COPY DRUG_STRENGTH FROM '<path_to_csv_file>\\DRUG_STRENGTH.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; > >COPY CONCEPT FROM '<path_to_csv_file>\\CONCEPT.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; From 2d6375def29f961d5d87f6eac1a52747f8cc364a Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Thu, 4 Apr 2024 16:23:18 +0300 Subject: [PATCH 06/18] Update README.md --- working/local_environment/README.md | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 112ccdff7..34ba6b934 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -106,14 +106,14 @@ When tables are created for the first time, everything should be executed from t - DevV5_DDL.sql without created, created_by, modified, modified_by fields [Vocabulary-v5.0/working/DevV5_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) - Or just run this script [Vocabulary-v5.0/working/local_environment/DevV5_tables_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)] (https://github.com/OHDSI/Vocabulary-v5.0/blob/master/local_environment/DevV5_tables_DDL.sql) + Or just run this script DevV5_tables_DDL.sql from this folder - Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) ## development schema - DevV5_DDL.sql without created, created_by, modified, modified_by fields - [Vocabulary-v5.0/working/DevV5_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) - Or just run this script [Vocabulary-v5.0/working/local_environment/DevV5_tables_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)] (https://github.com/OHDSI/Vocabulary-v5.0/blob/master/local_environment/DevV5_tables_DDL.sql) + [Vocabulary-v5.0/working/DevV5_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) + Or just run this script DevV5_tables_DDL.sql from this folder - Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) ## Update Vocabulary table structure @@ -166,7 +166,7 @@ After all the data has been imported, it is necessary to create constraints and # Import Source Data -Filling out source tables according to instructions for a vocabulary. +Filling out source tables according to instructions for vocabulary you are going to work. # Start the Vocabulary Development Process From 2c9cc508e22f240a0a09dc73bae836db77c18ef5 Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Mon, 15 Apr 2024 16:01:00 +0300 Subject: [PATCH 07/18] Update README.md --- working/local_environment/README.md | 42 +++++++---------------------- 1 file changed, 9 insertions(+), 33 deletions(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 34ba6b934..243678930 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -8,6 +8,13 @@ This document describes the local database preparation that needs to be done for PostgreSQL 14 or higher. +# Creating Extensions + +Pgcrypto and Tablefunc extensions should be installed for some functions to work correctly. +Create extensions: +>CREATE EXTENSION pg_trgm; +>CREATE EXTENSION tablefunc; + # Creating Schemas As an initial step, it needs to create schemas in the database. @@ -60,36 +67,6 @@ This section describes the features and procedures that should be installed in t - Functions from [Vocabulary-v5.0/working/packages/QA_TESTS at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/tree/master/working/packages/QA_TESTS) -## admin_pack - -Pgcrypto and Tablefunc extensions should be installed for some functions to work correctly. -Create extensions: ->CREATE EXTENSION pgcrypto; ->CREATE EXTENSION tablefunc; - -- admin_pack_ddl.sql - [Vocabulary-v5.0/working/packages/admin_pack/admin_pack_ddl.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/admin_pack_ddl.sql) -- VirtualLogIn() - [Vocabulary-v5.0/working/packages/admin_pack/VirtualLogIn.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/VirtualLogIn.sql) -- CreateVirtualUser() - [Vocabulary-v5.0/working/packages/admin_pack/CreateVirtualUser.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CreateVirtualUser.sql) -- CheckUserPrivilege() - [Vocabulary-v5.0/working/packages/admin_pack/CheckUserPrivilege.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CheckUserPrivilege.sql) -- GetUserID() - [Vocabulary-v5.0/working/packages/admin_pack/GetUserID.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/GetUserID.sql) -- CheckEmailCharacters() - [Vocabulary-v5.0/working/packages/admin_pack/CheckEmailCharacters.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CheckEmailCharacters.sql) -- CheckLoginCharacters() - [Vocabulary-v5.0/working/packages/admin_pack/CheckLoginCharacters.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CheckLoginCharacters.sql) -- CheckPasswordStrength() - [Vocabulary-v5.0/working/packages/admin_pack/CheckPasswordStrength.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CheckPasswordStrength.sql) -- CheckPrivilegeCharacters() - [Vocabulary-v5.0/working/packages/admin_pack/CheckPrivilegeCharacters.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CheckPrivilegeCharacters.sql) -- CheckUserSpecificVocabulary() - [Vocabulary-v5.0/working/packages/admin_pack/CheckUserSpecificVocabulary.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CheckUserSpecificVocabulary.sql) -- CreatePrivilege() - [Vocabulary-v5.0/working/packages/admin_pack/CreatePrivilege.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/CreatePrivilege.sql) - # Creating Tables The next four columns are for internal use only, so they should be excluded from the DevV5_DDL script before execution (from **base_concept_relationship_manual**, **base_concept_manual**, **base_concept_synonym_manual** tables): @@ -172,6 +149,5 @@ Filling out source tables according to instructions for vocabulary you are going 1. **devv5**.FastRecreateSchema() 2. Load_Stage in **dev_schema_name** -3. **qa_tests**.check_stage_tables() -4. **devv5**.GenericUpdate -5. **qa_tests**.get_\* functions +3. **devv5**.GenericUpdate +4. **qa_tests**.get_\* functions From 1fa9937f4f1aef5b16de35d4839ce8d5af1010bf Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Mon, 15 Apr 2024 17:03:10 +0300 Subject: [PATCH 08/18] Update README.md --- working/local_environment/README.md | 1 + 1 file changed, 1 insertion(+) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 243678930..7f12e0798 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -14,6 +14,7 @@ Pgcrypto and Tablefunc extensions should be installed for some functions to work Create extensions: >CREATE EXTENSION pg_trgm; >CREATE EXTENSION tablefunc; +>CREATE EXTENSION plpython3u; # Creating Schemas From d03f1458930cc152d1714bb2cb0c63c6cd84b1f5 Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Mon, 15 Apr 2024 17:03:27 +0300 Subject: [PATCH 09/18] Update README.md --- working/local_environment/README.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 7f12e0798..2d98d598d 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -13,7 +13,7 @@ PostgreSQL 14 or higher. Pgcrypto and Tablefunc extensions should be installed for some functions to work correctly. Create extensions: >CREATE EXTENSION pg_trgm; ->CREATE EXTENSION tablefunc; +>CREATE EXTENSION tablefunc; >CREATE EXTENSION plpython3u; # Creating Schemas From be35024fd6292c2138ef116b61afa7f6919cf5d1 Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Thu, 18 Apr 2024 14:08:26 +0300 Subject: [PATCH 10/18] Update README.md --- working/local_environment/README.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 2d98d598d..68cb13111 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -1,4 +1,4 @@ -Preparing a Local Environment for the Vocabulary Development Process +# Preparing a Local Environment for the Vocabulary Development Process # Description From f27cd7014e2a27116043d2869cc4a79208e91c74 Mon Sep 17 00:00:00 2001 From: AlaikseiKatyshou Date: Thu, 18 Apr 2024 15:45:04 +0300 Subject: [PATCH 11/18] Modify the instruction: - update README.md - delete unnecessary DDL files - delete custom GenericUpdate_LE - update generic_update() for local env --- working/generic_update.sql | 8 +- .../DevV5_constraints_DDL.sql | 77 -- .../local_environment/DevV5_tables_DDL.sql | 280 ----- .../local_environment/GenericUpdate_LE.sql | 1095 ----------------- working/local_environment/README.md | 46 +- 5 files changed, 25 insertions(+), 1481 deletions(-) delete mode 100644 working/local_environment/DevV5_constraints_DDL.sql delete mode 100644 working/local_environment/DevV5_tables_DDL.sql delete mode 100644 working/local_environment/GenericUpdate_LE.sql diff --git a/working/generic_update.sql b/working/generic_update.sql index 33811c8dd..06582c81d 100644 --- a/working/generic_update.sql +++ b/working/generic_update.sql @@ -28,7 +28,7 @@ BEGIN END $$; --1.3 Start logging manual work - PERFORM admin_pack.LogManualChanges(); + /*PERFORM admin_pack.LogManualChanges();*/ --1.4 Clear concept_id's just in case UPDATE concept_stage @@ -243,8 +243,8 @@ BEGIN SELECT concept_id, LEAD (concept_id) OVER (ORDER BY concept_id) next_id FROM ( SELECT concept_id FROM concept - UNION ALL - SELECT concept_id FROM devv5.concept_blacklisted --blacklisted concept_id's (AVOF-2395) + /*UNION ALL + SELECT concept_id FROM devv5.concept_blacklisted*/ --blacklisted concept_id's (AVOF-2395) ) AS i WHERE concept_id >= 581480 AND concept_id < 500000000 ) AS t @@ -1083,7 +1083,7 @@ BEGIN ANALYZE concept_synonym; --36. Update concept_id fields in the "basic" manual tables for storing in audit - PERFORM admin_pack.UpdateManualConceptID(); + /*PERFORM admin_pack.UpdateManualConceptID();*/ --QA (should return NULL) --SELECT * FROM QA_TESTS.GET_CHECKS(); diff --git a/working/local_environment/DevV5_constraints_DDL.sql b/working/local_environment/DevV5_constraints_DDL.sql deleted file mode 100644 index 3f39ae428..000000000 --- a/working/local_environment/DevV5_constraints_DDL.sql +++ /dev/null @@ -1,77 +0,0 @@ - ---Create PKs -ALTER TABLE concept ADD CONSTRAINT xpk_concept PRIMARY KEY (concept_id); -ALTER TABLE vocabulary ADD CONSTRAINT xpk_vocabulary PRIMARY KEY (vocabulary_id); -ALTER TABLE domain ADD CONSTRAINT xpk_domain PRIMARY KEY (domain_id); -ALTER TABLE concept_class ADD CONSTRAINT xpk_concept_class PRIMARY KEY (concept_class_id); -ALTER TABLE concept_relationship ADD CONSTRAINT xpk_concept_relationship PRIMARY KEY (concept_id_1,concept_id_2,relationship_id); -ALTER TABLE relationship ADD CONSTRAINT xpk_relationship PRIMARY KEY (relationship_id); -ALTER TABLE concept_ancestor ADD CONSTRAINT xpkconcept_ancestor PRIMARY KEY (ancestor_concept_id,descendant_concept_id); -ALTER TABLE drug_strength ADD CONSTRAINT xpk_drug_strength PRIMARY KEY (drug_concept_id, ingredient_concept_id); - ---Create external keys -ALTER TABLE concept ADD CONSTRAINT fpk_concept_domain FOREIGN KEY (domain_id) REFERENCES domain (domain_id); -ALTER TABLE concept ADD CONSTRAINT fpk_concept_class FOREIGN KEY (concept_class_id) REFERENCES concept_class (concept_class_id); -ALTER TABLE concept ADD CONSTRAINT fpk_concept_vocabulary FOREIGN KEY (vocabulary_id) REFERENCES vocabulary (vocabulary_id); -ALTER TABLE vocabulary ADD CONSTRAINT fpk_vocabulary_concept FOREIGN KEY (vocabulary_concept_id) REFERENCES concept (concept_id); -ALTER TABLE domain ADD CONSTRAINT fpk_domain_concept FOREIGN KEY (domain_concept_id) REFERENCES concept (concept_id); -ALTER TABLE concept_class ADD CONSTRAINT fpk_concept_class_concept FOREIGN KEY (concept_class_concept_id) REFERENCES concept (concept_id); -ALTER TABLE concept_relationship ADD CONSTRAINT fpk_concept_relationship_c_1 FOREIGN KEY (concept_id_1) REFERENCES concept (concept_id); -ALTER TABLE concept_relationship ADD CONSTRAINT fpk_concept_relationship_c_2 FOREIGN KEY (concept_id_2) REFERENCES concept (concept_id); -ALTER TABLE concept_relationship ADD CONSTRAINT fpk_concept_relationship_id FOREIGN KEY (relationship_id) REFERENCES relationship (relationship_id); -ALTER TABLE relationship ADD CONSTRAINT fpk_relationship_concept FOREIGN KEY (relationship_concept_id) REFERENCES concept (concept_id); -ALTER TABLE relationship ADD CONSTRAINT fpk_relationship_reverse FOREIGN KEY (reverse_relationship_id) REFERENCES relationship (relationship_id); -ALTER TABLE concept_synonym ADD CONSTRAINT fpk_concept_synonym_concept FOREIGN KEY (concept_id) REFERENCES concept (concept_id); -ALTER TABLE concept_synonym ADD CONSTRAINT fpk_concept_synonym_language FOREIGN KEY (language_concept_id) REFERENCES concept (concept_id); -ALTER TABLE concept_synonym ADD CONSTRAINT unique_synonyms UNIQUE (concept_id,concept_synonym_name,language_concept_id); -ALTER TABLE drug_strength ADD CONSTRAINT fpk_drug_strength_concept_1 FOREIGN KEY (drug_concept_id) REFERENCES concept (concept_id); -ALTER TABLE drug_strength ADD CONSTRAINT fpk_drug_strength_concept_2 FOREIGN KEY (ingredient_concept_id) REFERENCES concept (concept_id); -ALTER TABLE drug_strength ADD CONSTRAINT fpk_drug_strength_unit_1 FOREIGN KEY (amount_unit_concept_id) REFERENCES concept (concept_id); -ALTER TABLE drug_strength ADD CONSTRAINT fpk_drug_strength_unit_2 FOREIGN KEY (numerator_unit_concept_id) REFERENCES concept (concept_id); -ALTER TABLE drug_strength ADD CONSTRAINT fpk_drug_strength_unit_3 FOREIGN KEY (denominator_unit_concept_id) REFERENCES concept (concept_id); -ALTER TABLE pack_content ADD CONSTRAINT fpk_pack_content_concept_1 FOREIGN KEY (pack_concept_id) REFERENCES concept (concept_id); -ALTER TABLE pack_content ADD CONSTRAINT fpk_pack_content_concept_2 FOREIGN KEY (drug_concept_id) REFERENCES concept (concept_id); -ALTER TABLE concept_relationship_manual ADD CONSTRAINT unique_manual_relationships UNIQUE (concept_code_1,concept_code_2,vocabulary_id_1,vocabulary_id_2,relationship_id); -ALTER TABLE concept_manual ADD CONSTRAINT unique_manual_concepts UNIQUE (vocabulary_id,concept_code); -ALTER TABLE concept_synonym_manual ADD CONSTRAINT unique_manual_synonyms UNIQUE (synonym_name,synonym_concept_code,synonym_vocabulary_id,language_concept_id); - ---Create indexes -CREATE UNIQUE INDEX idx_unique_concept_code ON concept (vocabulary_id, concept_code) WHERE vocabulary_id NOT IN ('DRG', 'SMQ') AND concept_code <> 'OMOP generated'; -/* - We need index listed below for queries like "SELECT * FROM concept WHERE vocabulary_id='xxx'". - Previous unique index only to support unique pairs of voabulary_id+concept_code with some exceptions -*/ -CREATE INDEX idx_vocab_concept_code ON concept (vocabulary_id varchar_pattern_ops, concept_code); -CREATE INDEX idx_concept_relationship_id_2 ON concept_relationship (concept_id_2); -CREATE INDEX idx_concept_synonym_id ON concept_synonym (concept_id); -CREATE INDEX idx_csyn_concept_syn_name ON concept_synonym (concept_synonym_name); -CREATE INDEX idx_drug_strength_id_1 ON drug_strength (drug_concept_id); -CREATE INDEX idx_drug_strength_id_2 ON drug_strength (ingredient_concept_id); -CREATE INDEX idx_pack_content_id_2 ON pack_content (drug_concept_id); -CREATE UNIQUE INDEX u_pack_content ON pack_content (pack_concept_id, drug_concept_id, COALESCE(amount,-1)); -ALTER TABLE concept_stage ADD CONSTRAINT idx_pk_cs PRIMARY KEY (concept_code,vocabulary_id); -CREATE INDEX idx_cs_concept_id ON concept_stage (concept_id); -ALTER TABLE concept_relationship_stage ADD CONSTRAINT idx_pk_crs PRIMARY KEY (concept_code_1,concept_code_2,vocabulary_id_1,vocabulary_id_2,relationship_id); -CREATE INDEX idx_concept_code_2 ON concept_relationship_stage (concept_code_2); -ALTER TABLE concept_synonym_stage ADD CONSTRAINT idx_pk_css PRIMARY KEY (synonym_vocabulary_id,synonym_name,synonym_concept_code,language_concept_id); -CREATE INDEX idx_dss_concept_code ON drug_strength_stage (drug_concept_code); -CREATE INDEX idx_ca_descendant ON concept_ancestor (descendant_concept_id); -CREATE UNIQUE INDEX xpk_vocab_conversion ON vocabulary_conversion (vocabulary_id_v5); -CREATE INDEX idx_base_crm_cid1 ON base_concept_relationship_manual (concept_id_1) WHERE concept_id_1=0; -CREATE INDEX idx_base_crm_cid2 ON base_concept_relationship_manual (concept_id_2) WHERE concept_id_2=0; -CREATE INDEX idx_base_cm_cid ON base_concept_manual (concept_id) WHERE concept_id=0; -CREATE INDEX idx_base_csm_cid ON base_concept_synonym_manual (concept_id) WHERE concept_id=0; - ---Create checks -ALTER TABLE concept ADD CONSTRAINT chk_c_concept_name CHECK (concept_name <> ''); -ALTER TABLE concept ADD CONSTRAINT chk_c_standard_concept CHECK (COALESCE(standard_concept,'C') in ('C','S')); -ALTER TABLE concept ADD CONSTRAINT chk_c_concept_code CHECK (concept_code <> ''); -ALTER TABLE concept ADD CONSTRAINT chk_c_invalid_reason CHECK (COALESCE(invalid_reason,'D') in ('D','U')); -ALTER TABLE concept_relationship ADD CONSTRAINT chk_cr_invalid_reason CHECK (COALESCE(invalid_reason,'D')='D'); -ALTER TABLE concept_synonym ADD CONSTRAINT chk_csyn_concept_synonym_name CHECK (concept_synonym_name <> ''); -ALTER TABLE concept_manual ADD CONSTRAINT chk_cmnl_concept_name CHECK (concept_name <> ''); -ALTER TABLE concept_manual ADD CONSTRAINT chk_cmnl_concept_code CHECK (concept_code <> ''); -ALTER TABLE concept_synonym_manual ADD CONSTRAINT chk_csynmnl_concept_synonym_name CHECK (synonym_name <> ''); -ALTER TABLE concept_relationship_manual ADD CONSTRAINT chk_crm_invalid_reason CHECK (COALESCE(invalid_reason,'D')='D'); -ALTER TABLE concept_relationship_manual ADD CONSTRAINT chk_crm_concept_code_1 CHECK (concept_code_1 <> ''); -ALTER TABLE concept_relationship_manual ADD CONSTRAINT chk_crm_concept_code_2 CHECK (concept_code_2 <> ''); \ No newline at end of file diff --git a/working/local_environment/DevV5_tables_DDL.sql b/working/local_environment/DevV5_tables_DDL.sql deleted file mode 100644 index 8a602bdb7..000000000 --- a/working/local_environment/DevV5_tables_DDL.sql +++ /dev/null @@ -1,280 +0,0 @@ -/************************************************************************** -* Copyright 2016 Observational Health Data Sciences and Informatics (OHDSI) -* -* Licensed under the Apache License, Version 2.0 (the License); -* you may not use this file except in compliance with the License. -* You may obtain a copy of the License at -* -* http://www.apache.org/licenses/LICENSE-2.0 -* -* Unless required by applicable law or agreed to in writing, software -* distributed under the License is distributed on an AS IS BASIS, -* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. -* See the License for the specific language governing permissions and -* limitations under the License. -* -* Authors: Timur Vakhitov -* Date: 2020 -**************************************************************************/ - ---Main DDL - -DROP TABLE IF EXISTS concept CASCADE; -CREATE TABLE concept ( - concept_id int4 NOT NULL, - concept_name VARCHAR (255) NOT NULL, - domain_id VARCHAR (20) NOT NULL, - vocabulary_id VARCHAR (20) NOT NULL, - concept_class_id VARCHAR (20) NOT NULL, - standard_concept VARCHAR (1), - concept_code VARCHAR (50) NOT NULL, - valid_start_date DATE NOT NULL, - valid_end_date DATE NOT NULL, - invalid_reason VARCHAR (1) -); - -DROP TABLE IF EXISTS concept_relationship CASCADE; -CREATE TABLE concept_relationship ( - concept_id_1 int4 NOT NULL, - concept_id_2 int4 NOT NULL, - relationship_id VARCHAR (20) NOT NULL, - valid_start_date DATE NOT NULL, - valid_end_date DATE NOT NULL, - invalid_reason VARCHAR (1) -); - -DROP TABLE IF EXISTS concept_synonym CASCADE; -CREATE TABLE concept_synonym ( - concept_id int4 NOT NULL, - concept_synonym_name VARCHAR (1000) NOT NULL, - language_concept_id int4 NOT NULL -); - -DROP TABLE IF EXISTS concept_ancestor CASCADE; -CREATE TABLE concept_ancestor ( - ancestor_concept_id int4 NOT NULL, - descendant_concept_id int4 NOT NULL, - min_levels_of_separation int4 NOT NULL, - max_levels_of_separation int4 NOT NULL -); - -DROP TABLE IF EXISTS relationship CASCADE; -CREATE TABLE relationship ( - relationship_id VARCHAR (20) NOT NULL, - relationship_name VARCHAR (255) NOT NULL UNIQUE, - is_hierarchical int NOT NULL, - defines_ancestry int2 NOT NULL, - reverse_relationship_id VARCHAR (20) NOT NULL, - relationship_concept_id int4 NOT NULL -); - -DROP TABLE IF EXISTS vocabulary CASCADE; -CREATE TABLE vocabulary ( - vocabulary_id VARCHAR (20) NOT NULL, - vocabulary_name VARCHAR (255) NOT NULL, - vocabulary_reference VARCHAR (255) NOT NULL, - vocabulary_version VARCHAR (255), - vocabulary_concept_id int4 NOT NULL, - latest_update DATE, --service field (new update date for using in load_stage/functions/generic_update) - dev_schema_name TEXT, --service field (the name of the schema where manual changes come from if the script is run in the devv5) - vocabulary_params JSONB --service field (for storing additional params) -); - -DROP TABLE IF EXISTS vocabulary_conversion CASCADE; -CREATE TABLE vocabulary_conversion ( - vocabulary_id_v4 int4 PRIMARY KEY, - vocabulary_id_v5 VARCHAR (20), - omop_req VARCHAR (1), - click_default VARCHAR (1), - available VARCHAR (25), - url VARCHAR (256), - click_disabled VARCHAR (1), - latest_update DATE -); - -DROP TABLE IF EXISTS relationship_conversion CASCADE; -CREATE TABLE relationship_conversion ( - relationship_id int2 NOT NULL, - relationship_id_new VARCHAR (20) NOT NULL -); - -DROP TABLE IF EXISTS concept_class_conversion CASCADE; -CREATE TABLE concept_class_conversion -( - concept_class VARCHAR (50) NOT NULL, - concept_class_id_new VARCHAR (20) NOT NULL -); - -DROP TABLE IF EXISTS concept_class CASCADE; -CREATE TABLE concept_class ( - concept_class_id VARCHAR (20) NOT NULL, - concept_class_name VARCHAR (255) NOT NULL, - concept_class_concept_id int4 NOT NULL -); - -DROP TABLE IF EXISTS domain CASCADE; -CREATE TABLE domain ( - domain_id VARCHAR (20) NOT NULL, - domain_name VARCHAR (255) NOT NULL, - domain_concept_id int4 NOT NULL -); - -DROP TABLE IF EXISTS drug_strength CASCADE; -CREATE TABLE drug_strength ( - drug_concept_id int4 NOT NULL, - ingredient_concept_id int4 NOT NULL, - amount_value NUMERIC, - amount_unit_concept_id int4, - numerator_value NUMERIC, - numerator_unit_concept_id int4, - denominator_value NUMERIC, - denominator_unit_concept_id int4, - box_size int2, - valid_start_date DATE NOT NULL, - valid_end_date DATE NOT NULL, - invalid_reason VARCHAR (1) -); - -DROP TABLE IF EXISTS pack_content CASCADE; -CREATE TABLE pack_content ( - pack_concept_id int4 NOT NULL, - drug_concept_id int4 NOT NULL, - amount int2, - box_size int2 -); - -DROP TABLE IF EXISTS concept_stage; -CREATE TABLE concept_stage ( - concept_id int4, - concept_name VARCHAR (255), - domain_id VARCHAR (20), - vocabulary_id VARCHAR (20) NOT NULL, - concept_class_id VARCHAR (20), - standard_concept VARCHAR (1), - concept_code VARCHAR (50) NOT NULL, - valid_start_date DATE NOT NULL, - valid_end_date DATE NOT NULL, - invalid_reason VARCHAR (1) -); - -DROP TABLE IF EXISTS concept_relationship_stage; -CREATE TABLE concept_relationship_stage ( - concept_id_1 int4, - concept_id_2 int4, - concept_code_1 VARCHAR (50) NOT NULL, - concept_code_2 VARCHAR (50) NOT NULL, - vocabulary_id_1 VARCHAR (20) NOT NULL, - vocabulary_id_2 VARCHAR (20) NOT NULL, - relationship_id VARCHAR (20) NOT NULL, - valid_start_date DATE NOT NULL, - valid_end_date DATE NOT NULL, - invalid_reason VARCHAR (1) -); - -DROP TABLE IF EXISTS concept_synonym_stage; -CREATE TABLE concept_synonym_stage ( - synonym_concept_id int4, - synonym_name VARCHAR (1000) NOT NULL, - synonym_concept_code VARCHAR (50) NOT NULL, - synonym_vocabulary_id VARCHAR (20) NOT NULL, - language_concept_id int4 NOT NULL -); - -DROP TABLE IF EXISTS drug_strength_stage; -CREATE TABLE drug_strength_stage ( - drug_concept_code VARCHAR (20) NOT NULL, - vocabulary_id_1 VARCHAR (20) NOT NULL, - ingredient_concept_code VARCHAR (20) NOT NULL, - vocabulary_id_2 VARCHAR (20) NOT NULL, - amount_value NUMERIC, - amount_unit_concept_id int4, - numerator_value NUMERIC, - numerator_unit_concept_id int4, - denominator_value NUMERIC, - denominator_unit_concept_id int4, - valid_start_date DATE NOT NULL, - valid_end_date DATE NOT NULL, - invalid_reason VARCHAR (1) -); - -DROP TABLE IF EXISTS pack_content_stage; -CREATE TABLE pack_content_stage ( - pack_concept_code VARCHAR (20) NOT NULL, - pack_vocabulary_id VARCHAR (20) NOT NULL, - drug_concept_code VARCHAR (20) NOT NULL, - drug_vocabulary_id VARCHAR (20) NOT NULL, - amount int2, - box_size int2 -); - -DROP TABLE IF EXISTS concept_relationship_manual; -CREATE TABLE concept_relationship_manual ( - concept_code_1 VARCHAR (50) NOT NULL, - concept_code_2 VARCHAR (50) NOT NULL, - vocabulary_id_1 VARCHAR (20) NOT NULL, - vocabulary_id_2 VARCHAR (20) NOT NULL, - relationship_id VARCHAR (20) NOT NULL, - valid_start_date DATE NOT NULL, - valid_end_date DATE NOT NULL, - invalid_reason VARCHAR (1) -); - -DROP TABLE IF EXISTS concept_manual; -CREATE TABLE concept_manual ( - concept_name VARCHAR (255), - domain_id VARCHAR (20), - vocabulary_id VARCHAR (20) NOT NULL, - concept_class_id VARCHAR (20), - standard_concept VARCHAR (1), - concept_code VARCHAR (50) NOT NULL, - valid_start_date DATE, - valid_end_date DATE, - invalid_reason VARCHAR (1) -); - -DROP TABLE IF EXISTS concept_synonym_manual; -CREATE TABLE concept_synonym_manual ( - synonym_name VARCHAR (1000) NOT NULL, - synonym_concept_code VARCHAR (50) NOT NULL, - synonym_vocabulary_id VARCHAR (20) NOT NULL, - language_concept_id int4 NOT NULL -); - ---Create a base table for manual relationships, it stores all manual relationships from all vocabularies -DROP TABLE IF EXISTS base_concept_relationship_manual; -CREATE TABLE base_concept_relationship_manual ( - LIKE concept_relationship_manual, - concept_id_1 INT4 NOT NULL, - concept_id_2 INT4 NOT NULL, - CONSTRAINT idx_pk_base_crm PRIMARY KEY ( - concept_code_1, - concept_code_2, - vocabulary_id_1, - vocabulary_id_2, - relationship_id - ) - ); - ---Create a base table for manual concepts, it stores all manual concepts from all vocabularies -DROP TABLE IF EXISTS base_concept_manual CASCADE; -CREATE TABLE base_concept_manual ( - LIKE concept_manual, - concept_id INT4 NOT NULL, - CONSTRAINT idx_pk_base_cm PRIMARY KEY ( - concept_code, - vocabulary_id - ) - ); - ---Create a base table for manual synonyms, it stores all manual synonyms from all vocabularies -DROP TABLE IF EXISTS base_concept_synonym_manual CASCADE; -CREATE TABLE base_concept_synonym_manual ( - LIKE concept_synonym_manual, - concept_id INT4 NOT NULL, - CONSTRAINT idx_pk_base_csm PRIMARY KEY ( - synonym_vocabulary_id, - synonym_name, - synonym_concept_code, - language_concept_id - ) - ); diff --git a/working/local_environment/GenericUpdate_LE.sql b/working/local_environment/GenericUpdate_LE.sql deleted file mode 100644 index 01f452c21..000000000 --- a/working/local_environment/GenericUpdate_LE.sql +++ /dev/null @@ -1,1095 +0,0 @@ --- DROP FUNCTION devv5.genericupdate(); - -CREATE OR REPLACE FUNCTION devv5.genericupdate() - RETURNS void - LANGUAGE plpgsql - SET client_min_messages TO 'error' -AS $function$ -BEGIN - --1. Prerequisites: - --1.1 Check vocabulary table, at least one vocabulary must have the latest_update field set - PERFORM FROM vocabulary WHERE latest_update IS NOT NULL LIMIT 1; - IF NOT FOUND THEN - RAISE EXCEPTION 'At least one vocabulary must have the latest_update field set' - USING HINT = 'Forgot to execute SetLatestUpdate?'; - END IF; - - --1.2 Check stage tables for incorrect rows - DO $$ - DECLARE - z TEXT; - crlf TEXT:=E'\r\n'; - BEGIN - SELECT STRING_AGG(error_text||' [rows_count='||rows_count||']', crlf) INTO z FROM qa_tests.Check_Stage_Tables(); - IF LENGTH(z)>10000 THEN - z:=SUBSTR(z,1,10000)||'... (cut)'; - END IF; - IF z IS NOT NULL THEN - z:=crlf||z||crlf||crlf||'NOTE: You can also run SELECT * FROM qa_tests.Check_Stage_Tables();'; - RAISE EXCEPTION '%', z; - END IF; - END $$; - - --1.3 Start logging manual work - /*PERFORM admin_pack.LogManualChanges();*/ - - --1.4 Clear concept_id's just in case - UPDATE concept_stage - SET concept_id = NULL - WHERE concept_id IS NOT NULL; - - UPDATE concept_relationship_stage - SET concept_id_1 = NULL, - concept_id_2 = NULL - WHERE COALESCE(concept_id_1, concept_id_2) IS NOT NULL; - - UPDATE concept_synonym_stage - SET synonym_concept_id = NULL - WHERE synonym_concept_id IS NOT NULL; - - --2. Make sure that invalid concepts are standard_concept = NULL - UPDATE concept_stage cs - SET standard_concept = NULL - WHERE cs.invalid_reason IS NOT NULL - AND cs.standard_concept IS NOT NULL; - - --3. Make sure invalid_reason = null if the valid_end_date is 31-Dec-2099 - UPDATE concept_stage cs - SET invalid_reason = NULL - WHERE cs.valid_end_date = TO_DATE ('20991231', 'YYYYMMDD') - AND cs.invalid_reason IS NOT NULL; - - --4. Update concept_id in concept_stage from concept for existing concepts - UPDATE concept_stage cs - SET concept_id = c.concept_id - FROM concept c - WHERE cs.concept_code = c.concept_code - AND cs.vocabulary_id = c.vocabulary_id; - - --5. Analyzing - ANALYZE concept_stage; - ANALYZE concept_relationship_stage; - - --6. Clearing the concept_name - --Remove double spaces, carriage return, newline, vertical tab, form feed, unicode spaces - UPDATE concept_stage - SET concept_name = TRIM(REGEXP_REPLACE(concept_name, '[[:cntrl:]\u00a0\u180e\u2007\u200b-\u200f\u202f\u2060\ufeff]+', ' ', 'g')) - WHERE concept_name ~ '[[:cntrl:]\u00a0\u180e\u2007\u200b-\u200f\u202f\u2060\ufeff]'; - - UPDATE concept_stage - SET concept_name = REGEXP_REPLACE(concept_name, ' {2,}', ' ', 'g') - WHERE concept_name ~ ' {2,}'; - - --Remove long dashes - UPDATE concept_stage - SET concept_name = REPLACE(concept_name, '–', '-') - WHERE concept_name LIKE '%–%'; - - --Remove trailing escape character (\) - UPDATE concept_stage - SET concept_name = RTRIM(concept_name, $c$\$c$) - WHERE concept_name LIKE '%\\'; - - --7. Clearing the synonym_name - --Remove double spaces, carriage return, newline, vertical tab and form feed - WITH del - AS ( - DELETE - FROM concept_synonym_stage - WHERE synonym_name ~ '[[:cntrl:]\u00a0\u180e\u2007\u200b-\u200f\u202f\u2060\ufeff]' - RETURNING * - ) - INSERT INTO concept_synonym_stage - SELECT d.synonym_concept_id, - TRIM(REGEXP_REPLACE(d.synonym_name, '[[:cntrl:]\u00a0\u180e\u2007\u200b-\u200f\u202f\u2060\ufeff]+', ' ', 'g')) AS synonym_name, - d.synonym_concept_code, - d.synonym_vocabulary_id, - d.language_concept_id - FROM del d - ON CONFLICT DO NOTHING; - - --Remove double spaces - WITH del - AS ( - DELETE - FROM concept_synonym_stage - WHERE synonym_name ~ ' {2,}' - RETURNING * - ) - INSERT INTO concept_synonym_stage - SELECT d.synonym_concept_id, - REGEXP_REPLACE(d.synonym_name, ' {2,}', ' ', 'g') AS synonym_name, - d.synonym_concept_code, - d.synonym_vocabulary_id, - d.language_concept_id - FROM del d - ON CONFLICT DO NOTHING; - - --Remove long dashes - WITH del - AS ( - DELETE - FROM concept_synonym_stage - WHERE synonym_name LIKE '%–%' - RETURNING * - ) - INSERT INTO concept_synonym_stage - SELECT d.synonym_concept_id, - REPLACE(d.synonym_name, '–', '-') AS synonym_name, - d.synonym_concept_code, - d.synonym_vocabulary_id, - d.language_concept_id - FROM del d - ON CONFLICT DO NOTHING; - - --Remove trailing escape character (\) - WITH del - AS ( - DELETE - FROM concept_synonym_stage - WHERE synonym_name LIKE '%\\' - RETURNING * - ) - INSERT INTO concept_synonym_stage - SELECT d.synonym_concept_id, - RTRIM(d.synonym_name, $c$\$c$) AS synonym_name, - d.synonym_concept_code, - d.synonym_vocabulary_id, - d.language_concept_id - FROM del d - ON CONFLICT DO NOTHING; - - /*************************** - * Update the concept table * - ****************************/ - - --8. Update existing concept details from concept_stage. - --All fields (concept_name, domain_id, concept_class_id, standard_concept, valid_start_date, valid_end_date, invalid_reason) are updated - UPDATE concept c - SET ( - concept_name, - domain_id, - concept_class_id, - standard_concept, - valid_start_date, - valid_end_date, - invalid_reason - ) = ( - cs.concept_name, - cs.domain_id, - cs.concept_class_id, - cs.standard_concept, - CASE - WHEN cs.valid_start_date <> v.latest_update --if we have a real date in the concept_stage, use it. If it is only the release date, use the existing - THEN cs.valid_start_date - ELSE c.valid_start_date - END, - cs.valid_end_date, - cs.invalid_reason - ) - FROM concept_stage cs - JOIN vocabulary v USING (vocabulary_id) - WHERE c.concept_id = cs.concept_id - AND ROW(c.concept_name, c.domain_id, c.concept_class_id, c.standard_concept, c.valid_start_date, c.valid_end_date, c.invalid_reason) - IS DISTINCT FROM - ROW(cs.concept_name, cs.domain_id, cs.concept_class_id, cs.standard_concept, cs.valid_start_date, cs.valid_end_date, cs.invalid_reason); - - --9. Deprecate concepts missing from concept_stage and are not already deprecated. - --This only works for vocabularies where we expect a full set of active concepts in concept_stage. - --If the vocabulary only provides changed concepts, this should not be run, and the update information is already dealt with in step 1. - --20180523: new rule for some vocabularies, see http://forums.ohdsi.org/t/proposal-to-keep-outdated-standard-concepts-active-and-standard/3695/22 and AVOF-981 - --20200730 added ICD10PCS - --9.1. Update the concept for 'regular' vocabularies - UPDATE concept c - SET invalid_reason = 'D', - standard_concept = NULL, - valid_end_date = v.latest_update - 1 - FROM vocabulary v - WHERE c.vocabulary_id = v.vocabulary_id - AND COALESCE(v.vocabulary_params ->> 'is_full', '0') = '1' --all vocabularies that give us a full list of active concepts at each release we can safely assume to deprecate missing ones (in default we will not deprecate) - AND NOT (COALESCE(v.vocabulary_params ->> 'special_deprecation', '0') = '1') - AND v.latest_update IS NOT NULL --only for current vocabularies - AND NOT EXISTS ( - SELECT 1 - FROM concept_stage cs - WHERE cs.concept_id = c.concept_id - AND cs.vocabulary_id = c.vocabulary_id - ) --if concept missing from concept_stage - AND c.invalid_reason IS NULL;--not already deprecated - - --9.2. Update the concept for 'special' vocabs - UPDATE concept c - SET valid_end_date = v.latest_update - 1 - FROM vocabulary v - WHERE c.vocabulary_id = v.vocabulary_id - AND v.vocabulary_params ->> 'special_deprecation' = '1' - AND v.latest_update IS NOT NULL --only for current vocabularies - AND NOT EXISTS ( - SELECT 1 - FROM concept_stage cs - WHERE cs.concept_id = c.concept_id - AND cs.vocabulary_id = c.vocabulary_id - ) --if concept missing from concept_stage - AND c.valid_end_date = TO_DATE('20991231', 'YYYYMMDD');--not already deprecated - - --10. Add new concepts from concept_stage - --Create sequence after last valid one - DO $$ - DECLARE - ex INTEGER; - BEGIN - --SELECT MAX(concept_id)+1 INTO ex FROM concept WHERE concept_id<500000000; -- Last valid below HOI concept_id - DROP SEQUENCE IF EXISTS v5_concept; - SELECT concept_id + 1 INTO ex FROM ( - SELECT concept_id, next_id, next_id - concept_id - 1 free_concept_ids - FROM ( - SELECT concept_id, LEAD (concept_id) OVER (ORDER BY concept_id) next_id FROM - ( - SELECT concept_id FROM concept - /*UNION ALL - SELECT concept_id FROM devv5.concept_blacklisted*/ --blacklisted concept_id's (AVOF-2395) - ) AS i - WHERE concept_id >= 581480 AND concept_id < 500000000 - ) AS t - WHERE concept_id <> next_id - 1 AND next_id - concept_id > (SELECT COUNT (*) FROM concept_stage WHERE concept_id IS NULL) - ORDER BY next_id - concept_id - LIMIT 1 - ) AS sq; - EXECUTE 'CREATE SEQUENCE v5_concept INCREMENT BY 1 START WITH ' || ex || ' NO CYCLE CACHE 20'; - END$$; - - --11. Insert new concepts - 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 - ) - SELECT NEXTVAL('v5_concept'), - cs.concept_name, - cs.domain_id, - cs.vocabulary_id, - cs.concept_class_id, - cs.standard_concept, - cs.concept_code, - cs.valid_start_date, - cs.valid_end_date, - cs.invalid_reason - FROM concept_stage cs - WHERE cs.concept_id IS NULL;-- new because no concept_id could be found for the concept_code/vocabulary_id combination - - DROP SEQUENCE v5_concept; - ANALYZE concept; - - --12. Update concept_id for new concepts - UPDATE concept_stage cs - SET concept_id = c.concept_id - FROM concept c - WHERE cs.concept_code = c.concept_code - AND cs.vocabulary_id = c.vocabulary_id - AND cs.concept_id IS NULL; - ANALYZE concept_stage; - - --13. Update concept_id_1 and concept_id_2 in concept_relationship_stage from concept_stage and concept - UPDATE concept_relationship_stage crs - SET concept_id_1 = c1.concept_id, - concept_id_2 = c2.concept_id - FROM concept_stage c1, - concept_stage c2 - WHERE c1.concept_code = crs.concept_code_1 - AND c1.vocabulary_id = crs.vocabulary_id_1 - AND c2.concept_code = crs.concept_code_2 - AND c2.vocabulary_id = crs.vocabulary_id_2; - - UPDATE concept_relationship_stage crs - SET concept_id_1 = c.concept_id - FROM concept c - WHERE c.concept_code = crs.concept_code_1 - AND c.vocabulary_id = crs.vocabulary_id_1 - AND crs.concept_id_1 IS NULL; - - UPDATE concept_relationship_stage crs - SET concept_id_2 = c.concept_id - FROM concept c - WHERE c.concept_code = crs.concept_code_2 - AND c.vocabulary_id = crs.vocabulary_id_2 - AND crs.concept_id_2 IS NULL; - - /**************************************** - * Update the concept_relationship table * - ****************************************/ - - --14. Turn all relationship records so they are symmetrical if necessary and create an index - INSERT INTO concept_relationship_stage ( - concept_id_1, - concept_id_2, - concept_code_1, - concept_code_2, - vocabulary_id_1, - vocabulary_id_2, - relationship_id, - valid_start_date, - valid_end_date, - invalid_reason - ) - SELECT crs.concept_id_2, - crs.concept_id_1, - crs.concept_code_2, - crs.concept_code_1, - crs.vocabulary_id_2, - crs.vocabulary_id_1, - r.reverse_relationship_id, - crs.valid_start_date, - crs.valid_end_date, - crs.invalid_reason - FROM concept_relationship_stage crs - JOIN relationship r USING (relationship_id) - ON CONFLICT DO NOTHING; - - CREATE INDEX idx_crs_ids_generic_temp ON concept_relationship_stage ( - concept_id_1, - concept_id_2, - relationship_id - ); - ANALYZE concept_relationship_stage; - - --15. Update all relationships existing in concept_relationship_stage, including undeprecation of formerly deprecated ones - UPDATE concept_relationship cr - SET valid_end_date = crs.valid_end_date, - invalid_reason = crs.invalid_reason - FROM concept_relationship_stage crs - WHERE crs.concept_id_1 = cr.concept_id_1 - AND crs.concept_id_2 = cr.concept_id_2 - AND crs.relationship_id = cr.relationship_id - AND crs.valid_end_date <> cr.valid_end_date; - - --16. Deprecate missing relationships, but only if the concepts are fresh. If relationships are missing because of deprecated concepts, leave them intact. - --Also, only relationships are considered missing if the combination of vocabulary_id_1, vocabulary_id_2 AND relationship_id is present in concept_relationship_stage - --The latter will prevent large-scale deprecations of relationships between vocabularies where the relationship is defined not here, but together with the other vocab - - --Do the deprecation - WITH relationships - AS ( - SELECT * - FROM UNNEST(ARRAY [ - 'Concept replaced by', - 'Concept same_as to', - 'Concept alt_to to', - 'Concept was_a to', - 'Maps to', - 'CPT4 - SNOMED cat', -- AVOC-4022 - 'CPT4 - SNOMED eq' -- AVOC-4022 - ]) AS relationship_id - ), - vocab_combinations - AS ( - --Create a list of vocab1, vocab2 and relationship_id existing in concept_relationship_stage, except 'Maps' to and replacement relationships - --Also excludes manual mappings from concept_relationship_manual - SELECT DISTINCT s0.vocabulary_id_1, - s0.vocabulary_id_2, - s0.relationship_id, - -- One of latest_update (if we have more than one vocabulary in concept_relationship_stage) may be NULL, therefore use GREATEST to get one non-null date - GREATEST(v1.latest_update, v2.latest_update) AS max_latest_update - FROM ( - SELECT concept_code_1, - concept_code_2, - vocabulary_id_1, - vocabulary_id_2, - relationship_id - FROM concept_relationship_stage - - EXCEPT - - ( - SELECT concept_code_1, - concept_code_2, - vocabulary_id_1, - vocabulary_id_2, - relationship_id - FROM concept_relationship_manual - - UNION ALL - - --Add reverse mappings for exclude - SELECT concept_code_2, - concept_code_1, - vocabulary_id_2, - vocabulary_id_1, - reverse_relationship_id - FROM concept_relationship_manual - JOIN relationship USING (relationship_id) - ) - ) AS s0 - JOIN vocabulary v1 ON v1.vocabulary_id = s0.vocabulary_id_1 - JOIN vocabulary v2 ON v2.vocabulary_id = s0.vocabulary_id_2 - WHERE s0.vocabulary_id_1 NOT IN ( - 'SPL', - 'RxNorm Extension', - 'CDM' - ) - AND s0.vocabulary_id_2 NOT IN ( - 'SPL', - 'RxNorm Extension', - 'CDM' - ) - AND s0.relationship_id NOT IN ( - SELECT relationship_id - FROM relationships - - UNION ALL - - SELECT reverse_relationship_id - FROM relationships - JOIN relationship USING (relationship_id) - ) - AND COALESCE(v1.latest_update, v2.latest_update) IS NOT NULL - ) - UPDATE concept_relationship d - SET valid_end_date = vc.max_latest_update - 1, - invalid_reason = 'D' - --Whether the combination of vocab1, vocab2 and relationship exists (in subquery) - --(intended to be covered by this particular vocab udpate) - --And both concepts exist (don't deprecate relationships of deprecated concepts) - FROM concept c1, - concept c2, - vocab_combinations vc - WHERE c1.concept_id = d.concept_id_1 - AND c2.concept_id = d.concept_id_2 - AND c1.valid_end_date = TO_DATE('20991231', 'YYYYMMDD') - AND c2.valid_end_date = TO_DATE('20991231', 'YYYYMMDD') - AND c1.vocabulary_id = vc.vocabulary_id_1 - AND c2.vocabulary_id = vc.vocabulary_id_2 - AND d.relationship_id = vc.relationship_id - --And the record is currently fresh and not already deprecated - AND d.invalid_reason IS NULL - --And it was started before or equal the release date - AND d.valid_start_date <= vc.max_latest_update - --And it is missing from the new concept_relationship_stage - AND NOT EXISTS ( - SELECT 1 - FROM concept_relationship_stage crs - WHERE crs.concept_id_1 = d.concept_id_1 - AND crs.concept_id_2 = d.concept_id_2 - AND crs.relationship_id = d.relationship_id - ); - - --17. Deprecate old 'Maps to', 'Maps to value' and replacement records, but only if we have a new one in concept_relationship_stage with the same source concept - --part 1 (direct mappings) - WITH relationships AS ( - SELECT relationship_id FROM relationship - WHERE relationship_id IN ( - 'Concept replaced by', - 'Concept same_as to', - 'Concept alt_to to', - 'Concept was_a to', - 'Maps to', - 'Maps to value', - 'Source - RxNorm eq', -- AVOF-2118 - 'CPT4 - SNOMED cat', -- AVOC-4022 - 'CPT4 - SNOMED eq' -- AVOC-4022 - ) - ) - UPDATE concept_relationship r - SET valid_end_date = - GREATEST(r.valid_start_date, (SELECT MAX(v.latest_update) -1 -- one of latest_update (if we have more than one vocabulary in concept_relationship_stage) may be NULL, therefore use aggregate function MAX() to get one non-null date - FROM vocabulary v - WHERE v.vocabulary_id IN (c1.vocabulary_id, c2.vocabulary_id) --take both concept ids to get proper latest_update - )), - invalid_reason = 'D' - FROM concept c1, concept c2, relationships rel - WHERE r.concept_id_1=c1.concept_id - AND r.concept_id_2=c2.concept_id - AND r.invalid_reason IS NULL - AND r.relationship_id=rel.relationship_id - AND r.concept_id_1<>r.concept_id_2 - AND EXISTS ( - SELECT 1 FROM concept_relationship_stage crs - WHERE crs.concept_id_1=r.concept_id_1 - AND crs.relationship_id=r.relationship_id - AND crs.invalid_reason IS NULL - AND ( - crs.vocabulary_id_2=c2.vocabulary_id - OR (/*AVOF-459*/ - crs.vocabulary_id_2 IN ('RxNorm','RxNorm Extension') AND c2.vocabulary_id IN ('RxNorm','RxNorm Extension') - ) - OR (/*AVOF-1439*/ - crs.vocabulary_id_2 IN ('SNOMED','SNOMED Veterinary') AND c2.vocabulary_id IN ('SNOMED','SNOMED Veterinary') - ) - ) - ) - AND NOT EXISTS ( - SELECT 1 FROM concept_relationship_stage crs - WHERE crs.concept_id_1=r.concept_id_1 - AND crs.concept_id_2=r.concept_id_2 - AND crs.relationship_id=r.relationship_id - AND crs.invalid_reason IS NULL - ); - - --part 2 (reverse mappings) - WITH relationships AS ( - SELECT reverse_relationship_id FROM relationship - WHERE relationship_id in ( - 'Concept replaced by', - 'Concept same_as to', - 'Concept alt_to to', - 'Concept was_a to', - 'Maps to', - 'Maps to value', - 'Source - RxNorm eq', -- AVOF-2118 - 'CPT4 - SNOMED cat', -- AVOC-4022 - 'CPT4 - SNOMED eq' -- AVOC-4022 - ) - ) - UPDATE concept_relationship r - SET valid_end_date = - GREATEST(r.valid_start_date, (SELECT MAX(v.latest_update) -1 -- one of latest_update (if we have more than one vocabulary in concept_relationship_stage) may be NULL, therefore use aggregate function MAX() to get one non-null date - FROM vocabulary v - WHERE v.vocabulary_id IN (c1.vocabulary_id, c2.vocabulary_id) --take both concept ids to get proper latest_update - )), - invalid_reason = 'D' - FROM concept c1, concept c2, relationships rel - WHERE r.concept_id_1=c1.concept_id - AND r.concept_id_2=c2.concept_id - AND r.invalid_reason IS NULL - AND r.relationship_id=rel.reverse_relationship_id - AND r.concept_id_1<>r.concept_id_2 - AND EXISTS ( - SELECT 1 FROM concept_relationship_stage crs - WHERE crs.concept_id_2=r.concept_id_2 - AND crs.relationship_id=r.relationship_id - AND crs.invalid_reason IS NULL - AND ( - crs.vocabulary_id_1=c1.vocabulary_id - OR (/*AVOF-459*/ - crs.vocabulary_id_1 IN ('RxNorm','RxNorm Extension') AND c1.vocabulary_id IN ('RxNorm','RxNorm Extension') - ) - OR (/*AVOF-1439*/ - crs.vocabulary_id_1 IN ('SNOMED','SNOMED Veterinary') AND c1.vocabulary_id IN ('SNOMED','SNOMED Veterinary') - ) - ) - ) - AND NOT EXISTS ( - SELECT 1 FROM concept_relationship_stage crs - WHERE crs.concept_id_1=r.concept_id_1 - AND crs.concept_id_2=r.concept_id_2 - AND crs.relationship_id=r.relationship_id - AND crs.invalid_reason IS NULL - ); - - --18. Insert new relationships if they don't already exist - INSERT INTO concept_relationship - SELECT crs.concept_id_1, - crs.concept_id_2, - crs.relationship_id, - crs.valid_start_date, - crs.valid_end_date, - crs.invalid_reason - FROM concept_relationship_stage crs - ON CONFLICT DO NOTHING; - - /********************************************************* - * Update the correct invalid reason in the concept table * - * This should rarely happen * - *********************************************************/ - - --19. Make sure invalid_reason = 'U' if we have an active replacement record in the concept_relationship table - UPDATE concept c - SET valid_end_date = LEAST(c.valid_end_date, v.latest_update - 1), -- day before release day - invalid_reason = 'U', - standard_concept = NULL - FROM concept_relationship cr, vocabulary v - WHERE c.vocabulary_id = v.vocabulary_id - AND cr.concept_id_1 = c.concept_id - AND cr.invalid_reason IS NULL - AND cr.relationship_id IN ( - 'Concept replaced by', - 'Concept same_as to', - 'Concept alt_to to', - 'Concept was_a to' - ) - AND v.latest_update IS NOT NULL -- only for current vocabularies - AND (c.invalid_reason IS NULL OR c.invalid_reason = 'D'); -- not already upgraded - - --20. Make sure invalid_reason = 'D' if we have no active replacement record in the concept_relationship table for upgraded concepts - UPDATE concept c - SET valid_end_date = LEAST(c.valid_end_date, v.latest_update - 1), - invalid_reason = 'D', - standard_concept = NULL - FROM vocabulary v - WHERE v.vocabulary_id = c.vocabulary_id - AND NOT EXISTS ( - SELECT 1 - FROM concept_relationship r - WHERE r.concept_id_1 = c.concept_id - AND r.invalid_reason IS NULL - AND r.relationship_id IN ( - 'Concept replaced by', - 'Concept same_as to', - 'Concept alt_to to', - 'Concept was_a to' - ) - ) - AND v.latest_update IS NOT NULL -- only for current vocabularies - AND c.invalid_reason = 'U';-- not already deprecated - - --The following are a bunch of rules for Maps to and Maps from relationships. - --Since they work outside the _stage tables, they will be restricted to the vocabularies worked on - - --21. 'Maps to' and 'Mapped from' relationships from concepts to self should exist for all concepts where standard_concept = 'S' - INSERT INTO concept_relationship AS cr - SELECT c.concept_id AS concept_id_1, - c.concept_id AS concept_id_2, - r.relationship_id, - v.latest_update AS valid_start_date, - TO_DATE('20991231', 'yyyymmdd') AS valid_end_date, - NULL AS invalid_reason - FROM concept c - JOIN vocabulary v ON v.vocabulary_id = c.vocabulary_id - AND v.latest_update IS NOT NULL - CROSS JOIN ( - SELECT 'Maps to' AS relationship_id - - UNION ALL - - SELECT 'Mapped from' - ) r - WHERE c.standard_concept = 'S' - AND c.invalid_reason IS NULL - ON CONFLICT ON CONSTRAINT xpk_concept_relationship - DO UPDATE - SET valid_end_date = excluded.valid_end_date, - invalid_reason = excluded.invalid_reason - WHERE cr.invalid_reason IS NOT NULL; - - --22. 'Maps to' or 'Maps to value' relationships should not exist where - --a) the source concept has standard_concept = 'S', unless it is to self - --b) the target concept has standard_concept = 'C' or NULL - --c) the target concept has invalid_reason='D' or 'U' - - UPDATE concept_relationship r - SET valid_end_date = GREATEST(r.valid_start_date, (SELECT MAX(v.latest_update)-1 FROM vocabulary v WHERE v.vocabulary_id=c1.vocabulary_id OR v.vocabulary_id=c2.vocabulary_id)), -- day before release day or valid_start_date - invalid_reason = 'D' - FROM concept c1, concept c2, vocabulary v - WHERE r.concept_id_1 = c1.concept_id - AND r.concept_id_2 = c2.concept_id - AND ( - (c1.standard_concept = 'S' AND c1.concept_id <> c2.concept_id) -- rule a) - OR COALESCE (c2.standard_concept, 'X') <> 'S' -- rule b) - OR c2.invalid_reason IN ('U', 'D') -- rule c) - ) - AND v.vocabulary_id IN (c1.vocabulary_id, c2.vocabulary_id) - AND v.latest_update IS NOT NULL -- only the current vocabularies - AND r.relationship_id IN ('Maps to','Maps to value') - AND r.invalid_reason IS NULL; - - --And reverse - UPDATE concept_relationship r - SET valid_end_date = GREATEST(r.valid_start_date, (SELECT MAX(v.latest_update)-1 FROM vocabulary v WHERE v.vocabulary_id=c1.vocabulary_id OR v.vocabulary_id=c2.vocabulary_id)), -- day before release day or valid_start_date - invalid_reason = 'D' - FROM concept c1, concept c2, vocabulary v - WHERE r.concept_id_1 = c1.concept_id - AND r.concept_id_2 = c2.concept_id - AND ( - (c2.standard_concept = 'S' AND c1.concept_id <> c2.concept_id) -- rule a) - OR COALESCE (c1.standard_concept, 'X') <> 'S' -- rule b) - OR c1.invalid_reason IN ('U', 'D') -- rule c) - ) - AND v.vocabulary_id IN (c1.vocabulary_id, c2.vocabulary_id) - AND v.latest_update IS NOT NULL -- only the current vocabularies - AND r.relationship_id IN ('Mapped from','Value mapped from') - AND r.invalid_reason IS NULL; - - --23. Post-processing (some concepts might be deprecated when they missed in source, so load_stage doesn't know about them and DO NOT deprecate relationships proper) - --Deprecate replacement records if target concept was deprecated - UPDATE concept_relationship cr - SET invalid_reason = 'D', - valid_end_date = (SELECT MAX (v.latest_update) FROM concept c JOIN vocabulary v ON c.vocabulary_id = v.vocabulary_id WHERE c.concept_id IN (cr.concept_id_1, cr.concept_id_2))-1 - FROM ( - WITH RECURSIVE hierarchy_concepts (concept_id_1, concept_id_2, relationship_id, full_path) AS - ( - SELECT concept_id_1, concept_id_2, relationship_id, ARRAY [concept_id_1] AS full_path - FROM upgraded_concepts - WHERE concept_id_2 IN (SELECT concept_id_2 FROM upgraded_concepts WHERE invalid_reason = 'D') - UNION ALL - SELECT c.concept_id_1, c.concept_id_2, c.relationship_id, hc.full_path || c.concept_id_1 AS full_path - FROM upgraded_concepts c - JOIN hierarchy_concepts hc on hc.concept_id_1=c.concept_id_2 - WHERE c.concept_id_1 <> ALL (full_path) - ), - upgraded_concepts AS ( - SELECT r.concept_id_1, - r.concept_id_2, - r.relationship_id, - c2.invalid_reason - FROM concept c1, concept c2, concept_relationship r - WHERE r.relationship_id IN ( - 'Concept replaced by', - 'Concept same_as to', - 'Concept alt_to to', - 'Concept was_a to' - ) - AND r.invalid_reason IS NULL - AND c1.concept_id = r.concept_id_1 - AND c2.concept_id = r.concept_id_2 - AND EXISTS (SELECT 1 FROM vocabulary WHERE latest_update IS NOT NULL AND vocabulary_id IN (c1.vocabulary_id,c2.vocabulary_id)) - AND c2.concept_code <> 'OMOP generated' - AND r.concept_id_1 <> r.concept_id_2 - ) - SELECT concept_id_1, concept_id_2, relationship_id FROM hierarchy_concepts - ) i - WHERE cr.concept_id_1 = i.concept_id_1 AND cr.concept_id_2 = i.concept_id_2 AND cr.relationship_id = i.relationship_id; - - --Deprecate concepts if we have no active replacement record in the concept_relationship - UPDATE concept c - SET valid_end_date = LEAST(c.valid_end_date, v.latest_update - 1), - invalid_reason = 'D', - standard_concept = NULL - FROM vocabulary v - WHERE v.vocabulary_id = c.vocabulary_id - AND NOT EXISTS ( - SELECT 1 - FROM concept_relationship r - WHERE r.concept_id_1 = c.concept_id - AND r.invalid_reason IS NULL - AND r.relationship_id IN ( - 'Concept replaced by', - 'Concept same_as to', - 'Concept alt_to to', - 'Concept was_a to' - ) - ) - AND v.latest_update IS NOT NULL -- only for current vocabularies - AND c.invalid_reason = 'U';-- not already deprecated - - --Deprecate 'Maps to' mappings to deprecated and upgraded concepts - UPDATE concept_relationship r - SET valid_end_date = ( - SELECT MAX(v.latest_update) - FROM concept c - JOIN vocabulary v ON c.vocabulary_id = v.vocabulary_id - WHERE c.concept_id IN ( - r.concept_id_1, - r.concept_id_2 - ) - ) - 1, - invalid_reason = 'D' - WHERE r.relationship_id = 'Maps to' - AND r.invalid_reason IS NULL - AND EXISTS ( - SELECT 1 - FROM concept c - WHERE c.concept_id = r.concept_id_2 - AND c.invalid_reason IN ( - 'U', - 'D' - ) - ) - AND EXISTS ( - SELECT 1 - FROM concept c - JOIN vocabulary v ON c.vocabulary_id = v.vocabulary_id - WHERE c.concept_id IN ( - r.concept_id_1, - r.concept_id_2 - ) - AND v.latest_update IS NOT NULL - ); - - --Reverse for deprecating - UPDATE concept_relationship r - SET invalid_reason = r1.invalid_reason, - valid_end_date = r1.valid_end_date - FROM concept_relationship r1 - JOIN relationship rel ON r1.relationship_id = rel.relationship_id - WHERE r1.relationship_id IN ( - 'Concept replaced by', - 'Concept same_as to', - 'Concept alt_to to', - 'Concept was_a to', - 'Maps to' - ) - AND EXISTS ( - SELECT 1 - FROM concept c - JOIN vocabulary v ON c.vocabulary_id = v.vocabulary_id - WHERE c.concept_id IN ( - r1.concept_id_1, - r1.concept_id_2 - ) - AND v.latest_update IS NOT NULL - ) - AND r.concept_id_1 = r1.concept_id_2 - AND r.concept_id_2 = r1.concept_id_1 - AND r.relationship_id = rel.reverse_relationship_id - AND r.valid_end_date <> r1.valid_end_date; - - /*********************************** - * Update the concept_synonym table * - ************************************/ - - --24. Remove duplicates from concept_synonym_stage that might appear after concept_name corrections - DELETE - FROM concept_synonym_stage css - WHERE EXISTS ( - SELECT 1 - FROM concept_synonym_stage css_int - WHERE css_int.synonym_name = css.synonym_name - AND css_int.synonym_concept_code = css.synonym_concept_code - AND css_int.synonym_vocabulary_id = css.synonym_vocabulary_id - AND css_int.language_concept_id = css.language_concept_id - AND css_int.ctid > css.ctid - ); - - --25. Remove synonyms from concept_synonym_stage if synonym_name alreay exists in concept_stage, but only for English - DELETE - FROM concept_synonym_stage css - WHERE EXISTS ( - SELECT 1 - FROM concept_stage cs - WHERE cs.concept_code = css.synonym_concept_code - AND cs.vocabulary_id = css.synonym_vocabulary_id - AND LOWER(cs.concept_name) = LOWER(css.synonym_name) - AND css.language_concept_id = 4180186 - ); - - --26. Update synonym_concept_id - UPDATE concept_synonym_stage css - SET synonym_concept_id = cs.concept_id - FROM concept_stage cs - WHERE cs.concept_code = css.synonym_concept_code - AND cs.vocabulary_id = css.synonym_vocabulary_id - AND css.synonym_concept_id IS NULL; - - --27. Remove all existing synonyms for concepts that are in concept_stage - --Synonyms are built from scratch each time, no life cycle - DELETE - FROM concept_synonym csyn - WHERE NOT EXISTS ( - SELECT 1 - FROM concept_synonym_stage css_int - WHERE css_int.synonym_concept_id = csyn.concept_id - AND css_int.synonym_name = csyn.concept_synonym_name - AND css_int.language_concept_id = csyn.language_concept_id - ) - AND EXISTS ( - SELECT 1 - FROM concept_stage c_int - WHERE c_int.concept_id = csyn.concept_id - ); - - --28. Add new synonyms - INSERT INTO concept_synonym ( - concept_id, - concept_synonym_name, - language_concept_id - ) - SELECT css.synonym_concept_id, - css.synonym_name, - css.language_concept_id - FROM concept_synonym_stage css - ON CONFLICT ON CONSTRAINT unique_synonyms DO NOTHING; - - --29. Fillig drug_strength - --Special rules for RxNorm Extension: same as 'Maps to' rules, but records from deprecated concepts will be deleted - DELETE - FROM drug_strength - WHERE drug_concept_id IN ( - SELECT c.concept_id - FROM concept c - JOIN vocabulary v ON c.vocabulary_id = v.vocabulary_id - WHERE latest_update IS NOT NULL - AND v.vocabulary_id <> 'RxNorm Extension' - ); - - --Replace with fresh records (only for 'RxNorm Extension') - DELETE - FROM drug_strength ds - WHERE EXISTS ( - SELECT 1 - FROM drug_strength_stage dss - JOIN concept c1 ON c1.concept_code = dss.drug_concept_code - AND c1.vocabulary_id = dss.vocabulary_id_1 - AND ds.drug_concept_id = c1.concept_id - JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id - WHERE v.latest_update IS NOT NULL - AND v.vocabulary_id = 'RxNorm Extension' - ); - - --Insert new records - INSERT INTO drug_strength ( - drug_concept_id, - ingredient_concept_id, - amount_value, - amount_unit_concept_id, - numerator_value, - numerator_unit_concept_id, - denominator_value, - denominator_unit_concept_id, - box_size, - valid_start_date, - valid_end_date, - invalid_reason - ) - SELECT c1.concept_id, - c2.concept_id, - ds.amount_value, - ds.amount_unit_concept_id, - ds.numerator_value, - ds.numerator_unit_concept_id, - ds.denominator_value, - ds.denominator_unit_concept_id, - REGEXP_REPLACE(bs.concept_name, '.+Box of ([0-9]+).*', '\1')::INT2 AS box_size, - ds.valid_start_date, - ds.valid_end_date, - ds.invalid_reason - FROM drug_strength_stage ds - JOIN concept c1 ON c1.concept_code = ds.drug_concept_code - AND c1.vocabulary_id = ds.vocabulary_id_1 - JOIN concept c2 ON c2.concept_code = ds.ingredient_concept_code - AND c2.vocabulary_id = ds.vocabulary_id_2 - JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id - LEFT JOIN concept bs ON bs.concept_id = c1.concept_id - AND bs.vocabulary_id = 'RxNorm Extension' - AND bs.concept_name LIKE '%Box of%' - WHERE v.latest_update IS NOT NULL; - - --Delete drug if concept is deprecated (only for 'RxNorm Extension') - DELETE - FROM drug_strength ds - WHERE EXISTS ( - SELECT 1 - FROM concept c1 - JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id - WHERE ds.drug_concept_id = c1.concept_id - AND v.latest_update IS NOT NULL - AND v.vocabulary_id = 'RxNorm Extension' - AND c1.invalid_reason IS NOT NULL - ); - - --30. Fillig pack_content - --Special rules for RxNorm Extension: same as 'Maps to' rules, but records from deprecated concepts will be deleted - DELETE - FROM pack_content - WHERE pack_concept_id IN ( - SELECT c.concept_id - FROM concept c - JOIN vocabulary v ON c.vocabulary_id = v.vocabulary_id - WHERE latest_update IS NOT NULL - AND v.vocabulary_id <> 'RxNorm Extension' - ); - - --Replace with fresh records (only for 'RxNorm Extension') - DELETE - FROM pack_content pc - WHERE EXISTS ( - SELECT 1 - FROM pack_content_stage pcs - JOIN concept c1 ON c1.concept_code = pcs.pack_concept_code - AND c1.vocabulary_id = pcs.pack_vocabulary_id - AND pc.pack_concept_id = c1.concept_id - JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id - WHERE v.latest_update IS NOT NULL - AND v.vocabulary_id = 'RxNorm Extension' - ); - - INSERT INTO pack_content ( - pack_concept_id, - drug_concept_id, - amount, - box_size - ) - SELECT c1.concept_id, - c2.concept_id, - ds.amount, - ds.box_size - FROM pack_content_stage ds - JOIN concept c1 ON c1.concept_code = ds.pack_concept_code - AND c1.vocabulary_id = ds.pack_vocabulary_id - JOIN concept c2 ON c2.concept_code = ds.drug_concept_code - AND c2.vocabulary_id = ds.drug_vocabulary_id - JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id - WHERE v.latest_update IS NOT NULL; - - --Delete if concept is deprecated (only for 'RxNorm Extension') - DELETE - FROM pack_content pc - WHERE EXISTS ( - SELECT 1 - FROM concept c1 - JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id - WHERE pc.pack_concept_id = c1.concept_id - AND v.latest_update IS NOT NULL - AND v.vocabulary_id = 'RxNorm Extension' - AND c1.invalid_reason IS NOT NULL - ); - - --31. Fix empty concept names, new rules [AVOF-2206] - UPDATE concept c - SET concept_name = i.concept_name - FROM ( - SELECT c1.concept_id, - vocabulary_pack.CutConceptName(CONCAT ( - 'No name provided', - ' - mapped to ' || STRING_AGG(c2.concept_name, ' | ' ORDER BY c2.concept_name) - )) AS concept_name - FROM concept c1 - JOIN vocabulary v ON v.vocabulary_id = c1.vocabulary_id - LEFT JOIN concept_relationship cr ON cr.concept_id_1 = c1.concept_id - AND cr.relationship_id = 'Maps to' - AND cr.invalid_reason IS NULL - LEFT JOIN concept c2 ON c2.concept_id = cr.concept_id_2 - WHERE c1.vocabulary_id IN ( - 'Read', - 'GPI' - ) - AND c1.concept_name = ' ' - AND v.latest_update IS NOT NULL --only for current vocabularies - GROUP BY c1.concept_id - ) i - WHERE i.concept_id = c.concept_id; - - --32. Check if current vocabulary exists in vocabulary_conversion table - INSERT INTO vocabulary_conversion ( - vocabulary_id_v4, - vocabulary_id_v5 - ) - SELECT -1, - v.vocabulary_id - FROM vocabulary v - WHERE v.latest_update IS NOT NULL - ON CONFLICT DO NOTHING; - - --33. Update latest_update on vocabulary_conversion - UPDATE vocabulary_conversion vc - SET latest_update = v.latest_update - FROM vocabulary v - WHERE v.latest_update IS NOT NULL - AND v.vocabulary_id = vc.vocabulary_id_v5; - - --34. Clean up - UPDATE vocabulary - SET latest_update = NULL, - dev_schema_name = NULL - WHERE latest_update IS NOT NULL; - - DROP INDEX idx_crs_ids_generic_temp; - - --35. Final analysing for base tables - ANALYZE concept; - ANALYZE concept_relationship; - ANALYZE concept_synonym; - - --36. Update concept_id fields in the "basic" manual tables for storing in audit - /*PERFORM admin_pack.UpdateManualConceptID();*/ - - --QA (should return NULL) - --SELECT * FROM QA_TESTS.GET_CHECKS(); -END; -$function$ -; diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 68cb13111..edbda8180 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -34,39 +34,39 @@ This section describes the features and procedures that should be installed in t ## devv5 -- GenericUpdate_LE.sql (a version of the GenericUpdate function for a local environment) - [Vocabulary-v5.0/working/local_environment/GenericUpdate_LE.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/local_environment/GenericUpdate_LE.sql) +- GenericUpdate() (a version of the GenericUpdate function for a local environment) + [Vocabulary-v5.0/working/generic_update.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/local_environment/working/generic_update.sql) - FastRecreateSchema() - [Vocabulary-v5.0/working/fast_recreate_schema.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/fast_recreate_schema.sql) -- GetPrimaryRelationshipID() [Vocabulary-v5.0/working/packages/admin_pack/GetPrimaryRelationshipID.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/GetPrimaryRelationshipID.sql) + [Vocabulary-v5.0/working/fast_recreate_schema.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/fast_recreate_schema.sql) +- GetPrimaryRelationshipID() [Vocabulary-v5.0/working/packages/admin_pack/GetPrimaryRelationshipID.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/GetPrimaryRelationshipID.sql) - Functions from - [Vocabulary-v5.0/working/packages/DevV5_additional_functions at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/tree/master/working/packages/DevV5_additional_functions) + [Vocabulary-v5.0/working/packages/DevV5_additional_functions](https://github.com/OHDSI/Vocabulary-v5.0/tree/master/working/packages/DevV5_additional_functions) ## vocabulary_pack - DropFKConstraints() - [Vocabulary-v5.0/working/packages/vocabulary_pack/DropFKConstraints.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DropFKConstraints.sql) + [Vocabulary-v5.0/working/packages/vocabulary_pack/DropFKConstraints.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DropFKConstraints.sql) - SetLatestUpdate() - [Vocabulary-v5.0/working/packages/vocabulary_pack/SetLatestUpdate.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/SetLatestUpdate.sql) + [Vocabulary-v5.0/working/packages/vocabulary_pack/SetLatestUpdate.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/SetLatestUpdate.sql) - ProcessManualSynonyms() - [Vocabulary-v5.0/working/packages/vocabulary_pack/ProcessManualSynonyms.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/ProcessManualSynonyms.sql) + [Vocabulary-v5.0/working/packages/vocabulary_pack/ProcessManualSynonyms.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/ProcessManualSynonyms.sql) - CheckManualSynonyms() - [Vocabulary-v5.0/working/packages/vocabulary_pack/CheckManualSynonyms.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/CheckManualSynonyms.sql) + [Vocabulary-v5.0/working/packages/vocabulary_pack/CheckManualSynonyms.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/CheckManualSynonyms.sql) - ProcessManualRelationships() - [Vocabulary-v5.0/working/packages/vocabulary_pack/ProcessManualRelationships.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/ProcessManualRelationships.sql) + [Vocabulary-v5.0/working/packages/vocabulary_pack/ProcessManualRelationships.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/ProcessManualRelationships.sql) - CheckReplacementMappings() - [Vocabulary-v5.0/working/packages/vocabulary_pack/CheckReplacementMappings.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/CheckReplacementMappings.sql) + [Vocabulary-v5.0/working/packages/vocabulary_pack/CheckReplacementMappings.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/CheckReplacementMappings.sql) - AddFreshMAPSTO() - [Vocabulary-v5.0/working/packages/vocabulary_pack/AddFreshMAPSTO.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/AddFreshMAPSTO.sql) -- GetActualConceptInfo() [Vocabulary-v5.0/working/packages/vocabulary_pack/GetActualConceptInfo.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/GetActualConceptInfo.sql) -- DeprecateWrongMapsTo() [Vocabulary-v5.0/working/packages/vocabulary_pack/DeprecateWrongMapsTo.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DeprecateWrongMapsTo.sql) + [Vocabulary-v5.0/working/packages/vocabulary_pack/AddFreshMAPSTO.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/AddFreshMAPSTO.sql) +- GetActualConceptInfo() [Vocabulary-v5.0/working/packages/vocabulary_pack/GetActualConceptInfo.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/GetActualConceptInfo.sql) +- DeprecateWrongMapsTo() [Vocabulary-v5.0/working/packages/vocabulary_pack/DeprecateWrongMapsTo.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DeprecateWrongMapsTo.sql) - DeleteAmbiguousMapsTo() -[Vocabulary-v5.0/working/packages/vocabulary_pack/DeleteAmbiguousMapsTo.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DeleteAmbiguousMapsTo.sql) +[Vocabulary-v5.0/working/packages/vocabulary_pack/DeleteAmbiguousMapsTo.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DeleteAmbiguousMapsTo.sql) ## qa_tests -- Functions from [Vocabulary-v5.0/working/packages/QA_TESTS at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/tree/master/working/packages/QA_TESTS) +- Functions from [Vocabulary-v5.0/working/packages/QA_TESTS](https://github.com/OHDSI/Vocabulary-v5.0/tree/master/working/packages/QA_TESTS) # Creating Tables @@ -83,16 +83,14 @@ In case the table structure already exists in the database, this part can be ski When tables are created for the first time, everything should be executed from the script except creating constraints and indexes so that they do not interfere with the import of vocabularies from Athena. - DevV5_DDL.sql without created, created_by, modified, modified_by fields - [Vocabulary-v5.0/working/DevV5_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) - Or just run this script DevV5_tables_DDL.sql from this folder -- Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) + [Vocabulary-v5.0/working/DevV5_DDL.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) +- Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) ## development schema - DevV5_DDL.sql without created, created_by, modified, modified_by fields - [Vocabulary-v5.0/working/DevV5_DDL.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) - Or just run this script DevV5_tables_DDL.sql from this folder -- Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql at master · OHDSI/Vocabulary-v5.0 (github.com)](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) + [Vocabulary-v5.0/working/DevV5_DDL.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) +- Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) ## Update Vocabulary table structure @@ -138,9 +136,7 @@ The “COPY” command to import data from CSV files (psql): > >COPY DOMAIN FROM '<path_to_csv_file>\\DOMAIN.csv' WITH DELIMITER E'\\t' CSV HEADER QUOTE E'\\b'; -After all the data has been imported, it is necessary to create constraints and indexes from the DevV5_DDL.sql, mentioned above, or use this script: -**DevV5_constraints_DDL.sql** - +After all the data has been imported, it is necessary to create constraints and indexes from the DevV5_DDL.sql, mentioned above. # Import Source Data From da558f7a9f8579af595e997f4235108b06a4220a Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Thu, 18 Apr 2024 15:49:58 +0300 Subject: [PATCH 12/18] Update README.md --- working/local_environment/README.md | 11 ++++------- 1 file changed, 4 insertions(+), 7 deletions(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index edbda8180..900f1bbf5 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -34,13 +34,10 @@ This section describes the features and procedures that should be installed in t ## devv5 -- GenericUpdate() (a version of the GenericUpdate function for a local environment) - [Vocabulary-v5.0/working/generic_update.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/local_environment/working/generic_update.sql) -- FastRecreateSchema() - [Vocabulary-v5.0/working/fast_recreate_schema.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/fast_recreate_schema.sql) -- GetPrimaryRelationshipID() [Vocabulary-v5.0/working/packages/admin_pack/GetPrimaryRelationshipID.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/GetPrimaryRelationshipID.sql) -- Functions from - [Vocabulary-v5.0/working/packages/DevV5_additional_functions](https://github.com/OHDSI/Vocabulary-v5.0/tree/master/working/packages/DevV5_additional_functions) +- GenericUpdate() (a version of the GenericUpdate function for a local environment) [Vocabulary-v5.0/working/generic_update.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/local_environment/working/generic_update.sql) +- FastRecreateSchema() [Vocabulary-v5.0/working/fast_recreate_schema.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/fast_recreate_schema.sql) +- GetPrimaryRelationshipID() [Vocabulary-v5.0/working/packages/admin_pack/GetPrimaryRelationshipID.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/GetPrimaryRelationshipID.sql) +- Functions from [Vocabulary-v5.0/working/packages/DevV5_additional_functions](https://github.com/OHDSI/Vocabulary-v5.0/tree/master/working/packages/DevV5_additional_functions) ## vocabulary_pack From 12e280869b3491c9a8792bde24130871b0d632cf Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Thu, 18 Apr 2024 15:54:09 +0300 Subject: [PATCH 13/18] Update README.md --- working/local_environment/README.md | 29 ++++++++++------------------- 1 file changed, 10 insertions(+), 19 deletions(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 900f1bbf5..3a745418f 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -41,25 +41,16 @@ This section describes the features and procedures that should be installed in t ## vocabulary_pack -- DropFKConstraints() - [Vocabulary-v5.0/working/packages/vocabulary_pack/DropFKConstraints.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DropFKConstraints.sql) -- SetLatestUpdate() - [Vocabulary-v5.0/working/packages/vocabulary_pack/SetLatestUpdate.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/SetLatestUpdate.sql) -- ProcessManualSynonyms() - [Vocabulary-v5.0/working/packages/vocabulary_pack/ProcessManualSynonyms.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/ProcessManualSynonyms.sql) -- CheckManualSynonyms() - [Vocabulary-v5.0/working/packages/vocabulary_pack/CheckManualSynonyms.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/CheckManualSynonyms.sql) -- ProcessManualRelationships() - [Vocabulary-v5.0/working/packages/vocabulary_pack/ProcessManualRelationships.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/ProcessManualRelationships.sql) -- CheckReplacementMappings() - [Vocabulary-v5.0/working/packages/vocabulary_pack/CheckReplacementMappings.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/CheckReplacementMappings.sql) -- AddFreshMAPSTO() - [Vocabulary-v5.0/working/packages/vocabulary_pack/AddFreshMAPSTO.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/AddFreshMAPSTO.sql) -- GetActualConceptInfo() [Vocabulary-v5.0/working/packages/vocabulary_pack/GetActualConceptInfo.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/GetActualConceptInfo.sql) -- DeprecateWrongMapsTo() [Vocabulary-v5.0/working/packages/vocabulary_pack/DeprecateWrongMapsTo.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DeprecateWrongMapsTo.sql) -- DeleteAmbiguousMapsTo() - -[Vocabulary-v5.0/working/packages/vocabulary_pack/DeleteAmbiguousMapsTo.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DeleteAmbiguousMapsTo.sql) +- DropFKConstraints() [Vocabulary-v5.0/working/packages/vocabulary_pack/DropFKConstraints.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DropFKConstraints.sql) +- SetLatestUpdate() [Vocabulary-v5.0/working/packages/vocabulary_pack/SetLatestUpdate.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/SetLatestUpdate.sql) +- ProcessManualSynonyms() [Vocabulary-v5.0/working/packages/vocabulary_pack/ProcessManualSynonyms.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/ProcessManualSynonyms.sql) +- CheckManualSynonyms() [Vocabulary-v5.0/working/packages/vocabulary_pack/CheckManualSynonyms.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/CheckManualSynonyms.sql) +- ProcessManualRelationships() [Vocabulary-v5.0/working/packages/vocabulary_pack/ProcessManualRelationships.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/ProcessManualRelationships.sql) +- CheckReplacementMappings() [Vocabulary-v5.0/working/packages/vocabulary_pack/CheckReplacementMappings.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/CheckReplacementMappings.sql) +- AddFreshMAPSTO() [Vocabulary-v5.0/working/packages/vocabulary_pack/AddFreshMAPSTO.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/AddFreshMAPSTO.sql) +- GetActualConceptInfo() [Vocabulary-v5.0/working/packages/vocabulary_pack/GetActualConceptInfo.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/GetActualConceptInfo.sql) +- DeprecateWrongMapsTo() [Vocabulary-v5.0/working/packages/vocabulary_pack/DeprecateWrongMapsTo.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DeprecateWrongMapsTo.sql) +- DeleteAmbiguousMapsTo() [Vocabulary-v5.0/working/packages/vocabulary_pack/DeleteAmbiguousMapsTo.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/vocabulary_pack/DeleteAmbiguousMapsTo.sql) ## qa_tests From 709bfecadafef323e57fd980571cc41eac171c46 Mon Sep 17 00:00:00 2001 From: AlaikseiKatyshou Date: Tue, 23 Apr 2024 14:47:33 +0300 Subject: [PATCH 14/18] Remove columns that are for internal use --- working/DevV5_DDL.sql | 19 ------------------- 1 file changed, 19 deletions(-) diff --git a/working/DevV5_DDL.sql b/working/DevV5_DDL.sql index c56c38de1..6423bb7e2 100644 --- a/working/DevV5_DDL.sql +++ b/working/DevV5_DDL.sql @@ -240,23 +240,12 @@ CREATE TABLE concept_synonym_manual ( language_concept_id int4 NOT NULL ); -/* - the next four columns are for our internal use, you don't need to include them in your work environment: - created - created_by - modified - modified_by -*/ --Create a base table for manual relationships, it stores all manual relationships from all vocabularies DROP TABLE IF EXISTS base_concept_relationship_manual; CREATE TABLE base_concept_relationship_manual ( LIKE concept_relationship_manual, concept_id_1 INT4 NOT NULL, concept_id_2 INT4 NOT NULL, - created TIMESTAMPTZ NOT NULL, - created_by INT4 NOT NULL REFERENCES admin_pack.virtual_user(user_id), - modified TIMESTAMPTZ, - modified_by INT4 REFERENCES admin_pack.virtual_user(user_id), CONSTRAINT idx_pk_base_crm PRIMARY KEY ( concept_code_1, concept_code_2, @@ -271,10 +260,6 @@ DROP TABLE IF EXISTS base_concept_manual CASCADE; CREATE TABLE base_concept_manual ( LIKE concept_manual, concept_id INT4 NOT NULL, - created TIMESTAMPTZ NOT NULL, - created_by INT4 NOT NULL REFERENCES admin_pack.virtual_user(user_id), - modified TIMESTAMPTZ, - modified_by INT4 REFERENCES admin_pack.virtual_user(user_id), CONSTRAINT idx_pk_base_cm PRIMARY KEY ( concept_code, vocabulary_id @@ -286,10 +271,6 @@ DROP TABLE IF EXISTS base_concept_synonym_manual CASCADE; CREATE TABLE base_concept_synonym_manual ( LIKE concept_synonym_manual, concept_id INT4 NOT NULL, - created TIMESTAMPTZ NOT NULL, - created_by INT4 NOT NULL REFERENCES admin_pack.virtual_user(user_id), - modified TIMESTAMPTZ, - modified_by INT4 REFERENCES admin_pack.virtual_user(user_id), CONSTRAINT idx_pk_base_csm PRIMARY KEY ( synonym_vocabulary_id, synonym_name, From b86ab79c28ca384c8fa8d7cdb1cb5794417ac079 Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Tue, 23 Apr 2024 14:53:50 +0300 Subject: [PATCH 15/18] Update README.md --- working/local_environment/README.md | 10 ++-------- 1 file changed, 2 insertions(+), 8 deletions(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 3a745418f..3b0cbdef5 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -58,20 +58,14 @@ This section describes the features and procedures that should be installed in t # Creating Tables -The next four columns are for internal use only, so they should be excluded from the DevV5_DDL script before execution (from **base_concept_relationship_manual**, **base_concept_manual**, **base_concept_synonym_manual** tables): -- created -- created_by -- modified -- modified_by - ## Devv5 In case the table structure already exists in the database, this part can be skipped. When tables are created for the first time, everything should be executed from the script except creating constraints and indexes so that they do not interfere with the import of vocabularies from Athena. -- DevV5_DDL.sql without created, created_by, modified, modified_by fields - [Vocabulary-v5.0/working/DevV5_DDL.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/DevV5_DDL.sql) +- DevV5_DDL.sql (create only tables structures without any constraints) + [Vocabulary-v5.0/working/DevV5_DDL.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/local_environment/working/DevV5_DDL.sql) - Prepare_manual_tables.sql [Vocabulary-v5.0/working/packages/admin_pack/prepare_manual_tables.sql](https://github.com/OHDSI/Vocabulary-v5.0/blob/master/working/packages/admin_pack/prepare_manual_tables.sql) ## development schema From 1370800dc3a274ba853270d08abe38e4488795e7 Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Tue, 23 Apr 2024 15:24:15 +0300 Subject: [PATCH 16/18] Update README.md --- working/local_environment/README.md | 1 + 1 file changed, 1 insertion(+) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 3b0cbdef5..512f552a7 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -31,6 +31,7 @@ It is also necessary to give an appropriate name to a schema for the vocabulary # Creating Functions This section describes the features and procedures that should be installed in the database in the appropriate schemas. +All functions except Generic_Update() (which is in the **local_environment** brantch) are in the **master** branch. ## devv5 From a2aaccf0fd4c2aa284a952d2d1a97373cfdaaa5f Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Tue, 22 Oct 2024 09:40:17 +0300 Subject: [PATCH 17/18] Update README.md Add plpython3u package installation --- working/local_environment/README.md | 17 ++++++++++++++++- 1 file changed, 16 insertions(+), 1 deletion(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 512f552a7..9d00fcc9f 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -14,7 +14,22 @@ Pgcrypto and Tablefunc extensions should be installed for some functions to work Create extensions: >CREATE EXTENSION pg_trgm; >CREATE EXTENSION tablefunc; ->CREATE EXTENSION plpython3u; +>CREATE EXTENSION plpython3u; +>CREATE EXTENSION pg_trgm; + +If during the installation of plpython3u you get an error like: +_“ERROR: could not load library "C:/Program Files/PostgreSQL/15/lib/plpython3.dll": The specified module could not be found.”_ +this means that it is necessary to install the required packages. +There is an example for Postgresql 15 using apt or apt-get (for Linux system): +>**apt-get:** +>sudo apt-get update +>sudo apt-get -y install postgresql-plpython3-15 +> +>**apt:** +>sudo apt update +>sudo apt -y install postgresql-plpython3-15 + + # Creating Schemas From a6e66d0d057d9eb6da1312f4af59a85cccba678c Mon Sep 17 00:00:00 2001 From: Aliaksei Katyshou <159019348+AlaikseiKatyshou@users.noreply.github.com> Date: Tue, 22 Oct 2024 12:49:40 +0300 Subject: [PATCH 18/18] Update README.md update --- working/local_environment/README.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/working/local_environment/README.md b/working/local_environment/README.md index 9d00fcc9f..c3fc9b2ff 100644 --- a/working/local_environment/README.md +++ b/working/local_environment/README.md @@ -17,7 +17,7 @@ Create extensions: >CREATE EXTENSION plpython3u; >CREATE EXTENSION pg_trgm; -If during the installation of plpython3u you get an error like: +If during the installation of plpython3u you are getting an error like: _“ERROR: could not load library "C:/Program Files/PostgreSQL/15/lib/plpython3.dll": The specified module could not be found.”_ this means that it is necessary to install the required packages. There is an example for Postgresql 15 using apt or apt-get (for Linux system):