diff --git a/Snowflake/OMOP CDM Results snowflake ddl.txt b/Snowflake/OMOP CDM Results snowflake ddl.txt new file mode 100644 index 0000000..a0f2e11 --- /dev/null +++ b/Snowflake/OMOP CDM Results snowflake ddl.txt @@ -0,0 +1,56 @@ +/********************************************************************************* +# Copyright 2019 Observational Health Data Sciences and Informatics +# +# +# 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. +********************************************************************************/ + +/************************ + + ####### # # ####### ###### ##### ###### # # ##### ### + # # ## ## # # # # # # # # ## ## # # # # # # + # # # # # # # # # # # # # # # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### # # + # # # # # # # # # # # # # # # # ### # # + # # # # # # # # # # # # # # # # # ### # # + ####### # # ####### # ##### ###### # # ## ##### ### ### + +snowflake script to create OMOP common data model results schema version 6.0 + +last revised: 05-Aug-2019 + +Authors: Kathryn Watson + + +*************************/ + +CREATE TABLE cohort_definition ( + cohort_definition_id INTEGER NOT NULL, + cohort_definition_name VARCHAR NOT NULL, + cohort_definition_description VARCHAR NULL, + definition_type_concept_id INTEGER NOT NULL, + cohort_definition_syntax VARCHAR NULL, + subject_concept_id INTEGER NOT NULL, + cohort_initiation_date DATE NULL +) +; + + +CREATE TABLE cohort +( + cohort_definition_id INTEGER NOT NULL, + subject_id INTEGER NOT NULL, + cohort_start_date DATE NOT NULL , + cohort_end_date DATE NOT NULL +) +; \ No newline at end of file diff --git a/Snowflake/OMOP CDM snowflake cluster keys.txt b/Snowflake/OMOP CDM snowflake cluster keys.txt new file mode 100644 index 0000000..9e8602f --- /dev/null +++ b/Snowflake/OMOP CDM snowflake cluster keys.txt @@ -0,0 +1,159 @@ +/********************************************************************************* +# Copyright 2019 Observational Health Data Sciences and Informatics +# +# +# 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. +********************************************************************************/ + +/************************ + + ####### # # ####### ###### ##### ###### # # ##### ### ###### # # ## ### + # # ## ## # # # # # # # # ## ## # # # # # # # # # # # # # # # ##### # #### ###### #### + # # # # # # # # # # # # # # # # # # # # # # # # # # ## # ## # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### # # ###### ### ### # # # # # # # # ##### #### + # # # # # # # # # # # # # # # # ### # # # # # # # # # # # # # # # # # # + # # # # # # # # # # # # # # # # # ### # # # # # # # # # ## # # # # # # # # + ####### # # ####### # ##### ###### # # ## ##### ### ### # # # ### # ### # # ##### # #### ###### #### + + +snowflake script to create suggested cluster keys within the OMOP common data model, version 6.0 + +last revised: 05-Aug-2019 + +author: Kathryn Watson + +description: These cluster keys are optional and should be evaluated on a table by table basis in each environment. Cluster keys increase compute costs and should only be implemented as needed for performance improvements. + +*************************/ + + +/************************ +************************* +************************* +************************* + +Cluster Keys + +************************* +************************* +************************* +************************/ + +/************************ + +Standardized vocabulary + +************************/ + +ALTER TABLE concept CLUSTER BY (concept_code,vocabulary_id,domain_id,concept_class_id); + +ALTER TABLE concept_relationship CLUSTER BY (concept_id_1,concept_id_2,relationship_id); + +ALTER TABLE concept_synonym CLUSTER BY (concept_id); + +ALTER TABLE concept_ancestor CLUSTER BY (ancestor_concept_id,descendant_concept_id); + +ALTER TABLE source_to_concept_map CLUSTER BY (target_concept_id,target_vocabulary_id,source_vocabulary_id,source_code); + +ALTER TABLE drug_strength CLUSTER BY (drug_concept_id,ingredient_concept_id); + + +/************************** + +Standardized meta-data + +***************************/ + + + + + +/************************ + +Standardized clinical data + +************************/ + +ALTER TABLE observation_period CLUSTER BY (person_id); + +ALTER TABLE specimen CLUSTER BY (person_id,specimen_concept_id); + +ALTER TABLE visit_occurrence CLUSTER BY (person_id,visit_concept_id); + +ALTER TABLE visit_detail CLUSTER BY (person_id,visit_detail_concept_id); + +ALTER TABLE procedure_occurrence CLUSTER BY (person_id,procedure_concept_id,visit_occurrence_id); + +ALTER TABLE drug_exposure CLUSTER BY (person_id,drug_concept_id,visit_occurrence_id); + +ALTER TABLE device_exposure CLUSTER BY (person_id,device_concept_id,visit_occurrence_id); + +ALTER TABLE condition_occurrence CLUSTER BY (person_id,condition_concept_id,visit_occurrence_id); + +ALTER TABLE measurement CLUSTER BY (person_id,measurement_concept_id,visit_occurrence_id); + +ALTER TABLE note CLUSTER BY (person_id,note_type_concept_id,visit_occurrence_id); + +ALTER TABLE note_nlp CLUSTER BY (note_id,note_nlp_concept_id); + +ALTER TABLE observation CLUSTER BY (person_id,observation_concept_id,visit_occurrence_id); + +ALTER TABLE survey_conduct CLUSTER BY (person_id); + +ALTER TABLE fact_relationship CLUSTER BY (domain_concept_id_1,domain_concept_id_2,relationship_concept_id); + + + +/************************ + +Standardized health system data + +************************/ + + + + + +/************************ + +Standardized health economics + +************************/ + +ALTER TABLE payer_plan_period CLUSTER BY (person_id); + +ALTER TABLE cost CLUSTER BY (person_id); + + +/************************ + +Standardized derived elements + +************************/ + + +ALTER TABLE drug_era CLUSTER BY (person_id,drug_concept_id); + +ALTER TABLE dose_era CLUSTER BY (person_id,drug_concept_id); + +ALTER TABLE condition_era CLUSTER BY (person_id,condition_concept_id); + + +/************************ + +Results elements + +************************/ + + +ALTER TABLE cohort CLUSTER BY (subject_id); diff --git a/Snowflake/OMOP CDM snowflake constraints.txt b/Snowflake/OMOP CDM snowflake constraints.txt new file mode 100644 index 0000000..f9dd961 --- /dev/null +++ b/Snowflake/OMOP CDM snowflake constraints.txt @@ -0,0 +1,506 @@ +/********************************************************************************* +# Copyright 2019 Observational Health Data Sciences and Informatics +# +# +# 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. +********************************************************************************/ + +/************************ + + ####### # # ####### ###### ##### ###### # # ##### ### ##### + # # ## ## # # # # # # # # ## ## # # # # # # # # #### # # #### ##### ##### ## # # # ##### #### + # # # # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # ## # # # + # # # # # # # ###### # # # # # # # # ###### # # # # # # # # #### # # # # # # # # # # #### + # # # # # # # # # # # # # # # # ### # # # # # # # # # # ##### ###### # # # # # # + # # # # # # # # # # # # # # # # # ### # # # # # # # ## # # # # # # # # # ## # # # + ####### # # ####### # ##### ###### # # ## ##### ### ### ##### #### # # #### # # # # # # # # # #### + + +snowflake script to create foreign key and unique constraints within the OMOP common data model, version 6.0 + +last revised: 05-Aug-2019 + +author: Kathryn Watson + + +*************************/ + + +/************************ +************************* +************************* +************************* + +Foreign key constraints + +************************* +************************* +************************* +************************/ + + +/************************ + +Standardized vocabulary + +************************/ + + +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_synonym_language FOREIGN KEY (language_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE concept_ancestor ADD CONSTRAINT fpk_concept_ancestor_concept_1 FOREIGN KEY (ancestor_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE concept_ancestor ADD CONSTRAINT fpk_concept_ancestor_concept_2 FOREIGN KEY (descendant_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE source_to_concept_map ADD CONSTRAINT fpk_source_to_concept_map_v_1 FOREIGN KEY (source_vocabulary_id) REFERENCES vocabulary (vocabulary_id); + +ALTER TABLE source_to_concept_map ADD CONSTRAINT fpk_source_to_concept_map_v_2 FOREIGN KEY (target_vocabulary_id) REFERENCES vocabulary (vocabulary_id); + +ALTER TABLE source_to_concept_map ADD CONSTRAINT fpk_source_to_concept_map_c_1 FOREIGN KEY (target_concept_id) REFERENCES concept (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); + + +/************************** + +Standardized meta-data + +***************************/ + + +ALTER TABLE metadata ADD CONSTRAINT fpk_metadata_concept FOREIGN KEY (metadata_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE metadata ADD CONSTRAINT fpk_metadata_type_concept FOREIGN KEY (metadata_type_concept_id) REFERENCES concept (concept_id); + + +/************************ + +Standardized clinical data + +************************/ + +ALTER TABLE person ADD CONSTRAINT fpk_person_gender_concept FOREIGN KEY (gender_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE person ADD CONSTRAINT fpk_person_race_concept FOREIGN KEY (race_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE person ADD CONSTRAINT fpk_person_ethnicity_concept FOREIGN KEY (ethnicity_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE person ADD CONSTRAINT fpk_person_gender_concept_s FOREIGN KEY (gender_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE person ADD CONSTRAINT fpk_person_race_concept_s FOREIGN KEY (race_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE person ADD CONSTRAINT fpk_person_ethnicity_concept_s FOREIGN KEY (ethnicity_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE person ADD CONSTRAINT fpk_person_location FOREIGN KEY (location_id) REFERENCES location (location_id); + +ALTER TABLE person ADD CONSTRAINT fpk_person_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); + +ALTER TABLE person ADD CONSTRAINT fpk_person_care_site FOREIGN KEY (care_site_id) REFERENCES care_site (care_site_id); + + +ALTER TABLE observation_period ADD CONSTRAINT fpk_observation_period_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE observation_period ADD CONSTRAINT fpk_observation_period_concept FOREIGN KEY (period_type_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE specimen ADD CONSTRAINT fpk_specimen_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE specimen ADD CONSTRAINT fpk_specimen_concept FOREIGN KEY (specimen_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE specimen ADD CONSTRAINT fpk_specimen_type_concept FOREIGN KEY (specimen_type_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE specimen ADD CONSTRAINT fpk_specimen_unit_concept FOREIGN KEY (unit_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE specimen ADD CONSTRAINT fpk_specimen_site_concept FOREIGN KEY (anatomic_site_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE specimen ADD CONSTRAINT fpk_specimen_status_concept FOREIGN KEY (disease_status_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_concept FOREIGN KEY (visit_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_type_concept FOREIGN KEY (visit_type_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); + +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_care_site FOREIGN KEY (care_site_id) REFERENCES care_site (care_site_id); + +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_concept_s FOREIGN KEY (visit_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_admitting_s FOREIGN KEY (admitted_from_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_discharge FOREIGN KEY (discharge_to_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_preceding FOREIGN KEY (preceding_visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); + + +ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_concept FOREIGN KEY (visit_detail_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_type_concept FOREIGN KEY (visit_detail_type_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); + +ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_care_site FOREIGN KEY (care_site_id) REFERENCES care_site (care_site_id); + +ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_discharge FOREIGN KEY (discharge_to_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_admitting_s FOREIGN KEY (admitted_from_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_concept_s FOREIGN KEY (visit_detail_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_preceding FOREIGN KEY (preceding_visit_detail_id) REFERENCES visit_detail (visit_detail_id); + +ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_parent FOREIGN KEY (visit_detail_parent_id) REFERENCES visit_detail (visit_detail_id); + +ALTER TABLE visit_detail ADD CONSTRAINT fpd_v_detail_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); + + +ALTER TABLE procedure_occurrence ADD CONSTRAINT fpk_procedure_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE procedure_occurrence ADD CONSTRAINT fpk_procedure_concept FOREIGN KEY (procedure_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE procedure_occurrence ADD CONSTRAINT fpk_procedure_type_concept FOREIGN KEY (procedure_type_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE procedure_occurrence ADD CONSTRAINT fpk_procedure_modifier FOREIGN KEY (modifier_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE procedure_occurrence ADD CONSTRAINT fpk_procedure_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); + +ALTER TABLE procedure_occurrence ADD CONSTRAINT fpk_procedure_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); + +ALTER TABLE procedure_occurrence ADD CONSTRAINT fpk_procedure_v_detail FOREIGN KEY (visit_detail_id) REFERENCES visit_detail (visit_detail_id); + +ALTER TABLE procedure_occurrence ADD CONSTRAINT fpk_procedure_concept_s FOREIGN KEY (procedure_source_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE drug_exposure ADD CONSTRAINT fpk_drug_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE drug_exposure ADD CONSTRAINT fpk_drug_concept FOREIGN KEY (drug_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE drug_exposure ADD CONSTRAINT fpk_drug_type_concept FOREIGN KEY (drug_type_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE drug_exposure ADD CONSTRAINT fpk_drug_route_concept FOREIGN KEY (route_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE drug_exposure ADD CONSTRAINT fpk_drug_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); + +ALTER TABLE drug_exposure ADD CONSTRAINT fpk_drug_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); + +ALTER TABLE drug_exposure ADD CONSTRAINT fpk_drug_v_detail FOREIGN KEY (visit_detail_id) REFERENCES visit_detail (visit_detail_id); + +ALTER TABLE drug_exposure ADD CONSTRAINT fpk_drug_concept_s FOREIGN KEY (drug_source_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE device_exposure ADD CONSTRAINT fpk_device_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE device_exposure ADD CONSTRAINT fpk_device_concept FOREIGN KEY (device_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE device_exposure ADD CONSTRAINT fpk_device_type_concept FOREIGN KEY (device_type_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE device_exposure ADD CONSTRAINT fpk_device_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); + +ALTER TABLE device_exposure ADD CONSTRAINT fpk_device_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); + +ALTER TABLE device_exposure ADD CONSTRAINT fpk_device_v_detail FOREIGN KEY (visit_detail_id) REFERENCES visit_detail (visit_detail_id); + +ALTER TABLE device_exposure ADD CONSTRAINT fpk_device_concept_s FOREIGN KEY (device_source_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_concept FOREIGN KEY (condition_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_type_concept FOREIGN KEY (condition_type_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_status_concept FOREIGN KEY (condition_status_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); + +ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); + +ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_v_detail FOREIGN KEY (visit_detail_id) REFERENCES visit_detail (visit_detail_id); + +ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_concept_s FOREIGN KEY (condition_source_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_concept FOREIGN KEY (measurement_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_type_concept FOREIGN KEY (measurement_type_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_operator FOREIGN KEY (operator_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_value FOREIGN KEY (value_as_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_unit FOREIGN KEY (unit_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); + +ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); + +ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_v_detail FOREIGN KEY (visit_detail_id) REFERENCES visit_detail (visit_detail_id); + +ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_concept_s FOREIGN KEY (measurement_source_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE note ADD CONSTRAINT fpk_note_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE note ADD CONSTRAINT fpk_note_type_concept FOREIGN KEY (note_type_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note ADD CONSTRAINT fpk_note_class_concept FOREIGN KEY (note_class_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note ADD CONSTRAINT fpk_note_encoding_concept FOREIGN KEY (encoding_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note ADD CONSTRAINT fpk_language_concept FOREIGN KEY (language_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note ADD CONSTRAINT fpk_note_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); + +ALTER TABLE note ADD CONSTRAINT fpk_note_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); + +ALTER TABLE note ADD CONSTRAINT fpk_note_v_detail FOREIGN KEY (visit_detail_id) REFERENCES visit_detail (visit_detail_id); + + +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_note FOREIGN KEY (note_id) REFERENCES note (note_id); + +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_section_concept FOREIGN KEY (section_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_concept FOREIGN KEY (note_nlp_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_concept_s FOREIGN KEY (note_nlp_source_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE observation ADD CONSTRAINT fpk_observation_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE observation ADD CONSTRAINT fpk_observation_concept FOREIGN KEY (observation_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE observation ADD CONSTRAINT fpk_observation_type_concept FOREIGN KEY (observation_type_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE observation ADD CONSTRAINT fpk_observation_value FOREIGN KEY (value_as_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE observation ADD CONSTRAINT fpk_observation_qualifier FOREIGN KEY (qualifier_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE observation ADD CONSTRAINT fpk_observation_unit FOREIGN KEY (unit_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE observation ADD CONSTRAINT fpk_observation_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); + +ALTER TABLE observation ADD CONSTRAINT fpk_observation_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); + +ALTER TABLE observation ADD CONSTRAint fpk_observation_v_detail FOREIGN KEY (visit_detail_id) REFERENCES visit_detail (visit_detail_id); + +ALTER TABLE observation ADD CONSTRAINT fpk_observation_concept_s FOREIGN KEY (observation_source_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE survey_conduct ADD CONSTRAINT fpk_survey_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE survey_conduct ADD CONSTRAINT fpk_survey_concept FOREIGN KEY (survey_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE survey_conduct ADD CONSTRAINT fpk_survey_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); + +ALTER TABLE survey_conduct ADD CONSTRAINT fpk_survey_assist FOREIGN KEY (assisted_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE survey_conduct ADD CONSTRAINT fpk_respondent_type FOREIGN KEY (respondent_type_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE survey_conduct ADD CONSTRAINT fpk_survey_timing FOREIGN KEY (timing_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE survey_conduct ADD CONSTRAINT fpk_collection_method FOREIGN KEY (collection_method_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE survey_conduct ADD CONSTRAINT fpk_survey_source FOREIGN KEY (survey_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE survey_conduct ADD CONSTRAINT fpk_validation FOREIGN KEY (validated_survey_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE survey_conduct ADD CONSTRAINT fpk_survey_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); + +ALTER TABLE survey_conduct ADD CONSTRAINT fpk_survey_v_detail FOREIGN KEY (visit_detail_id) REFERENCES visit_detail (visit_detail_id); + +ALTER TABLE survey_conduct ADD CONSTRAINT fpk_response_visit FOREIGN KEY (response_visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); + + +ALTER TABLE fact_relationship ADD CONSTRAINT fpk_fact_domain_1 FOREIGN KEY (domain_concept_id_1) REFERENCES concept (concept_id); + +ALTER TABLE fact_relationship ADD CONSTRAINT fpk_fact_domain_2 FOREIGN KEY (domain_concept_id_2) REFERENCES concept (concept_id); + +ALTER TABLE fact_relationship ADD CONSTRAINT fpk_fact_relationship FOREIGN KEY (relationship_concept_id) REFERENCES concept (concept_id); + + + +/************************ + +Standardized health system data + +************************/ + +ALTER TABLE location_history ADD CONSTRAINT fpk_location_history FOREIGN KEY ( location_id ) REFERENCES location ( location_id ) ; + +ALTER TABLE location_history ADD CONSTRAINT fpk_relationship_type FOREIGN KEY (relationship_type_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE care_site ADD CONSTRAINT fpk_care_site_place FOREIGN KEY (place_of_service_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE care_site ADD CONSTRAINT fpk_care_site_location FOREIGN KEY (location_id) REFERENCES location (location_id); + + +ALTER TABLE provider ADD CONSTRAINT fpk_provider_specialty FOREIGN KEY (specialty_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE provider ADD CONSTRAINT fpk_provider_care_site FOREIGN KEY (care_site_id) REFERENCES care_site (care_site_id); + +ALTER TABLE provider ADD CONSTRAINT fpk_provider_gender FOREIGN KEY (gender_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE provider ADD CONSTRAINT fpk_provider_specialty_s FOREIGN KEY (specialty_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE provider ADD CONSTRAINT fpk_provider_gender_s FOREIGN KEY (gender_source_concept_id) REFERENCES concept (concept_id); + + + +/************************ + +Standardized health economics + +************************/ + +ALTER TABLE payer_plan_period ADD CONSTRAINT fpk_payer_plan_period FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE payer_plan_period ADD CONSTRAINT fpk_contract_person FOREIGN KEY (contract_person_id) REFERENCES person (person_id); + +ALTER TABLE payer_plan_period ADD CONSTRAINT fpk_payer_concept FOREIGN KEY (payer_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE payer_plan_period ADD CONSTRAINT fpk_plan_concept_id FOREIGN KEY (plan_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE payer_plan_period ADD CONSTRAINT fpk_contract_concept FOREIGN KEY (contract_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE payer_plan_period ADD CONSTRAINT fpk_sponsor_concept FOREIGN KEY (sponsor_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE payer_plan_period ADD CONSTRAINT fpk_stop_reason_concept FOREIGN KEY (stop_reason_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE payer_plan_period ADD CONSTRAINT fpk_payer_s FOREIGN KEY (payer_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE payer_plan_period ADD CONSTRAINT fpk_plan_s FOREIGN KEY (plan_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE payer_plan_period ADD CONSTRAINT fpk_contract_s FOREIGN KEY (contract_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE payer_plan_period ADD CONSTRAINT fpk_sponsor_s FOREIGN KEY (sponsor_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE payer_plan_period ADD CONSTRAINT fpk_stop_reason_s FOREIGN KEY (stop_reason_source_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE cost ADD CONSTRAINT fpk_cost_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE cost ADD CONSTRAINT fpk_cost_concept FOREIGN KEY (cost_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE cost ADD CONSTRAINT fpk_cost_type FOREIGN KEY (cost_type_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE cost ADD CONSTRAINT fpk_cost_currency FOREIGN KEY (currency_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE cost ADD CONSTRAINT fpk_revenue_concept FOREIGN KEY (revenue_code_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE cost ADD CONSTRAINT fpk_drg_concept FOREIGN KEY (drg_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE cost ADD CONSTRAINT fpk_cost_s FOREIGN KEY (cost_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE cost ADD CONSTRAINT fpk_cost_period FOREIGN KEY (payer_plan_period_id) REFERENCES payer_plan_period (payer_plan_period_id); + + +/************************ + +Standardized derived elements + +************************/ + + +ALTER TABLE drug_era ADD CONSTRAINT fpk_drug_era_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE drug_era ADD CONSTRAINT fpk_drug_era_concept FOREIGN KEY (drug_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE dose_era ADD CONSTRAINT fpk_dose_era_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE dose_era ADD CONSTRAINT fpk_dose_era_concept FOREIGN KEY (drug_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE dose_era ADD CONSTRAINT fpk_dose_era_unit_concept FOREIGN KEY (unit_concept_id) REFERENCES concept (concept_id); + + +ALTER TABLE condition_era ADD CONSTRAINT fpk_condition_era_person FOREIGN KEY (person_id) REFERENCES person (person_id); + +ALTER TABLE condition_era ADD CONSTRAINT fpk_condition_era_concept FOREIGN KEY (condition_concept_id) REFERENCES concept (concept_id); + + +/************************ + +Results elements + +************************/ + + +ALTER TABLE cohort_definition ADD CONSTRAINT fpk_cohort_definition_concept FOREIGN KEY ( definition_type_concept_id ) REFERENCES concept ( concept_id ); + +ALTER TABLE cohort_definition ADD CONSTRAINT fpk_subject_concept FOREIGN KEY ( subject_concept_id ) REFERENCES concept ( concept_id ); + +ALTER TABLE cohort ADD CONSTRAINT fpk_cohort_definition FOREIGN KEY ( cohort_definition_id ) REFERENCES cohort_definition ( cohort_definition_id ); + + + +/************************ +************************* +************************* +************************* + +Unique constraints + +************************* +************************* +************************* +************************/ + +ALTER TABLE concept_synonym ADD CONSTRAINT uq_concept_synonym UNIQUE (concept_id, concept_synonym_name, language_concept_id); diff --git a/Snowflake/OMOP CDM snowflake ddl.txt b/Snowflake/OMOP CDM snowflake ddl.txt new file mode 100644 index 0000000..130770d --- /dev/null +++ b/Snowflake/OMOP CDM snowflake ddl.txt @@ -0,0 +1,706 @@ +/********************************************************************************* +# Copyright 2019 Observational Health Data Sciences and Informatics +# +# +# 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. +********************************************************************************/ + +/************************ + + ####### # # ####### ###### ##### ###### # # ##### ### + # # ## ## # # # # # # # # ## ## # # # # # # + # # # # # # # # # # # # # # # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### # # + # # # # # # # # # # # # # # # # ### # # + # # # # # # # # # # # # # # # # # ### # # + ####### # # ####### # ##### ###### # # ## ##### ### ### + +snowflake script to create OMOP common data model version 6.0 + +last revised: 05-Aug-2019 + +Authors: Kathryn Watson + + +*************************/ + + +/************************ + +Standardized vocabulary + +************************/ + + +CREATE TABLE concept ( + concept_id INTEGER NOT NULL , + concept_name VARCHAR NOT NULL , + domain_id VARCHAR NOT NULL , + vocabulary_id VARCHAR NOT NULL , + concept_class_id VARCHAR NOT NULL , + standard_concept VARCHAR NULL , + concept_code VARCHAR NOT NULL , + valid_start_date DATE NOT NULL , + valid_end_date DATE NOT NULL , + invalid_reason VARCHAR NULL +) +; + + +CREATE TABLE vocabulary ( + vocabulary_id VARCHAR NOT NULL, + vocabulary_name VARCHAR NOT NULL, + vocabulary_reference VARCHAR NOT NULL, + vocabulary_version VARCHAR NULL, + vocabulary_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE domain ( + domain_id VARCHAR NOT NULL, + domain_name VARCHAR NOT NULL, + domain_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE concept_class ( + concept_class_id VARCHAR NOT NULL, + concept_class_name VARCHAR NOT NULL, + concept_class_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE concept_relationship ( + concept_id_1 INTEGER NOT NULL, + concept_id_2 INTEGER NOT NULL, + relationship_id VARCHAR NOT NULL, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR NULL + ) +; + + +CREATE TABLE relationship ( + relationship_id VARCHAR NOT NULL, + relationship_name VARCHAR NOT NULL, + is_hierarchical VARCHAR NOT NULL, + defines_ancestry VARCHAR NOT NULL, + reverse_relationship_id VARCHAR NOT NULL, + relationship_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE concept_synonym ( + concept_id INTEGER NOT NULL, + concept_synonym_name VARCHAR NOT NULL, + language_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE concept_ancestor ( + ancestor_concept_id INTEGER NOT NULL, + descendant_concept_id INTEGER NOT NULL, + min_levels_of_separation INTEGER NOT NULL, + max_levels_of_separation INTEGER NOT NULL +) +; + + +CREATE TABLE source_to_concept_map ( + source_code VARCHAR NOT NULL, + source_concept_id INTEGER NOT NULL, + source_vocabulary_id VARCHAR NOT NULL, + source_code_description VARCHAR NULL, + target_concept_id INTEGER NOT NULL, + target_vocabulary_id VARCHAR NOT NULL, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR NULL +) +; + + +CREATE TABLE drug_strength ( + drug_concept_id INTEGER NOT NULL, + ingredient_concept_id INTEGER NOT NULL, + amount_value FLOAT NULL, + amount_unit_concept_id INTEGER NULL, + numerator_value FLOAT NULL, + numerator_unit_concept_id INTEGER NULL, + denominator_value FLOAT NULL, + denominator_unit_concept_id INTEGER NULL, + box_size INTEGER NULL, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR NULL +) +; + + +/************************** + +Standardized meta-data + +***************************/ + + +CREATE TABLE cdm_source +( + cdm_source_name VARCHAR NOT NULL , + cdm_source_abbreviation VARCHAR NULL , + cdm_holder VARCHAR NULL , + source_description VARCHAR NULL , + source_documentation_reference VARCHAR NULL , + cdm_etl_reference VARCHAR NULL , + source_release_date DATE NULL , + cdm_release_date DATE NULL , + cdm_version VARCHAR NULL , + vocabulary_version VARCHAR NULL +) +; + + +CREATE TABLE metadata +( + metadata_concept_id INTEGER NOT NULL , + metadata_type_concept_id INTEGER NOT NULL , + name VARCHAR NOT NULL , + value_as_string VARCHAR NULL , + value_as_concept_id INTEGER NULL , + metadata_date DATE NULL , + metadata_datetime TIMESTAMP NULL +) +; + +INSERT INTO metadata (metadata_concept_id, metadata_type_concept_id, name, value_as_string, value_as_concept_id, metadata_date, metadata_datetime) --Added cdm version record +VALUES (0,0,'CDM Version', '6.0',0,NULL,NULL) +; + + +/************************ + +Standardized clinical data + +************************/ + + +CREATE TABLE person +( + person_id INTEGER NOT NULL , + gender_concept_id INTEGER NOT NULL , + year_of_birth INTEGER NOT NULL , + month_of_birth INTEGER NULL, + day_of_birth INTEGER NULL, + birth_datetime TIMESTAMP NULL, + death_datetime TIMESTAMP NULL, + race_concept_id INTEGER NOT NULL, + ethnicity_concept_id INTEGER NOT NULL, + location_id INTEGER NULL, + provider_id INTEGER NULL, + care_site_id INTEGER NULL, + person_source_value VARCHAR NULL, + gender_source_value VARCHAR NULL, + gender_source_concept_id INTEGER NOT NULL, + race_source_value VARCHAR NULL, + race_source_concept_id INTEGER NOT NULL, + ethnicity_source_value VARCHAR NULL, + ethnicity_source_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE observation_period +( + observation_period_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + observation_period_start_date DATE NOT NULL , + observation_period_end_date DATE NOT NULL , + period_type_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE specimen +( + specimen_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + specimen_concept_id INTEGER NOT NULL , + specimen_type_concept_id INTEGER NOT NULL , + specimen_date DATE NULL , + specimen_datetime TIMESTAMP NOT NULL , + quantity FLOAT NULL , + unit_concept_id INTEGER NULL , + anatomic_site_concept_id INTEGER NOT NULL , + disease_status_concept_id INTEGER NOT NULL , + specimen_source_id VARCHAR NULL , + specimen_source_value VARCHAR NULL , + unit_source_value VARCHAR NULL , + anatomic_site_source_value VARCHAR NULL , + disease_status_source_value VARCHAR NULL +) +; + + +CREATE TABLE visit_occurrence +( + visit_occurrence_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + visit_concept_id INTEGER NOT NULL , + visit_start_date DATE NULL , + visit_start_datetime TIMESTAMP NOT NULL , + visit_end_date DATE NULL , + visit_end_datetime TIMESTAMP NOT NULL , + visit_type_concept_id INTEGER NOT NULL , + provider_id INTEGER NULL, + care_site_id INTEGER NULL, + visit_source_value VARCHAR NULL, + visit_source_concept_id INTEGER NOT NULL , + admitted_from_concept_id INTEGER NOT NULL , + admitted_from_source_value VARCHAR NULL , + discharge_to_source_value VARCHAR NULL , + discharge_to_concept_id INTEGER NOT NULL , + preceding_visit_occurrence_id INTEGER NULL +) +; + + +CREATE TABLE visit_detail +( + visit_detail_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + visit_detail_concept_id INTEGER NOT NULL , + visit_detail_start_date DATE NULL , + visit_detail_start_datetime TIMESTAMP NOT NULL , + visit_detail_end_date DATE NULL , + visit_detail_end_datetime TIMESTAMP NOT NULL , + visit_detail_type_concept_id INTEGER NOT NULL , + provider_id INTEGER NULL , + care_site_id INTEGER NULL , + discharge_to_concept_id INTEGER NOT NULL , + admitted_from_concept_id INTEGER NOT NULL , + admitted_from_source_value VARCHAR NULL , + visit_detail_source_value VARCHAR NULL , + visit_detail_source_concept_id INTEGER NOT NULL , + discharge_to_source_value VARCHAR NULL , + preceding_visit_detail_id INTEGER NULL , + visit_detail_parent_id INTEGER NULL , + visit_occurrence_id INTEGER NOT NULL +) +; + + +CREATE TABLE procedure_occurrence +( + procedure_occurrence_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + procedure_concept_id INTEGER NOT NULL , + procedure_date DATE NULL , + procedure_datetime TIMESTAMP NOT NULL , + procedure_type_concept_id INTEGER NOT NULL , + modifier_concept_id INTEGER NOT NULL , + quantity INTEGER NULL , + provider_id INTEGER NULL , + visit_occurrence_id INTEGER NULL , + visit_detail_id INTEGER NULL , + procedure_source_value VARCHAR NULL , + procedure_source_concept_id INTEGER NOT NULL , + modifier_source_value VARCHAR NULL +) +; + + +CREATE TABLE drug_exposure +( + drug_exposure_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + drug_concept_id INTEGER NOT NULL , + drug_exposure_start_date DATE NULL , + drug_exposure_start_datetime TIMESTAMP NOT NULL , + drug_exposure_end_date DATE NULL , + drug_exposure_end_datetime TIMESTAMP NOT NULL , + verbatim_end_date DATE NULL , + drug_type_concept_id INTEGER NOT NULL , + stop_reason VARCHAR NULL , + refills INTEGER NULL , + quantity FLOAT NULL , + days_supply INTEGER NULL , + sig VARCHAR NULL , + route_concept_id INTEGER NOT NULL , + lot_number VARCHAR NULL , + provider_id INTEGER NULL , + visit_occurrence_id INTEGER NULL , + visit_detail_id INTEGER NULL , + drug_source_value VARCHAR NULL , + drug_source_concept_id INTEGER NOT NULL , + route_source_value VARCHAR NULL , + dose_unit_source_value VARCHAR NULL +) +; + + +CREATE TABLE device_exposure +( + device_exposure_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + device_concept_id INTEGER NOT NULL , + device_exposure_start_date DATE NULL , + device_exposure_start_datetime TIMESTAMP NOT NULL , + device_exposure_end_date DATE NULL , + device_exposure_end_datetime TIMESTAMP NULL , + device_type_concept_id INTEGER NOT NULL , + unique_device_id VARCHAR NULL , + quantity INTEGER NULL , + provider_id INTEGER NULL , + visit_occurrence_id INTEGER NULL , + visit_detail_id INTEGER NULL , + device_source_value VARCHAR NULL , + device_source_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE condition_occurrence +( + condition_occurrence_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + condition_concept_id INTEGER NOT NULL , + condition_start_date DATE NULL , + condition_start_datetime TIMESTAMP NOT NULL , + condition_end_date DATE NULL , + condition_end_datetime TIMESTAMP NULL , + condition_type_concept_id INTEGER NOT NULL , + condition_status_concept_id INTEGER NOT NULL , + stop_reason VARCHAR NULL , + provider_id INTEGER NULL , + visit_occurrence_id INTEGER NULL , + visit_detail_id INTEGER NULL , + condition_source_value VARCHAR NULL , + condition_source_concept_id INTEGER NOT NULL , + condition_status_source_value VARCHAR NULL +) +; + + +CREATE TABLE measurement +( + measurement_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + measurement_concept_id INTEGER NOT NULL , + measurement_date DATE NULL , + measurement_datetime TIMESTAMP NOT NULL , + measurement_time VARCHAR NULL, + measurement_type_concept_id INTEGER NOT NULL , + operator_concept_id INTEGER NULL , + value_as_number FLOAT NULL , + value_as_concept_id INTEGER NULL , + unit_concept_id INTEGER NULL , + range_low FLOAT NULL , + range_high FLOAT NULL , + provider_id INTEGER NULL , + visit_occurrence_id INTEGER NULL , + visit_detail_id INTEGER NULL , + measurement_source_value VARCHAR NULL , + measurement_source_concept_id INTEGER NOT NULL , + unit_source_value VARCHAR NULL , + value_source_value VARCHAR NULL +) +; + + +CREATE TABLE note +( + note_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + note_event_id INTEGER NULL , + note_event_field_concept_id INTEGER NOT NULL , + note_date DATE NULL , + note_datetime TIMESTAMP NOT NULL , + note_type_concept_id INTEGER NOT NULL , + note_class_concept_id INTEGER NOT NULL , + note_title VARCHAR NULL , + note_text VARCHAR NULL , + encoding_concept_id INTEGER NOT NULL , + language_concept_id INTEGER NOT NULL , + provider_id INTEGER NULL , + visit_occurrence_id INTEGER NULL , + visit_detail_id INTEGER NULL , + note_source_value VARCHAR NULL +) +; + + +CREATE TABLE note_nlp +( + note_nlp_id INTEGER NOT NULL , + note_id INTEGER NOT NULL , + section_concept_id INTEGER NOT NULL , + snippet VARCHAR NULL , + "offset" VARCHAR NULL , + lexical_variant VARCHAR NOT NULL , + note_nlp_concept_id INTEGER NOT NULL , + nlp_system VARCHAR NULL , + nlp_date DATE NOT NULL , + nlp_datetime TIMESTAMP NULL , + term_exists VARCHAR NULL , + term_temporal VARCHAR NULL , + term_modifiers VARCHAR NULL , + note_nlp_source_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE observation +( + observation_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + observation_concept_id INTEGER NOT NULL , + observation_date DATE NULL , + observation_datetime TIMESTAMP NOT NULL , + observation_type_concept_id INTEGER NOT NULL , + value_as_number FLOAT NULL , + value_as_string VARCHAR NULL , + value_as_concept_id INTEGER NULL , + qualifier_concept_id INTEGER NULL , + unit_concept_id INTEGER NULL , + provider_id INTEGER NULL , + visit_occurrence_id INTEGER NULL , + visit_detail_id INTEGER NULL , + observation_source_value VARCHAR NULL , + observation_source_concept_id INTEGER NOT NULL , + unit_source_value VARCHAR NULL , + qualifier_source_value VARCHAR NULL , + observation_event_id INTEGER NULL , + obs_event_field_concept_id INTEGER NOT NULL , + value_as_datetime TIMESTAMP NULL +) +; + + +CREATE TABLE survey_conduct --Table added +( + survey_conduct_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + survey_concept_id INTEGER NOT NULL , + survey_start_date DATE NULL , + survey_start_datetime TIMESTAMP NULL , + survey_end_date DATE NULL , + survey_end_datetime TIMESTAMP NOT NULL , + provider_id INTEGER NULL , + assisted_concept_id INTEGER NOT NULL , + respondent_type_concept_id INTEGER NOT NULL , + timing_concept_id INTEGER NOT NULL , + collection_method_concept_id INTEGER NOT NULL , + assisted_source_value VARCHAR NULL , + respondent_type_source_value VARCHAR NULL , + timing_source_value VARCHAR NULL , + collection_method_source_value VARCHAR NULL , + survey_source_value VARCHAR NULL , + survey_source_concept_id INTEGER NOT NULL , + survey_source_identifier VARCHAR NULL , + validated_survey_concept_id INTEGER NOT NULL , + validated_survey_source_value VARCHAR NULL , + survey_version_number VARCHAR NULL , + visit_occurrence_id INTEGER NULL , + visit_detail_id INTEGER NULL , + response_visit_occurrence_id INTEGER NULL +) +; + + +CREATE TABLE fact_relationship +( + domain_concept_id_1 INTEGER NOT NULL , + fact_id_1 INTEGER NOT NULL , + domain_concept_id_2 INTEGER NOT NULL , + fact_id_2 INTEGER NOT NULL , + relationship_concept_id INTEGER NOT NULL +) +; + + + +/************************ + +Standardized health system data + +************************/ + + +CREATE TABLE location +( + location_id INTEGER NOT NULL , + address_1 VARCHAR NULL , + address_2 VARCHAR NULL , + city VARCHAR NULL , + state VARCHAR NULL , + zip VARCHAR NULL , + county VARCHAR NULL , + country VARCHAR NULL , + location_source_value VARCHAR NULL , + latitude FLOAT NULL , + longitude FLOAT NULL +) +; + + +CREATE TABLE location_history --Table added +( + location_history_id INTEGER NOT NULL , + location_id INTEGER NOT NULL , + relationship_type_concept_id INTEGER NOT NULL , + domain_id VARCHAR NOT NULL , + entity_id INTEGER NOT NULL , + start_date DATE NOT NULL , + end_date DATE NULL +) +; + + +CREATE TABLE care_site +( + care_site_id INTEGER NOT NULL , + care_site_name VARCHAR NULL , + place_of_service_concept_id INTEGER NOT NULL , + location_id INTEGER NULL , + care_site_source_value VARCHAR NULL , + place_of_service_source_value VARCHAR NULL +) +; + + +CREATE TABLE provider +( + provider_id INTEGER NOT NULL , + provider_name VARCHAR NULL , + NPI VARCHAR NULL , + DEA VARCHAR NULL , + specialty_concept_id INTEGER NOT NULL , + care_site_id INTEGER NULL , + year_of_birth INTEGER NULL , + gender_concept_id INTEGER NULL , + provider_source_value VARCHAR NULL , + specialty_source_value VARCHAR NULL , + specialty_source_concept_id INTEGER NOT NULL , + gender_source_value VARCHAR NULL , + gender_source_concept_id INTEGER NOT NULL +) +; + + +/************************ + +Standardized health economics + +************************/ + + +CREATE TABLE payer_plan_period +( + payer_plan_period_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + contract_person_id INTEGER NULL , + payer_plan_period_start_date DATE NOT NULL , + payer_plan_period_end_date DATE NOT NULL , + payer_concept_id INTEGER NOT NULL , + plan_concept_id INTEGER NOT NULL , + contract_concept_id INTEGER NOT NULL , + sponsor_concept_id INTEGER NOT NULL , + stop_reason_concept_id INTEGER NOT NULL , + payer_source_value VARCHAR NULL , + payer_source_concept_id INTEGER NOT NULL , + plan_source_value VARCHAR NULL , + plan_source_concept_id INTEGER NOT NULL , + contract_source_value VARCHAR NULL , + contract_source_concept_id INTEGER NOT NULL , + sponsor_source_value VARCHAR NULL , + sponsor_source_concept_id INTEGER NOT NULL , + family_source_value VARCHAR NULL , + stop_reason_source_value VARCHAR NULL , + stop_reason_source_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE cost +( + cost_id INTEGER NOT NULL , + person_id INTEGER NOT NULL, + cost_event_id INTEGER NOT NULL , + cost_event_field_concept_id INTEGER NOT NULL , + cost_concept_id INTEGER NOT NULL , + cost_type_concept_id INTEGER NOT NULL , + currency_concept_id INTEGER NOT NULL , + cost FLOAT NULL , + incurred_date DATE NOT NULL , + billed_date DATE NULL , + paid_date DATE NULL , + revenue_code_concept_id INTEGER NOT NULL , + drg_concept_id INTEGER NOT NULL , + cost_source_value VARCHAR NULL , + cost_source_concept_id INTEGER NOT NULL , + revenue_code_source_value VARCHAR NULL , + drg_source_value VARCHAR NULL , + payer_plan_period_id INTEGER NULL +) +; + + +/************************ + +Standardized derived elements + +************************/ + + +CREATE TABLE drug_era +( + drug_era_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + drug_concept_id INTEGER NOT NULL , + drug_era_start_datetime TIMESTAMP NOT NULL , + drug_era_end_datetime TIMESTAMP NOT NULL , + drug_exposure_count INTEGER NULL , + gap_days INTEGER NULL +) +; + + +CREATE TABLE dose_era +( + dose_era_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + drug_concept_id INTEGER NOT NULL , + unit_concept_id INTEGER NOT NULL , + dose_value FLOAT NOT NULL , + dose_era_start_datetime TIMESTAMP NOT NULL , + dose_era_end_datetime TIMESTAMP NOT NULL +) +; + + +CREATE TABLE condition_era +( + condition_era_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , + condition_concept_id INTEGER NOT NULL , + condition_era_start_datetime TIMESTAMP NOT NULL , + condition_era_end_datetime TIMESTAMP NOT NULL , + condition_occurrence_count INTEGER NULL +) +; \ No newline at end of file diff --git a/Snowflake/OMOP CDM snowflake primary keys.txt b/Snowflake/OMOP CDM snowflake primary keys.txt new file mode 100644 index 0000000..18c2aaa --- /dev/null +++ b/Snowflake/OMOP CDM snowflake primary keys.txt @@ -0,0 +1,177 @@ +/********************************************************************************* +# Copyright 2019 Observational Health Data Sciences and Informatics +# +# +# 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. +********************************************************************************/ + +/************************ + + ####### # # ####### ###### ##### ###### # # ##### ### ###### # # ## ### + # # ## ## # # # # # # # # ## ## # # # # # # # # # # # # # # # ##### # #### ###### #### + # # # # # # # # # # # # # # # # # # # # # # # # # # ## # ## # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### # # ###### ### ### # # # # # # # # ##### #### + # # # # # # # # # # # # # # # # ### # # # # # # # # # # # # # # # # # # + # # # # # # # # # # # # # # # # # ### # # # # # # # # # ## # # # # # # # # + ####### # # ####### # ##### ###### # # ## ##### ### ### # # # ### # ### # # ##### # #### ###### #### + + +snowflake script to create the required primary keys within the OMOP common data model, version 6.0 + +last revised: 05-Aug-2019 + +author: Kathryn Watson + +description: These primary keys are considered a minimal requirement to ensure adequate performance of analyses. + +*************************/ + + +/************************ +************************* +************************* +************************* + +Primary key constraints + +************************* +************************* +************************* +************************/ + + + +/************************ + +Standardized vocabulary + +************************/ + + + +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 xpk_concept_ancestor PRIMARY KEY (ancestor_concept_id,descendant_concept_id); + +ALTER TABLE source_to_concept_map ADD CONSTRAINT xpk_source_to_concept_map PRIMARY KEY (source_vocabulary_id,target_concept_id,source_code,valid_end_date); + +ALTER TABLE drug_strength ADD CONSTRAINT xpk_drug_strength PRIMARY KEY (drug_concept_id, ingredient_concept_id); + + +/************************** + +Standardized meta-data + +***************************/ + + + +/************************ + +Standardized clinical data + +************************/ + + +/**PRIMARY KEY NONCLUSTERED constraints**/ + +ALTER TABLE person ADD CONSTRAINT xpk_person PRIMARY KEY ( person_id ) ; + +ALTER TABLE observation_period ADD CONSTRAINT xpk_observation_period PRIMARY KEY ( observation_period_id ) ; + +ALTER TABLE specimen ADD CONSTRAINT xpk_specimen PRIMARY KEY ( specimen_id ) ; + +ALTER TABLE visit_occurrence ADD CONSTRAINT xpk_visit_occurrence PRIMARY KEY ( visit_occurrence_id ) ; + +ALTER TABLE visit_detail ADD CONSTRAINT xpk_visit_detail PRIMARY KEY ( visit_detail_id ) ; + +ALTER TABLE procedure_occurrence ADD CONSTRAINT xpk_procedure_occurrence PRIMARY KEY ( procedure_occurrence_id ) ; + +ALTER TABLE drug_exposure ADD CONSTRAINT xpk_drug_exposure PRIMARY KEY ( drug_exposure_id ) ; + +ALTER TABLE device_exposure ADD CONSTRAINT xpk_device_exposure PRIMARY KEY ( device_exposure_id ) ; + +ALTER TABLE condition_occurrence ADD CONSTRAINT xpk_condition_occurrence PRIMARY KEY ( condition_occurrence_id ) ; + +ALTER TABLE measurement ADD CONSTRAINT xpk_measurement PRIMARY KEY ( measurement_id ) ; + +ALTER TABLE note ADD CONSTRAINT xpk_note PRIMARY KEY ( note_id ) ; + +ALTER TABLE note_nlp ADD CONSTRAINT xpk_note_nlp PRIMARY KEY ( note_nlp_id ) ; + +ALTER TABLE observation ADD CONSTRAINT xpk_observation PRIMARY KEY ( observation_id ) ; + +ALTER TABLE survey_conduct ADD CONSTRAINT xpk_survey_conduct PRIMARY KEY ( survey_conduct_id ) ; + + +/************************ + +Standardized health system data + +************************/ + + +ALTER TABLE location ADD CONSTRAINT xpk_location PRIMARY KEY ( location_id ) ; + +ALTER TABLE location_history ADD CONSTRAINT xpk_location_history PRIMARY KEY ( location_history_id ) ; + +ALTER TABLE care_site ADD CONSTRAINT xpk_care_site PRIMARY KEY ( care_site_id ) ; + +ALTER TABLE provider ADD CONSTRAINT xpk_provider PRIMARY KEY ( provider_id ) ; + + + +/************************ + +Standardized health economics + +************************/ + + +ALTER TABLE payer_plan_period ADD CONSTRAINT xpk_payer_plan_period PRIMARY KEY ( payer_plan_period_id ) ; + +ALTER TABLE cost ADD CONSTRAINT xpk_visit_cost PRIMARY KEY ( cost_id ) ; + + +/************************ + +Standardized derived elements + +************************/ + +ALTER TABLE drug_era ADD CONSTRAINT xpk_drug_era PRIMARY KEY ( drug_era_id ) ; + +ALTER TABLE dose_era ADD CONSTRAINT xpk_dose_era PRIMARY KEY ( dose_era_id ) ; + +ALTER TABLE condition_era ADD CONSTRAINT xpk_condition_era PRIMARY KEY ( condition_era_id ) ; + + +/************************ + +Results elements + +************************/ + +ALTER TABLE cohort ADD CONSTRAINT xpk_cohort PRIMARY KEY ( cohort_definition_id, subject_id, cohort_start_date, cohort_end_date ) ; + +ALTER TABLE cohort_definition ADD CONSTRAINT xpk_cohort_definition PRIMARY KEY ( cohort_definition_id ); \ No newline at end of file diff --git a/Snowflake/README.md b/Snowflake/README.md new file mode 100644 index 0000000..4cd6dcc --- /dev/null +++ b/Snowflake/README.md @@ -0,0 +1,26 @@ +Common-Data-Model / Snowflake +================= + +This folder contains the SQL scripts for Snowflake. + +In order to create your instantiation of the Common Data Model, we recommend following these steps: + +1. Create a database for all OHDSI assets, if one does not already exist within your Snowflake account. + +2. Within the OHDSI database, create a schema for the Common Data Model. + +3. Open a Snowflake session and set the session context to use the database and schema referenced in Steps 1 and 2. + +4. Set the session context to use an available Warehouse. + +5. Execute the scripts `OMOP CDM snowflake ddl.txt` and `OMOP CDM Results snowflake ddl.txt` to create the tables and fields. + +6. Execute the script `OMOP CDM snowflake primary keys.txt` to add the minimum set of primary keys we recommend. + +7. Execute the script `OMOP CDM snowflake constraints.txt` to add the foreign key constraints. + +8. Load your data into the schema. + +Optionally, before loading your data into the schema, execute the `OMOP CDM snowflake cluster keys.txt` in full or for individual tables to add cluster keys where indexes are used in other technologies. + +Note: adding cluster keys will result in additional compute costs in Snowflake and should be considered carefully with respect to performance SLAs vs. compute costs. \ No newline at end of file