added azure synapse support
This commit is contained in:
parent
3b5f6819a5
commit
27e1924b1b
|
@ -0,0 +1 @@
|
|||
-- azure synapse does not allow Foreign Key Constraints for OMOP Common Data Model 5.4
|
|
@ -0,0 +1,546 @@
|
|||
-- azure synapse CDM DDL Specification for OMOP Common Data Model 5.4
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 datetime 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 )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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_datetime datetime NULL,
|
||||
visit_end_date date NOT NULL,
|
||||
visit_end_datetime datetime 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,
|
||||
admitted_from_concept_id integer NULL,
|
||||
admitted_from_source_value varchar(50) NULL,
|
||||
discharged_to_concept_id integer NULL,
|
||||
discharged_to_source_value varchar(50) NULL,
|
||||
preceding_visit_occurrence_id integer NULL )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 NOT NULL,
|
||||
visit_detail_start_datetime datetime NULL,
|
||||
visit_detail_end_date date NOT NULL,
|
||||
visit_detail_end_datetime datetime NULL,
|
||||
visit_detail_type_concept_id integer NOT NULL,
|
||||
provider_id integer NULL,
|
||||
care_site_id integer NULL,
|
||||
visit_detail_source_value varchar(50) NULL,
|
||||
visit_detail_source_concept_id Integer NULL,
|
||||
admitted_from_concept_id Integer NULL,
|
||||
admitted_from_source_value varchar(50) NULL,
|
||||
discharged_to_source_value varchar(50) NULL,
|
||||
discharged_to_concept_id integer NULL,
|
||||
preceding_visit_detail_id integer NULL,
|
||||
parent_visit_detail_id integer NULL,
|
||||
visit_occurrence_id integer NOT NULL )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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_start_datetime datetime NULL,
|
||||
condition_end_date date NULL,
|
||||
condition_end_datetime datetime NULL,
|
||||
condition_type_concept_id integer NOT NULL,
|
||||
condition_status_concept_id integer NULL,
|
||||
stop_reason varchar(20) NULL,
|
||||
provider_id integer NULL,
|
||||
visit_occurrence_id integer NULL,
|
||||
visit_detail_id integer NULL,
|
||||
condition_source_value varchar(50) NULL,
|
||||
condition_source_concept_id integer NULL,
|
||||
condition_status_source_value varchar(50) NULL )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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_start_datetime datetime NULL,
|
||||
drug_exposure_end_date date NOT NULL,
|
||||
drug_exposure_end_datetime datetime NULL,
|
||||
verbatim_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 varchar(MAX) NULL,
|
||||
route_concept_id integer NULL,
|
||||
lot_number varchar(50) NULL,
|
||||
provider_id integer NULL,
|
||||
visit_occurrence_id integer NULL,
|
||||
visit_detail_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 )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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_datetime datetime NULL,
|
||||
procedure_end_date date NULL,
|
||||
procedure_end_datetime datetime 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,
|
||||
visit_detail_id integer NULL,
|
||||
procedure_source_value varchar(50) NULL,
|
||||
procedure_source_concept_id integer NULL,
|
||||
modifier_source_value varchar(50) NULL )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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_start_datetime datetime NULL,
|
||||
device_exposure_end_date date NULL,
|
||||
device_exposure_end_datetime datetime NULL,
|
||||
device_type_concept_id integer NOT NULL,
|
||||
unique_device_id varchar(255) NULL,
|
||||
production_id varchar(255) NULL,
|
||||
quantity integer NULL,
|
||||
provider_id integer NULL,
|
||||
visit_occurrence_id integer NULL,
|
||||
visit_detail_id integer NULL,
|
||||
device_source_value varchar(50) NULL,
|
||||
device_source_concept_id integer NULL,
|
||||
unit_concept_id integer NULL,
|
||||
unit_source_value varchar(50) NULL,
|
||||
unit_source_concept_id integer NULL )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.MEASUREMENT (
|
||||
measurement_id integer NOT NULL,
|
||||
person_id integer NOT NULL,
|
||||
measurement_concept_id integer NOT NULL,
|
||||
measurement_date date NOT NULL,
|
||||
measurement_datetime datetime 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,
|
||||
visit_detail_id integer NULL,
|
||||
measurement_source_value varchar(50) NULL,
|
||||
measurement_source_concept_id integer NULL,
|
||||
unit_source_value varchar(50) NULL,
|
||||
unit_source_concept_id integer NULL,
|
||||
value_source_value varchar(50) NULL,
|
||||
measurement_event_id integer NULL,
|
||||
meas_event_field_concept_id integer NULL )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.OBSERVATION (
|
||||
observation_id integer NOT NULL,
|
||||
person_id integer NOT NULL,
|
||||
observation_concept_id integer NOT NULL,
|
||||
observation_date date NOT NULL,
|
||||
observation_datetime datetime 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,
|
||||
visit_detail_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,
|
||||
value_source_value varchar(50) NULL,
|
||||
observation_event_id integer NULL,
|
||||
obs_event_field_concept_id integer NULL )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.DEATH (
|
||||
person_id integer NOT NULL,
|
||||
death_date date NOT NULL,
|
||||
death_datetime datetime NULL,
|
||||
death_type_concept_id integer NULL,
|
||||
cause_concept_id integer NULL,
|
||||
cause_source_value varchar(50) NULL,
|
||||
cause_source_concept_id integer NULL )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.NOTE (
|
||||
note_id integer NOT NULL,
|
||||
person_id integer NOT NULL,
|
||||
note_date date NOT NULL,
|
||||
note_datetime datetime NULL,
|
||||
note_type_concept_id integer NOT NULL,
|
||||
note_class_concept_id integer NOT NULL,
|
||||
note_title varchar(250) NULL,
|
||||
note_text varchar(MAX) NOT 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(50) NULL,
|
||||
note_event_id integer NULL,
|
||||
note_event_field_concept_id integer NULL )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.NOTE_NLP (
|
||||
note_nlp_id integer NOT NULL,
|
||||
note_id integer NOT NULL,
|
||||
section_concept_id integer NULL,
|
||||
snippet varchar(250) NULL,
|
||||
"offset" varchar(50) NULL,
|
||||
lexical_variant varchar(250) NOT NULL,
|
||||
note_nlp_concept_id integer NULL,
|
||||
note_nlp_source_concept_id integer NULL,
|
||||
nlp_system varchar(250) NULL,
|
||||
nlp_date date NOT NULL,
|
||||
nlp_datetime datetime NULL,
|
||||
term_exists varchar(1) NULL,
|
||||
term_temporal varchar(50) NULL,
|
||||
term_modifiers varchar(2000) NULL )
|
||||
WITH (CLUSTERED INDEX(note_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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_datetime datetime 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 )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 );
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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,
|
||||
country_concept_id integer NULL,
|
||||
country_source_value varchar(80) NULL,
|
||||
latitude float NULL,
|
||||
longitude float NULL )
|
||||
WITH (CLUSTERED INDEX(location_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(care_site_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(provider_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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_concept_id integer NULL,
|
||||
payer_source_value varchar(50) NULL,
|
||||
payer_source_concept_id integer NULL,
|
||||
plan_concept_id integer NULL,
|
||||
plan_source_value varchar(50) NULL,
|
||||
plan_source_concept_id integer NULL,
|
||||
sponsor_concept_id integer NULL,
|
||||
sponsor_source_value varchar(50) NULL,
|
||||
sponsor_source_concept_id integer NULL,
|
||||
family_source_value varchar(50) NULL,
|
||||
stop_reason_concept_id integer NULL,
|
||||
stop_reason_source_value varchar(50) NULL,
|
||||
stop_reason_source_concept_id integer NULL )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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,
|
||||
revenue_code_source_value varchar(50) NULL,
|
||||
drg_concept_id integer NULL,
|
||||
drg_source_value varchar(3) NULL );
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(person_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.EPISODE (
|
||||
episode_id integer NOT NULL,
|
||||
person_id integer NOT NULL,
|
||||
episode_concept_id integer NOT NULL,
|
||||
episode_start_date date NOT NULL,
|
||||
episode_start_datetime datetime NULL,
|
||||
episode_end_date date NULL,
|
||||
episode_end_datetime datetime NULL,
|
||||
episode_parent_id integer NULL,
|
||||
episode_number integer NULL,
|
||||
episode_object_concept_id integer NOT NULL,
|
||||
episode_type_concept_id integer NOT NULL,
|
||||
episode_source_value varchar(50) NULL,
|
||||
episode_source_concept_id integer NULL );
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.EPISODE_EVENT (
|
||||
episode_id integer NOT NULL,
|
||||
event_id integer NOT NULL,
|
||||
episode_event_field_concept_id integer NOT NULL );
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.METADATA (
|
||||
metadata_id integer NOT NULL,
|
||||
metadata_concept_id integer NOT NULL,
|
||||
metadata_type_concept_id integer NOT NULL,
|
||||
name varchar(250) NOT NULL,
|
||||
value_as_string varchar(250) NULL,
|
||||
value_as_concept_id integer NULL,
|
||||
value_as_number float NULL,
|
||||
metadata_date date NULL,
|
||||
metadata_datetime datetime NULL )
|
||||
WITH (CLUSTERED INDEX(metadata_concept_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.CDM_SOURCE (
|
||||
cdm_source_name varchar(255) NOT NULL,
|
||||
cdm_source_abbreviation varchar(25) NOT NULL,
|
||||
cdm_holder varchar(255) NOT NULL,
|
||||
source_description varchar(MAX) NULL,
|
||||
source_documentation_reference varchar(255) NULL,
|
||||
cdm_etl_reference varchar(255) NULL,
|
||||
source_release_date date NOT NULL,
|
||||
cdm_release_date date NOT NULL,
|
||||
cdm_version varchar(10) NULL,
|
||||
cdm_version_concept_id integer NOT NULL,
|
||||
vocabulary_version varchar(20) NOT NULL )
|
||||
WITH (CLUSTERED INDEX(cdm_version_concept_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(concept_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(vocabulary_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.DOMAIN (
|
||||
domain_id varchar(20) NOT NULL,
|
||||
domain_name varchar(255) NOT NULL,
|
||||
domain_concept_id integer NOT NULL )
|
||||
WITH (CLUSTERED INDEX(domain_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.CONCEPT_CLASS (
|
||||
concept_class_id varchar(20) NOT NULL,
|
||||
concept_class_name varchar(255) NOT NULL,
|
||||
concept_class_concept_id integer NOT NULL )
|
||||
WITH (CLUSTERED INDEX(concept_class_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(concept_id_1));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(relationship_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.CONCEPT_SYNONYM (
|
||||
concept_id integer NOT NULL,
|
||||
concept_synonym_name varchar(1000) NOT NULL,
|
||||
language_concept_id integer NOT NULL )
|
||||
WITH (CLUSTERED INDEX(concept_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(ancestor_concept_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(target_concept_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.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 )
|
||||
WITH (CLUSTERED INDEX(drug_concept_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.COHORT (
|
||||
cohort_definition_id integer NOT NULL,
|
||||
subject_id integer NOT NULL,
|
||||
cohort_start_date date NOT NULL,
|
||||
cohort_end_date date NOT NULL )
|
||||
WITH (CLUSTERED INDEX(cohort_definition_id));
|
||||
|
||||
CREATE TABLE @cdmDatabaseSchema.COHORT_DEFINITION (
|
||||
cohort_definition_id integer NOT NULL,
|
||||
cohort_definition_name varchar(255) NOT NULL,
|
||||
cohort_definition_description varchar(MAX) NULL,
|
||||
definition_type_concept_id integer NOT NULL,
|
||||
cohort_definition_syntax varchar(MAX) NULL,
|
||||
subject_concept_id integer NOT NULL,
|
||||
cohort_initiation_date date NULL )
|
||||
WITH (CLUSTERED INDEX(cohort_definition_id));
|
|
@ -0,0 +1,84 @@
|
|||
-- azure synapse OMOP CDM Indices
|
||||
|
||||
|
||||
/************************
|
||||
|
||||
Standardized clinical data
|
||||
|
||||
************************/
|
||||
|
||||
CREATE INDEX idx_gender ON @cdmDatabaseSchema.person (gender_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_visit_concept_id_1 ON @cdmDatabaseSchema.visit_occurrence (visit_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_visit_det_concept_id_1 ON @cdmDatabaseSchema.visit_detail (visit_detail_concept_id ASC);
|
||||
CREATE INDEX idx_visit_det_occ_id ON @cdmDatabaseSchema.visit_detail (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_condition_concept_id_1 ON @cdmDatabaseSchema.condition_occurrence (condition_concept_id ASC);
|
||||
CREATE INDEX idx_condition_visit_id_1 ON @cdmDatabaseSchema.condition_occurrence (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_drug_concept_id_1 ON @cdmDatabaseSchema.drug_exposure (drug_concept_id ASC);
|
||||
CREATE INDEX idx_drug_visit_id_1 ON @cdmDatabaseSchema.drug_exposure (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_procedure_concept_id_1 ON @cdmDatabaseSchema.procedure_occurrence (procedure_concept_id ASC);
|
||||
CREATE INDEX idx_procedure_visit_id_1 ON @cdmDatabaseSchema.procedure_occurrence (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_device_concept_id_1 ON @cdmDatabaseSchema.device_exposure (device_concept_id ASC);
|
||||
CREATE INDEX idx_device_visit_id_1 ON @cdmDatabaseSchema.device_exposure (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_measurement_concept_id_1 ON @cdmDatabaseSchema.measurement (measurement_concept_id ASC);
|
||||
CREATE INDEX idx_measurement_visit_id_1 ON @cdmDatabaseSchema.measurement (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_observation_concept_id_1 ON @cdmDatabaseSchema.observation (observation_concept_id ASC);
|
||||
CREATE INDEX idx_observation_visit_id_1 ON @cdmDatabaseSchema.observation (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_note_concept_id_1 ON @cdmDatabaseSchema.note (note_type_concept_id ASC);
|
||||
CREATE INDEX idx_note_visit_id_1 ON @cdmDatabaseSchema.note (visit_occurrence_id ASC);
|
||||
|
||||
CREATE INDEX idx_note_nlp_concept_id_1 ON @cdmDatabaseSchema.note_nlp (note_nlp_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_specimen_concept_id_1 ON @cdmDatabaseSchema.specimen (specimen_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_fact_relationship_id1 ON @cdmDatabaseSchema.fact_relationship (domain_concept_id_1 ASC);
|
||||
CREATE INDEX idx_fact_relationship_id2 ON @cdmDatabaseSchema.fact_relationship (domain_concept_id_2 ASC);
|
||||
CREATE INDEX idx_fact_relationship_id3 ON @cdmDatabaseSchema.fact_relationship (relationship_concept_id ASC);
|
||||
|
||||
/************************
|
||||
|
||||
Standardized health economics
|
||||
|
||||
************************/
|
||||
|
||||
CREATE INDEX idx_cost_event_id ON @cdmDatabaseSchema.cost (cost_event_id ASC);
|
||||
|
||||
/************************
|
||||
|
||||
Standardized derived elements
|
||||
|
||||
************************/
|
||||
CREATE INDEX idx_drug_era_concept_id_1 ON @cdmDatabaseSchema.drug_era (drug_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_dose_era_concept_id_1 ON @cdmDatabaseSchema.dose_era (drug_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_condition_era_concept_id_1 ON @cdmDatabaseSchema.condition_era (condition_concept_id ASC);
|
||||
|
||||
/**************************
|
||||
|
||||
Standardized vocabularies
|
||||
|
||||
***************************/
|
||||
CREATE INDEX idx_concept_code ON @cdmDatabaseSchema.concept (concept_code ASC);
|
||||
CREATE INDEX idx_concept_vocabluary_id ON @cdmDatabaseSchema.concept (vocabulary_id ASC);
|
||||
CREATE INDEX idx_concept_domain_id ON @cdmDatabaseSchema.concept (domain_id ASC);
|
||||
CREATE INDEX idx_concept_class_id ON @cdmDatabaseSchema.concept (concept_class_id ASC);
|
||||
|
||||
CREATE INDEX idx_concept_relationship_id_2 ON @cdmDatabaseSchema.concept_relationship (concept_id_2 ASC);
|
||||
CREATE INDEX idx_concept_relationship_id_3 ON @cdmDatabaseSchema.concept_relationship (relationship_id ASC);
|
||||
|
||||
CREATE INDEX idx_concept_ancestor_id_2 ON @cdmDatabaseSchema.concept_ancestor (descendant_concept_id ASC);
|
||||
|
||||
CREATE INDEX idx_source_to_concept_map_1 ON @cdmDatabaseSchema.source_to_concept_map (source_vocabulary_id ASC);
|
||||
CREATE INDEX idx_source_to_concept_map_2 ON @cdmDatabaseSchema.source_to_concept_map (target_vocabulary_id ASC);
|
||||
CREATE INDEX idx_source_to_concept_map_c ON @cdmDatabaseSchema.source_to_concept_map (source_code ASC);
|
||||
|
||||
CREATE INDEX idx_drug_strength_id_2 ON @cdmDatabaseSchema.drug_strength (ingredient_concept_id ASC);
|
|
@ -0,0 +1,57 @@
|
|||
-- azure synapse CDM Primary Key Constraints for OMOP Common Data Model 5.4
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.PERSON ADD CONSTRAINT xpk_PERSON PRIMARY KEY NONCLUSTERED (person_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.OBSERVATION_PERIOD ADD CONSTRAINT xpk_OBSERVATION_PERIOD PRIMARY KEY NONCLUSTERED (observation_period_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.VISIT_OCCURRENCE ADD CONSTRAINT xpk_VISIT_OCCURRENCE PRIMARY KEY NONCLUSTERED (visit_occurrence_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.VISIT_DETAIL ADD CONSTRAINT xpk_VISIT_DETAIL PRIMARY KEY NONCLUSTERED (visit_detail_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.CONDITION_OCCURRENCE ADD CONSTRAINT xpk_CONDITION_OCCURRENCE PRIMARY KEY NONCLUSTERED (condition_occurrence_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.DRUG_EXPOSURE ADD CONSTRAINT xpk_DRUG_EXPOSURE PRIMARY KEY NONCLUSTERED (drug_exposure_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.PROCEDURE_OCCURRENCE ADD CONSTRAINT xpk_PROCEDURE_OCCURRENCE PRIMARY KEY NONCLUSTERED (procedure_occurrence_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.DEVICE_EXPOSURE ADD CONSTRAINT xpk_DEVICE_EXPOSURE PRIMARY KEY NONCLUSTERED (device_exposure_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.MEASUREMENT ADD CONSTRAINT xpk_MEASUREMENT PRIMARY KEY NONCLUSTERED (measurement_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.OBSERVATION ADD CONSTRAINT xpk_OBSERVATION PRIMARY KEY NONCLUSTERED (observation_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.NOTE ADD CONSTRAINT xpk_NOTE PRIMARY KEY NONCLUSTERED (note_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.NOTE_NLP ADD CONSTRAINT xpk_NOTE_NLP PRIMARY KEY NONCLUSTERED (note_nlp_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.SPECIMEN ADD CONSTRAINT xpk_SPECIMEN PRIMARY KEY NONCLUSTERED (specimen_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.LOCATION ADD CONSTRAINT xpk_LOCATION PRIMARY KEY NONCLUSTERED (location_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.CARE_SITE ADD CONSTRAINT xpk_CARE_SITE PRIMARY KEY NONCLUSTERED (care_site_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.PROVIDER ADD CONSTRAINT xpk_PROVIDER PRIMARY KEY NONCLUSTERED (provider_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.PAYER_PLAN_PERIOD ADD CONSTRAINT xpk_PAYER_PLAN_PERIOD PRIMARY KEY NONCLUSTERED (payer_plan_period_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.COST ADD CONSTRAINT xpk_COST PRIMARY KEY NONCLUSTERED (cost_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.DRUG_ERA ADD CONSTRAINT xpk_DRUG_ERA PRIMARY KEY NONCLUSTERED (drug_era_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.DOSE_ERA ADD CONSTRAINT xpk_DOSE_ERA PRIMARY KEY NONCLUSTERED (dose_era_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.CONDITION_ERA ADD CONSTRAINT xpk_CONDITION_ERA PRIMARY KEY NONCLUSTERED (condition_era_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.EPISODE ADD CONSTRAINT xpk_EPISODE PRIMARY KEY NONCLUSTERED (episode_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.METADATA ADD CONSTRAINT xpk_METADATA PRIMARY KEY NONCLUSTERED (metadata_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.CONCEPT ADD CONSTRAINT xpk_CONCEPT PRIMARY KEY NONCLUSTERED (concept_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.VOCABULARY ADD CONSTRAINT xpk_VOCABULARY PRIMARY KEY NONCLUSTERED (vocabulary_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.DOMAIN ADD CONSTRAINT xpk_DOMAIN PRIMARY KEY NONCLUSTERED (domain_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.CONCEPT_CLASS ADD CONSTRAINT xpk_CONCEPT_CLASS PRIMARY KEY NONCLUSTERED (concept_class_id) NOT ENFORCED;
|
||||
|
||||
ALTER TABLE @cdmDatabaseSchema.RELATIONSHIP ADD CONSTRAINT xpk_RELATIONSHIP PRIMARY KEY NONCLUSTERED (relationship_id) NOT ENFORCED;
|
Loading…
Reference in New Issue