From 62207c43094d871a810c5bbc1585e24692cd0078 Mon Sep 17 00:00:00 2001 From: clairblacketer Date: Mon, 24 Sep 2018 12:55:05 -0400 Subject: [PATCH] Fixes to bigquery as a result of testing and bigquery, impala, oracle, and netezza results schema ddls. --- BigQuery/OMOP CDM Results bigquery ddl.txt | 48 ++ BigQuery/OMOP CDM bigquery ddl.txt | 820 ++++++++++----------- Impala/OMOP CDM Results impala ddl.txt | 57 ++ Netezza/OMOP CDM Results netezza ddl.txt | 65 ++ Oracle/OMOP CDM Results oracle ddl.txt | 70 ++ 5 files changed, 613 insertions(+), 447 deletions(-) create mode 100644 BigQuery/OMOP CDM Results bigquery ddl.txt create mode 100644 Impala/OMOP CDM Results impala ddl.txt create mode 100644 Netezza/OMOP CDM Results netezza ddl.txt create mode 100644 Oracle/OMOP CDM Results oracle ddl.txt diff --git a/BigQuery/OMOP CDM Results bigquery ddl.txt b/BigQuery/OMOP CDM Results bigquery ddl.txt new file mode 100644 index 0000000..71f243b --- /dev/null +++ b/BigQuery/OMOP CDM Results bigquery ddl.txt @@ -0,0 +1,48 @@ +/* + Copyright 2018-08 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. + +OMOP CDM v6.0 DDL + +bigquery script to create OMOP common data model results schema version 6.0 + +last revised: 27-Aug-2018 + +Authors: Patrick Ryan, Christian Reich, Clair Blacketer +*/ + +#standardsql + +--HINT DISTRIBUTE_ON_KEY(subject_id) +create table cohort +( + cohort_definition_id INT64 not null , + subject_id INT64 not null , + cohort_start_date date not null , + cohort_end_date date not null +) +; + + +create table cohort_definition ( + cohort_definition_id INT64 not null, + cohort_definition_name STRING not null, + cohort_definition_description STRING null, + definition_type_concept_id INT64 not null, + cohort_definition_syntax STRING null, + subject_concept_id INT64 not null, + cohort_initiation_date date null +) +; diff --git a/BigQuery/OMOP CDM bigquery ddl.txt b/BigQuery/OMOP CDM bigquery ddl.txt index f1bb04f..e1891da 100644 --- a/BigQuery/OMOP CDM bigquery ddl.txt +++ b/BigQuery/OMOP CDM bigquery ddl.txt @@ -25,79 +25,79 @@ Authors: Patrick Ryan, Christian Reich, Clair Blacketer #standardsql create table concept ( - concept_id INT64 not null , - concept_name STRING not null , - domain_id STRING not null , - vocabulary_id STRING not null , + concept_id INT64 not null , + concept_name STRING not null , + domain_id STRING not null , + vocabulary_id STRING not null , concept_class_id STRING not null , standard_concept STRING null , - concept_code STRING not null , - valid_start_date date not null , - valid_end_date date not null , - invalid_reason STRING null + concept_code STRING not null , + valid_start_date date not null , + valid_end_date date not null , + invalid_reason STRING null ) ; create table vocabulary ( vocabulary_id STRING not null, - vocabulary_name STRING not null, - vocabulary_reference STRING not null, - vocabulary_version STRING not null, - vocabulary_concept_id INT64 not null + vocabulary_name STRING not null, + vocabulary_reference STRING not null, + vocabulary_version STRING not null, + vocabulary_concept_id INT64 not null ) ; create table domain ( domain_id STRING not null, - domain_name STRING not null, - domain_concept_id INT64 not null + domain_name STRING not null, + domain_concept_id INT64 not null ) ; create table concept_class ( concept_class_id STRING not null, - concept_class_name STRING not null, - concept_class_concept_id INT64 not null + concept_class_name STRING not null, + concept_class_concept_id INT64 not null ) ; create table concept_relationship ( - concept_id_1 INT64 not null, - concept_id_2 INT64 not null, - relationship_id STRING not null, - valid_start_date date not null, - valid_end_date date not null, - invalid_reason STRING null + concept_id_1 INT64 not null, + concept_id_2 INT64 not null, + relationship_id STRING not null, + valid_start_date date not null, + valid_end_date date not null, + invalid_reason STRING null ) ; create table relationship ( - relationship_id STRING not null, - relationship_name STRING not null, - is_hierarchical STRING not null, - defines_ancestry STRING not null, + relationship_id STRING not null, + relationship_name STRING not null, + is_hierarchical STRING not null, + defines_ancestry STRING not null, reverse_relationship_id STRING not null, - relationship_concept_id INT64 not null + relationship_concept_id INT64 not null ) ; create table concept_synonym ( - concept_id INT64 not null, - concept_synonym_name STRING not null, - language_concept_id INT64 not null + concept_id INT64 not null, + concept_synonym_name STRING not null, + language_concept_id INT64 not null ) ; create table concept_ancestor ( - ancestor_concept_id INT64 not null, - descendant_concept_id INT64 not null, + ancestor_concept_id INT64 not null, + descendant_concept_id INT64 not null, min_levels_of_separation INT64 not null, max_levels_of_separation INT64 not null ) @@ -105,72 +105,48 @@ create table concept_ancestor ( create table source_to_concept_map ( - source_code STRING not null, - source_concept_id INT64 not null, + source_code STRING not null, + source_concept_id INT64 not null, source_vocabulary_id STRING not null, - source_code_description STRING null, - target_concept_id INT64 not null, + source_code_description STRING null, + target_concept_id INT64 not null, target_vocabulary_id STRING not null, - valid_start_date date not null, - valid_end_date date not null, - invalid_reason STRING null + valid_start_date date not null, + valid_end_date date not null, + invalid_reason STRING null ) ; create table drug_strength ( - drug_concept_id INT64 not null, - ingredient_concept_id INT64 not null, - amount_value FLOAT64 null, - amount_unit_concept_id INT64 null, - numerator_value FLOAT64 null, + drug_concept_id INT64 not null, + ingredient_concept_id INT64 not null, + amount_value FLOAT64 null, + amount_unit_concept_id INT64 null, + numerator_value FLOAT64 null, numerator_unit_concept_id INT64 null, - denominator_value FLOAT64 null, + denominator_value FLOAT64 null, denominator_unit_concept_id INT64 null, - box_size INT64 null, - valid_start_date date not null, - valid_end_date date not null, - invalid_reason STRING null + box_size INT64 null, + valid_start_date date not null, + valid_end_date date not null, + invalid_reason STRING null ) ; -create table cohort_definition ( - cohort_definition_id INT64 not null, - cohort_definition_name STRING not null, - cohort_definition_description STRING null, - definition_type_concept_id INT64 not null, - cohort_definition_syntax STRING null, - subject_concept_id INT64 not null, - cohort_initiation_date date null -) -; - - -create table attribute_definition ( - attribute_definition_id INT64 not null, - attribute_name STRING not null, - attribute_description STRING null, - attribute_type_concept_id INT64 not null, - attribute_syntax STRING null -) -; - - - - create table cdm_source ( - cdm_source_name STRING not null , - cdm_source_abbreviation STRING null , - cdm_holder STRING null , - source_description STRING null , - source_documentation_reference STRING null , - cdm_etl_reference STRING null , - source_release_date date null , - cdm_release_date date null , - cdm_version STRING null , - vocabulary_version STRING null + cdm_source_name STRING not null , + cdm_source_abbreviation STRING null , + cdm_holder STRING null , + source_description STRING null , + source_documentation_reference STRING null , + cdm_etl_reference STRING null , + source_release_date date null , + cdm_release_date date null , + cdm_version STRING null , + vocabulary_version STRING null ) ; @@ -179,42 +155,40 @@ create table metadata ( metadata_concept_id INT64 not null , metadata_type_concept_id INT64 not null , - name STRING not null , - value_as_string STRING null , + name STRING not null , + value_as_string STRING null , value_as_concept_id INT64 null , - metadata_date date null , - metadata_datetime DATETIME null + metadata_date date null , + metadata_datetime DATETIME null ) ; -insert into metadata (name, value_as_string) --Added cdm version record -values ('CDM Version', '6.0') +insert into metadata (metadata_concept_id, metadata_type_concept_id, name, value_as_string, value_as_concept_id, metadata_date, measurement_datetime) --Added cdm version record +values (0, 0, 'CDM Version', '6.0', 0, NULL, NULL) ; - - --HINT DISTRIBUTE_ON_KEY(person_id) create table person ( - person_id INT64 not null , --INT64s added - gender_concept_id INT64 not null , - year_of_birth INT64 not null , - month_of_birth INT64 null, - day_of_birth INT64 null, - birth_datetime DATETIME null, - race_concept_id INT64 not null, - ethnicity_concept_id INT64 not null, - location_id INT64 null, - provider_id INT64 null, - care_site_id INT64 null, - person_source_value STRING null, - gender_source_value STRING null, - gender_source_concept_id INT64 null, - race_source_value STRING null, - race_source_concept_id INT64 null, - ethnicity_source_value STRING null, - ethnicity_source_concept_id INT64 null + person_id INT64 not null , --INT64s added + gender_concept_id INT64 not null , + year_of_birth INT64 not null , + month_of_birth INT64 null, + day_of_birth INT64 null, + birth_datetime DATETIME null, + race_concept_id INT64 not null, + ethnicity_concept_id INT64 not null, + location_id INT64 null, + provider_id INT64 null, + care_site_id INT64 null, + person_source_value STRING null, + gender_source_value STRING null, + gender_source_concept_id INT64 null, + race_source_value STRING null, + race_source_concept_id INT64 null, + ethnicity_source_value STRING null, + ethnicity_source_concept_id INT64 null ) ; @@ -222,11 +196,11 @@ create table person --HINT DISTRIBUTE_ON_KEY(person_id) create table observation_period ( - observation_period_id INT64 not null , - person_id INT64 not null , - observation_period_start_date date not null , - observation_period_end_date date not null , - period_type_concept_id INT64 not null + observation_period_id INT64 not null , + person_id INT64 not null , + observation_period_start_date date not null , + observation_period_end_date date not null , + period_type_concept_id INT64 not null ) ; @@ -234,35 +208,21 @@ create table observation_period --HINT DISTRIBUTE_ON_KEY(person_id) create table specimen ( - specimen_id INT64 not null , - person_id INT64 not null , - specimen_concept_id INT64 not null , - specimen_type_concept_id INT64 not null , - specimen_date date null , - specimen_datetime DATETIME not null , - quantity FLOAT64 null , - unit_concept_id INT64 null , - anatomic_site_concept_id INT64 null , - disease_status_concept_id INT64 null , - specimen_source_id STRING null , - specimen_source_value STRING null , - unit_source_value STRING null , - anatomic_site_source_value STRING null , - disease_status_source_value STRING null -) -; - - ---HINT DISTRIBUTE_ON_KEY(person_id) -create table death -( - person_id INT64 not null , - death_date date null , - death_datetime DATETIME not null , - death_type_concept_id INT64 not null , - cause_concept_id INT64 null , - cause_source_value STRING null, - cause_source_concept_id INT64 null + specimen_id INT64 not null , + person_id INT64 not null , + specimen_concept_id INT64 not null , + specimen_type_concept_id INT64 not null , + specimen_date date null , + specimen_datetime DATETIME not null , + quantity FLOAT64 null , + unit_concept_id INT64 null , + anatomic_site_concept_id INT64 null , + disease_status_concept_id INT64 null , + specimen_source_id STRING null , + specimen_source_value STRING null , + unit_source_value STRING null , + anatomic_site_source_value STRING null , + disease_status_source_value STRING null ) ; @@ -270,23 +230,23 @@ create table death --HINT DISTRIBUTE_ON_KEY(person_id) create table visit_occurrence ( - visit_occurrence_id INT64 not null , - person_id INT64 not null , - visit_concept_id INT64 not null , - visit_start_date date null , - visit_start_datetime DATETIME not null , - visit_end_date date null , - visit_end_datetime DATETIME not null , + visit_occurrence_id INT64 not null , + person_id INT64 not null , + visit_concept_id INT64 not null , + visit_start_date date null , + visit_start_datetime DATETIME not null , + visit_end_date date null , + visit_end_datetime DATETIME not null , visit_type_concept_id INT64 not null , - provider_id INT64 null, - care_site_id INT64 null, - visit_source_value STRING null, + provider_id INT64 null, + care_site_id INT64 null, + visit_source_value STRING null, visit_source_concept_id INT64 null , - admitted_from_concept_id INT64 NULL , /*Changed from admitting_source_* */ - admitted_from_source_value STRING NULL , - discharge_to_source_value STRING null , - discharge_to_concept_id INT64 null , - preceding_visit_occurrence_id INT64 null + admitted_from_concept_id INT64 NULL , /*Changed from admitting_source_* */ + admitted_from_source_value STRING NULL , + discharge_to_source_value STRING null , + discharge_to_concept_id INT64 null , + preceding_visit_occurrence_id INT64 null ) ; @@ -296,20 +256,20 @@ create table visit_detail ( visit_detail_id INT64 not null , person_id INT64 not null , - visit_detail_concept_id INT64 not null , - visit_detail_start_date date null , + visit_detail_concept_id INT64 not null , + visit_detail_start_date date null , visit_detail_start_datetime DATETIME not null , - visit_detail_end_date date null , - visit_detail_end_datetime DATETIME not null , - visit_detail_type_concept_id INT64 not null , - provider_id INT64 null , - care_site_id INT64 null , - discharge_to_concept_id INT64 null , - admitted_from_concept_id INT64 NULL , /*Changed from admitting_source_* */ - admitted_from_source_value STRING NULL , - visit_detail_source_value STRING null , - visit_detail_source_concept_id INT64 null , - discharge_to_source_value STRING null , + visit_detail_end_date date null , + visit_detail_end_datetime DATETIME not null , + visit_detail_type_concept_id INT64 not null , + provider_id INT64 null , + care_site_id INT64 null , + discharge_to_concept_id INT64 null , + admitted_from_concept_id INT64 NULL , /*Changed from admitting_source_* */ + admitted_from_source_value STRING NULL , + visit_detail_source_value STRING null , + visit_detail_source_concept_id INT64 null , + discharge_to_source_value STRING null , preceding_visit_detail_id INT64 null , visit_detail_parent_id INT64 null , visit_occurrence_id INT64 not null @@ -320,20 +280,20 @@ create table visit_detail --HINT DISTRIBUTE_ON_KEY(person_id) create table procedure_occurrence ( - procedure_occurrence_id INT64 not null , - person_id INT64 not null , - procedure_concept_id INT64 not null , - procedure_date date null , - procedure_datetime DATETIME not null , + procedure_occurrence_id INT64 not null , + person_id INT64 not null , + procedure_concept_id INT64 not null , + procedure_date date null , + procedure_datetime DATETIME not null , procedure_type_concept_id INT64 not null , - modifier_concept_id INT64 null , - quantity INT64 null , - provider_id INT64 null , - visit_occurrence_id INT64 null , - visit_detail_id INT64 null , - procedure_source_value STRING null , + modifier_concept_id INT64 null , + quantity INT64 null , + provider_id INT64 null , + visit_occurrence_id INT64 null , + visit_detail_id INT64 null , + procedure_source_value STRING null , procedure_source_concept_id INT64 null , - modifier_source_value STRING null , + modifier_source_value STRING null ) ; @@ -341,29 +301,29 @@ create table procedure_occurrence --HINT DISTRIBUTE_ON_KEY(person_id) create table drug_exposure ( - drug_exposure_id INT64 not null , - person_id INT64 not null , - drug_concept_id INT64 not null , - drug_exposure_start_date date null , - drug_exposure_start_datetime DATETIME not null , - drug_exposure_end_date date null , - drug_exposure_end_datetime DATETIME not null , - verbatim_end_date date null , - drug_type_concept_id INT64 not null , - stop_reason STRING null , - refills INT64 null , - quantity FLOAT64 null , - days_supply INT64 null , - sig STRING null , - route_concept_id INT64 null , - lot_number STRING null , - provider_id INT64 null , - visit_occurrence_id INT64 null , - visit_detail_id INT64 null , - drug_source_value STRING null , - drug_source_concept_id INT64 null , - route_source_value STRING null , - dose_unit_source_value STRING null + drug_exposure_id INT64 not null , + person_id INT64 not null , + drug_concept_id INT64 not null , + drug_exposure_start_date date null , + drug_exposure_start_datetime DATETIME not null , + drug_exposure_end_date date null , + drug_exposure_end_datetime DATETIME not null , + verbatim_end_date date null , + drug_type_concept_id INT64 not null , + stop_reason STRING null , + refills INT64 null , + quantity FLOAT64 null , + days_supply INT64 null , + sig STRING null , + route_concept_id INT64 null , + lot_number STRING null , + provider_id INT64 null , + visit_occurrence_id INT64 null , + visit_detail_id INT64 null , + drug_source_value STRING null , + drug_source_concept_id INT64 null , + route_source_value STRING null , + dose_unit_source_value STRING null ) ; @@ -371,21 +331,21 @@ create table drug_exposure --HINT DISTRIBUTE_ON_KEY(person_id) create table device_exposure ( - device_exposure_id INT64 not null , - person_id INT64 not null , - device_concept_id INT64 not null , - device_exposure_start_date date null , - device_exposure_start_datetime DATETIME not null , - device_exposure_end_date date null , - device_exposure_end_datetime DATETIME null , - device_type_concept_id INT64 not null , - unique_device_id STRING null , - quantity INT64 null , - provider_id INT64 null , - visit_occurrence_id INT64 null , - visit_detail_id INT64 null , - device_source_value STRING null , - device_source_concept_id INT64 null + device_exposure_id INT64 not null , + person_id INT64 not null , + device_concept_id INT64 not null , + device_exposure_start_date date null , + device_exposure_start_datetime DATETIME not null , + device_exposure_end_date date null , + device_exposure_end_datetime DATETIME null , + device_type_concept_id INT64 not null , + unique_device_id STRING null , + quantity INT64 null , + provider_id INT64 null , + visit_occurrence_id INT64 null , + visit_detail_id INT64 null , + device_source_value STRING null , + device_source_concept_id INT64 null ) ; @@ -394,21 +354,21 @@ create table device_exposure create table condition_occurrence ( condition_occurrence_id INT64 not null , - person_id INT64 not null , + person_id INT64 not null , condition_concept_id INT64 not null , - condition_start_date date null , - condition_start_datetime DATETIME not null , - condition_end_date date null , + condition_start_date date null , + condition_start_datetime DATETIME not null , + condition_end_date date null , condition_end_datetime DATETIME null , - condition_type_concept_id INT64 not null , - condition_status_concept_id INT64 null , - stop_reason STRING null , - provider_id INT64 null , - visit_occurrence_id INT64 null , - visit_detail_id INT64 null , - condition_source_value STRING null , - condition_source_concept_id INT64 null , - condition_status_source_value STRING null + condition_type_concept_id INT64 not null , + condition_status_concept_id INT64 null , + stop_reason STRING null , + provider_id INT64 null , + visit_occurrence_id INT64 null , + visit_detail_id INT64 null , + condition_source_value STRING null , + condition_source_concept_id INT64 null , + condition_status_source_value STRING null ) ; @@ -416,26 +376,26 @@ create table condition_occurrence --HINT DISTRIBUTE_ON_KEY(person_id) create table measurement ( - measurement_id INT64 not null , - person_id INT64 not null , + measurement_id INT64 not null , + person_id INT64 not null , measurement_concept_id INT64 not null , - measurement_date date null , + measurement_date date null , measurement_datetime DATETIME not null , - measurement_time STRING null, - measurement_type_concept_id INT64 not null , - operator_concept_id INT64 null , - value_as_number FLOAT64 null , - value_as_concept_id INT64 null , - unit_concept_id INT64 null , - range_low FLOAT64 null , - range_high FLOAT64 null , - provider_id INT64 null , - visit_occurrence_id INT64 null , - visit_detail_id INT64 null , - measurement_source_value STRING null , - measurement_source_concept_id INT64 null , - unit_source_value STRING null , - value_source_value STRING null + measurement_time STRING null, + measurement_type_concept_id INT64 not null , + operator_concept_id INT64 null , + value_as_number FLOAT64 null , + value_as_concept_id INT64 null , + unit_concept_id INT64 null , + range_low FLOAT64 null , + range_high FLOAT64 null , + provider_id INT64 null , + visit_occurrence_id INT64 null , + visit_detail_id INT64 null , + measurement_source_value STRING null , + measurement_source_concept_id INT64 null , + unit_source_value STRING null , + value_source_value STRING null ) ; @@ -443,23 +403,22 @@ create table measurement --HINT DISTRIBUTE_ON_KEY(person_id) create table note ( - note_id INT64 not null , - person_id INT64 not null , - note_event_id INT64 null , --This and the field below added - note_domain_id STRING null , --This field may be removed in favor of the one below ---note_event_table_concept_id INT64 NULL , --This may be added based on 9/4 meeting - note_date date null , - note_datetime DATETIME not null , - note_type_concept_id INT64 not null , - note_class_concept_id INT64 not null , - note_title STRING null , - note_text STRING null , - encoding_concept_id INT64 not null , - language_concept_id INT64 not null , - provider_id INT64 null , - visit_occurrence_id INT64 null , - visit_detail_id INT64 null , - note_source_value STRING null + note_id INT64 not null , + person_id INT64 not null , + note_event_id INT64 null , + note_event_field_concept_id INT64 NULL , + note_date date null , + note_datetime DATETIME not null , + note_type_concept_id INT64 not null , + note_class_concept_id INT64 not null , + note_title STRING null , + note_text STRING null , + encoding_concept_id INT64 not null , + language_concept_id INT64 not null , + provider_id INT64 null , + visit_occurrence_id INT64 null , + visit_detail_id INT64 null , + note_source_value STRING null ) ; @@ -467,20 +426,20 @@ create table note create table note_nlp ( - note_nlp_id INT64 not null , - note_id INT64 not null , - section_concept_id INT64 null , - snippet STRING null , - "offset" STRING null , - lexical_variant STRING not null , - note_nlp_concept_id INT64 null , - nlp_system STRING null , - nlp_date date not null , - nlp_datetime DATETIME null , - term_exists STRING null , - term_temporal STRING null , - term_modifiers STRING null , - note_nlp_source_concept_id INT64 null + note_nlp_id INT64 not null , + note_id INT64 not null , + section_concept_id INT64 null , + snippet STRING null , + "offset" STRING null , + lexical_variant STRING not null , + note_nlp_concept_id INT64 null , + nlp_system STRING null , + nlp_date date not null , + nlp_datetime DATETIME null , + term_exists STRING null , + term_temporal STRING null , + term_modifiers STRING null , + note_nlp_source_concept_id INT64 null ) ; @@ -488,162 +447,157 @@ create table note_nlp --HINT DISTRIBUTE_ON_KEY(person_id) create table observation ( - observation_id INT64 not null , - person_id INT64 not null , - observation_concept_id INT64 not null , - observation_date date null , - observation_datetime DATETIME not null , + observation_id INT64 not null , + person_id INT64 not null , + observation_concept_id INT64 not null , + observation_date date null , + observation_datetime DATETIME not null , observation_type_concept_id INT64 not null , - value_as_number FLOAT64 null , - value_as_string STRING null , - value_as_concept_id INT64 null , - qualifier_concept_id INT64 null , - unit_concept_id INT64 null , - provider_id INT64 null , - visit_occurrence_id INT64 null , - visit_detail_id INT64 null , - observation_source_value STRING null , + value_as_number FLOAT64 null , + value_as_string STRING null , + value_as_concept_id INT64 null , + qualifier_concept_id INT64 null , + unit_concept_id INT64 null , + provider_id INT64 null , + visit_occurrence_id INT64 null , + visit_detail_id INT64 null , + observation_source_value STRING null , observation_source_concept_id INT64 null , - unit_source_value STRING null , - qualifier_source_value STRING null , - observation_event_id INT64 null , /* This will link back to the event table (SURVEY) on SURVEY_OCCURRENCE_ID, changed name to comply with COST and NOTE*/ - observation_event_domain_id STRING null , - --obs_event_table_concept_id INT64 NULL , /* Changed name to comply with COST and NOTE. This should be 'Survey'. Had to use 'obs' for oracle restriction, may be added on 9/4*/ - value_as_datetime DATETIME null + unit_source_value STRING null , + qualifier_source_value STRING null , + observation_event_id INT64 null , + obs_event_field_concept_id INT64 NULL , + value_as_datetime DATETIME null ) ; -create table survey_conduct /*Should this be SURVEY_OCCURRENCE instead to comply with the other tables?*/ +create table survey_conduct ( - survey_conduct_id INT64 not null , - person_id INT64 not null , - survey_concept_id INT64 not null , - survey_start_date date null , - survey_start_datetime DATETIME null , - survey_end_date date null , - survey_end_datetime DATETIME not null , - provider_id INT64 null , - assisted_concept_id INT64 null , - respondent_type_concept_id INT64 null , - timing_concept_id INT64 null , - collection_method_concept_id INT64 null , - assisted_source_value STRING null , - respondent_type_source_value STRING null , - timing_source_value STRING null , - collection_method_source_value STRING null , - survey_source_value STRING null , - survey_source_concept_id INT64 null , - survey_source_identifier STRING null , - validated_survey_concept_id INT64 null , - validated_survey_source_value STRING null , - survey_version_number STRING null , - visit_occurrence_id INT64 null , + survey_conduct_id INT64 not null , + person_id INT64 not null , + survey_concept_id INT64 not null , + survey_start_date date null , + survey_start_datetime DATETIME null , + survey_end_date date null , + survey_end_datetime DATETIME not null , + provider_id INT64 null , + assisted_concept_id INT64 null , + respondent_type_concept_id INT64 null , + timing_concept_id INT64 null , + collection_method_concept_id INT64 null , + assisted_source_value STRING null , + respondent_type_source_value STRING null , + timing_source_value STRING null , + collection_method_source_value STRING null , + survey_source_value STRING null , + survey_source_concept_id INT64 null , + survey_source_identifier STRING null , + validated_survey_concept_id INT64 null , + validated_survey_source_value STRING null , + survey_version_number STRING null , + visit_occurrence_id INT64 null , visit_detail_id INT64 null , - response_to_visit_occurrence_id INT64 null + response_visit_occurrence_id INT64 null ) ; - create table fact_relationship ( - domain_concept_id_1 INT64 not null , - fact_id_1 INT64 not null , - domain_concept_id_2 INT64 not null , - fact_id_2 INT64 not null , + domain_concept_id_1 INT64 not null , + fact_id_1 INT64 not null , + domain_concept_id_2 INT64 not null , + fact_id_2 INT64 not null , relationship_concept_id INT64 not null ) ; - - create table location ( - location_id INT64 not null , + location_id INT64 not null , address_1 STRING null , address_2 STRING null , - city STRING null , - state STRING null , - zip STRING null , - county STRING null , - country STRING null , - location_source_value STRING null , - latitude FLOAT64 null , - longitude FLOAT64 null + city STRING null , + state STRING null , + zip STRING null , + county STRING null , + country STRING null , + location_source_value STRING null , + latitude FLOAT64 null , + longitude FLOAT64 null ) ; + create table location_history ( - location_history_id INT64 not null , - location_id INT64 not null , - relationship_type_concept_id INT64 null , --Recent addition based on github discussion - domain_id STRING not null , - entity_id INT64 not null , - start_date date not null , - end_date date null + location_history_id INT64 not null , + location_id INT64 not null , + relationship_type_concept_id INT64 null , --Recent addition based on github discussion + domain_id STRING not null , + entity_id INT64 not null , + start_date date not null , + end_date date null ) ; create table care_site ( - care_site_id INT64 not null , - care_site_name STRING null , - place_of_service_concept_id INT64 null , - location_id INT64 null , - care_site_source_value STRING null , - place_of_service_source_value STRING null + care_site_id INT64 not null , + care_site_name STRING null , + place_of_service_concept_id INT64 null , + location_id INT64 null , + care_site_source_value STRING null , + place_of_service_source_value STRING null ) ; create table provider ( - provider_id INT64 not null , - provider_name STRING null , - npi STRING null , - dea STRING null , - specialty_concept_id INT64 null , - care_site_id INT64 null , - year_of_birth INT64 null , - gender_concept_id INT64 null , - provider_source_value STRING null , - specialty_source_value STRING null , - specialty_source_concept_id INT64 null , - gender_source_value STRING null , - gender_source_concept_id INT64 null + provider_id INT64 not null , + provider_name STRING null , + npi STRING null , + dea STRING null , + specialty_concept_id INT64 null , + care_site_id INT64 null , + year_of_birth INT64 null , + gender_concept_id INT64 null , + provider_source_value STRING null , + specialty_source_value STRING null , + specialty_source_concept_id INT64 null , + gender_source_value STRING null , + gender_source_concept_id INT64 null ) ; - - --HINT DISTRIBUTE_ON_KEY(person_id) create table payer_plan_period ( - payer_plan_period_id INT64 not null , - person_id INT64 not null , - contract_person_id INT64 null , - payer_plan_period_start_date date not null , - payer_plan_period_end_date date not null , + payer_plan_period_id INT64 not null , + person_id INT64 not null , + contract_person_id INT64 null , + payer_plan_period_start_date date not null , + payer_plan_period_end_date date not null , payer_concept_id INT64 null , plan_concept_id INT64 null , contract_concept_id INT64 null , sponsor_concept_id INT64 null , stop_reason_concept_id INT64 null , - payer_source_value STRING null , + payer_source_value STRING null , payer_source_concept_id INT64 null , - plan_source_value STRING null , + plan_source_value STRING null , plan_source_concept_id INT64 null , - contract_source_value STRING null , + contract_source_value STRING null , contract_source_concept_id INT64 null , - sponsor_source_value STRING null , + sponsor_source_value STRING null , sponsor_source_concept_id INT64 null , - family_source_value STRING null , - stop_reason_source_value STRING null , + family_source_value STRING null , + stop_reason_source_value STRING null , stop_reason_source_concept_id INT64 null ) ; @@ -651,52 +605,24 @@ create table payer_plan_period create table cost ( - cost_id INT64 not null , - person_id INT64 not null, - cost_event_id INT64 not null , - cost_domain_id STRING not null , ---cost_event_table_concept_id INT64 NOT NULL , /*This is still in discussion and most likely will replace cost_domain_id at 9/4 meeting*/ - cost_concept_id INT64 not null , - cost_type_concept_id INT64 not null , - currency_concept_id INT64 null , - cost FLOAT64 null , - incurred_date date not null , - billed_date date null , - paid_date date null , - revenue_code_concept_id INT64 null , - drg_concept_id INT64 null , - cost_source_value STRING null , - cost_source_concept_id INT64 null , - revenue_code_source_value STRING null , - drg_source_value STRING null , - payer_plan_period_id INT64 null -) -; - - - - ---HINT DISTRIBUTE_ON_KEY(subject_id) -create table cohort -( - cohort_definition_id INT64 not null , - subject_id INT64 not null , - cohort_start_date date not null , - cohort_end_date date not null -) -; - - ---HINT DISTRIBUTE_ON_KEY(subject_id) -create table cohort_attribute -( - cohort_definition_id INT64 not null , - subject_id INT64 not null , - cohort_start_date date not null , - cohort_end_date date not null , - attribute_definition_id INT64 not null , - value_as_number FLOAT64 null , - value_as_concept_id INT64 null + cost_id INT64 not null , + person_id INT64 not null, + cost_event_id INT64 not null , + cost_event_field_concept_id INT64 NOT NULL , + cost_concept_id INT64 not null , + cost_type_concept_id INT64 not null , + currency_concept_id INT64 null , + cost FLOAT64 null , + incurred_date date not null , + billed_date date null , + paid_date date null , + revenue_code_concept_id INT64 null , + drg_concept_id INT64 null , + cost_source_value STRING null , + cost_source_concept_id INT64 null , + revenue_code_source_value STRING null , + drg_source_value STRING null , + payer_plan_period_id INT64 null ) ; @@ -704,13 +630,13 @@ create table cohort_attribute --HINT DISTRIBUTE_ON_KEY(person_id) create table drug_era ( - drug_era_id INT64 not null , - person_id INT64 not null , - drug_concept_id INT64 not null , - drug_era_start_date date not null , - drug_era_end_date date not null , + drug_era_id INT64 not null , + person_id INT64 not null , + drug_concept_id INT64 not null , + drug_era_start_date date not null , + drug_era_end_date date not null , drug_exposure_count INT64 null , - gap_days INT64 null + gap_days INT64 null ) ; @@ -718,13 +644,13 @@ create table drug_era --HINT DISTRIBUTE_ON_KEY(person_id) create table dose_era ( - dose_era_id INT64 not null , - person_id INT64 not null , - drug_concept_id INT64 not null , - unit_concept_id INT64 not null , - dose_value FLOAT64 not null , - dose_era_start_date date not null , - dose_era_end_date date not null + dose_era_id INT64 not null , + person_id INT64 not null , + drug_concept_id INT64 not null , + unit_concept_id INT64 not null , + dose_value FLOAT64 not null , + dose_era_start_date date not null , + dose_era_end_date date not null ) ; @@ -732,11 +658,11 @@ create table dose_era --HINT DISTRIBUTE_ON_KEY(person_id) create table condition_era ( - condition_era_id INT64 not null , - person_id INT64 not null , - condition_concept_id INT64 not null , - condition_era_start_date date not null , - condition_era_end_date date not null , + condition_era_id INT64 not null , + person_id INT64 not null , + condition_concept_id INT64 not null , + condition_era_start_date date not null , + condition_era_end_date date not null , condition_occurrence_count INT64 null ) ; diff --git a/Impala/OMOP CDM Results impala ddl.txt b/Impala/OMOP CDM Results impala ddl.txt new file mode 100644 index 0000000..65a78f2 --- /dev/null +++ b/Impala/OMOP CDM Results impala ddl.txt @@ -0,0 +1,57 @@ +/********************************************************************************* +# Copyright 2018-08 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 results schema version 6.0 + +last revised: 27-Aug-2018 + +Authors: Patrick Ryan, Christian Reich, Clair Blacketer + + +*************************/ + +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 +) +; + + +--HINT DISTRIBUTE_ON_KEY(subject_id) +CREATE TABLE cohort +( + cohort_definition_id BIGINT , + subject_id BIGINT , + cohort_start_date TIMESTAMP , + cohort_end_date TIMESTAMP +) +; \ No newline at end of file diff --git a/Netezza/OMOP CDM Results netezza ddl.txt b/Netezza/OMOP CDM Results netezza ddl.txt new file mode 100644 index 0000000..31abb07 --- /dev/null +++ b/Netezza/OMOP CDM Results netezza ddl.txt @@ -0,0 +1,65 @@ +/********************************************************************************* +# Copyright 2018-08 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. +********************************************************************************/ + +/************************ + + ####### # # ####### ###### ##### ###### # # ##### ### + # # ## ## # # # # # # # # ## ## # # # # # # + # # # # # # # # # # # # # # # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### # # + # # # # # # # # # # # # # # # # ### # # + # # # # # # # # # # # # # # # # # ### # # + ####### # # ####### # ##### ###### # # ## ##### ### ### + +Netezza script to create OMOP common data model results schema version 6.0 + +last revised: 27-Aug-2018 + +Authors: Patrick Ryan, Christian Reich, Clair Blacketer + + +*************************/ + + +--HINT DISTRIBUTE_ON_KEY(subject_id) +CREATE TABLE cohort +( + cohort_definition_id BIGINT NOT NULL , + subject_id BIGINT NOT NULL , + cohort_start_date DATE NOT NULL , + cohort_end_date DATE NOT NULL +) +DISTRIBUTE ON (subject_id) +; + + +--HINT DISTRIBUTE ON RANDOM +CREATE TABLE cohort_definition ( + cohort_definition_id INTEGER NOT NULL, + cohort_definition_name VARCHAR(255) NOT NULL, + cohort_definition_description VARCHAR(1000) NULL, + definition_type_concept_id INTEGER NOT NULL, + cohort_definition_syntax VARCHAR(1000) NULL, + subject_concept_id INTEGER NOT NULL, + cohort_initiation_date DATE NULL +) +DISTRIBUTE ON RANDOM +; + +ALTER TABLE cohort ADD CONSTRAINT xpk_cohort PRIMARY KEY ( cohort_definition_id, subject_id, cohort_start_date, cohort_end_date ) ; + +ALTER TABLE cohort_definition ADD CONSTRAINT xpk_cohort_definition PRIMARY KEY (cohort_definition_id); diff --git a/Oracle/OMOP CDM Results oracle ddl.txt b/Oracle/OMOP CDM Results oracle ddl.txt new file mode 100644 index 0000000..074c1e1 --- /dev/null +++ b/Oracle/OMOP CDM Results oracle ddl.txt @@ -0,0 +1,70 @@ +/********************************************************************************* +# Copyright 2018-08 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. +********************************************************************************/ + +/************************ + + ####### # # ####### ###### ##### ###### # # ##### ### + # # ## ## # # # # # # # # ## ## # # # # # # + # # # # # # # # # # # # # # # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### # # + # # # # # # # # # # # # # # # # ### # # + # # # # # # # # # # # # # # # # # ### # # + ####### # # ####### # ##### ###### # # ## ##### ### ### + +oracle script to create OMOP common data model results schema version 6.0 + +last revised: 27-Aug-2018 + +Authors: Patrick Ryan, Christian Reich, Clair Blacketer + + +*************************/ + +--HINT DISTRIBUTE ON RANDOM +CREATE TABLE cohort_definition ( + cohort_definition_id INTEGER NOT NULL, + cohort_definition_name VARCHAR(255) NOT NULL, + cohort_definition_description CLOB NULL, + definition_type_concept_id INTEGER NOT NULL, + cohort_definition_syntax CLOB NULL, + subject_concept_id INTEGER NOT NULL, + cohort_initiation_date DATE NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(subject_id) +CREATE TABLE cohort +( + cohort_definition_id NUMBER(19) NOT NULL , + subject_id NUMBER(19) NOT NULL , + cohort_start_date DATE NOT NULL , + cohort_end_date DATE NOT NULL +) +; + +ALTER TABLE cohort ADD CONSTRAINT xpk_cohort PRIMARY KEY ( cohort_definition_id, subject_id, cohort_start_date, cohort_end_date ) ; + +ALTER TABLE cohort_definition ADD CONSTRAINT xpk_cohort_definition PRIMARY KEY ( cohort_definition_id ); + +ALTER TABLE cohort_definition ADD CONSTRAINT fpk_cohort_definition_concept FOREIGN KEY ( definition_type_concept_id ) REFERENCES concept ( concept_id ); + +ALTER TABLE cohort_definition ADD CONSTRAINT fpk_subject_concept FOREIGN KEY ( subject_concept_id ) REFERENCES concept ( concept_id ); + +ALTER TABLE cohort ADD CONSTRAINT fpk_cohort_definition FOREIGN KEY ( cohort_definition_id ) REFERENCES cohort_definition ( cohort_definition_id ); + +CREATE INDEX idx_cohort_subject_id ON cohort ( subject_id ASC );