849 lines
27 KiB
Plaintext
849 lines
27 KiB
Plaintext
/*********************************************************************************
|
|
# 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 version 6.0
|
|
|
|
last revised: 27-Aug-2018
|
|
|
|
Authors: Patrick Ryan, Christian Reich, Clair Blacketer
|
|
|
|
|
|
*************************/
|
|
|
|
|
|
/************************
|
|
|
|
Standardized vocabulary
|
|
|
|
************************/
|
|
|
|
|
|
--HINT DISTRIBUTE ON RANDOM
|
|
CREATE TABLE concept (
|
|
concept_id INTEGER NOT NULL ,
|
|
concept_name VARCHAR(255) NOT NULL ,
|
|
domain_id VARCHAR(20) NOT NULL ,
|
|
vocabulary_id VARCHAR(20) NOT NULL ,
|
|
concept_class_id VARCHAR(20) NOT NULL ,
|
|
standard_concept VARCHAR(1) NULL ,
|
|
concept_code VARCHAR(50) NOT NULL ,
|
|
valid_start_date DATE NOT NULL ,
|
|
valid_end_date DATE NOT NULL ,
|
|
invalid_reason VARCHAR(1) NULL
|
|
)
|
|
DISTRIBUTE ON RANDOM
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE ON RANDOM
|
|
CREATE TABLE vocabulary (
|
|
vocabulary_id VARCHAR(20) NOT NULL,
|
|
vocabulary_name VARCHAR(255) NOT NULL,
|
|
vocabulary_reference VARCHAR(255) NOT NULL,
|
|
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,
|
|
relationship_id VARCHAR(20) NOT 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 relationship (
|
|
relationship_id VARCHAR(20) NOT NULL,
|
|
relationship_name VARCHAR(255) NOT NULL,
|
|
is_hierarchical VARCHAR(1) NOT NULL,
|
|
defines_ancestry VARCHAR(1) NOT NULL,
|
|
reverse_relationship_id VARCHAR(20) NOT NULL,
|
|
relationship_concept_id INTEGER NOT NULL
|
|
)
|
|
DISTRIBUTE ON RANDOM
|
|
;
|
|
|
|
|
|
--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,
|
|
source_vocabulary_id VARCHAR(20) NOT NULL,
|
|
source_code_description VARCHAR(255) NULL,
|
|
target_concept_id INTEGER NOT NULL,
|
|
target_vocabulary_id VARCHAR(20) NOT NULL,
|
|
valid_start_date DATE NOT NULL,
|
|
valid_end_date DATE NOT NULL,
|
|
invalid_reason VARCHAR(1) NULL
|
|
)
|
|
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 REAL NULL,
|
|
amount_unit_concept_id INTEGER NULL,
|
|
numerator_value REAL NULL,
|
|
numerator_unit_concept_id INTEGER 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,
|
|
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
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE ON RANDOM
|
|
CREATE TABLE attribute_definition (
|
|
attribute_definition_id INTEGER NOT NULL,
|
|
attribute_name VARCHAR(255) NOT NULL,
|
|
attribute_description VARCHAR(1000) NULL,
|
|
attribute_type_concept_id INTEGER NOT NULL,
|
|
attribute_syntax VARCHAR(1000) NULL
|
|
)
|
|
DISTRIBUTE ON RANDOM
|
|
;
|
|
|
|
|
|
/**************************
|
|
|
|
Standardized meta-data
|
|
|
|
***************************/
|
|
|
|
|
|
--HINT DISTRIBUTE ON RANDOM
|
|
CREATE TABLE cdm_source
|
|
(
|
|
cdm_source_name VARCHAR(255) NOT NULL ,
|
|
cdm_source_abbreviation VARCHAR(25) NULL ,
|
|
cdm_holder VARCHAR(255) NULL ,
|
|
source_description VARCHAR(1000) NULL ,
|
|
source_documentation_reference VARCHAR(255) NULL ,
|
|
cdm_etl_reference VARCHAR(255) NULL ,
|
|
source_release_date DATE NULL ,
|
|
cdm_release_date DATE NULL ,
|
|
cdm_version VARCHAR(10) NULL ,
|
|
vocabulary_version VARCHAR(20) NULL
|
|
)
|
|
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 VARCHAR(1000) NULL ,
|
|
value_as_concept_id INTEGER NULL ,
|
|
metadata_date DATE NULL ,
|
|
metadata_datetime DATETIME NULL
|
|
)
|
|
DISTRIBUTE ON RANDOM
|
|
;
|
|
|
|
INSERT INTO metadata (name, value_as_string) --Added cdm version record
|
|
VALUES ('CDM Version', '6.0')
|
|
;
|
|
|
|
|
|
/************************
|
|
|
|
Standardized clinical data
|
|
|
|
************************/
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE person
|
|
(
|
|
person_id BIGINT NOT NULL , --BIGINTs added
|
|
gender_concept_id INTEGER NOT NULL ,
|
|
year_of_birth INTEGER NOT NULL ,
|
|
month_of_birth INTEGER NULL,
|
|
day_of_birth INTEGER NULL,
|
|
birth_datetime DATETIME NULL,
|
|
race_concept_id INTEGER NOT NULL,
|
|
ethnicity_concept_id INTEGER NOT NULL,
|
|
location_id INTEGER NULL,
|
|
provider_id INTEGER NULL,
|
|
care_site_id INTEGER NULL,
|
|
person_source_value VARCHAR(50) NULL,
|
|
gender_source_value VARCHAR(50) NULL,
|
|
gender_source_concept_id INTEGER NULL,
|
|
race_source_value VARCHAR(50) NULL,
|
|
race_source_concept_id INTEGER NULL,
|
|
ethnicity_source_value VARCHAR(50) NULL,
|
|
ethnicity_source_concept_id INTEGER NULL
|
|
)
|
|
|
|
DISTRUBTE ON (person_id);
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE observation_period
|
|
(
|
|
observation_period_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
observation_period_start_date DATE NOT NULL ,
|
|
observation_period_end_date DATE NOT NULL ,
|
|
period_type_concept_id INTEGER NOT NULL
|
|
)
|
|
|
|
DISTRUBTE ON (person_id);
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE specimen
|
|
(
|
|
specimen_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
specimen_concept_id INTEGER NOT NULL ,
|
|
specimen_type_concept_id INTEGER NOT NULL ,
|
|
specimen_date DATE NULL ,
|
|
specimen_datetime DATETIME NOT NULL ,
|
|
quantity REAL NULL ,
|
|
unit_concept_id INTEGER NULL ,
|
|
anatomic_site_concept_id INTEGER NULL ,
|
|
disease_status_concept_id INTEGER NULL ,
|
|
specimen_source_id VARCHAR(50) NULL ,
|
|
specimen_source_value VARCHAR(50) NULL ,
|
|
unit_source_value VARCHAR(50) NULL ,
|
|
anatomic_site_source_value VARCHAR(50) NULL ,
|
|
disease_status_source_value VARCHAR(50) NULL
|
|
)
|
|
|
|
DISTRUBTE ON (person_id);
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE death
|
|
(
|
|
person_id BIGINT NOT NULL ,
|
|
death_date DATE NULL ,
|
|
death_datetime DATETIME NOT NULL ,
|
|
death_type_concept_id INTEGER NOT NULL ,
|
|
cause_concept_id INTEGER NULL ,
|
|
cause_source_value VARCHAR(50) NULL,
|
|
cause_source_concept_id INTEGER NULL
|
|
)
|
|
|
|
DISTRUBTE ON (person_id);
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE visit_occurrence
|
|
(
|
|
visit_occurrence_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
visit_concept_id INTEGER 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 INTEGER NOT NULL ,
|
|
provider_id INTEGER NULL,
|
|
care_site_id INTEGER NULL,
|
|
visit_source_value VARCHAR(50) NULL,
|
|
visit_source_concept_id INTEGER NULL ,
|
|
admitted_from_concept_id INTEGER NULL ,
|
|
admitted_from_source_value VARCHAR(50) NULL ,
|
|
discharge_to_source_value VARCHAR(50) NULL ,
|
|
discharge_to_concept_id INTEGER NULL ,
|
|
preceding_visit_occurrence_id INTEGER NULL
|
|
)
|
|
|
|
DISTRUBTE ON (person_id);
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE visit_detail
|
|
(
|
|
visit_detail_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
visit_detail_concept_id INTEGER 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 INTEGER NOT NULL ,
|
|
provider_id INTEGER NULL ,
|
|
care_site_id INTEGER NULL ,
|
|
discharge_to_concept_id INTEGER NULL ,
|
|
admitted_from_concept_id INTEGER NULL ,
|
|
admitted_from_source_value VARCHAR(50) NULL ,
|
|
visit_detail_source_value VARCHAR(50) NULL ,
|
|
visit_detail_source_concept_id INTEGER NULL ,
|
|
discharge_to_source_value VARCHAR(50) NULL ,
|
|
preceding_visit_detail_id BIGINT NULL ,
|
|
visit_detail_parent_id BIGINT NULL ,
|
|
visit_occurrence_id BIGINT NOT NULL
|
|
)
|
|
|
|
DISTRUBTE ON (person_id);
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE procedure_occurrence
|
|
(
|
|
procedure_occurrence_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
procedure_concept_id INTEGER NOT NULL ,
|
|
procedure_date DATE NULL ,
|
|
procedure_datetime DATETIME NOT NULL ,
|
|
procedure_type_concept_id INTEGER NOT NULL ,
|
|
modifier_concept_id INTEGER NULL ,
|
|
quantity INTEGER NULL ,
|
|
provider_id INTEGER NULL ,
|
|
visit_occurrence_id INTEGER NULL ,
|
|
visit_detail_id INTEGER NULL ,
|
|
procedure_source_value VARCHAR(50) NULL ,
|
|
procedure_source_concept_id INTEGER NULL ,
|
|
modifier_source_value VARCHAR(50) NULL ,
|
|
)
|
|
|
|
DISTRUBTE ON (person_id);
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE drug_exposure
|
|
(
|
|
drug_exposure_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
drug_concept_id INTEGER 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 INTEGER NOT NULL ,
|
|
stop_reason VARCHAR(20) NULL ,
|
|
refills INTEGER NULL ,
|
|
quantity REAL NULL ,
|
|
days_supply INTEGER NULL ,
|
|
sig VARCHAR(1000) NULL ,
|
|
route_concept_id INTEGER NULL ,
|
|
lot_number VARCHAR(50) NULL ,
|
|
provider_id INTEGER NULL ,
|
|
visit_occurrence_id INTEGER NULL ,
|
|
visit_detail_id INTEGER NULL ,
|
|
drug_source_value VARCHAR(50) NULL ,
|
|
drug_source_concept_id INTEGER NULL ,
|
|
route_source_value VARCHAR(50) NULL ,
|
|
dose_unit_source_value VARCHAR(50) NULL
|
|
)
|
|
|
|
DISTRUBTE ON (person_id);
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE device_exposure
|
|
(
|
|
device_exposure_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
device_concept_id INTEGER 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 INTEGER NOT NULL ,
|
|
unique_device_id VARCHAR(50) NULL ,
|
|
quantity INTEGER NULL ,
|
|
provider_id INTEGER NULL ,
|
|
visit_occurrence_id INTEGER NULL ,
|
|
visit_detail_id INTEGER NULL ,
|
|
device_source_value VARCHAR(100) NULL ,
|
|
device_source_concept_id INTEGER NULL
|
|
)
|
|
|
|
DISTRUBTE ON (person_id);
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE condition_occurrence
|
|
(
|
|
condition_occurrence_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
condition_concept_id INTEGER NOT 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 INTEGER NOT NULL ,
|
|
condition_status_concept_id INTEGER NULL ,
|
|
stop_reason VARCHAR(20) NULL ,
|
|
provider_id INTEGER NULL ,
|
|
visit_occurrence_id INTEGER NULL ,
|
|
visit_detail_id INTEGER NULL ,
|
|
condition_source_value VARCHAR(50) NULL ,
|
|
condition_source_concept_id INTEGER NULL ,
|
|
condition_status_source_value VARCHAR(50) NULL
|
|
)
|
|
|
|
DISTRUBTE ON (person_id);
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE measurement
|
|
(
|
|
measurement_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
measurement_concept_id INTEGER NOT NULL ,
|
|
measurement_date DATE NULL ,
|
|
measurement_datetime DATETIME NOT NULL ,
|
|
measurement_time VARCHAR(10) NULL,
|
|
measurement_type_concept_id INTEGER NOT NULL ,
|
|
operator_concept_id INTEGER NULL ,
|
|
value_as_number REAL NULL ,
|
|
value_as_concept_id INTEGER NULL ,
|
|
unit_concept_id INTEGER NULL ,
|
|
range_low REAL NULL ,
|
|
range_high REAL NULL ,
|
|
provider_id INTEGER NULL ,
|
|
visit_occurrence_id INTEGER NULL ,
|
|
visit_detail_id INTEGER NULL ,
|
|
measurement_source_value VARCHAR(50) NULL ,
|
|
measurement_source_concept_id INTEGER NULL ,
|
|
unit_source_value VARCHAR(50) NULL ,
|
|
value_source_value VARCHAR(50) NULL
|
|
)
|
|
DISTRUBTE ON (person_id)
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE note
|
|
(
|
|
note_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
note_event_id BIGINT NULL , --This and the field below added
|
|
note_domain_id VARCHAR(20) NULL , --This field may be removed in favor of the one below
|
|
--note_event_table_concept_id INTEGER NULL , --This may be added based on 9/4 meeting
|
|
note_date DATE NULL ,
|
|
note_datetime DATETIME NOT NULL ,
|
|
note_type_concept_id INTEGER NOT NULL ,
|
|
note_class_concept_id INTEGER NOT NULL ,
|
|
note_title VARCHAR(250) NULL ,
|
|
note_text VARCHAR(1000) NULL ,
|
|
encoding_concept_id INTEGER NOT NULL ,
|
|
language_concept_id INTEGER NOT NULL ,
|
|
provider_id INTEGER NULL ,
|
|
visit_occurrence_id INTEGER NULL ,
|
|
visit_detail_id INTEGER NULL ,
|
|
note_source_value VARCHAR(50) NULL
|
|
)
|
|
DISTRUBTE ON (person_id)
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE ON RANDOM
|
|
CREATE TABLE note_nlp
|
|
(
|
|
note_nlp_id BIGINT NOT NULL ,
|
|
note_id BIGINT NOT NULL ,
|
|
section_concept_id INTEGER NULL ,
|
|
snippet VARCHAR(250) NULL ,
|
|
"offset" VARCHAR(250) NULL ,
|
|
lexical_variant VARCHAR(250) NOT NULL ,
|
|
note_nlp_concept_id INTEGER NULL ,
|
|
nlp_system VARCHAR(250) NULL ,
|
|
nlp_date DATE NOT NULL ,
|
|
nlp_datetime DATETIME NULL ,
|
|
term_exists VARCHAR(1) NULL ,
|
|
term_temporal VARCHAR(50) NULL ,
|
|
term_modifiers VARCHAR(2000) NULL ,
|
|
note_nlp_source_concept_id INTEGER NULL
|
|
)
|
|
DISTRIBUTE ON RANDOM
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE observation
|
|
(
|
|
observation_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
observation_concept_id INTEGER NOT NULL ,
|
|
observation_date DATE NULL ,
|
|
observation_datetime DATETIME NOT NULL ,
|
|
observation_type_concept_id INTEGER NOT NULL ,
|
|
value_as_number REAL NULL ,
|
|
value_as_string VARCHAR(60) NULL ,
|
|
value_as_concept_id INTEGER NULL ,
|
|
qualifier_concept_id INTEGER NULL ,
|
|
unit_concept_id INTEGER NULL ,
|
|
provider_id INTEGER NULL ,
|
|
visit_occurrence_id BIGINT NULL ,
|
|
visit_detail_id BIGINT NULL ,
|
|
observation_source_value VARCHAR(50) NULL ,
|
|
observation_source_concept_id INTEGER NULL ,
|
|
unit_source_value VARCHAR(50) NULL ,
|
|
qualifier_source_value VARCHAR(50) NULL ,
|
|
observation_event_id BIGINT 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 VARCHAR(20) NULL ,
|
|
--obs_event_table_concept_id INTEGER 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
|
|
)
|
|
DISTRUBTE ON (person_id)
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE ON KEY(person_id)
|
|
CREATE TABLE survey_conduct /*Should this be SURVEY_OCCURRENCE instead to comply with the other tables?*/
|
|
(
|
|
survey_conduct_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
survey_concept_id INTEGER 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 BIGINT NULL ,
|
|
assisted_concept_id INTEGER NULL ,
|
|
respondent_type_concept_id INTEGER NULL ,
|
|
timing_concept_id INTEGER NULL ,
|
|
collection_method_concept_id INTEGER NULL ,
|
|
assisted_source_value VARCHAR(50) NULL ,
|
|
respondent_type_source_value VARCHAR(100) NULL ,
|
|
timing_source_value VARCHAR(100) NULL ,
|
|
collection_method_source_value VARCHAR(100) NULL ,
|
|
survey_source_value VARCHAR(100) NULL ,
|
|
survey_source_concept_id INTEGER NULL ,
|
|
survey_source_identifier VARCHAR(100) NULL ,
|
|
validated_survey_concept_id INTEGER NULL ,
|
|
validated_survey_source_value VARCHAR(100) NULL ,
|
|
survey_version_number VARCHAR(20) NULL ,
|
|
visit_occurrence_id BIGINT NULL ,
|
|
visit_detail_id BIGINT NULL ,
|
|
response_to_visit_occurrence_id BIGINT NULL
|
|
)
|
|
DISTRIBUTE ON (person_id)
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE ON RANDOM
|
|
CREATE TABLE fact_relationship
|
|
(
|
|
domain_concept_id_1 INTEGER NOT NULL ,
|
|
fact_id_1 BIGINT NOT NULL ,
|
|
domain_concept_id_2 INTEGER NOT NULL ,
|
|
fact_id_2 BIGINT NOT NULL ,
|
|
relationship_concept_id INTEGER NOT NULL
|
|
)
|
|
DISTRIBUTE ON RANDOM
|
|
;
|
|
|
|
|
|
|
|
/************************
|
|
|
|
Standardized health system data
|
|
|
|
************************/
|
|
|
|
|
|
--HINT DISTRIBUTE ON RANDOM
|
|
CREATE TABLE location
|
|
(
|
|
location_id BIGINT NOT NULL ,
|
|
address_1 VARCHAR(50) NULL ,
|
|
address_2 VARCHAR(50) NULL ,
|
|
city VARCHAR(50) NULL ,
|
|
state VARCHAR(2) NULL ,
|
|
zip VARCHAR(9) NULL ,
|
|
county VARCHAR(20) NULL ,
|
|
country VARCHAR(100) NULL ,
|
|
location_source_value VARCHAR(50) NULL ,
|
|
latitude REAL NULL ,
|
|
longitude REAL NULL
|
|
)
|
|
DISTRIBUTE ON RANDOM
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE ON RANDOM
|
|
CREATE TABLE location_history
|
|
(
|
|
location_history_id BIGINT NOT NULL , --unauthorized addition based on CDM conventions
|
|
location_id BIGINT NOT NULL ,
|
|
relationship_type_concept_id INTEGER NULL , --Recent addition based on github discussion
|
|
domain_id VARCHAR(50) NOT NULL ,
|
|
entity_id BIGINT NOT NULL ,
|
|
start_date DATE NOT NULL ,
|
|
end_date DATE NULL
|
|
)
|
|
DISTRIBUTE ON RANDOM
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE ON RANDOM
|
|
CREATE TABLE care_site
|
|
(
|
|
care_site_id BIGINT NOT NULL ,
|
|
care_site_name VARCHAR(255) NULL ,
|
|
place_of_service_concept_id INTEGER NULL ,
|
|
location_id BIGINT NULL ,
|
|
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 BIGINT NOT NULL ,
|
|
provider_name VARCHAR(255) NULL ,
|
|
NPI VARCHAR(20) NULL ,
|
|
DEA VARCHAR(20) NULL ,
|
|
specialty_concept_id INTEGER NULL ,
|
|
care_site_id BIGINT NULL ,
|
|
year_of_birth INTEGER NULL ,
|
|
gender_concept_id INTEGER NULL ,
|
|
provider_source_value VARCHAR(50) NULL ,
|
|
specialty_source_value VARCHAR(50) NULL ,
|
|
specialty_source_concept_id INTEGER NULL ,
|
|
gender_source_value VARCHAR(50) NULL ,
|
|
gender_source_concept_id INTEGER NULL
|
|
)
|
|
DISTRIBUTE ON RANDOM
|
|
;
|
|
|
|
|
|
/************************
|
|
|
|
Standardized health economics
|
|
|
|
************************/
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE payer_plan_period
|
|
(
|
|
payer_plan_period_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
contract_person_id BIGINT NULL ,
|
|
payer_plan_period_start_date DATE NOT NULL ,
|
|
payer_plan_period_end_date DATE NOT NULL ,
|
|
payer_concept_id INTEGER NULL ,
|
|
plan_concept_id INTEGER NULL ,
|
|
contract_concept_id INTEGER NULL ,
|
|
sponsor_concept_id INTEGER NULL ,
|
|
stop_reason_concept_id INTEGER NULL ,
|
|
payer_source_value VARCHAR(50) NULL ,
|
|
payer_source_concept_id INTEGER NULL ,
|
|
plan_source_value VARCHAR(50) NULL ,
|
|
plan_source_concept_id INTEGER NULL ,
|
|
contract_source_value VARCHAR(50) NULL ,
|
|
contract_source_concept_id INTEGER NULL ,
|
|
sponsor_source_value VARCHAR(50) NULL ,
|
|
sponsor_source_concept_id INTEGER NULL ,
|
|
family_source_value VARCHAR(50) NULL ,
|
|
stop_reason_source_value VARCHAR(50) NULL ,
|
|
stop_reason_source_concept_id INTEGER NULL
|
|
)
|
|
DISTRUBTE ON (person_id)
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE ON KEY(person_id)
|
|
CREATE TABLE cost
|
|
(
|
|
cost_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL,
|
|
cost_event_id BIGINT NOT NULL ,
|
|
cost_domain_id VARCHAR(20) NOT NULL ,
|
|
--cost_event_table_concept_id INTEGER NOT NULL , /*This is still in discussion and most likely will replace cost_domain_id at 9/4 meeting*/
|
|
cost_concept_id INTEGER NOT NULL ,
|
|
cost_type_concept_id INTEGER NOT NULL ,
|
|
currency_concept_id INTEGER NULL ,
|
|
cost REAL NULL ,
|
|
incurred_date DATE NOT NULL ,
|
|
billed_date DATE NULL ,
|
|
paid_date DATE NULL ,
|
|
revenue_code_concept_id INTEGER NULL ,
|
|
drg_concept_id INTEGER NULL ,
|
|
cost_source_value VARCHAR(50) NULL ,
|
|
cost_source_concept_id INTEGER NULL ,
|
|
revenue_code_source_value VARCHAR(50) NULL ,
|
|
drg_source_value VARCHAR(3) NULL ,
|
|
payer_plan_period_id BIGINT NULL
|
|
)
|
|
DISTRIBUTE ON (person_id)
|
|
;
|
|
|
|
|
|
/************************
|
|
|
|
Standardized derived elements
|
|
|
|
************************/
|
|
|
|
|
|
--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
|
|
)
|
|
DISTRUBTE ON (subject_id)
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(subject_id)
|
|
CREATE TABLE cohort_attribute
|
|
(
|
|
cohort_definition_id BIGINT NOT NULL ,
|
|
subject_id BIGINT NOT NULL ,
|
|
cohort_start_date DATE NOT NULL ,
|
|
cohort_end_date DATE NOT NULL ,
|
|
attribute_definition_id BIGINT NOT NULL ,
|
|
value_as_number REAL NULL ,
|
|
value_as_concept_id INTEGER NULL
|
|
)
|
|
DISTRUBTE ON (subject_id)
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE drug_era
|
|
(
|
|
drug_era_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
drug_concept_id INTEGER NOT NULL ,
|
|
drug_era_start_date DATE NOT NULL ,
|
|
drug_era_end_date DATE NOT NULL ,
|
|
drug_exposure_count INTEGER NULL ,
|
|
gap_days INTEGER NULL
|
|
)
|
|
DISTRUBTE ON (person_id)
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE dose_era
|
|
(
|
|
dose_era_id BIGINT NOT NULL ,
|
|
person_id BIGINT NOT NULL ,
|
|
drug_concept_id INTEGER NOT NULL ,
|
|
unit_concept_id INTEGER NOT NULL ,
|
|
dose_value REAL NOT NULL ,
|
|
dose_era_start_date DATE NOT NULL ,
|
|
dose_era_end_date DATE NOT NULL
|
|
)
|
|
DISTRUBTE ON (person_id)
|
|
;
|
|
|
|
|
|
--HINT DISTRIBUTE_ON_KEY(person_id)
|
|
CREATE TABLE condition_era
|
|
(
|
|
condition_era_id BIGINT NOT NULL ,
|
|
person_id BIGINT 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
|
|
)
|
|
DISTRUBTE ON (person_id)
|
|
;
|