Add support for MySQL and a Mac/Unix loader script
This commit is contained in:
parent
ec3fdc2f1e
commit
7db262cbb6
|
@ -0,0 +1 @@
|
|||
.*
|
|
@ -0,0 +1,544 @@
|
|||
/*********************************************************************************
|
||||
# Copyright 2014 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.
|
||||
********************************************************************************/
|
||||
|
||||
/************************
|
||||
|
||||
####### # # ####### ###### ##### ###### # # ####### #####
|
||||
# # ## ## # # # # # # # # ## ## # # # # # #### # # #### ##### ##### ## # # # ##### ####
|
||||
# # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # ## # # #
|
||||
# # # # # # # ###### # # # # # # # # ###### # # # # # # #### # # # # # # # # # # ####
|
||||
# # # # # # # # # # # # # # # # # # # # # # # ##### ###### # # # # # #
|
||||
# # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # # ## # # #
|
||||
####### # # ####### # ##### ###### # # ## ##### ##### #### # # #### # # # # # # # # # ####
|
||||
|
||||
|
||||
script to create constraints within OMOP common data model, version 5.0 for Oracle database
|
||||
|
||||
last revised: 12 Oct 2014
|
||||
|
||||
author: Patrick Ryan
|
||||
|
||||
*************************/
|
||||
|
||||
|
||||
/************************
|
||||
*************************
|
||||
*************************
|
||||
*************************
|
||||
|
||||
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);
|
||||
|
||||
ALTER TABLE cohort_definition ADD CONSTRAINT xpk_cohort_definition PRIMARY KEY (cohort_definition_id);
|
||||
|
||||
ALTER TABLE attribute_definition ADD CONSTRAINT xpk_attribute_definition PRIMARY KEY (attribute_definition_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 death ADD CONSTRAINT xpk_death PRIMARY KEY ( person_id ) ;
|
||||
|
||||
ALTER TABLE visit_occurrence ADD CONSTRAINT xpk_visit_occurrence PRIMARY KEY ( visit_occurrence_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 observation ADD CONSTRAINT xpk_observation PRIMARY KEY ( observation_id ) ;
|
||||
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized health system data
|
||||
|
||||
************************/
|
||||
|
||||
|
||||
ALTER TABLE location ADD CONSTRAINT xpk_location PRIMARY KEY ( location_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 visit_cost ADD CONSTRAINT xpk_visit_cost PRIMARY KEY ( visit_cost_id ) ;
|
||||
|
||||
ALTER TABLE procedure_cost ADD CONSTRAINT xpk_procedure_cost PRIMARY KEY ( procedure_cost_id ) ;
|
||||
|
||||
ALTER TABLE drug_cost ADD CONSTRAINT xpk_drug_cost PRIMARY KEY ( drug_cost_id ) ;
|
||||
|
||||
ALTER TABLE device_cost ADD CONSTRAINT xpk_device_cost PRIMARY KEY ( device_cost_id ) ;
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized derived elements
|
||||
|
||||
************************/
|
||||
|
||||
ALTER TABLE cohort ADD CONSTRAINT xpk_cohort PRIMARY KEY ( cohort_definition_id, subject_id, cohort_start_date, cohort_end_date ) ;
|
||||
|
||||
ALTER TABLE cohort_attribute ADD CONSTRAINT xpk_cohort_attribute PRIMARY KEY ( cohort_definition_id, subject_id, cohort_start_date, cohort_end_date, attribute_definition_id ) ;
|
||||
|
||||
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 ) ;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
*************************
|
||||
*************************
|
||||
*************************
|
||||
|
||||
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_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);
|
||||
|
||||
ALTER TABLE cohort_definition ADD CONSTRAINT fpk_cohort_definition_concept FOREIGN KEY (definition_type_concept_id) REFERENCES concept (concept_id);
|
||||
|
||||
|
||||
/**************************
|
||||
|
||||
Standardized meta-data
|
||||
|
||||
***************************/
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
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 death ADD CONSTRAINT fpk_death_person FOREIGN KEY (person_id) REFERENCES person (person_id);
|
||||
|
||||
ALTER TABLE death ADD CONSTRAINT fpk_death_type_concept FOREIGN KEY (death_type_concept_id) REFERENCES concept (concept_id);
|
||||
|
||||
ALTER TABLE death ADD CONSTRAINT fpk_death_cause_concept FOREIGN KEY (cause_concept_id) REFERENCES concept (concept_id);
|
||||
|
||||
ALTER TABLE death ADD CONSTRAINT fpk_death_cause_concept_s FOREIGN KEY (cause_source_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 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_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_dose_unit_concept FOREIGN KEY (dose_unit_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_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_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_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_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_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_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 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_concept_s FOREIGN KEY (observation_source_concept_id) REFERENCES concept (concept_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 care_site ADD CONSTRAINT fpk_care_site_location FOREIGN KEY (location_id) REFERENCES location (location_id);
|
||||
|
||||
ALTER TABLE care_site ADD CONSTRAINT fpk_care_site_place FOREIGN KEY (place_of_service_concept_id) REFERENCES concept (concept_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 visit_cost ADD CONSTRAINT fpk_visit_cost_id FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id);
|
||||
|
||||
ALTER TABLE visit_cost ADD CONSTRAINT fpk_visit_cost_currency FOREIGN KEY (currency_concept_id) REFERENCES concept (concept_id);
|
||||
|
||||
ALTER TABLE visit_cost ADD CONSTRAINT fpk_visit_cost_period FOREIGN KEY (payer_plan_period_id) REFERENCES payer_plan_period (payer_plan_period_id);
|
||||
|
||||
|
||||
ALTER TABLE procedure_cost ADD CONSTRAINT fpk_procedure_cost_id FOREIGN KEY (procedure_occurrence_id) REFERENCES procedure_occurrence (procedure_occurrence_id);
|
||||
|
||||
ALTER TABLE procedure_cost ADD CONSTRAINT fpk_procedure_cost_currency FOREIGN KEY (currency_concept_id) REFERENCES concept (concept_id);
|
||||
|
||||
ALTER TABLE procedure_cost ADD CONSTRAINT fpk_procedure_cost_period FOREIGN KEY (payer_plan_period_id) REFERENCES payer_plan_period (payer_plan_period_id);
|
||||
|
||||
ALTER TABLE procedure_cost ADD CONSTRAINT fpk_procedure_cost_revenue FOREIGN KEY (revenue_code_concept_id) REFERENCES concept (concept_id);
|
||||
|
||||
|
||||
ALTER TABLE drug_cost ADD CONSTRAINT fpk_drug_cost_id FOREIGN KEY (drug_exposure_id) REFERENCES drug_exposure (drug_exposure_id);
|
||||
|
||||
ALTER TABLE drug_cost ADD CONSTRAINT fpk_drug_cost_currency FOREIGN KEY (currency_concept_id) REFERENCES concept (concept_id);
|
||||
|
||||
ALTER TABLE drug_cost ADD CONSTRAINT fpk_drug_cost_period FOREIGN KEY (payer_plan_period_id) REFERENCES payer_plan_period (payer_plan_period_id);
|
||||
|
||||
|
||||
ALTER TABLE device_cost ADD CONSTRAINT fpk_device_cost_id FOREIGN KEY (device_exposure_id) REFERENCES device_exposure (device_exposure_id);
|
||||
|
||||
ALTER TABLE device_cost ADD CONSTRAINT fpk_device_cost_currency FOREIGN KEY (currency_concept_id) REFERENCES concept (concept_id);
|
||||
|
||||
ALTER TABLE device_cost ADD CONSTRAINT fpk_device_cost_period FOREIGN KEY (payer_plan_period_id) REFERENCES payer_plan_period (payer_plan_period_id);
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized derived elements
|
||||
|
||||
************************/
|
||||
|
||||
|
||||
ALTER TABLE cohort ADD CONSTRAINT fpk_cohort_definition FOREIGN KEY (cohort_definition_id) REFERENCES cohort_definition (cohort_definition_id);
|
||||
|
||||
|
||||
ALTER TABLE cohort_attribute ADD CONSTRAINT fpk_ca_cohort_definition FOREIGN KEY (cohort_definition_id) REFERENCES cohort_definition (cohort_definition_id);
|
||||
|
||||
ALTER TABLE cohort_attribute ADD CONSTRAINT fpk_ca_attribute_definition FOREIGN KEY (attribute_definition_id) REFERENCES attribute_definition (attribute_definition_id);
|
||||
|
||||
ALTER TABLE cohort_attribute ADD CONSTRAINT fpk_ca_value FOREIGN KEY (value_as_concept_id) REFERENCES concept (concept_id);
|
||||
|
||||
|
||||
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);
|
||||
|
|
@ -0,0 +1,705 @@
|
|||
/*********************************************************************************
|
||||
# Copyright 2014-6 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.
|
||||
********************************************************************************/
|
||||
|
||||
/************************
|
||||
|
||||
####### # # ####### ###### ##### ###### # # #######
|
||||
# # ## ## # # # # # # # # ## ## # # #
|
||||
# # # # # # # # # # # # # # # # # # # #
|
||||
# # # # # # # ###### # # # # # # # # ######
|
||||
# # # # # # # # # # # # # # #
|
||||
# # # # # # # # # # # # # # # # #
|
||||
####### # # ####### # ##### ###### # # ## #####
|
||||
|
||||
|
||||
script to create OMOP common data model, version 5.0 for Oracle database
|
||||
|
||||
last revised: 30 Sept 2016
|
||||
|
||||
Authors: Patrick Ryan, Christian Reich, Peter G. Williams
|
||||
*************************/
|
||||
|
||||
#Uncomment if you need to create a user as well
|
||||
#GRANT ALL PRIVILEGES ON cdm.* To 'cdm' IDENTIFIED BY 'cdm';
|
||||
|
||||
/************************
|
||||
Standardized vocabulary
|
||||
************************/
|
||||
|
||||
CREATE TABLE concept (
|
||||
concept_id INTEGER 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) NULL,
|
||||
concept_code VARCHAR(50) NOT NULL,
|
||||
valid_start_date DATE NOT NULL,
|
||||
valid_end_date DATE NOT NULL,
|
||||
invalid_reason VARCHAR(1) NULL
|
||||
);
|
||||
|
||||
CREATE TABLE vocabulary (
|
||||
vocabulary_id VARCHAR(20) NOT NULL,
|
||||
vocabulary_name VARCHAR(255) NOT NULL,
|
||||
vocabulary_reference VARCHAR(255) NULL,
|
||||
vocabulary_version VARCHAR(255) NULL,
|
||||
vocabulary_concept_id INTEGER NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE domain (
|
||||
domain_id VARCHAR(20) NOT NULL,
|
||||
domain_name VARCHAR(255) NOT NULL,
|
||||
domain_concept_id INTEGER NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE concept_class (
|
||||
concept_class_id VARCHAR(20) NOT NULL,
|
||||
concept_class_name VARCHAR(255) 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(20) NOT NULL,
|
||||
valid_start_date DATE NOT NULL,
|
||||
valid_end_date DATE NOT NULL,
|
||||
invalid_reason VARCHAR(1) NULL
|
||||
);
|
||||
|
||||
CREATE TABLE relationship (
|
||||
relationship_id VARCHAR(20) NOT NULL,
|
||||
relationship_name VARCHAR(255) NOT NULL,
|
||||
is_hierarchical VARCHAR(1) NOT NULL,
|
||||
defines_ancestry VARCHAR(1) NOT NULL,
|
||||
reverse_relationship_id VARCHAR(20) NOT NULL,
|
||||
relationship_concept_id INTEGER NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE concept_synonym (
|
||||
concept_id INTEGER NOT NULL,
|
||||
concept_synonym_name VARCHAR(1000) 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(50) NOT NULL,
|
||||
source_concept_id INTEGER NOT NULL,
|
||||
source_vocabulary_id VARCHAR(20) NOT NULL,
|
||||
source_code_description VARCHAR(255) NULL,
|
||||
target_concept_id INTEGER NOT NULL,
|
||||
target_vocabulary_id VARCHAR(20) NOT NULL,
|
||||
valid_start_date DATE NOT NULL,
|
||||
valid_end_date DATE NOT NULL,
|
||||
invalid_reason VARCHAR(1) 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(1) NULL
|
||||
);
|
||||
|
||||
CREATE TABLE cohort_definition (
|
||||
cohort_definition_id INTEGER NOT NULL,
|
||||
cohort_definition_name VARCHAR(255) NOT NULL,
|
||||
cohort_definition_description TEXT NULL,
|
||||
definition_type_concept_id INTEGER NOT NULL,
|
||||
cohort_definition_syntax TEXT NULL,
|
||||
subject_concept_id INTEGER NOT NULL,
|
||||
cohort_initiation_date DATE NULL
|
||||
);
|
||||
|
||||
CREATE TABLE attribute_definition (
|
||||
attribute_definition_id INTEGER NOT NULL,
|
||||
attribute_name VARCHAR(255) NOT NULL,
|
||||
attribute_description TEXT NULL,
|
||||
attribute_type_concept_id INTEGER NOT NULL,
|
||||
attribute_syntax TEXT NULL
|
||||
);
|
||||
|
||||
/**************************
|
||||
|
||||
Standardized meta-data
|
||||
|
||||
***************************/
|
||||
|
||||
|
||||
CREATE TABLE cdm_source
|
||||
(
|
||||
cdm_source_name VARCHAR(255) NOT NULL,
|
||||
cdm_source_abbreviation VARCHAR(25) NULL,
|
||||
cdm_holder VARCHAR(255) NULL,
|
||||
source_description TEXT NULL,
|
||||
source_documentation_reference VARCHAR(255) NULL,
|
||||
cdm_etl_reference VARCHAR(255) NULL,
|
||||
source_release_date DATE NULL,
|
||||
cdm_release_date DATE NULL,
|
||||
cdm_version VARCHAR(10) NULL,
|
||||
vocabulary_version VARCHAR(20) 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,
|
||||
time_of_birth VARCHAR(10) 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(50) NULL,
|
||||
gender_source_value VARCHAR(50) NULL,
|
||||
gender_source_concept_id INTEGER NULL,
|
||||
race_source_value VARCHAR(50) NULL,
|
||||
race_source_concept_id INTEGER NULL,
|
||||
ethnicity_source_value VARCHAR(50) NULL,
|
||||
ethnicity_source_concept_id INTEGER 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 NOT NULL ,
|
||||
specimen_time VARCHAR(10) NULL ,
|
||||
quantity FLOAT NULL ,
|
||||
unit_concept_id INTEGER NULL ,
|
||||
anatomic_site_concept_id INTEGER NULL ,
|
||||
disease_status_concept_id INTEGER NULL ,
|
||||
specimen_source_id VARCHAR(50) NULL ,
|
||||
specimen_source_value VARCHAR(50) NULL ,
|
||||
unit_source_value VARCHAR(50) NULL ,
|
||||
anatomic_site_source_value VARCHAR(50) NULL ,
|
||||
disease_status_source_value VARCHAR(50) NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE death
|
||||
(
|
||||
person_id INTEGER NOT NULL ,
|
||||
death_date DATE NOT NULL ,
|
||||
death_type_concept_id INTEGER NOT NULL ,
|
||||
cause_concept_id INTEGER NULL ,
|
||||
cause_source_value VARCHAR(50) NULL,
|
||||
cause_source_concept_id INTEGER 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 NOT NULL ,
|
||||
visit_start_time VARCHAR(10) NULL ,
|
||||
visit_end_date DATE NOT NULL ,
|
||||
visit_end_time VARCHAR(10) NULL ,
|
||||
visit_type_concept_id INTEGER NOT NULL ,
|
||||
provider_id INTEGER NULL,
|
||||
care_site_id INTEGER NULL,
|
||||
visit_source_value VARCHAR(50) NULL,
|
||||
visit_source_concept_id INTEGER 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 NOT NULL ,
|
||||
procedure_type_concept_id INTEGER NOT NULL ,
|
||||
modifier_concept_id INTEGER NULL ,
|
||||
quantity INTEGER NULL ,
|
||||
provider_id INTEGER NULL ,
|
||||
visit_occurrence_id INTEGER NULL ,
|
||||
procedure_source_value VARCHAR(50) NULL ,
|
||||
procedure_source_concept_id INTEGER NULL ,
|
||||
qualifier_source_value VARCHAR(50) 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 NOT NULL ,
|
||||
drug_exposure_end_date DATE NULL ,
|
||||
drug_type_concept_id INTEGER NOT NULL ,
|
||||
stop_reason VARCHAR(20) NULL ,
|
||||
refills INTEGER NULL ,
|
||||
quantity FLOAT NULL ,
|
||||
days_supply INTEGER NULL ,
|
||||
sig TEXT NULL ,
|
||||
route_concept_id INTEGER NULL ,
|
||||
effective_drug_dose FLOAT NULL ,
|
||||
dose_unit_concept_id INTEGER NULL ,
|
||||
lot_number VARCHAR(50) NULL ,
|
||||
provider_id INTEGER NULL ,
|
||||
visit_occurrence_id INTEGER NULL ,
|
||||
drug_source_value VARCHAR(50) NULL ,
|
||||
drug_source_concept_id INTEGER NULL ,
|
||||
route_source_value VARCHAR(50) NULL ,
|
||||
dose_unit_source_value VARCHAR(50) 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 NOT NULL ,
|
||||
device_exposure_end_date DATE NULL ,
|
||||
device_type_concept_id INTEGER NOT NULL ,
|
||||
unique_device_id VARCHAR(50) NULL ,
|
||||
quantity INTEGER NULL ,
|
||||
provider_id INTEGER NULL ,
|
||||
visit_occurrence_id INTEGER NULL ,
|
||||
device_source_value VARCHAR(100) NULL ,
|
||||
device_source_concept_id INTEGER 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 NOT NULL ,
|
||||
condition_end_date DATE NULL ,
|
||||
condition_type_concept_id INTEGER NOT NULL ,
|
||||
stop_reason VARCHAR(20) NULL ,
|
||||
provider_id INTEGER NULL ,
|
||||
visit_occurrence_id INTEGER NULL ,
|
||||
condition_source_value VARCHAR(50) NULL ,
|
||||
condition_source_concept_id INTEGER NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE measurement
|
||||
(
|
||||
measurement_id INTEGER NOT NULL ,
|
||||
person_id INTEGER NOT NULL ,
|
||||
measurement_concept_id INTEGER NOT NULL ,
|
||||
measurement_date DATE NOT NULL ,
|
||||
measurement_time VARCHAR(10) 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 ,
|
||||
measurement_source_value VARCHAR(50) NULL ,
|
||||
measurement_source_concept_id INTEGER NULL ,
|
||||
unit_source_value VARCHAR(50) NULL ,
|
||||
value_source_value VARCHAR(50) NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE note
|
||||
(
|
||||
note_id INTEGER NOT NULL ,
|
||||
person_id INTEGER NOT NULL ,
|
||||
note_date DATE NOT NULL ,
|
||||
note_time VARCHAR(10) NULL ,
|
||||
note_type_concept_id INTEGER NOT NULL ,
|
||||
note_text TEXT NOT NULL ,
|
||||
provider_id INTEGER NULL ,
|
||||
visit_occurrence_id INTEGER NULL ,
|
||||
note_source_value VARCHAR(50) NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE observation
|
||||
(
|
||||
observation_id INTEGER NOT NULL ,
|
||||
person_id INTEGER NOT NULL ,
|
||||
observation_concept_id INTEGER NOT NULL ,
|
||||
observation_date DATE NOT NULL ,
|
||||
observation_time VARCHAR(10) NULL ,
|
||||
observation_type_concept_id INTEGER NOT NULL ,
|
||||
value_as_number FLOAT NULL ,
|
||||
value_as_string VARCHAR(60) 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 ,
|
||||
observation_source_value VARCHAR(50) NULL ,
|
||||
observation_source_concept_id INTEGER NULL ,
|
||||
unit_source_value VARCHAR(50) NULL ,
|
||||
qualifier_source_value VARCHAR(50) 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(50) NULL ,
|
||||
address_2 VARCHAR(50) NULL ,
|
||||
city VARCHAR(50) NULL ,
|
||||
state VARCHAR(2) NULL ,
|
||||
zip VARCHAR(9) NULL ,
|
||||
county VARCHAR(20) NULL ,
|
||||
location_source_value VARCHAR(50) NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE care_site
|
||||
(
|
||||
care_site_id INTEGER NOT NULL ,
|
||||
care_site_name VARCHAR(255) NULL ,
|
||||
place_of_service_concept_id INTEGER NULL ,
|
||||
location_id INTEGER NULL ,
|
||||
care_site_source_value VARCHAR(50) NULL ,
|
||||
place_of_service_source_value VARCHAR(50) NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE provider
|
||||
(
|
||||
provider_id INTEGER NOT NULL ,
|
||||
provider_name VARCHAR(255) NULL ,
|
||||
NPI VARCHAR(20) NULL ,
|
||||
DEA VARCHAR(20) NULL ,
|
||||
specialty_concept_id INTEGER NULL ,
|
||||
care_site_id INTEGER NULL ,
|
||||
year_of_birth INTEGER NULL ,
|
||||
gender_concept_id INTEGER NULL ,
|
||||
provider_source_value VARCHAR(50) NULL ,
|
||||
specialty_source_value VARCHAR(50) NULL ,
|
||||
specialty_source_concept_id INTEGER NULL ,
|
||||
gender_source_value VARCHAR(50) NULL ,
|
||||
gender_source_concept_id INTEGER NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized health economics
|
||||
|
||||
************************/
|
||||
|
||||
|
||||
CREATE TABLE payer_plan_period
|
||||
(
|
||||
payer_plan_period_id INTEGER NOT NULL ,
|
||||
person_id INTEGER NOT NULL ,
|
||||
payer_plan_period_start_date DATE NOT NULL ,
|
||||
payer_plan_period_end_date DATE NOT NULL ,
|
||||
payer_source_value VARCHAR (50) NULL ,
|
||||
plan_source_value VARCHAR (50) NULL ,
|
||||
family_source_value VARCHAR (50) NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
-- The individual cost tables are phased out and will be removed
|
||||
/*
|
||||
CREATE TABLE visit_cost
|
||||
(
|
||||
visit_cost_id INTEGER NOT NULL ,
|
||||
visit_occurrence_id INTEGER NOT NULL ,
|
||||
currency_concept_id INTEGER NULL ,
|
||||
paid_copay FLOAT NULL ,
|
||||
paid_coinsurance FLOAT NULL ,
|
||||
paid_toward_deductible FLOAT NULL ,
|
||||
paid_by_payer FLOAT NULL ,
|
||||
paid_by_coordination_benefits FLOAT NULL ,
|
||||
total_out_of_pocket FLOAT NULL ,
|
||||
total_paid FLOAT NULL ,
|
||||
payer_plan_period_id INTEGER NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE procedure_cost
|
||||
(
|
||||
procedure_cost_id INTEGER NOT NULL ,
|
||||
procedure_occurrence_id INTEGER NOT NULL ,
|
||||
currency_concept_id INTEGER NULL ,
|
||||
paid_copay FLOAT NULL ,
|
||||
paid_coinsurance FLOAT NULL ,
|
||||
paid_toward_deductible FLOAT NULL ,
|
||||
paid_by_payer FLOAT NULL ,
|
||||
paid_by_coordination_benefits FLOAT NULL ,
|
||||
total_out_of_pocket FLOAT NULL ,
|
||||
total_paid FLOAT NULL ,
|
||||
revenue_code_concept_id INTEGER NULL ,
|
||||
payer_plan_period_id INTEGER NULL ,
|
||||
revenue_code_source_value VARCHAR(50) NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE drug_cost
|
||||
(
|
||||
drug_cost_id INTEGER NOT NULL ,
|
||||
drug_exposure_id INTEGER NOT NULL ,
|
||||
currency_concept_id INTEGER NULL ,
|
||||
paid_copay FLOAT NULL ,
|
||||
paid_coinsurance FLOAT NULL ,
|
||||
paid_toward_deductible FLOAT NULL ,
|
||||
paid_by_payer FLOAT NULL ,
|
||||
paid_by_coordination_benefits FLOAT NULL ,
|
||||
total_out_of_pocket FLOAT NULL ,
|
||||
total_paid FLOAT NULL ,
|
||||
ingredient_cost FLOAT NULL ,
|
||||
dispensing_fee FLOAT NULL ,
|
||||
average_wholesale_price FLOAT NULL ,
|
||||
payer_plan_period_id INTEGER NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
CREATE TABLE device_cost
|
||||
(
|
||||
device_cost_id INTEGER NOT NULL ,
|
||||
device_exposure_id INTEGER NOT NULL ,
|
||||
currency_concept_id INTEGER NULL ,
|
||||
paid_copay FLOAT NULL ,
|
||||
paid_coinsurance FLOAT NULL ,
|
||||
paid_toward_deductible FLOAT NULL ,
|
||||
paid_by_payer FLOAT NULL ,
|
||||
paid_by_coordination_benefits FLOAT NULL ,
|
||||
total_out_of_pocket FLOAT NULL ,
|
||||
total_paid FLOAT NULL ,
|
||||
payer_plan_period_id INTEGER NULL
|
||||
)
|
||||
;
|
||||
*/
|
||||
|
||||
|
||||
CREATE TABLE cost
|
||||
(
|
||||
cost_id INTEGER NOT NULL ,
|
||||
cost_event_id INTEGER NOT NULL ,
|
||||
cost_domain_id VARCHAR(20) NOT NULL ,
|
||||
cost_type_concept_id INTEGER NOT NULL ,
|
||||
currency_concept_id INTEGER NULL ,
|
||||
total_charge FLOAT NULL ,
|
||||
total_cost FLOAT NULL ,
|
||||
total_paid FLOAT NULL ,
|
||||
paid_by_payer FLOAT NULL ,
|
||||
paid_by_patient FLOAT NULL ,
|
||||
paid_patient_copay FLOAT NULL ,
|
||||
paid_patient_coinsurance FLOAT NULL ,
|
||||
paid_patient_deductible FLOAT NULL ,
|
||||
paid_by_primary FLOAT NULL ,
|
||||
paid_ingredient_cost FLOAT NULL ,
|
||||
paid_dispensing_fee FLOAT NULL ,
|
||||
payer_plan_period_id INTEGER NULL ,
|
||||
amount_allowed FLOAT NULL ,
|
||||
revenue_code_concept_id INTEGER NULL ,
|
||||
reveue_code_source_value VARCHAR(50) NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized derived elements
|
||||
|
||||
************************/
|
||||
|
||||
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
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
CREATE TABLE cohort_attribute
|
||||
(
|
||||
cohort_definition_id INTEGER NOT NULL ,
|
||||
cohort_start_date DATE NOT NULL ,
|
||||
cohort_end_date DATE NOT NULL ,
|
||||
subject_id INTEGER NOT NULL ,
|
||||
attribute_definition_id INTEGER NOT NULL ,
|
||||
value_as_number FLOAT NULL ,
|
||||
value_as_concept_id INTEGER NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
|
||||
CREATE TABLE drug_era
|
||||
(
|
||||
drug_era_id INTEGER NOT NULL ,
|
||||
person_id INTEGER NOT NULL ,
|
||||
drug_concept_id INTEGER NOT NULL ,
|
||||
drug_era_start_date DATE NOT NULL ,
|
||||
drug_era_end_date DATE 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_date DATE NOT NULL ,
|
||||
dose_era_end_date DATE 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_date DATE NOT NULL ,
|
||||
condition_era_end_date DATE NOT NULL ,
|
||||
condition_occurrence_count INTEGER NULL
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
|
@ -0,0 +1,168 @@
|
|||
/*********************************************************************************
|
||||
# Copyright 2014 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.
|
||||
********************************************************************************/
|
||||
|
||||
/************************
|
||||
|
||||
####### # # ####### ###### ##### ###### # # ####### ###
|
||||
# # ## ## # # # # # # # # ## ## # # # # # # ##### ###### # # ###### ####
|
||||
# # # # # # # # # # # # # # # # # # # # # ## # # # # # # # #
|
||||
# # # # # # # ###### # # # # # # # # ###### # # # # # # ##### ## ##### ####
|
||||
# # # # # # # # # # # # # # # # # # # # # # ## # #
|
||||
# # # # # # # # # # # # # # # # # # # ## # # # # # # # #
|
||||
####### # # ####### # ##### ###### # # ## ##### ### # # ##### ###### # # ###### ####
|
||||
|
||||
|
||||
script to create the required indexes within OMOP common data model, version 5.0 for Oracle database
|
||||
|
||||
last revised: 12 Oct 2014
|
||||
|
||||
author: Patrick Ryan
|
||||
|
||||
description: These indices are considered a minimal requirement to ensure adequate performance of analyses.
|
||||
|
||||
*************************/
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized vocabulary
|
||||
|
||||
************************/
|
||||
|
||||
CREATE INDEX idx_concept_code ON concept (concept_code ASC);
|
||||
CREATE INDEX idx_concept_vocabluary_id ON concept (vocabulary_id ASC);
|
||||
CREATE INDEX idx_concept_domain_id ON concept (domain_id ASC);
|
||||
CREATE INDEX idx_concept_class_id ON concept (concept_class_id ASC);
|
||||
|
||||
CREATE INDEX idx_concept_relationship_id_1 ON concept_relationship (concept_id_1 ASC);
|
||||
CREATE INDEX idx_concept_relationship_id_2 ON concept_relationship (concept_id_2 ASC);
|
||||
CREATE INDEX idx_concept_relationship_id_3 ON concept_relationship (relationship_id ASC);
|
||||
|
||||
CREATE INDEX idx_concept_synonym_id ON concept_synonym (concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_concept_ancestor_id_1 ON concept_ancestor (ancestor_concept_id ASC);
|
||||
CREATE INDEX idx_concept_ancestor_id_2 ON concept_ancestor (descendant_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_source_to_concept_map_id_3 ON source_to_concept_map (target_concept_id ASC);
|
||||
CREATE INDEX idx_source_to_concept_map_id_1 ON source_to_concept_map (source_vocabulary_id ASC);
|
||||
CREATE INDEX idx_source_to_concept_map_id_2 ON source_to_concept_map (target_vocabulary_id ASC);
|
||||
CREATE INDEX idx_source_to_concept_map_code ON source_to_concept_map (source_code ASC);
|
||||
|
||||
CREATE INDEX idx_drug_strength_id_1 ON drug_strength (drug_concept_id ASC);
|
||||
CREATE INDEX idx_drug_strength_id_2 ON drug_strength (ingredient_concept_id ASC);
|
||||
|
||||
/**************************
|
||||
|
||||
Standardized meta-data
|
||||
|
||||
***************************/
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized clinical data
|
||||
|
||||
************************/
|
||||
|
||||
CREATE INDEX idx_observation_period_id ON observation_period (person_id ASC);
|
||||
|
||||
CREATE INDEX idx_specimen_person_id ON specimen (person_id ASC);
|
||||
CREATE INDEX idx_specimen_concept_id ON specimen (specimen_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_visit_person_id ON visit_occurrence (person_id ASC);
|
||||
CREATE INDEX idx_visit_concept_id ON visit_occurrence (visit_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_procedure_person_id ON procedure_occurrence (person_id ASC);
|
||||
CREATE INDEX idx_procedure_concept_id ON procedure_occurrence (procedure_concept_id ASC);
|
||||
CREATE INDEX idx_procedure_visit_id ON procedure_occurrence (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_drug_person_id ON drug_exposure (person_id ASC);
|
||||
CREATE INDEX idx_drug_concept_id ON drug_exposure (drug_concept_id ASC);
|
||||
CREATE INDEX idx_drug_visit_id ON drug_exposure (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_device_person_id ON device_exposure (person_id ASC);
|
||||
CREATE INDEX idx_device_concept_id ON device_exposure (device_concept_id ASC);
|
||||
CREATE INDEX idx_device_visit_id ON device_exposure (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_condition_person_id ON condition_occurrence (person_id ASC);
|
||||
CREATE INDEX idx_condition_concept_id ON condition_occurrence (condition_concept_id ASC);
|
||||
CREATE INDEX idx_condition_visit_id ON condition_occurrence (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_measurement_person_id ON measurement (person_id ASC);
|
||||
CREATE INDEX idx_measurement_concept_id ON measurement (measurement_concept_id ASC);
|
||||
CREATE INDEX idx_measurement_visit_id ON measurement (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_note_person_id ON note (person_id ASC);
|
||||
CREATE INDEX idx_note_concept_id ON note (note_type_concept_id ASC);
|
||||
CREATE INDEX idx_note_visit_id ON note (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_observation_person_id ON observation (person_id ASC);
|
||||
CREATE INDEX idx_observation_concept_id ON observation (observation_concept_id ASC);
|
||||
CREATE INDEX idx_observation_visit_id ON observation (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_fact_relationship_id_1 ON fact_relationship (domain_concept_id_1 ASC);
|
||||
CREATE INDEX idx_fact_relationship_id_2 ON fact_relationship (domain_concept_id_2 ASC);
|
||||
CREATE INDEX idx_fact_relationship_id_3 ON fact_relationship (relationship_concept_id ASC);
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized health system data
|
||||
|
||||
************************/
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized health economics
|
||||
|
||||
************************/
|
||||
|
||||
CREATE INDEX idx_period_person_id ON payer_plan_period (person_id ASC);
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized derived elements
|
||||
|
||||
************************/
|
||||
|
||||
CREATE INDEX idx_cohort_subject_id ON cohort (subject_id ASC);
|
||||
CREATE INDEX idx_cohort_c_definition_id ON cohort (cohort_definition_id ASC);
|
||||
|
||||
CREATE INDEX idx_ca_subject_id ON cohort_attribute (subject_id ASC);
|
||||
CREATE INDEX idx_ca_definition_id ON cohort_attribute (cohort_definition_id ASC);
|
||||
|
||||
CREATE INDEX idx_drug_era_person_id ON drug_era (person_id ASC);
|
||||
CREATE INDEX idx_drug_era_concept_id ON drug_era (drug_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_dose_era_person_id ON dose_era (person_id ASC);
|
||||
CREATE INDEX idx_dose_era_concept_id ON dose_era (drug_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_condition_era_person_id ON condition_era (person_id ASC);
|
||||
CREATE INDEX idx_condition_era_concept_id ON condition_era (condition_concept_id ASC);
|
||||
|
|
@ -0,0 +1,188 @@
|
|||
/*********************************************************************************
|
||||
# Copyright 2014 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.
|
||||
********************************************************************************/
|
||||
|
||||
/************************
|
||||
|
||||
####### # # ####### ###### ##### ###### # # ####### ###
|
||||
# # ## ## # # # # # # # # ## ## # # # # # # ##### ###### # # ###### ####
|
||||
# # # # # # # # # # # # # # # # # # # # # ## # # # # # # # #
|
||||
# # # # # # # ###### # # # # # # # # ###### # # # # # # ##### ## ##### ####
|
||||
# # # # # # # # # # # # # # # # # # # # # # ## # #
|
||||
# # # # # # # # # # # # # # # # # # # ## # # # # # # # #
|
||||
####### # # ####### # ##### ###### # # ## ##### ### # # ##### ###### # # ###### ####
|
||||
|
||||
|
||||
script to create the required indexes within OMOP common data model, version 5.0 for Oracle database
|
||||
|
||||
last revised: 12 Oct 2014
|
||||
|
||||
author: Patrick Ryan
|
||||
|
||||
description: These indices are considered a minimal requirement to ensure adequate performance of analyses.
|
||||
|
||||
*************************/
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized vocabulary
|
||||
|
||||
************************/
|
||||
|
||||
CREATE UNIQUE INDEX idx_concept_concept_id ON concept (concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_concept_code ON concept (concept_code ASC);
|
||||
CREATE INDEX idx_concept_vocabluary_id ON concept (vocabulary_id ASC);
|
||||
CREATE INDEX idx_concept_domain_id ON concept (domain_id ASC);
|
||||
CREATE INDEX idx_concept_class_id ON concept (concept_class_id ASC);
|
||||
|
||||
CREATE UNIQUE INDEX idx_vocabulary_vocabulary_id ON vocabulary (vocabulary_id ASC);
|
||||
|
||||
CREATE UNIQUE INDEX idx_domain_domain_id ON domain (domain_id ASC);
|
||||
|
||||
CREATE UNIQUE INDEX idx_concept_class_class_id ON concept_class (concept_class_id ASC);
|
||||
|
||||
CREATE INDEX idx_concept_relationship_id_1 ON concept_relationship (concept_id_1 ASC);
|
||||
CREATE INDEX idx_concept_relationship_id_2 ON concept_relationship (concept_id_2 ASC);
|
||||
CREATE INDEX idx_concept_relationship_id_3 ON concept_relationship (relationship_id ASC);
|
||||
|
||||
CREATE UNIQUE INDEX idx_relationship_rel_id ON relationship (relationship_id ASC);
|
||||
|
||||
CREATE INDEX idx_concept_synonym_id ON concept_synonym (concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_concept_ancestor_id_1 ON concept_ancestor (ancestor_concept_id ASC);
|
||||
CREATE INDEX idx_concept_ancestor_id_2 ON concept_ancestor (descendant_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_source_to_concept_map_id_3 ON source_to_concept_map (target_concept_id ASC);
|
||||
CREATE INDEX idx_source_to_concept_map_id_1 ON source_to_concept_map (source_vocabulary_id ASC);
|
||||
CREATE INDEX idx_source_to_concept_map_id_2 ON source_to_concept_map (target_vocabulary_id ASC);
|
||||
CREATE INDEX idx_source_to_concept_map_code ON source_to_concept_map (source_code ASC);
|
||||
|
||||
CREATE INDEX idx_drug_strength_id_1 ON drug_strength (drug_concept_id ASC);
|
||||
CREATE INDEX idx_drug_strength_id_2 ON drug_strength (ingredient_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_cohort_definition_id ON cohort_definition (cohort_definition_id ASC);
|
||||
|
||||
CREATE INDEX idx_attribute_definition_id ON attribute_definition (attribute_definition_id ASC);
|
||||
|
||||
|
||||
/**************************
|
||||
|
||||
Standardized meta-data
|
||||
|
||||
***************************/
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized clinical data
|
||||
|
||||
************************/
|
||||
|
||||
CREATE UNIQUE INDEX idx_person_id ON person (person_id ASC);
|
||||
|
||||
CREATE INDEX idx_observation_period_id ON observation_period (person_id ASC);
|
||||
|
||||
CREATE INDEX idx_specimen_person_id ON specimen (person_id ASC);
|
||||
CREATE INDEX idx_specimen_concept_id ON specimen (specimen_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_death_person_id ON death (person_id ASC);
|
||||
|
||||
CREATE INDEX idx_visit_person_id ON visit_occurrence (person_id ASC);
|
||||
CREATE INDEX idx_visit_concept_id ON visit_occurrence (visit_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_procedure_person_id ON procedure_occurrence (person_id ASC);
|
||||
CREATE INDEX idx_procedure_concept_id ON procedure_occurrence (procedure_concept_id ASC);
|
||||
CREATE INDEX idx_procedure_visit_id ON procedure_occurrence (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_drug_person_id ON drug_exposure (person_id ASC);
|
||||
CREATE INDEX idx_drug_concept_id ON drug_exposure (drug_concept_id ASC);
|
||||
CREATE INDEX idx_drug_visit_id ON drug_exposure (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_device_person_id ON device_exposure (person_id ASC);
|
||||
CREATE INDEX idx_device_concept_id ON device_exposure (device_concept_id ASC);
|
||||
CREATE INDEX idx_device_visit_id ON device_exposure (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_condition_person_id ON condition_occurrence (person_id ASC);
|
||||
CREATE INDEX idx_condition_concept_id ON condition_occurrence (condition_concept_id ASC);
|
||||
CREATE INDEX idx_condition_visit_id ON condition_occurrence (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_measurement_person_id ON measurement (person_id ASC);
|
||||
CREATE INDEX idx_measurement_concept_id ON measurement (measurement_concept_id ASC);
|
||||
CREATE INDEX idx_measurement_visit_id ON measurement (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_note_person_id ON note (person_id ASC);
|
||||
CREATE INDEX idx_note_concept_id ON note (note_type_concept_id ASC);
|
||||
CREATE INDEX idx_note_visit_id ON note (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_observation_person_id ON observation (person_id ASC);
|
||||
CREATE INDEX idx_observation_concept_id ON observation (observation_concept_id ASC);
|
||||
CREATE INDEX idx_observation_visit_id ON observation (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_fact_relationship_id_1 ON fact_relationship (domain_concept_id_1 ASC);
|
||||
CREATE INDEX idx_fact_relationship_id_2 ON fact_relationship (domain_concept_id_2 ASC);
|
||||
CREATE INDEX idx_fact_relationship_id_3 ON fact_relationship (relationship_concept_id ASC);
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized health system data
|
||||
|
||||
************************/
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized health economics
|
||||
|
||||
************************/
|
||||
|
||||
CREATE INDEX idx_period_person_id ON payer_plan_period (person_id ASC);
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized derived elements
|
||||
|
||||
************************/
|
||||
|
||||
|
||||
CREATE INDEX idx_cohort_subject_id ON cohort (subject_id ASC);
|
||||
CREATE INDEX idx_cohort_c_definition_id ON cohort (cohort_definition_id ASC);
|
||||
|
||||
CREATE INDEX idx_ca_subject_id ON cohort_attribute (subject_id ASC);
|
||||
CREATE INDEX idx_ca_definition_id ON cohort_attribute (cohort_definition_id ASC);
|
||||
|
||||
CREATE INDEX idx_drug_era_person_id ON drug_era (person_id ASC);
|
||||
CREATE INDEX idx_drug_era_concept_id ON drug_era (drug_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_dose_era_person_id ON dose_era (person_id ASC);
|
||||
CREATE INDEX idx_dose_era_concept_id ON dose_era (drug_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_condition_era_person_id ON condition_era (person_id ASC);
|
||||
CREATE INDEX idx_condition_era_concept_id ON condition_era (condition_concept_id ASC);
|
||||
|
|
@ -0,0 +1,20 @@
|
|||
Common-Data-Model / MySQL
|
||||
=================
|
||||
|
||||
This folder contains the SQL scripts for MySQL.
|
||||
|
||||
In order to create your instantiation of the Common Data Model, we recommend following these steps:
|
||||
|
||||
1. Create an empty schema.
|
||||
|
||||
2. Execute the script `OMOP CDM ddl - MySQL.sql` to create the tables and fields.
|
||||
|
||||
3. Load your data into the schema.
|
||||
|
||||
4. Execute the script `OMOP CDM constraints - MySQL.sql` to add the constraints (primary and foreign keys).
|
||||
|
||||
5. Execute the script `OMOP CDM indexes required - MySQL - With constraints.sql` to add the minimum set of indexes we recommend.
|
||||
|
||||
Note: you could also apply the constraints and/or the indexes before loading the data, but this will slow down the insertion of the data considerably.
|
||||
|
||||
Also note: you can apply the indexes without first applying the constraints, but then we recommend you use the script `OMOP CDM indexes required - MySQL - Without constraints.sql`. (This script will also create the indexes that would normally be automatically created by the primary key constraints.)
|
|
@ -0,0 +1,26 @@
|
|||
Common-Data-Model / MySQL Loader
|
||||
=================
|
||||
|
||||
This folder contains the a bash script for loading the csv data files. It should work on both MAC and Debian Family (eg Ubuntu)
|
||||
|
||||
It has two modes:
|
||||
|
||||
## Interactive
|
||||
```bash
|
||||
./omop_cmd_vocabulary_load-MySQL.sh
|
||||
CDMV5 Loader
|
||||
Where have the CDMV5 files been unzipped to?
|
||||
/users/peterw/tmp/cdm
|
||||
Local Database Schema?
|
||||
cdm
|
||||
Local Database username?
|
||||
cdm_user
|
||||
Local Database password?
|
||||
cmd_pwd
|
||||
```
|
||||
|
||||
## Headless
|
||||
In this mode, all the parameters required are passed on the command line and the nohup command means you can disconnect from the server and the processs will not terminate. Output is directected to a nohup.out file in the current directory
|
||||
```bash
|
||||
nohup ./omop_cmd_vocabulary_load-MySQL.sh /users/peter/tmp/cdm cdm cdm_user cdm_pwd
|
||||
```
|
|
@ -0,0 +1,97 @@
|
|||
#!/bin/bash
|
||||
# *********************************************************************************
|
||||
# Copyright 2014 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.
|
||||
# *******************************************************************************/
|
||||
|
||||
# ************************
|
||||
#
|
||||
# ####### # # ####### ###### ##### ###### # # #######
|
||||
# # # ## ## # # # # # # # # ## ## # # #
|
||||
# # # # # # # # # # # # # # # # # # # # #
|
||||
# # # # # # # # ###### # # # # # # # # ######
|
||||
# # # # # # # # # # # # # # # #
|
||||
# # # # # # # # # # # # # # # # # #
|
||||
# ####### # # ####### # ##### ###### # # ## #####
|
||||
#
|
||||
#
|
||||
# Script to load the common data model, version 5.0 vocabulary tables for PostgreSQL database on Windows (MS-DOS style file paths)
|
||||
#
|
||||
# Notes
|
||||
#
|
||||
# 1) There is no data file load for the SOURCE_TO_CONCEPT_MAP table because that table is deprecated in CDM version 5.0
|
||||
# 2) This script assumes the CDM version 5 vocabulary zip file has been unzipped into the "C:\CDMV5VOCAB" directory.
|
||||
# 3) If you unzipped your CDM version 5 vocabulary files into a different directory then replace all file paths below, with your directory path.
|
||||
#
|
||||
# last revised: 30 Sept 2016
|
||||
#
|
||||
# author: Lee Evans, Peter G. Williams (modified for MySQL)
|
||||
# *************************/
|
||||
|
||||
function makeFilesLowerCase() {
|
||||
cd $loadDir
|
||||
for f in `ls *.csv`; do mv "$f" "`echo $f | tr '[A-Z]' '[a-z]'`" 2>&1 | grep -v 'are the same'; done
|
||||
}
|
||||
|
||||
function loadData() {
|
||||
tableName=$1
|
||||
echo "Loading data into $tableName"
|
||||
{ mysql --local-infile --host=localhost --user=$dbUser --password=$dbPwd $dbName << END
|
||||
truncate table $tableName;
|
||||
load data local
|
||||
infile '$loadDir/$tableName.csv'
|
||||
into table $tableName
|
||||
columns terminated by '\t'
|
||||
lines terminated by '\n'
|
||||
ignore 1 lines;
|
||||
SHOW WARNINGS LIMIT 10;
|
||||
select '$tableName', count(*) from $tableName;
|
||||
END
|
||||
} 2>&1 | grep -v "can be insecure"
|
||||
}
|
||||
|
||||
echo "CDMV5 Loader"
|
||||
if [ ! -z "$4" ]
|
||||
then
|
||||
loadDir=$1
|
||||
dbName=$2
|
||||
dbUser=$3
|
||||
dbPwd=$4
|
||||
else
|
||||
echo "Where have the CDMV5 files been unzipped to?"
|
||||
read loadDir
|
||||
echo "Local Database Schema? "
|
||||
read dbName
|
||||
echo "Local Database username? "
|
||||
read dbUser
|
||||
echo "Local Database password? "
|
||||
read dbPwd
|
||||
fi
|
||||
|
||||
#Windows scripts don't worry about this, but the archive currently uses all Caps
|
||||
#We can take some shortcuts with the table name to file mapping if they're all lower
|
||||
echo "Renaming files as lower case..."
|
||||
makeFilesLowerCase
|
||||
dt=$(date '+%d/%m/%Y %H:%M:%S');
|
||||
echo "Starting load at $dt"
|
||||
loadData concept_ancestor
|
||||
loadData concept_class
|
||||
loadData concept_relationship
|
||||
loadData concept
|
||||
loadData domain
|
||||
loadData drug_strength
|
||||
loadData relationship
|
||||
loadData vocabulary
|
||||
dt=$(date '+%d/%m/%Y %H:%M:%S');
|
||||
echo "Process complete at $dt"
|
Loading…
Reference in New Issue