From 38a0b9eb5f9b1bd909a260ea4638c6a1f0315734 Mon Sep 17 00:00:00 2001 From: Clair Blacketer Date: Fri, 15 Dec 2017 11:57:18 -0500 Subject: [PATCH] Updated CDM v5.3 DDLs based on tester feedback --- .../sql/sql_server/OMOP CDM constraints.sql | 4 - .../inst/sql/sql_server/OMOP CDM ddl.sql | 47 +- .../output/bigquery/OMOP CDM bigquery ddl.txt | 93 +- .../impala/OMOP CDM impala ddl_revised.txt | 1315 +++++++++++++++++ .../output/netezza/OMOP CDM netezza ddl.txt | 139 +- .../oracle/OMOP CDM oracle constraints.txt | 4 - .../output/oracle/OMOP CDM oracle ddl.txt | 93 +- .../output/pdw/OMOP CDM pdw constraints.txt | 4 - DDLGeneratr/output/pdw/OMOP CDM pdw ddl.txt | 129 +- .../OMOP CDM postgresql constraints.txt | 4 - .../postgresql/OMOP CDM postgresql ddl.txt | 93 +- .../output/redshift/OMOP CDM redshift ddl.txt | 10 +- .../OMOP CDM sql server constraints.txt | 4 - .../sql server/OMOP CDM sql server ddl.txt | 93 +- 14 files changed, 1666 insertions(+), 366 deletions(-) create mode 100644 DDLGeneratr/output/impala/OMOP CDM impala ddl_revised.txt diff --git a/DDLGeneratr/inst/sql/sql_server/OMOP CDM constraints.sql b/DDLGeneratr/inst/sql/sql_server/OMOP CDM constraints.sql index 17f363a..decda10 100644 --- a/DDLGeneratr/inst/sql/sql_server/OMOP CDM constraints.sql +++ b/DDLGeneratr/inst/sql/sql_server/OMOP CDM constraints.sql @@ -167,8 +167,6 @@ ALTER TABLE death ADD CONSTRAINT fpk_death_cause_concept_s FOREIGN KEY (cause_so 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); @@ -186,8 +184,6 @@ ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_preceding FOREIGN KEY (pre ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_person FOREIGN KEY (person_id) REFERENCES person (person_id); -ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_concept FOREIGN KEY (visit_concept_id) REFERENCES concept (concept_id); - ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_type_concept FOREIGN KEY (visit_type_concept_id) REFERENCES concept (concept_id); ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); diff --git a/DDLGeneratr/inst/sql/sql_server/OMOP CDM ddl.sql b/DDLGeneratr/inst/sql/sql_server/OMOP CDM ddl.sql index f1ff8f6..7ad20e0 100644 --- a/DDLGeneratr/inst/sql/sql_server/OMOP CDM ddl.sql +++ b/DDLGeneratr/inst/sql/sql_server/OMOP CDM ddl.sql @@ -207,10 +207,10 @@ CREATE TABLE metadata metadata_concept_id INTEGER NOT NULL , metadata_type_concept_id INTEGER NOT NULL , name VARCHAR(250) NOT NULL , - value_as_string NVARCHAR NULL , + value_as_string VARCHAR(MAX) NULL , value_as_concept_id INTEGER NULL , metadata_date DATE NULL , - metadata_datetime DATETIME2 NULL + metadata_datetime DATETIME NULL ) ; @@ -229,7 +229,7 @@ CREATE TABLE person year_of_birth INTEGER NOT NULL , month_of_birth INTEGER NULL, day_of_birth INTEGER NULL, - birth_datetime DATETIME2 NULL, + birth_datetime DATETIME NULL, race_concept_id INTEGER NOT NULL, ethnicity_concept_id INTEGER NOT NULL, location_id INTEGER NULL, @@ -266,7 +266,7 @@ CREATE TABLE specimen specimen_concept_id INTEGER NOT NULL , specimen_type_concept_id INTEGER NOT NULL , specimen_date DATE NOT NULL , - specimen_datetime DATETIME2 NULL , + specimen_datetime DATETIME NULL , quantity FLOAT NULL , unit_concept_id INTEGER NULL , anatomic_site_concept_id INTEGER NULL , @@ -285,7 +285,7 @@ CREATE TABLE death ( person_id INTEGER NOT NULL , death_date DATE NOT NULL , - death_datetime DATETIME2 NULL , + death_datetime DATETIME NULL , death_type_concept_id INTEGER NOT NULL , cause_concept_id INTEGER NULL , cause_source_value VARCHAR(50) NULL, @@ -301,17 +301,17 @@ CREATE TABLE visit_occurrence person_id INTEGER NOT NULL , visit_concept_id INTEGER NOT NULL , visit_start_date DATE NOT NULL , - visit_start_datetime DATETIME2 NULL , + visit_start_datetime DATETIME NULL , visit_end_date DATE NOT NULL , - visit_end_datetime DATETIME2 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 + visit_source_concept_id INTEGER NULL , admitting_source_concept_id INTEGER NULL , admitting_source_value VARCHAR(50) NULL , - discharge_to_concept_id INTEGER(50) NULL , + discharge_to_concept_id INTEGER NULL , discharge_to_source_value VARCHAR(50) NULL , preceding_visit_occurrence_id INTEGER NULL ) @@ -325,9 +325,9 @@ CREATE TABLE visit_detail person_id INTEGER NOT NULL , visit_detail_concept_id INTEGER NOT NULL , visit_start_date DATE NOT NULL , - visit_start_datetime DATETIME2 NULL , + visit_start_datetime DATETIME NULL , visit_end_date DATE NOT NULL , - visit_end_datetime DATETIME2 NULL , + visit_end_datetime DATETIME NULL , visit_type_concept_id INTEGER NOT NULL , provider_id INTEGER NULL , care_site_id INTEGER NULL , @@ -351,7 +351,7 @@ CREATE TABLE procedure_occurrence person_id INTEGER NOT NULL , procedure_concept_id INTEGER NOT NULL , procedure_date DATE NOT NULL , - procedure_datetime DATETIME2 NULL , + procedure_datetime DATETIME NULL , procedure_type_concept_id INTEGER NOT NULL , modifier_concept_id INTEGER NULL , quantity INTEGER NULL , @@ -372,9 +372,9 @@ CREATE TABLE drug_exposure person_id INTEGER NOT NULL , drug_concept_id INTEGER NOT NULL , drug_exposure_start_date DATE NOT NULL , - drug_exposure_start_datetime DATETIME2 NULL , + drug_exposure_start_datetime DATETIME NULL , drug_exposure_end_date DATE NOT NULL , - drug_exposure_end_datetime DATETIME2 NULL , + drug_exposure_end_datetime DATETIME NULL , verbatim_end_date DATE NULL , drug_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , @@ -402,9 +402,9 @@ CREATE TABLE device_exposure person_id INTEGER NOT NULL , device_concept_id INTEGER NOT NULL , device_exposure_start_date DATE NOT NULL , - device_exposure_start_datetime DATETIME2 NULL , + device_exposure_start_datetime DATETIME NULL , device_exposure_end_date DATE NULL , - device_exposure_end_datetime DATETIME2 NULL , + device_exposure_end_datetime DATETIME NULL , device_type_concept_id INTEGER NOT NULL , unique_device_id VARCHAR(50) NULL , quantity INTEGER NULL , @@ -424,9 +424,9 @@ CREATE TABLE condition_occurrence person_id INTEGER NOT NULL , condition_concept_id INTEGER NOT NULL , condition_start_date DATE NOT NULL , - condition_start_datetime DATETIME2 NULL , + condition_start_datetime DATETIME NULL , condition_end_date DATE NULL , - condition_end_datetime DATETIME2 NULL , + condition_end_datetime DATETIME NULL , condition_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , provider_id INTEGER NULL , @@ -447,8 +447,7 @@ CREATE TABLE measurement person_id INTEGER NOT NULL , measurement_concept_id INTEGER NOT NULL , measurement_date DATE NOT NULL , - measurement_time VARCHAR(10) NULL , - measurement_datetime DATETIME2 NULL , + measurement_datetime DATETIME NULL , measurement_type_concept_id INTEGER NOT NULL , operator_concept_id INTEGER NULL , value_as_number FLOAT NULL , @@ -473,7 +472,7 @@ CREATE TABLE note note_id INTEGER NOT NULL , person_id INTEGER NOT NULL , note_date DATE NOT NULL , - note_datetime DATETIME2 NULL , + note_datetime DATETIME NULL , note_type_concept_id INTEGER NOT NULL , note_class_concept_id INTEGER NOT NULL , note_title VARCHAR(250) NULL , @@ -495,13 +494,13 @@ CREATE TABLE note_nlp note_id INTEGER NOT NULL , section_concept_id INTEGER NULL , snippet VARCHAR(250) NULL , - offset VARCHAR(250) NULL , + "offset" VARCHAR(250) 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 DATETIME2 NULL , + nlp_datetime DATETIME NULL , term_exists VARCHAR(1) NULL , term_temporal VARCHAR(50) NULL , term_modifiers VARCHAR(2000) NULL @@ -516,7 +515,7 @@ CREATE TABLE observation person_id INTEGER NOT NULL , observation_concept_id INTEGER NOT NULL , observation_date DATE NOT NULL , - observation_datetime DATETIME2 NULL , + observation_datetime DATETIME NULL , observation_type_concept_id INTEGER NOT NULL , value_as_number FLOAT NULL , value_as_string VARCHAR(60) NULL , diff --git a/DDLGeneratr/output/bigquery/OMOP CDM bigquery ddl.txt b/DDLGeneratr/output/bigquery/OMOP CDM bigquery ddl.txt index e4869f2..7f947d7 100644 --- a/DDLGeneratr/output/bigquery/OMOP CDM bigquery ddl.txt +++ b/DDLGeneratr/output/bigquery/OMOP CDM bigquery ddl.txt @@ -207,10 +207,10 @@ create table metadata metadata_concept_id integer not null , metadata_type_concept_id integer not null , name varchar(250) not null , - value_as_string nvarchar null , + value_as_string varchar(max) null , value_as_concept_id integer null , metadata_date date null , - metadata_datetime datetime2 null + metadata_datetime datetime null ) ; @@ -221,7 +221,7 @@ Standardized clinical data ************************/ - +--HINT DISTRIBUTE_ON_KEY(person_id) create table person ( person_id integer not null , @@ -229,7 +229,7 @@ create table person year_of_birth integer not null , month_of_birth integer null, day_of_birth integer null, - birth_datetime datetime2 null, + birth_datetime datetime null, race_concept_id integer not null, ethnicity_concept_id integer not null, location_id integer null, @@ -246,6 +246,7 @@ create table person ; +--HINT DISTRIBUTE_ON_KEY(person_id) create table observation_period ( observation_period_id integer not null , @@ -257,6 +258,7 @@ create table observation_period ; +--HINT DISTRIBUTE_ON_KEY(person_id) create table specimen ( specimen_id integer not null , @@ -264,7 +266,7 @@ create table specimen specimen_concept_id integer not null , specimen_type_concept_id integer not null , specimen_date date not null , - specimen_datetime datetime2 null , + specimen_datetime datetime null , quantity float null , unit_concept_id integer null , anatomic_site_concept_id integer null , @@ -278,12 +280,12 @@ create table specimen ; - +--HINT DISTRIBUTE_ON_KEY(person_id) create table death ( person_id integer not null , death_date date not null , - death_datetime datetime2 null , + death_datetime datetime null , death_type_concept_id integer not null , cause_concept_id integer null , cause_source_value varchar(50) null, @@ -292,38 +294,40 @@ create table death ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_datetime datetime2 null , + visit_start_datetime datetime null , visit_end_date date not null , - visit_end_datetime datetime2 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 + visit_source_concept_id integer null , admitting_source_concept_id integer null , admitting_source_value varchar(50) null , - discharge_to_concept_id integer(50) null , + discharge_to_concept_id integer null , discharge_to_source_value varchar(50) null , preceding_visit_occurrence_id integer null ) ; +--HINT DISTRIBUTE_ON_KEY(person_id) create table visit_detail ( visit_detail_id integer not null , person_id integer not null , visit_detail_concept_id integer not null , visit_start_date date not null , - visit_start_datetime datetime2 null , + visit_start_datetime datetime null , visit_end_date date not null , - visit_end_datetime datetime2 null , + visit_end_datetime datetime null , visit_type_concept_id integer not null , provider_id integer null , care_site_id integer null , @@ -340,13 +344,14 @@ create table visit_detail ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_datetime datetime2 null , + procedure_datetime datetime null , procedure_type_concept_id integer not null , modifier_concept_id integer null , quantity integer null , @@ -360,15 +365,16 @@ create table procedure_occurrence ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_start_datetime datetime2 null , + drug_exposure_start_datetime datetime null , drug_exposure_end_date date not null , - drug_exposure_end_datetime datetime2 null , + drug_exposure_end_datetime datetime null , verbatim_end_date date null , drug_type_concept_id integer not null , stop_reason varchar(20) null , @@ -389,15 +395,16 @@ create table drug_exposure ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_start_datetime datetime2 null , + device_exposure_start_datetime datetime null , device_exposure_end_date date null , - device_exposure_end_datetime datetime2 null , + device_exposure_end_datetime datetime null , device_type_concept_id integer not null , unique_device_id varchar(50) null , quantity integer null , @@ -410,15 +417,16 @@ create table device_exposure ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_start_datetime datetime2 null , + condition_start_datetime datetime null , condition_end_date date null , - condition_end_datetime datetime2 null , + condition_end_datetime datetime null , condition_type_concept_id integer not null , stop_reason varchar(20) null , provider_id integer null , @@ -432,6 +440,7 @@ create table condition_occurrence ; +--HINT DISTRIBUTE_ON_KEY(person_id) create table measurement ( measurement_id integer not null , @@ -439,7 +448,7 @@ create table measurement measurement_concept_id integer not null , measurement_date date not null , measurement_time varchar(10) null , - measurement_datetime datetime2 null , + measurement_datetime datetime null , measurement_type_concept_id integer not null , operator_concept_id integer null , value_as_number float null , @@ -458,13 +467,13 @@ create table measurement ; - +--HINT DISTRIBUTE_ON_KEY(person_id) create table note ( note_id integer not null , person_id integer not null , note_date date not null , - note_datetime datetime2 null , + note_datetime datetime null , note_type_concept_id integer not null , note_class_concept_id integer not null , note_title varchar(250) null , @@ -486,13 +495,13 @@ create table note_nlp note_id integer not null , section_concept_id integer null , snippet varchar(250) null , - offset varchar(250) null , + "offset" varchar(250) 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 datetime2 null , + nlp_datetime datetime null , term_exists varchar(1) null , term_temporal varchar(50) null , term_modifiers varchar(2000) null @@ -500,14 +509,14 @@ create table note_nlp ; - +--HINT DISTRIBUTE_ON_KEY(person_id) 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_datetime datetime2 null , + observation_datetime datetime null , observation_type_concept_id integer not null , value_as_number float null , value_as_string varchar(60) null , @@ -525,7 +534,6 @@ create table observation ; - create table fact_relationship ( domain_concept_id_1 integer not null , @@ -538,7 +546,6 @@ create table fact_relationship - /************************ Standardized health system data @@ -546,7 +553,6 @@ Standardized health system data ************************/ - create table location ( location_id integer not null , @@ -561,7 +567,6 @@ create table location ; - create table care_site ( care_site_id integer not null , @@ -574,7 +579,6 @@ create table care_site ; - create table provider ( provider_id integer not null , @@ -594,8 +598,6 @@ create table provider ; - - /************************ Standardized health economics @@ -603,6 +605,7 @@ Standardized health economics ************************/ +--HINT DISTRIBUTE_ON_KEY(person_id) create table payer_plan_period ( payer_plan_period_id integer not null , @@ -654,15 +657,14 @@ create table cost ; - - - /************************ Standardized derived elements ************************/ + +--HINT DISTRIBUTE_ON_KEY(subject_id) create table cohort ( cohort_definition_id integer not null , @@ -673,12 +675,13 @@ create table cohort ; +--HINT DISTRIBUTE_ON_KEY(subject_id) create table cohort_attribute ( cohort_definition_id integer not null , + subject_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 @@ -686,8 +689,7 @@ create table cohort_attribute ; - - +--HINT DISTRIBUTE_ON_KEY(person_id) create table drug_era ( drug_era_id integer not null , @@ -701,6 +703,7 @@ create table drug_era ; +--HINT DISTRIBUTE_ON_KEY(person_id) create table dose_era ( dose_era_id integer not null , @@ -714,8 +717,7 @@ create table dose_era ; - - +--HINT DISTRIBUTE_ON_KEY(person_id) create table condition_era ( condition_era_id integer not null , @@ -726,10 +728,3 @@ create table condition_era condition_occurrence_count integer null ) ; - - - - - - - diff --git a/DDLGeneratr/output/impala/OMOP CDM impala ddl_revised.txt b/DDLGeneratr/output/impala/OMOP CDM impala ddl_revised.txt new file mode 100644 index 0000000..2c2299f --- /dev/null +++ b/DDLGeneratr/output/impala/OMOP CDM impala ddl_revised.txt @@ -0,0 +1,1315 @@ +/********************************************************************************* + +# Copyright 2017-11 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. + +********************************************************************************/ + + +/************************ + + + +####### # # ####### ###### ##### ###### # # ####### ##### + +# # ## ## # # # # # # # # ## ## # # # # # + +# # # # # # # # # # # # # # # # # # # # # + +# # # # # # # ###### # # # # # # # # ###### ##### + +# # # # # # # # # # # # # # # ### # + +# # # # # # # # # # # # # # # # # ### # # + +####### # # ####### # ##### ###### # # ## ##### ### ##### + + + +impala script to create OMOP common data model version 5.3 + + + +last revised: 6-Nov-2017 + + + +Authors: Patrick Ryan, Christian Reich, Clair Blacketer + + + + +*************************/ + + + + +/************************ + + + +Standardized vocabulary + + + +************************/ + + + +CREATE TABLE concept ( + + concept_id INTEGER, + + concept_name VARCHAR(255), + + domain_id VARCHAR(20), + + vocabulary_id VARCHAR(20), + + concept_class_id VARCHAR(20), + + standard_concept VARCHAR(1), + + concept_code VARCHAR(50), + + valid_start_date TIMESTAMP, + + valid_end_date TIMESTAMP, + + invalid_reason VARCHAR(1) + +) + +; + + + +CREATE TABLE vocabulary ( + + vocabulary_id VARCHAR(20), + + vocabulary_name VARCHAR(255), + + vocabulary_reference VARCHAR(255), + vocabulary_version VARCHAR(255), + + vocabulary_concept_id INTEGER + +) + +; + + + + +CREATE TABLE domain ( + + domain_id VARCHAR(20), + + domain_name VARCHAR(255), + + domain_concept_id INTEGER + +) + +; + + + + +CREATE TABLE concept_class ( + + concept_class_id VARCHAR(20), + + concept_class_name VARCHAR(255), + + concept_class_concept_id INTEGER + +) + +; + + + + +CREATE TABLE concept_relationship ( + + concept_id_1 INTEGER, + + concept_id_2 INTEGER, + + relationship_id VARCHAR(20), + + valid_start_date TIMESTAMP, + + valid_end_date TIMESTAMP, + + invalid_reason VARCHAR(1) + +) + +; + + + + +CREATE TABLE relationship ( + + relationship_id VARCHAR(20), + + relationship_name VARCHAR(255), + + is_hierarchical VARCHAR(1), + + defines_ancestry VARCHAR(1), + + reverse_relationship_id VARCHAR(20), + + relationship_concept_id INTEGER + +) + +; + + + + +CREATE TABLE concept_synonym ( + + concept_id INTEGER, + + concept_synonym_name STRING, + + language_concept_id INTEGER + +) + +; + + + + +CREATE TABLE concept_ancestor ( + + ancestor_concept_id INTEGER, + + descendant_concept_id INTEGER, + + min_levels_of_separation INTEGER, + + max_levels_of_separation INTEGER + +) + +; + + + + +CREATE TABLE source_to_concept_map ( + + source_code VARCHAR(50), + + source_concept_id INTEGER, + + source_vocabulary_id VARCHAR(20), + + source_code_description VARCHAR(255), + + target_concept_id INTEGER, + + target_vocabulary_id VARCHAR(20), + + valid_start_date TIMESTAMP, + + valid_end_date TIMESTAMP, + + invalid_reason VARCHAR(1) + +) + +; + + + + +CREATE TABLE drug_strength ( + + drug_concept_id INTEGER, + + ingredient_concept_id INTEGER, + + amount_value FLOAT, + + amount_unit_concept_id INTEGER, + + numerator_value FLOAT, + + numerator_unit_concept_id INTEGER, + + denominator_value FLOAT, + + denominator_unit_concept_id INTEGER, + + box_size INTEGER, + + valid_start_date TIMESTAMP, + + valid_end_date TIMESTAMP, + + invalid_reason VARCHAR(1) + +) + +; + + + + +CREATE TABLE cohort_definition ( + + cohort_definition_id INTEGER, + + cohort_definition_name VARCHAR(255), + + cohort_definition_description STRING, + + definition_type_concept_id INTEGER, + + cohort_definition_syntax STRING, + + subject_concept_id INTEGER, + + cohort_initiation_date TIMESTAMP + +) + +; + + + + +CREATE TABLE attribute_definition ( + + attribute_definition_id INTEGER, + + attribute_name VARCHAR(255), + + attribute_description STRING, + + attribute_type_concept_id INTEGER, + + attribute_syntax STRING + +) + +; + + + +/************************** + + + +Standardized meta-data + + + +***************************/ + + + +CREATE TABLE cdm_source +( + + cdm_source_name VARCHAR(255), + + cdm_source_abbreviation VARCHAR(25), + + cdm_holder VARCHAR(255), + + source_description STRING, + + source_documentation_reference VARCHAR(255), + + cdm_etl_reference VARCHAR(255), + + source_release_date TIMESTAMP, + + cdm_release_date TIMESTAMP, + + cdm_version VARCHAR(10), + + vocabulary_version VARCHAR(20) + +) + +; + + + + +CREATE TABLE "metadata" +( + + metadata_concept_id INTEGER, + + metadata_type_concept_id INTEGER, + + name VARCHAR(250), + + value_as_string VARCHAR(50), + + value_as_concept_id INTEGER, + + metadata_date TIMESTAMP, + + metadata_datetime TIMESTAMP + +) + +; + + + +/************************ + + + +Standardized clinical data + + + +************************/ + + + +CREATE TABLE person +( + + person_id INTEGER, + + gender_concept_id INTEGER, + + year_of_birth INTEGER, + + month_of_birth INTEGER, + + day_of_birth INTEGER, + + birth_datetime TIMESTAMP, + + race_concept_id INTEGER, + + ethnicity_concept_id INTEGER, + + location_id INTEGER, + + provider_id INTEGER, + + care_site_id INTEGER, + + person_source_value VARCHAR(50), + + gender_source_value VARCHAR(50), + + gender_source_concept_id INTEGER, + + race_source_value VARCHAR(50), + + race_source_concept_id INTEGER, + + ethnicity_source_value VARCHAR(50), + + ethnicity_source_concept_id INTEGER + +) + +; + + + + +CREATE TABLE observation_period +( + + observation_period_id INTEGER, + + person_id INTEGER, + + observation_period_start_date TIMESTAMP, + + observation_period_end_date TIMESTAMP, + + period_type_concept_id INTEGER + +) + +; + + + + +CREATE TABLE specimen +( + + specimen_id INTEGER, + person_id INTEGER, + + specimen_concept_id INTEGER, + + specimen_type_concept_id INTEGER, + + specimen_date TIMESTAMP, + + specimen_datetime TIMESTAMP, + + quantity FLOAT, + + unit_concept_id INTEGER, + + anatomic_site_concept_id INTEGER, + + disease_status_concept_id INTEGER, + + specimen_source_id VARCHAR(50), + + specimen_source_value VARCHAR(50), + + unit_source_value VARCHAR(50), + + anatomic_site_source_value VARCHAR(50), + + disease_status_source_value VARCHAR(50) + +) + +; + + + +CREATE TABLE death +( + + person_id INTEGER, + + death_date TIMESTAMP, + + death_datetime TIMESTAMP, + + death_type_concept_id INTEGER, + + cause_concept_id INTEGER, + + cause_source_value VARCHAR(50), + + cause_source_concept_id INTEGER + +) + +; + + + + +CREATE TABLE visit_occurrence +( + + visit_occurrence_id INTEGER, + + person_id INTEGER, + + visit_concept_id INTEGER, + + visit_start_date TIMESTAMP, + + visit_start_datetime TIMESTAMP, + + visit_end_date TIMESTAMP, + + visit_end_datetime TIMESTAMP, + + visit_type_concept_id INTEGER, + + provider_id INTEGER, + + care_site_id INTEGER, + + visit_source_value VARCHAR(50), + + visit_source_concept_id INTEGER +, + admitting_source_concept_id INTEGER, + + admitting_source_value VARCHAR(50), + + discharge_to_concept_id INTEGER, + + discharge_to_source_value VARCHAR(50), + + preceding_visit_occurrence_id INTEGER + +) + +; + + + + +CREATE TABLE visit_detail +( + + visit_detail_id INTEGER, + + person_id INTEGER, + + visit_detail_concept_id INTEGER, + + visit_start_date TIMESTAMP, + + visit_start_datetime TIMESTAMP, + + visit_end_date TIMESTAMP, + + visit_end_datetime TIMESTAMP, + + visit_type_concept_id INTEGER, + + provider_id INTEGER, + + care_site_id INTEGER, + + admitting_source_concept_id INTEGER, + + discharge_to_concept_id INTEGER, + + preceding_visit_detail_id INTEGER, + + visit_source_value VARCHAR(50), + + visit_source_concept_id INTEGER, + + admitting_source_value VARCHAR(50), + + discharge_to_source_value VARCHAR(50), + + visit_detail_parent_id INTEGER, + + visit_occurrence_id INTEGER + +) + +; + + + + +CREATE TABLE procedure_occurrence +( + + procedure_occurrence_id INTEGER, + + person_id INTEGER, + + procedure_concept_id INTEGER, + + procedure_date TIMESTAMP, + + procedure_datetime TIMESTAMP, + + procedure_type_concept_id INTEGER, + + modifier_concept_id INTEGER, + + quantity INTEGER, + + provider_id INTEGER, + + visit_occurrence_id INTEGER, + + visit_detail_id INTEGER, + + procedure_source_value VARCHAR(50), + + procedure_source_concept_id INTEGER, + + modifier_source_value VARCHAR(50) + +) + +; + + + + +CREATE TABLE drug_exposure +( + + drug_exposure_id INTEGER, + + person_id INTEGER, + + drug_concept_id INTEGER, + + drug_exposure_start_date TIMESTAMP, + + drug_exposure_start_datetime TIMESTAMP, + + drug_exposure_end_date TIMESTAMP, + + drug_exposure_end_datetime TIMESTAMP, + + verbatim_end_date TIMESTAMP, + + drug_type_concept_id INTEGER, + + stop_reason VARCHAR(20), + + refills INTEGER, + + quantity FLOAT, + + days_supply INTEGER, + + sig STRING, + + route_concept_id INTEGER, + + lot_number VARCHAR(50), + + provider_id INTEGER, + + visit_occurrence_id INTEGER, + + visit_detail_id INTEGER, + + drug_source_value VARCHAR(50), + + drug_source_concept_id INTEGER, + + route_source_value VARCHAR(50), + + dose_unit_source_value VARCHAR(50) + +) + +; + + + + +CREATE TABLE device_exposure +( + + device_exposure_id INTEGER, + + person_id INTEGER, + + device_concept_id INTEGER, + + device_exposure_start_date TIMESTAMP, + + device_exposure_start_datetime TIMESTAMP, + + device_exposure_end_date TIMESTAMP, + + device_exposure_end_datetime TIMESTAMP, + + device_type_concept_id INTEGER, + + unique_device_id VARCHAR(50), + + quantity INTEGER, + + provider_id INTEGER, + + visit_occurrence_id INTEGER, + + visit_detail_id INTEGER, + + device_source_value VARCHAR(100), + + device_source_concept_id INTEGER + +) + +; + + + + +CREATE TABLE condition_occurrence +( + + condition_occurrence_id INTEGER, + + person_id INTEGER, + + condition_concept_id INTEGER, + + condition_start_date TIMESTAMP, + + condition_start_datetime TIMESTAMP, + + condition_end_date TIMESTAMP, + + condition_end_datetime TIMESTAMP, + + condition_type_concept_id INTEGER, + + stop_reason VARCHAR(20), + + provider_id INTEGER, + + visit_occurrence_id INTEGER, + + visit_detail_id INTEGER, + + condition_source_value VARCHAR(50), + + condition_source_concept_id INTEGER, + + condition_status_source_value VARCHAR(50), + + condition_status_concept_id INTEGER + +) + +; + + + + +CREATE TABLE measurement +( + + measurement_id INTEGER, + + person_id INTEGER, + + measurement_concept_id INTEGER, + + measurement_date TIMESTAMP, + + measurement_datetime TIMESTAMP, + + measurement_type_concept_id INTEGER, + + operator_concept_id INTEGER, + + value_as_number FLOAT, + + value_as_concept_id INTEGER, + + unit_concept_id INTEGER, + + range_low FLOAT, + + range_high FLOAT, + + provider_id INTEGER, + visit_occurrence_id INTEGER, + + visit_detail_id INTEGER, + + measurement_source_value VARCHAR(50), + + measurement_source_concept_id INTEGER, + + unit_source_value VARCHAR(50), + + value_source_value VARCHAR(50) + +) + +; + + + + +CREATE TABLE note +( + + note_id INTEGER, + + person_id INTEGER, + + note_date TIMESTAMP, + + note_datetime TIMESTAMP, + + note_type_concept_id INTEGER, + + note_class_concept_id INTEGER, + + note_title VARCHAR(250), + + note_text STRING, + + encoding_concept_id INTEGER, + + language_concept_id INTEGER, + + provider_id INTEGER, + + visit_occurrence_id INTEGER, + + visit_detail_id INTEGER, + + note_source_value VARCHAR(50) + +) + +; + + + + +CREATE TABLE note_nlp +( + + note_nlp_id BIGINT, + + note_id INTEGER, + + section_concept_id INTEGER, + + snippet VARCHAR(250), + + "offset" VARCHAR(250), + + lexical_variant VARCHAR(250), + + note_nlp_concept_id INTEGER, + + note_nlp_source_concept_id INTEGER, + + nlp_system VARCHAR(250), + + nlp_date TIMESTAMP, + + nlp_datetime TIMESTAMP, + + term_exists VARCHAR(1), + + term_temporal VARCHAR(50), + + term_modifiers VARCHAR(2000) + +) + +; + + + + +CREATE TABLE observation +( + + observation_id INTEGER, + + person_id INTEGER, + + observation_concept_id INTEGER, + + observation_date TIMESTAMP, + + observation_datetime TIMESTAMP, + + observation_type_concept_id INTEGER, + + value_as_number FLOAT, + + value_as_string VARCHAR(60), + + value_as_concept_id INTEGER, + + qualifier_concept_id INTEGER, + + unit_concept_id INTEGER, + + provider_id INTEGER, + + visit_occurrence_id INTEGER, + + visit_detail_id INTEGER, + + observation_source_value VARCHAR(50), + + observation_source_concept_id INTEGER, + + unit_source_value VARCHAR(50), + + qualifier_source_value VARCHAR(50) + +) + +; + + + + +CREATE TABLE fact_relationship +( + + domain_concept_id_1 INTEGER, + + fact_id_1 INTEGER, + + domain_concept_id_2 INTEGER, + + fact_id_2 INTEGER, + + relationship_concept_id INTEGER + +) + +; + + + + +/************************ + + + +Standardized health system data + + + +************************/ + + + +CREATE TABLE "location" +( + + location_id INTEGER, + + address_1 VARCHAR(50), + + address_2 VARCHAR(50), + + city VARCHAR(50), + + state VARCHAR(2), + + zip VARCHAR(9), + + county VARCHAR(20), + + location_source_value VARCHAR(50) + +) + +; + + + + +CREATE TABLE care_site +( + + care_site_id INTEGER, + + care_site_name VARCHAR(255), + + place_of_service_concept_id INTEGER, + + location_id INTEGER, + + care_site_source_value VARCHAR(50), + + place_of_service_source_value VARCHAR(50) + +) + +; + + + + +CREATE TABLE provider +( + + provider_id INTEGER, + + provider_name VARCHAR(255), + + NPI VARCHAR(20), + + DEA VARCHAR(20), + + specialty_concept_id INTEGER, + care_site_id INTEGER, + + year_of_birth INTEGER, + + gender_concept_id INTEGER, + + provider_source_value VARCHAR(50), + + specialty_source_value VARCHAR(50), + + specialty_source_concept_id INTEGER, + + gender_source_value VARCHAR(50), + + gender_source_concept_id INTEGER + +) + +; + + + +/************************ + + + +Standardized health economics + + + +************************/ + + + + +CREATE TABLE payer_plan_period +( + + payer_plan_period_id INTEGER, + + person_id INTEGER, + + payer_plan_period_start_date TIMESTAMP, + + payer_plan_period_end_date TIMESTAMP, + + payer_concept_id INTEGER, + + payer_source_value VARCHAR(50), + + payer_source_concept_id INTEGER, + + plan_concept_id INTEGER, + + plan_source_value VARCHAR(50), + + plan_source_concept_id INTEGER, + + sponsor_concept_id INTEGER, + + sponsor_source_value VARCHAR(50), + + sponsor_source_concept_id INTEGER, + + family_source_value VARCHAR(50), + + stop_reason_concept_id INTEGER, + + stop_reason_source_value INTEGER, + + stop_reason_source_concept_id INTEGER +) + +; + + + + +CREATE TABLE cost +( + + cost_id INTEGER, + + cost_event_id INTEGER, + + cost_domain_id VARCHAR(20), + + cost_type_concept_id INTEGER, + + currency_concept_id INTEGER, + + total_charge FLOAT, + + total_cost FLOAT, + + total_paid FLOAT, + + paid_by_payer FLOAT, + + paid_by_patient FLOAT, + + paid_patient_copay FLOAT, + + paid_patient_coinsurance FLOAT, + + paid_patient_deductible FLOAT, + + paid_by_primary FLOAT, + + paid_ingredient_cost FLOAT, + + paid_dispensing_fee FLOAT, + + payer_plan_period_id INTEGER, + + amount_allowed FLOAT, + + revenue_code_concept_id INTEGER, + + reveue_code_source_value VARCHAR(50), + + drg_concept_id INTEGER, + + drg_source_value VARCHAR(3) + +) + +; + + + +/************************ + + + +Standardized derived elements + + + +************************/ + + + +CREATE TABLE cohort +( + + cohort_definition_id INTEGER, + + subject_id INTEGER, + + cohort_start_date TIMESTAMP, + + cohort_end_date TIMESTAMP + +) + +; + + + + +CREATE TABLE cohort_attribute +( + + cohort_definition_id INTEGER, + + cohort_start_date TIMESTAMP, + + cohort_end_date TIMESTAMP, + + subject_id INTEGER, + + attribute_definition_id INTEGER, + + value_as_number FLOAT, + + value_as_concept_id INTEGER + +) + +; + + + + +CREATE TABLE drug_era +( + + drug_era_id INTEGER, + + person_id INTEGER, + + drug_concept_id INTEGER, + + drug_era_start_date TIMESTAMP, + + drug_era_end_date TIMESTAMP, + + drug_exposure_count INTEGER, + + gap_days INTEGER + +) + +; + + + + +CREATE TABLE dose_era +( + + dose_era_id INTEGER, + + person_id INTEGER, + + drug_concept_id INTEGER, + + unit_concept_id INTEGER, + + dose_value FLOAT, + + dose_era_start_date TIMESTAMP, + + dose_era_end_date TIMESTAMP + +) + +; + + +CREATE TABLE condition_era +( + + condition_era_id INTEGER, + + person_id INTEGER, + + condition_concept_id INTEGER, + + condition_era_start_date TIMESTAMP, + + condition_era_end_date TIMESTAMP, + + condition_occurrence_count INTEGER +) +; diff --git a/DDLGeneratr/output/netezza/OMOP CDM netezza ddl.txt b/DDLGeneratr/output/netezza/OMOP CDM netezza ddl.txt index 5561434..7f0be1b 100644 --- a/DDLGeneratr/output/netezza/OMOP CDM netezza ddl.txt +++ b/DDLGeneratr/output/netezza/OMOP CDM netezza ddl.txt @@ -42,7 +42,7 @@ Standardized vocabulary ************************/ - +--HINT DISTRIBUTE ON RANDOM CREATE TABLE concept ( concept_id INTEGER NOT NULL , concept_name VARCHAR(255) NOT NULL , @@ -55,9 +55,11 @@ CREATE TABLE concept ( valid_end_date DATE NOT NULL , invalid_reason VARCHAR(1) NULL ) +DISTRIBUTE ON RANDOM ; +--HINT DISTRIBUTE ON RANDOM CREATE TABLE vocabulary ( vocabulary_id VARCHAR(20) NOT NULL, vocabulary_name VARCHAR(255) NOT NULL, @@ -65,25 +67,31 @@ CREATE TABLE vocabulary ( vocabulary_version VARCHAR(255) NOT NULL, vocabulary_concept_id INTEGER NOT NULL ) +DISTRIBUTE ON RANDOM ; +--HINT DISTRIBUTE ON RANDOM CREATE TABLE domain ( domain_id VARCHAR(20) NOT NULL, domain_name VARCHAR(255) NOT NULL, domain_concept_id INTEGER NOT NULL ) +DISTRIBUTE ON RANDOM ; +--HINT DISTRIBUTE ON RANDOM 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 ) +DISTRIBUTE ON RANDOM ; +--HINT DISTRIBUTE ON RANDOM CREATE TABLE concept_relationship ( concept_id_1 INTEGER NOT NULL, concept_id_2 INTEGER NOT NULL, @@ -92,9 +100,11 @@ CREATE TABLE concept_relationship ( valid_end_date DATE NOT NULL, invalid_reason VARCHAR(1) NULL ) +DISTRIBUTE ON RANDOM ; +--HINT DISTRIBUTE ON RANDOM CREATE TABLE relationship ( relationship_id VARCHAR(20) NOT NULL, relationship_name VARCHAR(255) NOT NULL, @@ -106,23 +116,28 @@ CREATE TABLE relationship ( ; +--HINT DISTRIBUTE ON RANDOM CREATE TABLE concept_synonym ( concept_id INTEGER NOT NULL, concept_synonym_name VARCHAR(1000) NOT NULL, language_concept_id INTEGER NOT NULL ) +DISTRIBUTE ON RANDOM ; +--HINT DISTRIBUTE ON RANDOM 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 ) +DISTRIBUTE ON RANDOM ; +--HINT DISTRIBUTE ON RANDOM CREATE TABLE source_to_concept_map ( source_code VARCHAR(50) NOT NULL, source_concept_id INTEGER NOT NULL, @@ -134,29 +149,30 @@ CREATE TABLE source_to_concept_map ( valid_end_date DATE NOT NULL, invalid_reason VARCHAR(1) NULL ) +DISTRIBUTE ON RANDOM ; - - +--HINT DISTRIBUTE ON RANDOM CREATE TABLE drug_strength ( drug_concept_id INTEGER NOT NULL, ingredient_concept_id INTEGER NOT NULL, - amount_value NUMERIC NULL, + amount_value REAL NULL, amount_unit_concept_id INTEGER NULL, - numerator_value NUMERIC NULL, + numerator_value REAL NULL, numerator_unit_concept_id INTEGER NULL, - denominator_value NUMERIC NULL, + denominator_value REAL 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 ) +DISTRIBUTE ON RANDOM ; - +-HINT DISTRIBUTE ON RANDOM CREATE TABLE cohort_definition ( cohort_definition_id INTEGER NOT NULL, cohort_definition_name VARCHAR(255) NOT NULL, @@ -166,9 +182,11 @@ CREATE TABLE cohort_definition ( subject_concept_id INTEGER NOT NULL, cohort_initiation_date DATE NULL ) +DISTRIBUTE ON RANDOM ; +--HINT DISTRIBUTE ON RANDOM CREATE TABLE attribute_definition ( attribute_definition_id INTEGER NOT NULL, attribute_name VARCHAR(255) NOT NULL, @@ -176,6 +194,7 @@ CREATE TABLE attribute_definition ( attribute_type_concept_id INTEGER NOT NULL, attribute_syntax VARCHAR(1000) NULL ) +DISTRIBUTE ON RANDOM ; @@ -185,7 +204,7 @@ Standardized meta-data ***************************/ - +--HINT DISTRIBUTE ON RANDOM CREATE TABLE cdm_source ( cdm_source_name VARCHAR(255) NOT NULL , @@ -199,19 +218,22 @@ CREATE TABLE cdm_source cdm_version VARCHAR(10) NULL , vocabulary_version VARCHAR(20) NULL ) +DISTRIBUTE ON RANDOM ; +--HINT DISTRIBUTE ON RANDOM CREATE TABLE metadata ( metadata_concept_id INTEGER NOT NULL , metadata_type_concept_id INTEGER NOT NULL , name VARCHAR(250) NOT NULL , - value_as_string NVARCHAR NULL , + value_as_string VARCHAR(1000) NULL , value_as_concept_id INTEGER NULL , metadata_date DATE NULL , - metadata_datetime DATETIME2 NULL + metadata_datetime DATETIME NULL ) +DISTRIBUTE ON RANDOM ; @@ -229,7 +251,7 @@ CREATE TABLE person year_of_birth INTEGER NOT NULL , month_of_birth INTEGER NULL, day_of_birth INTEGER NULL, - birth_datetime DATETIME2 NULL, + birth_datetime DATETIME NULL, race_concept_id INTEGER NOT NULL, ethnicity_concept_id INTEGER NOT NULL, location_id INTEGER NULL, @@ -268,8 +290,8 @@ CREATE TABLE specimen specimen_concept_id INTEGER NOT NULL , specimen_type_concept_id INTEGER NOT NULL , specimen_date DATE NOT NULL , - specimen_datetime DATETIME2 NULL , - quantity NUMERIC NULL , + specimen_datetime DATETIME NULL , + quantity REAL NULL , unit_concept_id INTEGER NULL , anatomic_site_concept_id INTEGER NULL , disease_status_concept_id INTEGER NULL , @@ -288,7 +310,7 @@ CREATE TABLE death ( person_id INTEGER NOT NULL , death_date DATE NOT NULL , - death_datetime DATETIME2 NULL , + death_datetime DATETIME NULL , death_type_concept_id INTEGER NOT NULL , cause_concept_id INTEGER NULL , cause_source_value VARCHAR(50) NULL, @@ -305,17 +327,17 @@ CREATE TABLE visit_occurrence person_id INTEGER NOT NULL , visit_concept_id INTEGER NOT NULL , visit_start_date DATE NOT NULL , - visit_start_datetime DATETIME2 NULL , + visit_start_datetime DATETIME NULL , visit_end_date DATE NOT NULL , - visit_end_datetime DATETIME2 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 + visit_source_concept_id INTEGER NULL, admitting_source_concept_id INTEGER NULL , admitting_source_value VARCHAR(50) NULL , - discharge_to_concept_id INTEGER(50) NULL , + discharge_to_concept_id INTEGER NULL , discharge_to_source_value VARCHAR(50) NULL , preceding_visit_occurrence_id INTEGER NULL ) @@ -330,9 +352,9 @@ CREATE TABLE visit_detail person_id INTEGER NOT NULL , visit_detail_concept_id INTEGER NOT NULL , visit_start_date DATE NOT NULL , - visit_start_datetime DATETIME2 NULL , + visit_start_datetime DATETIME NULL , visit_end_date DATE NOT NULL , - visit_end_datetime DATETIME2 NULL , + visit_end_datetime DATETIME NULL , visit_type_concept_id INTEGER NOT NULL , provider_id INTEGER NULL , care_site_id INTEGER NULL , @@ -357,7 +379,7 @@ CREATE TABLE procedure_occurrence person_id INTEGER NOT NULL , procedure_concept_id INTEGER NOT NULL , procedure_date DATE NOT NULL , - procedure_datetime DATETIME2 NULL , + procedure_datetime DATETIME NULL , procedure_type_concept_id INTEGER NOT NULL , modifier_concept_id INTEGER NULL , quantity INTEGER NULL , @@ -379,14 +401,14 @@ CREATE TABLE drug_exposure person_id INTEGER NOT NULL , drug_concept_id INTEGER NOT NULL , drug_exposure_start_date DATE NOT NULL , - drug_exposure_start_datetime DATETIME2 NULL , + drug_exposure_start_datetime DATETIME NULL , drug_exposure_end_date DATE NOT NULL , - drug_exposure_end_datetime DATETIME2 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 NUMERIC NULL , + quantity REAL NULL , days_supply INTEGER NULL , sig VARCHAR(1000) NULL , route_concept_id INTEGER NULL , @@ -410,9 +432,9 @@ CREATE TABLE device_exposure person_id INTEGER NOT NULL , device_concept_id INTEGER NOT NULL , device_exposure_start_date DATE NOT NULL , - device_exposure_start_datetime DATETIME2 NULL , + device_exposure_start_datetime DATETIME NULL , device_exposure_end_date DATE NULL , - device_exposure_end_datetime DATETIME2 NULL , + device_exposure_end_datetime DATETIME NULL , device_type_concept_id INTEGER NOT NULL , unique_device_id VARCHAR(50) NULL , quantity INTEGER NULL , @@ -433,9 +455,9 @@ CREATE TABLE condition_occurrence person_id INTEGER NOT NULL , condition_concept_id INTEGER NOT NULL , condition_start_date DATE NOT NULL , - condition_start_datetime DATETIME2 NULL , + condition_start_datetime DATETIME NULL , condition_end_date DATE NULL , - condition_end_datetime DATETIME2 NULL , + condition_end_datetime DATETIME NULL , condition_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , provider_id INTEGER NULL , @@ -457,15 +479,14 @@ CREATE TABLE measurement person_id INTEGER NOT NULL , measurement_concept_id INTEGER NOT NULL , measurement_date DATE NOT NULL , - measurement_time VARCHAR(10) NULL , - measurement_datetime DATETIME2 NULL , + measurement_datetime DATETIME NULL , measurement_type_concept_id INTEGER NOT NULL , operator_concept_id INTEGER NULL , - value_as_number NUMERIC NULL , + value_as_number REAL NULL , value_as_concept_id INTEGER NULL , unit_concept_id INTEGER NULL , - range_low NUMERIC NULL , - range_high NUMERIC NULL , + range_low REAL NULL , + range_high REAL NULL , provider_id INTEGER NULL , visit_occurrence_id INTEGER NULL , visit_detail_id INTEGER NULL , @@ -484,7 +505,7 @@ CREATE TABLE note note_id INTEGER NOT NULL , person_id INTEGER NOT NULL , note_date DATE NOT NULL , - note_datetime DATETIME2 NULL , + note_datetime DATETIME NULL , note_type_concept_id INTEGER NOT NULL , note_class_concept_id INTEGER NOT NULL , note_title VARCHAR(250) NULL , @@ -500,24 +521,25 @@ DISTRIBUTE ON (person_id) ; - +--HINT DISTRIBUTE ON RANDOM CREATE TABLE note_nlp ( note_nlp_id BIGINT NOT NULL , note_id INTEGER NOT NULL , section_concept_id INTEGER NULL , snippet VARCHAR(250) NULL , - offset VARCHAR(250) NULL , + "offset" VARCHAR(250) 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 DATETIME2 NULL , + nlp_datetime DATETIME NULL , term_exists VARCHAR(1) NULL , term_temporal VARCHAR(50) NULL , term_modifiers VARCHAR(2000) NULL ) +DISTRIBUTE ON RANDOM ; @@ -528,9 +550,9 @@ CREATE TABLE observation person_id INTEGER NOT NULL , observation_concept_id INTEGER NOT NULL , observation_date DATE NOT NULL , - observation_datetime DATETIME2 NULL , + observation_datetime DATETIME NULL , observation_type_concept_id INTEGER NOT NULL , - value_as_number NUMERIC NULL , + value_as_number REAL NULL , value_as_string VARCHAR(60) NULL , value_as_concept_id INTEGER NULL , qualifier_concept_id INTEGER NULL , @@ -547,6 +569,7 @@ DISTRIBUTE ON (person_id) ; +--HINT DISTRIBUTE ON RANDOM CREATE TABLE fact_relationship ( domain_concept_id_1 INTEGER NOT NULL , @@ -555,6 +578,7 @@ CREATE TABLE fact_relationship fact_id_2 INTEGER NOT NULL , relationship_concept_id INTEGER NOT NULL ) +DISTRIBUTE ON RANDOM ; @@ -565,7 +589,7 @@ Standardized health system data ************************/ - +--HINT DISTRIBUTE ON RANDOM CREATE TABLE location ( location_id INTEGER NOT NULL , @@ -577,9 +601,11 @@ CREATE TABLE location county VARCHAR(20) NULL , location_source_value VARCHAR(50) NULL ) +DISTRIBUTE ON RANDOM ; +--HINT DISTRIBUTE ON RANDOM CREATE TABLE care_site ( care_site_id INTEGER NOT NULL , @@ -589,9 +615,11 @@ CREATE TABLE care_site care_site_source_value VARCHAR(50) NULL , place_of_service_source_value VARCHAR(50) NULL ) +DISTRIBUTE ON RANDOM ; +--HINT DISTRIBUTE ON RANDOM CREATE TABLE provider ( provider_id INTEGER NOT NULL , @@ -608,6 +636,7 @@ CREATE TABLE provider gender_source_value VARCHAR(50) NULL , gender_source_concept_id INTEGER NULL ) +DISTRIBUTE ON RANDOM ; @@ -643,6 +672,7 @@ DISTRIBUTE ON (person_id) ; +--HINT DISTRIBUTE ON RANDOM CREATE TABLE cost ( cost_id INTEGER NOT NULL , @@ -650,24 +680,25 @@ CREATE TABLE cost cost_domain_id VARCHAR(20) NOT NULL , cost_type_concept_id INTEGER NOT NULL , currency_concept_id INTEGER NULL , - total_charge NUMERIC NULL , - total_cost NUMERIC NULL , - total_paid NUMERIC NULL , - paid_by_payer NUMERIC NULL , - paid_by_patient NUMERIC NULL , - paid_patient_copay NUMERIC NULL , - paid_patient_coinsurance NUMERIC NULL , - paid_patient_deductible NUMERIC NULL , - paid_by_primary NUMERIC NULL , - paid_ingredient_cost NUMERIC NULL , - paid_dispensing_fee NUMERIC NULL , + total_charge REAL NULL , + total_cost REAL NULL , + total_paid REAL NULL , + paid_by_payer REAL NULL , + paid_by_patient REAL NULL , + paid_patient_copay REAL NULL , + paid_patient_coinsurance REAL NULL , + paid_patient_deductible REAL NULL , + paid_by_primary REAL NULL , + paid_ingredient_cost REAL NULL , + paid_dispensing_fee REAL NULL , payer_plan_period_id INTEGER NULL , - amount_allowed NUMERIC NULL , + amount_allowed REAL NULL , revenue_code_concept_id INTEGER NULL , reveue_code_source_value VARCHAR(50) NULL, drg_concept_id INTEGER NULL, drg_source_value VARCHAR(3) NULL ) +DISTRIBUTE ON RANDOM ; @@ -698,7 +729,7 @@ CREATE TABLE cohort_attribute cohort_start_date DATE NOT NULL , cohort_end_date DATE NOT NULL , attribute_definition_id INTEGER NOT NULL , - value_as_number NUMERIC NULL , + value_as_number REAL NULL , value_as_concept_id INTEGER NULL ) DISTRIBUTE ON (subject_id) @@ -727,7 +758,7 @@ CREATE TABLE dose_era person_id INTEGER NOT NULL , drug_concept_id INTEGER NOT NULL , unit_concept_id INTEGER NOT NULL , - dose_value NUMERIC NOT NULL , + dose_value REAL NOT NULL , dose_era_start_date DATE NOT NULL , dose_era_end_date DATE NOT NULL ) diff --git a/DDLGeneratr/output/oracle/OMOP CDM oracle constraints.txt b/DDLGeneratr/output/oracle/OMOP CDM oracle constraints.txt index facbafa..c6d4134 100644 --- a/DDLGeneratr/output/oracle/OMOP CDM oracle constraints.txt +++ b/DDLGeneratr/output/oracle/OMOP CDM oracle constraints.txt @@ -167,8 +167,6 @@ ALTER TABLE death ADD CONSTRAINT fpk_death_cause_concept_s FOREIGN KEY (cause_so 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); @@ -186,8 +184,6 @@ ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_preceding FOREIGN KEY (pre ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_person FOREIGN KEY (person_id) REFERENCES person (person_id); -ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_concept FOREIGN KEY (visit_concept_id) REFERENCES concept (concept_id); - ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_type_concept FOREIGN KEY (visit_type_concept_id) REFERENCES concept (concept_id); ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); diff --git a/DDLGeneratr/output/oracle/OMOP CDM oracle ddl.txt b/DDLGeneratr/output/oracle/OMOP CDM oracle ddl.txt index 318f909..6d86ff9 100644 --- a/DDLGeneratr/output/oracle/OMOP CDM oracle ddl.txt +++ b/DDLGeneratr/output/oracle/OMOP CDM oracle ddl.txt @@ -207,10 +207,10 @@ CREATE TABLE metadata metadata_concept_id INTEGER NOT NULL , metadata_type_concept_id INTEGER NOT NULL , name VARCHAR(250) NOT NULL , - value_as_string NVARCHAR NULL , + value_as_string CLOB NULL , value_as_concept_id INTEGER NULL , metadata_date DATE NULL , - metadata_datetime DATETIME2 NULL + metadata_datetime TIMESTAMP NULL ) ; @@ -221,7 +221,7 @@ Standardized clinical data ************************/ - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE person ( person_id INTEGER NOT NULL , @@ -229,7 +229,7 @@ CREATE TABLE person year_of_birth INTEGER NOT NULL , month_of_birth INTEGER NULL, day_of_birth INTEGER NULL, - birth_datetime DATETIME2 NULL, + birth_datetime TIMESTAMP NULL, race_concept_id INTEGER NOT NULL, ethnicity_concept_id INTEGER NOT NULL, location_id INTEGER NULL, @@ -246,6 +246,7 @@ CREATE TABLE person ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE observation_period ( observation_period_id INTEGER NOT NULL , @@ -257,6 +258,7 @@ CREATE TABLE observation_period ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE specimen ( specimen_id INTEGER NOT NULL , @@ -264,7 +266,7 @@ CREATE TABLE specimen specimen_concept_id INTEGER NOT NULL , specimen_type_concept_id INTEGER NOT NULL , specimen_date DATE NOT NULL , - specimen_datetime DATETIME2 NULL , + specimen_datetime TIMESTAMP NULL , quantity FLOAT NULL , unit_concept_id INTEGER NULL , anatomic_site_concept_id INTEGER NULL , @@ -278,12 +280,12 @@ CREATE TABLE specimen ; - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE death ( person_id INTEGER NOT NULL , death_date DATE NOT NULL , - death_datetime DATETIME2 NULL , + death_datetime TIMESTAMP NULL , death_type_concept_id INTEGER NOT NULL , cause_concept_id INTEGER NULL , cause_source_value VARCHAR(50) NULL, @@ -292,38 +294,40 @@ CREATE TABLE death ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_datetime DATETIME2 NULL , + visit_start_datetime TIMESTAMP NULL , visit_end_date DATE NOT NULL , - visit_end_datetime DATETIME2 NULL , + visit_end_datetime TIMESTAMP 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 + visit_source_concept_id INTEGER NULL , admitting_source_concept_id INTEGER NULL , admitting_source_value VARCHAR(50) NULL , - discharge_to_concept_id INTEGER(50) NULL , + discharge_to_concept_id INTEGER NULL , discharge_to_source_value VARCHAR(50) NULL , preceding_visit_occurrence_id INTEGER NULL ) ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE visit_detail ( visit_detail_id INTEGER NOT NULL , person_id INTEGER NOT NULL , visit_detail_concept_id INTEGER NOT NULL , visit_start_date DATE NOT NULL , - visit_start_datetime DATETIME2 NULL , + visit_start_datetime TIMESTAMP NULL , visit_end_date DATE NOT NULL , - visit_end_datetime DATETIME2 NULL , + visit_end_datetime TIMESTAMP NULL , visit_type_concept_id INTEGER NOT NULL , provider_id INTEGER NULL , care_site_id INTEGER NULL , @@ -340,13 +344,14 @@ CREATE TABLE visit_detail ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_datetime DATETIME2 NULL , + procedure_datetime TIMESTAMP NULL , procedure_type_concept_id INTEGER NOT NULL , modifier_concept_id INTEGER NULL , quantity INTEGER NULL , @@ -360,15 +365,16 @@ CREATE TABLE procedure_occurrence ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_start_datetime DATETIME2 NULL , + drug_exposure_start_datetime TIMESTAMP NULL , drug_exposure_end_date DATE NOT NULL , - drug_exposure_end_datetime DATETIME2 NULL , + drug_exposure_end_datetime TIMESTAMP NULL , verbatim_end_date DATE NULL , drug_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , @@ -389,15 +395,16 @@ CREATE TABLE drug_exposure ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_start_datetime DATETIME2 NULL , + device_exposure_start_datetime TIMESTAMP NULL , device_exposure_end_date DATE NULL , - device_exposure_end_datetime DATETIME2 NULL , + device_exposure_end_datetime TIMESTAMP NULL , device_type_concept_id INTEGER NOT NULL , unique_device_id VARCHAR(50) NULL , quantity INTEGER NULL , @@ -410,15 +417,16 @@ CREATE TABLE device_exposure ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_start_datetime DATETIME2 NULL , + condition_start_datetime TIMESTAMP NULL , condition_end_date DATE NULL , - condition_end_datetime DATETIME2 NULL , + condition_end_datetime TIMESTAMP NULL , condition_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , provider_id INTEGER NULL , @@ -432,6 +440,7 @@ CREATE TABLE condition_occurrence ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE measurement ( measurement_id INTEGER NOT NULL , @@ -439,7 +448,7 @@ CREATE TABLE measurement measurement_concept_id INTEGER NOT NULL , measurement_date DATE NOT NULL , measurement_time VARCHAR(10) NULL , - measurement_datetime DATETIME2 NULL , + measurement_datetime TIMESTAMP NULL , measurement_type_concept_id INTEGER NOT NULL , operator_concept_id INTEGER NULL , value_as_number FLOAT NULL , @@ -458,13 +467,13 @@ CREATE TABLE measurement ; - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE note ( note_id INTEGER NOT NULL , person_id INTEGER NOT NULL , note_date DATE NOT NULL , - note_datetime DATETIME2 NULL , + note_datetime TIMESTAMP NULL , note_type_concept_id INTEGER NOT NULL , note_class_concept_id INTEGER NOT NULL , note_title VARCHAR(250) NULL , @@ -486,13 +495,13 @@ CREATE TABLE note_nlp note_id INTEGER NOT NULL , section_concept_id INTEGER NULL , snippet VARCHAR(250) NULL , - offset VARCHAR(250) NULL , + "offset" VARCHAR(250) 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 DATETIME2 NULL , + nlp_datetime TIMESTAMP NULL , term_exists VARCHAR(1) NULL , term_temporal VARCHAR(50) NULL , term_modifiers VARCHAR(2000) NULL @@ -500,14 +509,14 @@ CREATE TABLE note_nlp ; - +--HINT DISTRIBUTE_ON_KEY(person_id) 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_datetime DATETIME2 NULL , + observation_datetime TIMESTAMP NULL , observation_type_concept_id INTEGER NOT NULL , value_as_number FLOAT NULL , value_as_string VARCHAR(60) NULL , @@ -525,7 +534,6 @@ CREATE TABLE observation ; - CREATE TABLE fact_relationship ( domain_concept_id_1 INTEGER NOT NULL , @@ -538,7 +546,6 @@ CREATE TABLE fact_relationship - /************************ Standardized health system data @@ -546,7 +553,6 @@ Standardized health system data ************************/ - CREATE TABLE location ( location_id INTEGER NOT NULL , @@ -561,7 +567,6 @@ CREATE TABLE location ; - CREATE TABLE care_site ( care_site_id INTEGER NOT NULL , @@ -574,7 +579,6 @@ CREATE TABLE care_site ; - CREATE TABLE provider ( provider_id INTEGER NOT NULL , @@ -594,8 +598,6 @@ CREATE TABLE provider ; - - /************************ Standardized health economics @@ -603,6 +605,7 @@ Standardized health economics ************************/ +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE payer_plan_period ( payer_plan_period_id INTEGER NOT NULL , @@ -654,15 +657,14 @@ CREATE TABLE cost ; - - - /************************ Standardized derived elements ************************/ + +--HINT DISTRIBUTE_ON_KEY(subject_id) CREATE TABLE cohort ( cohort_definition_id INTEGER NOT NULL , @@ -673,12 +675,13 @@ CREATE TABLE cohort ; +--HINT DISTRIBUTE_ON_KEY(subject_id) CREATE TABLE cohort_attribute ( cohort_definition_id INTEGER NOT NULL , + subject_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 @@ -686,8 +689,7 @@ CREATE TABLE cohort_attribute ; - - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE drug_era ( drug_era_id INTEGER NOT NULL , @@ -701,6 +703,7 @@ CREATE TABLE drug_era ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE dose_era ( dose_era_id INTEGER NOT NULL , @@ -714,8 +717,7 @@ CREATE TABLE dose_era ; - - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE condition_era ( condition_era_id INTEGER NOT NULL , @@ -726,10 +728,3 @@ CREATE TABLE condition_era condition_occurrence_count INTEGER NULL ) ; - - - - - - - diff --git a/DDLGeneratr/output/pdw/OMOP CDM pdw constraints.txt b/DDLGeneratr/output/pdw/OMOP CDM pdw constraints.txt index a96d34c..0d31276 100644 --- a/DDLGeneratr/output/pdw/OMOP CDM pdw constraints.txt +++ b/DDLGeneratr/output/pdw/OMOP CDM pdw constraints.txt @@ -167,8 +167,6 @@ ALTER TABLE death ADD CONSTRAINT fpk_death_cause_concept_s FOREIGN KEY (cause_so 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); @@ -186,8 +184,6 @@ ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_preceding FOREIGN KEY (pre ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_person FOREIGN KEY (person_id) REFERENCES person (person_id); -ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_concept FOREIGN KEY (visit_concept_id) REFERENCES concept (concept_id); - ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_type_concept FOREIGN KEY (visit_type_concept_id) REFERENCES concept (concept_id); ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); diff --git a/DDLGeneratr/output/pdw/OMOP CDM pdw ddl.txt b/DDLGeneratr/output/pdw/OMOP CDM pdw ddl.txt index 4b1e565..9ddf970 100644 --- a/DDLGeneratr/output/pdw/OMOP CDM pdw ddl.txt +++ b/DDLGeneratr/output/pdw/OMOP CDM pdw ddl.txt @@ -193,10 +193,10 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE metadata (metadata_concept_id INTEGER NOT NULL , metadata_type_concept_id INTEGER NOT NULL , name VARCHAR(250) NOT NULL , - value_as_string NVARCHAR NULL , + value_as_string VARCHAR(1000) NULL , value_as_concept_id INTEGER NULL , metadata_date DATE NULL , - metadata_datetime DATETIME2 NULL + metadata_datetime DATETIME NULL ) WITH (DISTRIBUTION = REPLICATE); @@ -207,14 +207,14 @@ Standardized clinical data ************************/ - +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE person - ( person_id INTEGER NOT NULL , + (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 DATETIME2 NULL, + birth_datetime DATETIME NULL, race_concept_id INTEGER NOT NULL, ethnicity_concept_id INTEGER NOT NULL, location_id INTEGER NULL, @@ -231,9 +231,10 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE person WITH (DISTRIBUTION = HASH(person_id)); +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE observation_period (observation_period_id INTEGER NOT NULL , - person_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 @@ -241,13 +242,14 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE observation_period WITH (DISTRIBUTION = HASH(person_id)); +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE specimen (specimen_id INTEGER NOT NULL , - person_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 DATETIME2 NULL , + specimen_datetime DATETIME NULL , quantity FLOAT NULL , unit_concept_id INTEGER NULL , anatomic_site_concept_id INTEGER NULL , @@ -261,11 +263,11 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE specimen WITH (DISTRIBUTION = HASH(person_id)); - +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE death - ( person_id INTEGER NOT NULL , + (person_id INTEGER NOT NULL , death_date DATE NOT NULL , - death_datetime DATETIME2 NULL , + death_datetime DATETIME NULL , death_type_concept_id INTEGER NOT NULL , cause_concept_id INTEGER NULL , cause_source_value VARCHAR(50) NULL, @@ -274,36 +276,38 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE death WITH (DISTRIBUTION = HASH(person_id)); +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE visit_occurrence (visit_occurrence_id INTEGER NOT NULL , - person_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , visit_concept_id INTEGER NOT NULL , visit_start_date DATE NOT NULL , - visit_start_datetime DATETIME2 NULL , + visit_start_datetime DATETIME NULL , visit_end_date DATE NOT NULL , - visit_end_datetime DATETIME2 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 + visit_source_concept_id INTEGER NULL , admitting_source_concept_id INTEGER NULL , admitting_source_value VARCHAR(50) NULL , - discharge_to_concept_id INTEGER(50) NULL , + discharge_to_concept_id INTEGER NULL , discharge_to_source_value VARCHAR(50) NULL , preceding_visit_occurrence_id INTEGER NULL ) WITH (DISTRIBUTION = HASH(person_id)); +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE visit_detail (visit_detail_id INTEGER NOT NULL , - person_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , visit_detail_concept_id INTEGER NOT NULL , visit_start_date DATE NOT NULL , - visit_start_datetime DATETIME2 NULL , + visit_start_datetime DATETIME NULL , visit_end_date DATE NOT NULL , - visit_end_datetime DATETIME2 NULL , + visit_end_datetime DATETIME NULL , visit_type_concept_id INTEGER NOT NULL , provider_id INTEGER NULL , care_site_id INTEGER NULL , @@ -320,12 +324,13 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE visit_detail WITH (DISTRIBUTION = HASH(person_id)); +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE procedure_occurrence (procedure_occurrence_id INTEGER NOT NULL , - person_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , procedure_concept_id INTEGER NOT NULL , procedure_date DATE NOT NULL , - procedure_datetime DATETIME2 NULL , + procedure_datetime DATETIME NULL , procedure_type_concept_id INTEGER NOT NULL , modifier_concept_id INTEGER NULL , quantity INTEGER NULL , @@ -339,14 +344,15 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE procedure_occurrence WITH (DISTRIBUTION = HASH(person_id)); +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE drug_exposure (drug_exposure_id INTEGER NOT NULL , - person_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 DATETIME2 NULL , + drug_exposure_start_datetime DATETIME NULL , drug_exposure_end_date DATE NOT NULL , - drug_exposure_end_datetime DATETIME2 NULL , + drug_exposure_end_datetime DATETIME NULL , verbatim_end_date DATE NULL , drug_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , @@ -367,14 +373,15 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE drug_exposure WITH (DISTRIBUTION = HASH(person_id)); +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE device_exposure (device_exposure_id INTEGER NOT NULL , - person_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 DATETIME2 NULL , + device_exposure_start_datetime DATETIME NULL , device_exposure_end_date DATE NULL , - device_exposure_end_datetime DATETIME2 NULL , + device_exposure_end_datetime DATETIME NULL , device_type_concept_id INTEGER NOT NULL , unique_device_id VARCHAR(50) NULL , quantity INTEGER NULL , @@ -387,14 +394,15 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE device_exposure WITH (DISTRIBUTION = HASH(person_id)); +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE condition_occurrence (condition_occurrence_id INTEGER NOT NULL , - person_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , condition_concept_id INTEGER NOT NULL , condition_start_date DATE NOT NULL , - condition_start_datetime DATETIME2 NULL , + condition_start_datetime DATETIME NULL , condition_end_date DATE NULL , - condition_end_datetime DATETIME2 NULL , + condition_end_datetime DATETIME NULL , condition_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , provider_id INTEGER NULL , @@ -408,13 +416,14 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE condition_occurrence WITH (DISTRIBUTION = HASH(person_id)); +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE measurement (measurement_id INTEGER NOT NULL , - person_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_datetime DATETIME2 NULL , + measurement_datetime DATETIME NULL , measurement_type_concept_id INTEGER NOT NULL , operator_concept_id INTEGER NULL , value_as_number FLOAT NULL , @@ -433,12 +442,12 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE measurement WITH (DISTRIBUTION = HASH(person_id)); - +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE note (note_id INTEGER NOT NULL , - person_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , note_date DATE NOT NULL , - note_datetime DATETIME2 NULL , + note_datetime DATETIME NULL , note_type_concept_id INTEGER NOT NULL , note_class_concept_id INTEGER NOT NULL , note_title VARCHAR(250) NULL , @@ -459,13 +468,13 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE note_nlp note_id INTEGER NOT NULL , section_concept_id INTEGER NULL , snippet VARCHAR(250) NULL , - offset VARCHAR(250) NULL , + "offset" VARCHAR(250) 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 DATETIME2 NULL , + nlp_datetime DATETIME NULL , term_exists VARCHAR(1) NULL , term_temporal VARCHAR(50) NULL , term_modifiers VARCHAR(2000) NULL @@ -473,13 +482,13 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE note_nlp WITH (DISTRIBUTION = REPLICATE); - +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE observation (observation_id INTEGER NOT NULL , - person_id INTEGER NOT NULL , + person_id INTEGER NOT NULL , observation_concept_id INTEGER NOT NULL , observation_date DATE NOT NULL , - observation_datetime DATETIME2 NULL , + observation_datetime DATETIME NULL , observation_type_concept_id INTEGER NOT NULL , value_as_number FLOAT NULL , value_as_string VARCHAR(60) NULL , @@ -497,7 +506,6 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE observation WITH (DISTRIBUTION = HASH(person_id)); - IF XACT_STATE() = 1 COMMIT; CREATE TABLE fact_relationship (domain_concept_id_1 INTEGER NOT NULL , fact_id_1 INTEGER NOT NULL , @@ -509,7 +517,6 @@ WITH (DISTRIBUTION = REPLICATE); - /************************ Standardized health system data @@ -517,7 +524,6 @@ Standardized health system data ************************/ - IF XACT_STATE() = 1 COMMIT; CREATE TABLE location (location_id INTEGER NOT NULL , address_1 VARCHAR(50) NULL , @@ -531,7 +537,6 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE location WITH (DISTRIBUTION = REPLICATE); - IF XACT_STATE() = 1 COMMIT; CREATE TABLE care_site (care_site_id INTEGER NOT NULL , care_site_name VARCHAR(255) NULL , @@ -543,7 +548,6 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE care_site WITH (DISTRIBUTION = REPLICATE); - IF XACT_STATE() = 1 COMMIT; CREATE TABLE provider (provider_id INTEGER NOT NULL , provider_name VARCHAR(255) NULL , @@ -562,8 +566,6 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE provider WITH (DISTRIBUTION = REPLICATE); - - /************************ Standardized health economics @@ -571,9 +573,10 @@ Standardized health economics ************************/ +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE payer_plan_period (payer_plan_period_id INTEGER NOT NULL , - person_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 , @@ -620,29 +623,29 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE cost WITH (DISTRIBUTION = REPLICATE); - - - /************************ Standardized derived elements ************************/ + +--HINT DISTRIBUTE_ON_KEY(subject_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE cohort (cohort_definition_id INTEGER NOT NULL , - subject_id INTEGER NOT NULL , + subject_id INTEGER NOT NULL , cohort_start_date DATE NOT NULL , cohort_end_date DATE NOT NULL ) WITH (DISTRIBUTION = HASH(subject_id)); +--HINT DISTRIBUTE_ON_KEY(subject_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE cohort_attribute (cohort_definition_id INTEGER NOT NULL , + subject_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 @@ -650,11 +653,10 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE cohort_attribute WITH (DISTRIBUTION = HASH(subject_id)); - - +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE drug_era (drug_era_id INTEGER NOT NULL , - person_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 , @@ -664,9 +666,10 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE drug_era WITH (DISTRIBUTION = HASH(person_id)); +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE dose_era (dose_era_id INTEGER NOT NULL , - person_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 , @@ -676,21 +679,13 @@ IF XACT_STATE() = 1 COMMIT; CREATE TABLE dose_era WITH (DISTRIBUTION = HASH(person_id)); - - +--HINT DISTRIBUTE_ON_KEY(person_id) IF XACT_STATE() = 1 COMMIT; CREATE TABLE condition_era (condition_era_id INTEGER NOT NULL , - person_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 (DISTRIBUTION = HASH(person_id)); - - - - - - - diff --git a/DDLGeneratr/output/postgresql/OMOP CDM postgresql constraints.txt b/DDLGeneratr/output/postgresql/OMOP CDM postgresql constraints.txt index 075df5e..5428ee1 100644 --- a/DDLGeneratr/output/postgresql/OMOP CDM postgresql constraints.txt +++ b/DDLGeneratr/output/postgresql/OMOP CDM postgresql constraints.txt @@ -167,8 +167,6 @@ ALTER TABLE death ADD CONSTRAINT fpk_death_cause_concept_s FOREIGN KEY (cause_so 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); @@ -186,8 +184,6 @@ ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_preceding FOREIGN KEY (pre ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_person FOREIGN KEY (person_id) REFERENCES person (person_id); -ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_concept FOREIGN KEY (visit_concept_id) REFERENCES concept (concept_id); - ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_type_concept FOREIGN KEY (visit_type_concept_id) REFERENCES concept (concept_id); ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); diff --git a/DDLGeneratr/output/postgresql/OMOP CDM postgresql ddl.txt b/DDLGeneratr/output/postgresql/OMOP CDM postgresql ddl.txt index ff9f480..d92bb10 100644 --- a/DDLGeneratr/output/postgresql/OMOP CDM postgresql ddl.txt +++ b/DDLGeneratr/output/postgresql/OMOP CDM postgresql ddl.txt @@ -207,10 +207,10 @@ CREATE TABLE metadata metadata_concept_id INTEGER NOT NULL , metadata_type_concept_id INTEGER NOT NULL , name VARCHAR(250) NOT NULL , - value_as_string NVARCHAR NULL , + value_as_string TEXT NULL , value_as_concept_id INTEGER NULL , metadata_date DATE NULL , - metadata_datetime DATETIME2 NULL + metadata_datetime TIMESTAMP NULL ) ; @@ -221,7 +221,7 @@ Standardized clinical data ************************/ - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE person ( person_id INTEGER NOT NULL , @@ -229,7 +229,7 @@ CREATE TABLE person year_of_birth INTEGER NOT NULL , month_of_birth INTEGER NULL, day_of_birth INTEGER NULL, - birth_datetime DATETIME2 NULL, + birth_datetime TIMESTAMP NULL, race_concept_id INTEGER NOT NULL, ethnicity_concept_id INTEGER NOT NULL, location_id INTEGER NULL, @@ -246,6 +246,7 @@ CREATE TABLE person ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE observation_period ( observation_period_id INTEGER NOT NULL , @@ -257,6 +258,7 @@ CREATE TABLE observation_period ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE specimen ( specimen_id INTEGER NOT NULL , @@ -264,7 +266,7 @@ CREATE TABLE specimen specimen_concept_id INTEGER NOT NULL , specimen_type_concept_id INTEGER NOT NULL , specimen_date DATE NOT NULL , - specimen_datetime DATETIME2 NULL , + specimen_datetime TIMESTAMP NULL , quantity NUMERIC NULL , unit_concept_id INTEGER NULL , anatomic_site_concept_id INTEGER NULL , @@ -278,12 +280,12 @@ CREATE TABLE specimen ; - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE death ( person_id INTEGER NOT NULL , death_date DATE NOT NULL , - death_datetime DATETIME2 NULL , + death_datetime TIMESTAMP NULL , death_type_concept_id INTEGER NOT NULL , cause_concept_id INTEGER NULL , cause_source_value VARCHAR(50) NULL, @@ -292,38 +294,40 @@ CREATE TABLE death ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_datetime DATETIME2 NULL , + visit_start_datetime TIMESTAMP NULL , visit_end_date DATE NOT NULL , - visit_end_datetime DATETIME2 NULL , + visit_end_datetime TIMESTAMP 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 + visit_source_concept_id INTEGER NULL , admitting_source_concept_id INTEGER NULL , admitting_source_value VARCHAR(50) NULL , - discharge_to_concept_id INTEGER(50) NULL , + discharge_to_concept_id INTEGER NULL , discharge_to_source_value VARCHAR(50) NULL , preceding_visit_occurrence_id INTEGER NULL ) ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE visit_detail ( visit_detail_id INTEGER NOT NULL , person_id INTEGER NOT NULL , visit_detail_concept_id INTEGER NOT NULL , visit_start_date DATE NOT NULL , - visit_start_datetime DATETIME2 NULL , + visit_start_datetime TIMESTAMP NULL , visit_end_date DATE NOT NULL , - visit_end_datetime DATETIME2 NULL , + visit_end_datetime TIMESTAMP NULL , visit_type_concept_id INTEGER NOT NULL , provider_id INTEGER NULL , care_site_id INTEGER NULL , @@ -340,13 +344,14 @@ CREATE TABLE visit_detail ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_datetime DATETIME2 NULL , + procedure_datetime TIMESTAMP NULL , procedure_type_concept_id INTEGER NOT NULL , modifier_concept_id INTEGER NULL , quantity INTEGER NULL , @@ -360,15 +365,16 @@ CREATE TABLE procedure_occurrence ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_start_datetime DATETIME2 NULL , + drug_exposure_start_datetime TIMESTAMP NULL , drug_exposure_end_date DATE NOT NULL , - drug_exposure_end_datetime DATETIME2 NULL , + drug_exposure_end_datetime TIMESTAMP NULL , verbatim_end_date DATE NULL , drug_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , @@ -389,15 +395,16 @@ CREATE TABLE drug_exposure ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_start_datetime DATETIME2 NULL , + device_exposure_start_datetime TIMESTAMP NULL , device_exposure_end_date DATE NULL , - device_exposure_end_datetime DATETIME2 NULL , + device_exposure_end_datetime TIMESTAMP NULL , device_type_concept_id INTEGER NOT NULL , unique_device_id VARCHAR(50) NULL , quantity INTEGER NULL , @@ -410,15 +417,16 @@ CREATE TABLE device_exposure ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_start_datetime DATETIME2 NULL , + condition_start_datetime TIMESTAMP NULL , condition_end_date DATE NULL , - condition_end_datetime DATETIME2 NULL , + condition_end_datetime TIMESTAMP NULL , condition_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , provider_id INTEGER NULL , @@ -432,6 +440,7 @@ CREATE TABLE condition_occurrence ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE measurement ( measurement_id INTEGER NOT NULL , @@ -439,7 +448,7 @@ CREATE TABLE measurement measurement_concept_id INTEGER NOT NULL , measurement_date DATE NOT NULL , measurement_time VARCHAR(10) NULL , - measurement_datetime DATETIME2 NULL , + measurement_datetime TIMESTAMP NULL , measurement_type_concept_id INTEGER NOT NULL , operator_concept_id INTEGER NULL , value_as_number NUMERIC NULL , @@ -458,13 +467,13 @@ CREATE TABLE measurement ; - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE note ( note_id INTEGER NOT NULL , person_id INTEGER NOT NULL , note_date DATE NOT NULL , - note_datetime DATETIME2 NULL , + note_datetime TIMESTAMP NULL , note_type_concept_id INTEGER NOT NULL , note_class_concept_id INTEGER NOT NULL , note_title VARCHAR(250) NULL , @@ -486,13 +495,13 @@ CREATE TABLE note_nlp note_id INTEGER NOT NULL , section_concept_id INTEGER NULL , snippet VARCHAR(250) NULL , - offset VARCHAR(250) NULL , + "offset" VARCHAR(250) 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 DATETIME2 NULL , + nlp_datetime TIMESTAMP NULL , term_exists VARCHAR(1) NULL , term_temporal VARCHAR(50) NULL , term_modifiers VARCHAR(2000) NULL @@ -500,14 +509,14 @@ CREATE TABLE note_nlp ; - +--HINT DISTRIBUTE_ON_KEY(person_id) 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_datetime DATETIME2 NULL , + observation_datetime TIMESTAMP NULL , observation_type_concept_id INTEGER NOT NULL , value_as_number NUMERIC NULL , value_as_string VARCHAR(60) NULL , @@ -525,7 +534,6 @@ CREATE TABLE observation ; - CREATE TABLE fact_relationship ( domain_concept_id_1 INTEGER NOT NULL , @@ -538,7 +546,6 @@ CREATE TABLE fact_relationship - /************************ Standardized health system data @@ -546,7 +553,6 @@ Standardized health system data ************************/ - CREATE TABLE location ( location_id INTEGER NOT NULL , @@ -561,7 +567,6 @@ CREATE TABLE location ; - CREATE TABLE care_site ( care_site_id INTEGER NOT NULL , @@ -574,7 +579,6 @@ CREATE TABLE care_site ; - CREATE TABLE provider ( provider_id INTEGER NOT NULL , @@ -594,8 +598,6 @@ CREATE TABLE provider ; - - /************************ Standardized health economics @@ -603,6 +605,7 @@ Standardized health economics ************************/ +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE payer_plan_period ( payer_plan_period_id INTEGER NOT NULL , @@ -654,15 +657,14 @@ CREATE TABLE cost ; - - - /************************ Standardized derived elements ************************/ + +--HINT DISTRIBUTE_ON_KEY(subject_id) CREATE TABLE cohort ( cohort_definition_id INTEGER NOT NULL , @@ -673,12 +675,13 @@ CREATE TABLE cohort ; +--HINT DISTRIBUTE_ON_KEY(subject_id) CREATE TABLE cohort_attribute ( cohort_definition_id INTEGER NOT NULL , + subject_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 NUMERIC NULL , value_as_concept_id INTEGER NULL @@ -686,8 +689,7 @@ CREATE TABLE cohort_attribute ; - - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE drug_era ( drug_era_id INTEGER NOT NULL , @@ -701,6 +703,7 @@ CREATE TABLE drug_era ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE dose_era ( dose_era_id INTEGER NOT NULL , @@ -714,8 +717,7 @@ CREATE TABLE dose_era ; - - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE condition_era ( condition_era_id INTEGER NOT NULL , @@ -726,10 +728,3 @@ CREATE TABLE condition_era condition_occurrence_count INTEGER NULL ) ; - - - - - - - diff --git a/DDLGeneratr/output/redshift/OMOP CDM redshift ddl.txt b/DDLGeneratr/output/redshift/OMOP CDM redshift ddl.txt index c732058..91fbbc7 100644 --- a/DDLGeneratr/output/redshift/OMOP CDM redshift ddl.txt +++ b/DDLGeneratr/output/redshift/OMOP CDM redshift ddl.txt @@ -193,10 +193,10 @@ CREATE TABLE metadata (metadata_concept_id INTEGER NOT NULL , metadata_type_concept_id INTEGER NOT NULL , name VARCHAR(250) NOT NULL , - value_as_string NVARCHAR NULL , + value_as_string VARCHAR(MAX) NULL , value_as_concept_id INTEGER NULL , metadata_date DATE NULL , - metadata_datetime TIMESTAMP NULL + metadata_datetime TIMESTAMP NULL ) DISTSTYLE ALL; @@ -289,10 +289,10 @@ CREATE TABLE visit_occurrence provider_id INTEGER NULL, care_site_id INTEGER NULL, visit_source_value VARCHAR(50) NULL, - visit_source_concept_id INTEGER NULL + visit_source_concept_id INTEGER NULL , admitting_source_concept_id INTEGER NULL , admitting_source_value VARCHAR(50) NULL , - discharge_to_concept_id INTEGER(50) NULL , + discharge_to_concept_id INTEGER NULL , discharge_to_source_value VARCHAR(50) NULL , preceding_visit_occurrence_id INTEGER NULL ) @@ -468,7 +468,7 @@ CREATE TABLE note_nlp note_id INTEGER NOT NULL , section_concept_id INTEGER NULL , snippet VARCHAR(250) NULL , - offset VARCHAR(250) NULL , + "offset" VARCHAR(250) NULL , lexical_variant VARCHAR(250) NOT NULL , note_nlp_concept_id INTEGER NULL , note_nlp_source_concept_id INTEGER NULL , diff --git a/DDLGeneratr/output/sql server/OMOP CDM sql server constraints.txt b/DDLGeneratr/output/sql server/OMOP CDM sql server constraints.txt index 470bd94..3ec9744 100644 --- a/DDLGeneratr/output/sql server/OMOP CDM sql server constraints.txt +++ b/DDLGeneratr/output/sql server/OMOP CDM sql server constraints.txt @@ -167,8 +167,6 @@ ALTER TABLE death ADD CONSTRAINT fpk_death_cause_concept_s FOREIGN KEY (cause_so 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); @@ -186,8 +184,6 @@ ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_preceding FOREIGN KEY (pre ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_person FOREIGN KEY (person_id) REFERENCES person (person_id); -ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_concept FOREIGN KEY (visit_concept_id) REFERENCES concept (concept_id); - ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_type_concept FOREIGN KEY (visit_type_concept_id) REFERENCES concept (concept_id); ALTER TABLE visit_detail ADD CONSTRAINT fpk_v_detail_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); diff --git a/DDLGeneratr/output/sql server/OMOP CDM sql server ddl.txt b/DDLGeneratr/output/sql server/OMOP CDM sql server ddl.txt index 9dfe226..1d0e944 100644 --- a/DDLGeneratr/output/sql server/OMOP CDM sql server ddl.txt +++ b/DDLGeneratr/output/sql server/OMOP CDM sql server ddl.txt @@ -207,10 +207,10 @@ CREATE TABLE metadata metadata_concept_id INTEGER NOT NULL , metadata_type_concept_id INTEGER NOT NULL , name VARCHAR(250) NOT NULL , - value_as_string NVARCHAR NULL , + value_as_string VARCHAR(MAX) NULL , value_as_concept_id INTEGER NULL , metadata_date DATE NULL , - metadata_datetime DATETIME2 NULL + metadata_datetime DATETIME NULL ) ; @@ -221,7 +221,7 @@ Standardized clinical data ************************/ - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE person ( person_id INTEGER NOT NULL , @@ -229,7 +229,7 @@ CREATE TABLE person year_of_birth INTEGER NOT NULL , month_of_birth INTEGER NULL, day_of_birth INTEGER NULL, - birth_datetime DATETIME2 NULL, + birth_datetime DATETIME NULL, race_concept_id INTEGER NOT NULL, ethnicity_concept_id INTEGER NOT NULL, location_id INTEGER NULL, @@ -246,6 +246,7 @@ CREATE TABLE person ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE observation_period ( observation_period_id INTEGER NOT NULL , @@ -257,6 +258,7 @@ CREATE TABLE observation_period ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE specimen ( specimen_id INTEGER NOT NULL , @@ -264,7 +266,7 @@ CREATE TABLE specimen specimen_concept_id INTEGER NOT NULL , specimen_type_concept_id INTEGER NOT NULL , specimen_date DATE NOT NULL , - specimen_datetime DATETIME2 NULL , + specimen_datetime DATETIME NULL , quantity FLOAT NULL , unit_concept_id INTEGER NULL , anatomic_site_concept_id INTEGER NULL , @@ -278,12 +280,12 @@ CREATE TABLE specimen ; - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE death ( person_id INTEGER NOT NULL , death_date DATE NOT NULL , - death_datetime DATETIME2 NULL , + death_datetime DATETIME NULL , death_type_concept_id INTEGER NOT NULL , cause_concept_id INTEGER NULL , cause_source_value VARCHAR(50) NULL, @@ -292,38 +294,40 @@ CREATE TABLE death ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_datetime DATETIME2 NULL , + visit_start_datetime DATETIME NULL , visit_end_date DATE NOT NULL , - visit_end_datetime DATETIME2 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 + visit_source_concept_id INTEGER NULL , admitting_source_concept_id INTEGER NULL , admitting_source_value VARCHAR(50) NULL , - discharge_to_concept_id INTEGER(50) NULL , + discharge_to_concept_id INTEGER NULL , discharge_to_source_value VARCHAR(50) NULL , preceding_visit_occurrence_id INTEGER NULL ) ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE visit_detail ( visit_detail_id INTEGER NOT NULL , person_id INTEGER NOT NULL , visit_detail_concept_id INTEGER NOT NULL , visit_start_date DATE NOT NULL , - visit_start_datetime DATETIME2 NULL , + visit_start_datetime DATETIME NULL , visit_end_date DATE NOT NULL , - visit_end_datetime DATETIME2 NULL , + visit_end_datetime DATETIME NULL , visit_type_concept_id INTEGER NOT NULL , provider_id INTEGER NULL , care_site_id INTEGER NULL , @@ -340,13 +344,14 @@ CREATE TABLE visit_detail ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_datetime DATETIME2 NULL , + procedure_datetime DATETIME NULL , procedure_type_concept_id INTEGER NOT NULL , modifier_concept_id INTEGER NULL , quantity INTEGER NULL , @@ -360,15 +365,16 @@ CREATE TABLE procedure_occurrence ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_start_datetime DATETIME2 NULL , + drug_exposure_start_datetime DATETIME NULL , drug_exposure_end_date DATE NOT NULL , - drug_exposure_end_datetime DATETIME2 NULL , + drug_exposure_end_datetime DATETIME NULL , verbatim_end_date DATE NULL , drug_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , @@ -389,15 +395,16 @@ CREATE TABLE drug_exposure ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_start_datetime DATETIME2 NULL , + device_exposure_start_datetime DATETIME NULL , device_exposure_end_date DATE NULL , - device_exposure_end_datetime DATETIME2 NULL , + device_exposure_end_datetime DATETIME NULL , device_type_concept_id INTEGER NOT NULL , unique_device_id VARCHAR(50) NULL , quantity INTEGER NULL , @@ -410,15 +417,16 @@ CREATE TABLE device_exposure ; +--HINT DISTRIBUTE_ON_KEY(person_id) 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_start_datetime DATETIME2 NULL , + condition_start_datetime DATETIME NULL , condition_end_date DATE NULL , - condition_end_datetime DATETIME2 NULL , + condition_end_datetime DATETIME NULL , condition_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , provider_id INTEGER NULL , @@ -432,6 +440,7 @@ CREATE TABLE condition_occurrence ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE measurement ( measurement_id INTEGER NOT NULL , @@ -439,7 +448,7 @@ CREATE TABLE measurement measurement_concept_id INTEGER NOT NULL , measurement_date DATE NOT NULL , measurement_time VARCHAR(10) NULL , - measurement_datetime DATETIME2 NULL , + measurement_datetime DATETIME NULL , measurement_type_concept_id INTEGER NOT NULL , operator_concept_id INTEGER NULL , value_as_number FLOAT NULL , @@ -458,13 +467,13 @@ CREATE TABLE measurement ; - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE note ( note_id INTEGER NOT NULL , person_id INTEGER NOT NULL , note_date DATE NOT NULL , - note_datetime DATETIME2 NULL , + note_datetime DATETIME NULL , note_type_concept_id INTEGER NOT NULL , note_class_concept_id INTEGER NOT NULL , note_title VARCHAR(250) NULL , @@ -486,13 +495,13 @@ CREATE TABLE note_nlp note_id INTEGER NOT NULL , section_concept_id INTEGER NULL , snippet VARCHAR(250) NULL , - offset VARCHAR(250) NULL , + "offset" VARCHAR(250) 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 DATETIME2 NULL , + nlp_datetime DATETIME NULL , term_exists VARCHAR(1) NULL , term_temporal VARCHAR(50) NULL , term_modifiers VARCHAR(2000) NULL @@ -500,14 +509,14 @@ CREATE TABLE note_nlp ; - +--HINT DISTRIBUTE_ON_KEY(person_id) 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_datetime DATETIME2 NULL , + observation_datetime DATETIME NULL , observation_type_concept_id INTEGER NOT NULL , value_as_number FLOAT NULL , value_as_string VARCHAR(60) NULL , @@ -525,7 +534,6 @@ CREATE TABLE observation ; - CREATE TABLE fact_relationship ( domain_concept_id_1 INTEGER NOT NULL , @@ -538,7 +546,6 @@ CREATE TABLE fact_relationship - /************************ Standardized health system data @@ -546,7 +553,6 @@ Standardized health system data ************************/ - CREATE TABLE location ( location_id INTEGER NOT NULL , @@ -561,7 +567,6 @@ CREATE TABLE location ; - CREATE TABLE care_site ( care_site_id INTEGER NOT NULL , @@ -574,7 +579,6 @@ CREATE TABLE care_site ; - CREATE TABLE provider ( provider_id INTEGER NOT NULL , @@ -594,8 +598,6 @@ CREATE TABLE provider ; - - /************************ Standardized health economics @@ -603,6 +605,7 @@ Standardized health economics ************************/ +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE payer_plan_period ( payer_plan_period_id INTEGER NOT NULL , @@ -654,15 +657,14 @@ CREATE TABLE cost ; - - - /************************ Standardized derived elements ************************/ + +--HINT DISTRIBUTE_ON_KEY(subject_id) CREATE TABLE cohort ( cohort_definition_id INTEGER NOT NULL , @@ -673,12 +675,13 @@ CREATE TABLE cohort ; +--HINT DISTRIBUTE_ON_KEY(subject_id) CREATE TABLE cohort_attribute ( cohort_definition_id INTEGER NOT NULL , + subject_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 @@ -686,8 +689,7 @@ CREATE TABLE cohort_attribute ; - - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE drug_era ( drug_era_id INTEGER NOT NULL , @@ -701,6 +703,7 @@ CREATE TABLE drug_era ; +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE dose_era ( dose_era_id INTEGER NOT NULL , @@ -714,8 +717,7 @@ CREATE TABLE dose_era ; - - +--HINT DISTRIBUTE_ON_KEY(person_id) CREATE TABLE condition_era ( condition_era_id INTEGER NOT NULL , @@ -726,10 +728,3 @@ CREATE TABLE condition_era condition_occurrence_count INTEGER NULL ) ; - - - - - - -