Fixes to bigquery as a result of testing and bigquery, impala, oracle, and netezza results schema ddls.
This commit is contained in:
parent
eee81f61ad
commit
62207c4309
|
@ -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
|
||||
)
|
||||
;
|
|
@ -135,30 +135,6 @@ create table drug_strength (
|
|||
;
|
||||
|
||||
|
||||
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 ,
|
||||
|
@ -187,13 +163,11 @@ create table metadata
|
|||
)
|
||||
;
|
||||
|
||||
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
|
||||
(
|
||||
|
@ -253,20 +227,6 @@ create table specimen
|
|||
;
|
||||
|
||||
|
||||
--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
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
--HINT DISTRIBUTE_ON_KEY(person_id)
|
||||
create table visit_occurrence
|
||||
(
|
||||
|
@ -333,7 +293,7 @@ create table procedure_occurrence
|
|||
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
|
||||
)
|
||||
;
|
||||
|
||||
|
@ -445,9 +405,8 @@ 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_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 ,
|
||||
|
@ -506,15 +465,14 @@ create table observation
|
|||
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*/
|
||||
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 ,
|
||||
|
@ -540,12 +498,11 @@ create table survey_conduct /*Should this be SURVEY_OCCURRENCE instead to comply
|
|||
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 ,
|
||||
|
@ -557,8 +514,6 @@ create table fact_relationship
|
|||
;
|
||||
|
||||
|
||||
|
||||
|
||||
create table location
|
||||
(
|
||||
location_id INT64 not null ,
|
||||
|
@ -575,6 +530,7 @@ create table location
|
|||
)
|
||||
;
|
||||
|
||||
|
||||
create table location_history
|
||||
(
|
||||
location_history_id INT64 not null ,
|
||||
|
@ -619,8 +575,6 @@ create table provider
|
|||
;
|
||||
|
||||
|
||||
|
||||
|
||||
--HINT DISTRIBUTE_ON_KEY(person_id)
|
||||
create table payer_plan_period
|
||||
(
|
||||
|
@ -654,8 +608,7 @@ 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_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 ,
|
||||
|
@ -674,33 +627,6 @@ create table cost
|
|||
;
|
||||
|
||||
|
||||
|
||||
|
||||
--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
|
||||
)
|
||||
;
|
||||
|
||||
|
||||
--HINT DISTRIBUTE_ON_KEY(person_id)
|
||||
create table drug_era
|
||||
(
|
||||
|
|
|
@ -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
|
||||
)
|
||||
;
|
|
@ -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);
|
|
@ -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 );
|
Loading…
Reference in New Issue