/*
 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 version 6.0

last revised: 27-Aug-2018

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_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
)
;


create table vocabulary (
  vocabulary_id			    STRING		not null,
  vocabulary_name		    STRING		not null,
  vocabulary_reference		STRING		not null,
  vocabulary_version	  	STRING		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
)
;


create table concept_class (
  concept_class_id			    STRING		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
  )
;


create table relationship (
  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
)
;


create table concept_synonym (
  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,
  min_levels_of_separation	INT64		not null,
  max_levels_of_separation	INT64		not null
)
;


create table source_to_concept_map (
  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,
  target_vocabulary_id		STRING		not 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,
  numerator_unit_concept_id		INT64		  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
)
;


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
)
;


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 ,
  value_as_concept_id       INT64       null ,
  metadata_date             date        null ,
  metadata_datetime         DATETIME    null
)
;

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,
  death_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		not null,
  race_source_value				STRING 		null,
  race_source_concept_id		INT64		not null,
  ethnicity_source_value		STRING 		null,
  ethnicity_source_concept_id	INT64		not null
)
;


--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
)
;


--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		not null ,
  disease_status_concept_id		INT64		not 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 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_type_concept_id			    INT64			not null ,
  provider_id					    INT64			null,
  care_site_id					    INT64			null,
  visit_source_value				STRING			null,
  visit_source_concept_id		    INT64			not null ,
  admitted_from_concept_id      	INT64     		not NULL ,   /*Changed from admitting_source_* */
  admitted_from_source_value    	STRING 			NULL ,
  discharge_to_source_value		  	STRING			null ,
  discharge_to_concept_id		    INT64   		not null ,
  preceding_visit_occurrence_id		INT64			null
)
;


--HINT DISTRIBUTE_ON_KEY(person_id)
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_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     	not null ,
  admitted_from_concept_id           INT64     	not NULL , /*Changed from admitting_source_* */
  admitted_from_source_value         STRING 	NULL ,
  visit_detail_source_value          STRING 	null ,
  visit_detail_source_concept_id     INT64     	not 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
)
;


--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_type_concept_id		INT64			not null ,
  modifier_concept_id			INT64			not 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			not null ,
  modifier_source_value		    STRING			null 
)
;


--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			not 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			not null ,
  route_source_value			    STRING	  		null ,
  dose_unit_source_value		    STRING	  		null
)
;


--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			not null
)
;


--HINT DISTRIBUTE_ON_KEY(person_id)
create table condition_occurrence
(
  condition_occurrence_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_end_datetime		    DATETIME		null ,
  condition_type_concept_id		  	INT64			not null ,
  condition_status_concept_id	  	INT64			not 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			not null ,
  condition_status_source_value		STRING			null
)
;


--HINT DISTRIBUTE_ON_KEY(person_id)
create table measurement
(
  measurement_id				    INT64			not null ,
  person_id						    INT64			not null ,
  measurement_concept_id		    INT64			not 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			not null ,
  unit_source_value				    STRING			null ,
  value_source_value			    STRING			null
)
;


--HINT DISTRIBUTE_ON_KEY(person_id)
create table note
(
  note_id						INT64		not null ,
  person_id						INT64		not null ,
  note_event_id         		INT64       null , 
  note_event_field_concept_id	INT64		not 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
)
;



create table note_nlp
(
  note_nlp_id					INT64		not null ,
  note_id						INT64		not null ,
  section_concept_id			INT64		not null ,
  snippet						STRING		null ,
  "offset"					    STRING		null ,
  lexical_variant				STRING		not null ,
  note_nlp_concept_id			INT64		not 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		not null
)
;


--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_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 ,
  observation_source_concept_id		INT64			not null ,
  unit_source_value				    STRING			null ,
  qualifier_source_value			STRING			null ,
  observation_event_id				INT64			null , 
  obs_event_field_concept_id		INT64			not NULL , 
  value_as_datetime					DATETIME		null
)
;


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		not null ,
  respondent_type_concept_id		INT64		not null ,
  timing_concept_id					INT64		not null ,
  collection_method_concept_id		INT64		not 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		not null ,
  survey_source_identifier			STRING		null ,
  validated_survey_concept_id		INT64		not null ,
  validated_survey_source_value		STRING		null ,
  survey_version_number				STRING		null ,
  visit_occurrence_id				INT64		null ,
  visit_detail_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 ,
  relationship_concept_id	INT64			not null
)
;


create table location
(
  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
)
;


create table location_history
(
  location_history_id           INT64      	not null ,
  location_id			        INT64		not null ,
  relationship_type_concept_id	INT64		not 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	not 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		not null ,
  care_site_id					INT64		null ,
  year_of_birth					INT64		null ,
  gender_concept_id				INT64		not null ,
  provider_source_value			STRING		null ,
  specialty_source_value		STRING		null ,
  specialty_source_concept_id	INT64		not null ,
  gender_source_value			STRING		null ,
  gender_source_concept_id		INT64		not 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_concept_id              INT64       not null ,
  plan_concept_id               INT64       not null ,
  contract_concept_id           INT64       not null ,
  sponsor_concept_id            INT64       not null ,
  stop_reason_concept_id        INT64       not null ,
  payer_source_value			STRING	  	null ,
  payer_source_concept_id       INT64       not null ,
  plan_source_value				STRING	  	null ,
  plan_source_concept_id        INT64       not null ,
  contract_source_value         STRING   	null ,
  contract_source_concept_id    INT64       not null ,
  sponsor_source_value          STRING   	null ,
  sponsor_source_concept_id     INT64       not null ,
  family_source_value			STRING	  	null ,
  stop_reason_source_value      STRING   	null ,
  stop_reason_source_concept_id INT64       not null
)
;


create table cost
(
  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		not null ,
  cost							FLOAT64		null ,
  incurred_date					date		not null ,
  billed_date					date		null ,
  paid_date						date		null ,
  revenue_code_concept_id		INT64		not null ,
  drg_concept_id			    INT64		not null ,
  cost_source_value				STRING		null ,
  cost_source_concept_id	  	INT64		not null ,
  revenue_code_source_value 	STRING 		null ,
  drg_source_value			    STRING		null ,
  payer_plan_period_id			INT64		null
)
;


--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_datetime	datetime		not null ,
  drug_era_end_datetime		datetime		not null ,
  drug_exposure_count		INT64			null ,
  gap_days					INT64			null
)
;


--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_datetime	datetime		not null ,
  dose_era_end_datetime		datetime		not null
)
;


--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_datetime		datetime		not null ,
  condition_era_end_datetime		datetime		not null ,
  condition_occurrence_count		INT64			null
)
;