From e1e010a3df16abfdbbb36ab446d881790c9af6e4 Mon Sep 17 00:00:00 2001 From: ssuvorov-fls Date: Wed, 30 Mar 2022 10:53:52 +0300 Subject: [PATCH] added snowflake support --- R/listSupportedVersions.R | 2 +- R/writeDDL.R | 8 +- extras/codeToRun.R | 2 +- .../OMOPCDM_snowflake_5.4_constraints.sql | 158 ++++++ .../snowflake/OMOPCDM_snowflake_5.4_ddl.sql | 475 ++++++++++++++++++ .../OMOPCDM_snowflake_5.4_indices.sql | 1 + .../OMOPCDM_snowflake_5.4_primary_keys.sql | 26 + 7 files changed, 666 insertions(+), 6 deletions(-) create mode 100644 inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_constraints.sql create mode 100644 inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_ddl.sql create mode 100644 inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_indices.sql create mode 100644 inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_primary_keys.sql diff --git a/R/listSupportedVersions.R b/R/listSupportedVersions.R index 93c8cdf..f5d0b57 100644 --- a/R/listSupportedVersions.R +++ b/R/listSupportedVersions.R @@ -12,6 +12,6 @@ listSupportedVersions <- function() { #' @export listSupportedDialects <- function() { - supportedDialects <- c("oracle", "postgresql", "pdw", "redshift", "impala", "netezza", "bigquery", "sql server", "spark") + supportedDialects <- c("oracle", "postgresql", "pdw", "redshift", "impala", "netezza", "bigquery", "sql server", "spark", "snowflake") return(supportedDialects) } diff --git a/R/writeDDL.R b/R/writeDDL.R index a5bc013..666740f 100644 --- a/R/writeDDL.R +++ b/R/writeDDL.R @@ -30,7 +30,7 @@ writeDdl <- function(targetDialect, cdmVersion, outputfolder, cdmDatabaseSchema = "@cdmDatabaseSchema") { # argument checks - stopifnot(targetDialect %in% c("oracle", "postgresql", "pdw", "redshift", "impala", "netezza", "bigquery", "sql server", "spark")) + stopifnot(targetDialect %in% c("oracle", "postgresql", "pdw", "redshift", "impala", "netezza", "bigquery", "sql server", "spark", "snowflake")) stopifnot(cdmVersion %in% listSupportedVersions()) stopifnot(is.character(cdmDatabaseSchema)) @@ -54,7 +54,7 @@ writeDdl <- function(targetDialect, cdmVersion, outputfolder, cdmDatabaseSchema writePrimaryKeys <- function(targetDialect, cdmVersion, outputfolder, cdmDatabaseSchema = "@cdmDatabaseSchema") { # argument checks - stopifnot(targetDialect %in% c("oracle", "postgresql", "pdw", "redshift", "impala", "netezza", "bigquery", "sql server", "spark")) + stopifnot(targetDialect %in% c("oracle", "postgresql", "pdw", "redshift", "impala", "netezza", "bigquery", "sql server", "spark", "snowflake")) stopifnot(cdmVersion %in% listSupportedVersions()) stopifnot(is.character(cdmDatabaseSchema)) @@ -78,7 +78,7 @@ writePrimaryKeys <- function(targetDialect, cdmVersion, outputfolder, cdmDatabas writeForeignKeys <- function(targetDialect, cdmVersion, outputfolder, cdmDatabaseSchema = "@cdmDatabaseSchema") { # argument checks - stopifnot(targetDialect %in% c("oracle", "postgresql", "pdw", "redshift", "impala", "netezza", "bigquery", "sql server", "spark")) + stopifnot(targetDialect %in% c("oracle", "postgresql", "pdw", "redshift", "impala", "netezza", "bigquery", "sql server", "spark", "snowflake")) stopifnot(cdmVersion %in% listSupportedVersions()) stopifnot(is.character(cdmDatabaseSchema)) @@ -102,7 +102,7 @@ writeForeignKeys <- function(targetDialect, cdmVersion, outputfolder, cdmDatabas writeIndex <- function(targetDialect, cdmVersion, outputfolder, cdmDatabaseSchema = "@cdmDatabaseSchema") { # argument checks - stopifnot(targetDialect %in% c("oracle", "postgresql", "pdw", "redshift", "impala", "netezza", "bigquery", "sql server", "spark")) + stopifnot(targetDialect %in% c("oracle", "postgresql", "pdw", "redshift", "impala", "netezza", "bigquery", "sql server", "spark", "snowflake")) stopifnot(cdmVersion %in% listSupportedVersions()) stopifnot(is.character(cdmDatabaseSchema)) diff --git a/extras/codeToRun.R b/extras/codeToRun.R index 39862e5..e845425 100644 --- a/extras/codeToRun.R +++ b/extras/codeToRun.R @@ -7,7 +7,7 @@ cdmVersion <- "5.4" supportedVersions <- CommonDataModel::listSupportedVersions() for (cdmVersion in supportedVersions) { - for (targetDialect in c("oracle", "postgresql", "pdw", "redshift", "impala", "netezza", "bigquery", "sql server", "spark")) { + for (targetDialect in c("oracle", "postgresql", "pdw", "redshift", "impala", "netezza", "bigquery", "sql server", "spark", "snowflake")) { CommonDataModel::writeDdl(targetDialect = targetDialect, cdmVersion = cdmVersion) diff --git a/inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_constraints.sql b/inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_constraints.sql new file mode 100644 index 0000000..c242392 --- /dev/null +++ b/inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_constraints.sql @@ -0,0 +1,158 @@ +ALTER TABLE PERSON ADD CONSTRAINT fpk_PERSON_gender_concept_id FOREIGN KEY (gender_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PERSON ADD CONSTRAINT fpk_PERSON_race_concept_id FOREIGN KEY (race_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PERSON ADD CONSTRAINT fpk_PERSON_ethnicity_concept_id FOREIGN KEY (ethnicity_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PERSON ADD CONSTRAINT fpk_PERSON_location_id FOREIGN KEY (location_id) REFERENCES LOCATION (LOCATION_ID); +ALTER TABLE PERSON ADD CONSTRAINT fpk_PERSON_provider_id FOREIGN KEY (provider_id) REFERENCES PROVIDER (PROVIDER_ID); +ALTER TABLE PERSON ADD CONSTRAINT fpk_PERSON_care_site_id FOREIGN KEY (care_site_id) REFERENCES CARE_SITE (CARE_SITE_ID); +ALTER TABLE PERSON ADD CONSTRAINT fpk_PERSON_gender_source_concept_id FOREIGN KEY (gender_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PERSON ADD CONSTRAINT fpk_PERSON_race_source_concept_id FOREIGN KEY (race_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PERSON ADD CONSTRAINT fpk_PERSON_ethnicity_source_concept_id FOREIGN KEY (ethnicity_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE OBSERVATION_PERIOD ADD CONSTRAINT fpk_OBSERVATION_PERIOD_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE OBSERVATION_PERIOD ADD CONSTRAINT fpk_OBSERVATION_PERIOD_period_type_concept_id FOREIGN KEY (period_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE VISIT_OCCURRENCE ADD CONSTRAINT fpk_VISIT_OCCURRENCE_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE VISIT_OCCURRENCE ADD CONSTRAINT fpk_VISIT_OCCURRENCE_visit_concept_id FOREIGN KEY (visit_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE VISIT_OCCURRENCE ADD CONSTRAINT fpk_VISIT_OCCURRENCE_visit_type_concept_id FOREIGN KEY (visit_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE VISIT_OCCURRENCE ADD CONSTRAINT fpk_VISIT_OCCURRENCE_provider_id FOREIGN KEY (provider_id) REFERENCES PROVIDER (PROVIDER_ID); +ALTER TABLE VISIT_OCCURRENCE ADD CONSTRAINT fpk_VISIT_OCCURRENCE_care_site_id FOREIGN KEY (care_site_id) REFERENCES CARE_SITE (CARE_SITE_ID); +ALTER TABLE VISIT_OCCURRENCE ADD CONSTRAINT fpk_VISIT_OCCURRENCE_visit_source_concept_id FOREIGN KEY (visit_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE VISIT_OCCURRENCE ADD CONSTRAINT fpk_VISIT_OCCURRENCE_admitting_source_concept_id FOREIGN KEY (admitting_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE VISIT_OCCURRENCE ADD CONSTRAINT fpk_VISIT_OCCURRENCE_discharge_to_concept_id FOREIGN KEY (discharge_to_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE VISIT_OCCURRENCE ADD CONSTRAINT fpk_VISIT_OCCURRENCE_preceding_visit_occurrence_id FOREIGN KEY (preceding_visit_occurrence_id) REFERENCES VISIT_OCCURRENCE (VISIT_OCCURRENCE_ID); +ALTER TABLE VISIT_DETAIL ADD CONSTRAINT fpk_VISIT_DETAIL_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE VISIT_DETAIL ADD CONSTRAINT fpk_VISIT_DETAIL_visit_detail_concept_id FOREIGN KEY (visit_detail_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE VISIT_DETAIL ADD CONSTRAINT fpk_VISIT_DETAIL_visit_detail_type_concept_id FOREIGN KEY (visit_detail_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE VISIT_DETAIL ADD CONSTRAINT fpk_VISIT_DETAIL_provider_id FOREIGN KEY (provider_id) REFERENCES PROVIDER (PROVIDER_ID); +ALTER TABLE VISIT_DETAIL ADD CONSTRAINT fpk_VISIT_DETAIL_care_site_id FOREIGN KEY (care_site_id) REFERENCES CARE_SITE (CARE_SITE_ID); +ALTER TABLE VISIT_DETAIL ADD CONSTRAINT fpk_VISIT_DETAIL_visit_detail_source_concept_id FOREIGN KEY (visit_detail_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE VISIT_DETAIL ADD CONSTRAINT fpk_VISIT_DETAIL_admitting_source_concept_id FOREIGN KEY (admitting_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE VISIT_DETAIL ADD CONSTRAINT fpk_VISIT_DETAIL_discharge_to_concept_id FOREIGN KEY (discharge_to_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE VISIT_DETAIL ADD CONSTRAINT fpk_VISIT_DETAIL_preceding_visit_detail_id FOREIGN KEY (preceding_visit_detail_id) REFERENCES VISIT_DETAIL (VISIT_DETAIL_ID); +ALTER TABLE VISIT_DETAIL ADD CONSTRAINT fpk_VISIT_DETAIL_visit_detail_parent_id FOREIGN KEY (visit_detail_parent_id) REFERENCES VISIT_DETAIL (VISIT_DETAIL_ID); +ALTER TABLE VISIT_DETAIL ADD CONSTRAINT fpk_VISIT_DETAIL_visit_occurrence_id FOREIGN KEY (visit_occurrence_id) REFERENCES VISIT_OCCURRENCE (VISIT_OCCURRENCE_ID); +ALTER TABLE CONDITION_OCCURRENCE ADD CONSTRAINT fpk_CONDITION_OCCURRENCE_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE CONDITION_OCCURRENCE ADD CONSTRAINT fpk_CONDITION_OCCURRENCE_condition_concept_id FOREIGN KEY (condition_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONDITION_OCCURRENCE ADD CONSTRAINT fpk_CONDITION_OCCURRENCE_condition_type_concept_id FOREIGN KEY (condition_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONDITION_OCCURRENCE ADD CONSTRAINT fpk_CONDITION_OCCURRENCE_condition_status_concept_id FOREIGN KEY (condition_status_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONDITION_OCCURRENCE ADD CONSTRAINT fpk_CONDITION_OCCURRENCE_provider_id FOREIGN KEY (provider_id) REFERENCES PROVIDER (PROVIDER_ID); +ALTER TABLE CONDITION_OCCURRENCE ADD CONSTRAINT fpk_CONDITION_OCCURRENCE_visit_occurrence_id FOREIGN KEY (visit_occurrence_id) REFERENCES VISIT_OCCURRENCE (VISIT_OCCURRENCE_ID); +ALTER TABLE CONDITION_OCCURRENCE ADD CONSTRAINT fpk_CONDITION_OCCURRENCE_visit_detail_id FOREIGN KEY (visit_detail_id) REFERENCES VISIT_DETAIL (VISIT_DETAIL_ID); +ALTER TABLE CONDITION_OCCURRENCE ADD CONSTRAINT fpk_CONDITION_OCCURRENCE_condition_source_concept_id FOREIGN KEY (condition_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DRUG_EXPOSURE ADD CONSTRAINT fpk_DRUG_EXPOSURE_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE DRUG_EXPOSURE ADD CONSTRAINT fpk_DRUG_EXPOSURE_drug_concept_id FOREIGN KEY (drug_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DRUG_EXPOSURE ADD CONSTRAINT fpk_DRUG_EXPOSURE_drug_type_concept_id FOREIGN KEY (drug_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DRUG_EXPOSURE ADD CONSTRAINT fpk_DRUG_EXPOSURE_route_concept_id FOREIGN KEY (route_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DRUG_EXPOSURE ADD CONSTRAINT fpk_DRUG_EXPOSURE_provider_id FOREIGN KEY (provider_id) REFERENCES PROVIDER (PROVIDER_ID); +ALTER TABLE DRUG_EXPOSURE ADD CONSTRAINT fpk_DRUG_EXPOSURE_visit_occurrence_id FOREIGN KEY (visit_occurrence_id) REFERENCES VISIT_OCCURRENCE (VISIT_OCCURRENCE_ID); +ALTER TABLE DRUG_EXPOSURE ADD CONSTRAINT fpk_DRUG_EXPOSURE_visit_detail_id FOREIGN KEY (visit_detail_id) REFERENCES VISIT_DETAIL (VISIT_DETAIL_ID); +ALTER TABLE DRUG_EXPOSURE ADD CONSTRAINT fpk_DRUG_EXPOSURE_drug_source_concept_id FOREIGN KEY (drug_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PROCEDURE_OCCURRENCE ADD CONSTRAINT fpk_PROCEDURE_OCCURRENCE_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE PROCEDURE_OCCURRENCE ADD CONSTRAINT fpk_PROCEDURE_OCCURRENCE_procedure_concept_id FOREIGN KEY (procedure_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PROCEDURE_OCCURRENCE ADD CONSTRAINT fpk_PROCEDURE_OCCURRENCE_procedure_type_concept_id FOREIGN KEY (procedure_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PROCEDURE_OCCURRENCE ADD CONSTRAINT fpk_PROCEDURE_OCCURRENCE_modifier_concept_id FOREIGN KEY (modifier_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DEVICE_EXPOSURE ADD CONSTRAINT fpk_DEVICE_EXPOSURE_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE DEVICE_EXPOSURE ADD CONSTRAINT fpk_DEVICE_EXPOSURE_device_concept_id FOREIGN KEY (device_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DEVICE_EXPOSURE ADD CONSTRAINT fpk_DEVICE_EXPOSURE_device_type_concept_id FOREIGN KEY (device_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DEVICE_EXPOSURE ADD CONSTRAINT fpk_DEVICE_EXPOSURE_provider_id FOREIGN KEY (provider_id) REFERENCES PROVIDER (PROVIDER_ID); +ALTER TABLE DEVICE_EXPOSURE ADD CONSTRAINT fpk_DEVICE_EXPOSURE_visit_occurrence_id FOREIGN KEY (visit_occurrence_id) REFERENCES VISIT_OCCURRENCE (VISIT_OCCURRENCE_ID); +ALTER TABLE DEVICE_EXPOSURE ADD CONSTRAINT fpk_DEVICE_EXPOSURE_visit_detail_id FOREIGN KEY (visit_detail_id) REFERENCES VISIT_DETAIL (VISIT_DETAIL_ID); +ALTER TABLE DEVICE_EXPOSURE ADD CONSTRAINT fpk_DEVICE_EXPOSURE_device_source_concept_id FOREIGN KEY (device_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE MEASUREMENT ADD CONSTRAINT fpk_MEASUREMENT_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE MEASUREMENT ADD CONSTRAINT fpk_MEASUREMENT_measurement_concept_id FOREIGN KEY (measurement_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE MEASUREMENT ADD CONSTRAINT fpk_MEASUREMENT_measurement_type_concept_id FOREIGN KEY (measurement_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE MEASUREMENT ADD CONSTRAINT fpk_MEASUREMENT_operator_concept_id FOREIGN KEY (operator_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE MEASUREMENT ADD CONSTRAINT fpk_MEASUREMENT_value_as_concept_id FOREIGN KEY (value_as_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE MEASUREMENT ADD CONSTRAINT fpk_MEASUREMENT_unit_concept_id FOREIGN KEY (unit_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE MEASUREMENT ADD CONSTRAINT fpk_MEASUREMENT_provider_id FOREIGN KEY (provider_id) REFERENCES PROVIDER (PROVIDER_ID); +ALTER TABLE MEASUREMENT ADD CONSTRAINT fpk_MEASUREMENT_visit_occurrence_id FOREIGN KEY (visit_occurrence_id) REFERENCES VISIT_OCCURRENCE (VISIT_OCCURRENCE_ID); +ALTER TABLE MEASUREMENT ADD CONSTRAINT fpk_MEASUREMENT_visit_detail_id FOREIGN KEY (visit_detail_id) REFERENCES VISIT_DETAIL (VISIT_DETAIL_ID); +ALTER TABLE MEASUREMENT ADD CONSTRAINT fpk_MEASUREMENT_measurement_source_concept_id FOREIGN KEY (measurement_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE OBSERVATION ADD CONSTRAINT fpk_OBSERVATION_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE OBSERVATION ADD CONSTRAINT fpk_OBSERVATION_observation_concept_id FOREIGN KEY (observation_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE OBSERVATION ADD CONSTRAINT fpk_OBSERVATION_observation_type_concept_id FOREIGN KEY (observation_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE OBSERVATION ADD CONSTRAINT fpk_OBSERVATION_value_as_concept_id FOREIGN KEY (value_as_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE OBSERVATION ADD CONSTRAINT fpk_OBSERVATION_qualifier_concept_id FOREIGN KEY (qualifier_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE OBSERVATION ADD CONSTRAINT fpk_OBSERVATION_unit_concept_id FOREIGN KEY (unit_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE OBSERVATION ADD CONSTRAINT fpk_OBSERVATION_provider_id FOREIGN KEY (provider_id) REFERENCES PROVIDER (PROVIDER_ID); +ALTER TABLE OBSERVATION ADD CONSTRAINT fpk_OBSERVATION_visit_occurrence_id FOREIGN KEY (visit_occurrence_id) REFERENCES VISIT_OCCURRENCE (VISIT_OCCURRENCE_ID); +ALTER TABLE OBSERVATION ADD CONSTRAINT fpk_OBSERVATION_visit_detail_id FOREIGN KEY (visit_detail_id) REFERENCES VISIT_DETAIL (VISIT_DETAIL_ID); +ALTER TABLE OBSERVATION ADD CONSTRAINT fpk_OBSERVATION_observation_source_concept_id FOREIGN KEY (observation_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DEATH ADD CONSTRAINT fpk_DEATH_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE DEATH ADD CONSTRAINT fpk_DEATH_death_type_concept_id FOREIGN KEY (death_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DEATH ADD CONSTRAINT fpk_DEATH_cause_concept_id FOREIGN KEY (cause_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DEATH ADD CONSTRAINT fpk_DEATH_cause_source_concept_id FOREIGN KEY (cause_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE NOTE ADD CONSTRAINT fpk_NOTE_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE NOTE ADD CONSTRAINT fpk_NOTE_note_type_concept_id FOREIGN KEY (note_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE NOTE ADD CONSTRAINT fpk_NOTE_note_class_concept_id FOREIGN KEY (note_class_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE NOTE ADD CONSTRAINT fpk_NOTE_encoding_concept_id FOREIGN KEY (encoding_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE NOTE ADD CONSTRAINT fpk_NOTE_language_concept_id FOREIGN KEY (language_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE NOTE ADD CONSTRAINT fpk_NOTE_provider_id FOREIGN KEY (provider_id) REFERENCES PROVIDER (PROVIDER_ID); +ALTER TABLE NOTE ADD CONSTRAINT fpk_NOTE_visit_occurrence_id FOREIGN KEY (visit_occurrence_id) REFERENCES VISIT_OCCURRENCE (VISIT_OCCURRENCE_ID); +ALTER TABLE NOTE ADD CONSTRAINT fpk_NOTE_visit_detail_id FOREIGN KEY (visit_detail_id) REFERENCES VISIT_DETAIL (VISIT_DETAIL_ID); +ALTER TABLE NOTE_NLP ADD CONSTRAINT fpk_NOTE_NLP_section_concept_id FOREIGN KEY (section_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE NOTE_NLP ADD CONSTRAINT fpk_NOTE_NLP_note_nlp_concept_id FOREIGN KEY (note_nlp_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE NOTE_NLP ADD CONSTRAINT fpk_NOTE_NLP_note_nlp_source_concept_id FOREIGN KEY (note_nlp_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE SPECIMEN ADD CONSTRAINT fpk_SPECIMEN_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE SPECIMEN ADD CONSTRAINT fpk_SPECIMEN_specimen_concept_id FOREIGN KEY (specimen_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE SPECIMEN ADD CONSTRAINT fpk_SPECIMEN_specimen_type_concept_id FOREIGN KEY (specimen_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE SPECIMEN ADD CONSTRAINT fpk_SPECIMEN_unit_concept_id FOREIGN KEY (unit_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE SPECIMEN ADD CONSTRAINT fpk_SPECIMEN_anatomic_site_concept_id FOREIGN KEY (anatomic_site_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE SPECIMEN ADD CONSTRAINT fpk_SPECIMEN_disease_status_concept_id FOREIGN KEY (disease_status_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE FACT_RELATIONSHIP ADD CONSTRAINT fpk_FACT_RELATIONSHIP_domain_concept_id_1 FOREIGN KEY (domain_concept_id_1) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE FACT_RELATIONSHIP ADD CONSTRAINT fpk_FACT_RELATIONSHIP_domain_concept_id_2 FOREIGN KEY (domain_concept_id_2) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE FACT_RELATIONSHIP ADD CONSTRAINT fpk_FACT_RELATIONSHIP_relationship_concept_id FOREIGN KEY (relationship_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CARE_SITE ADD CONSTRAINT fpk_CARE_SITE_place_of_service_concept_id FOREIGN KEY (place_of_service_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CARE_SITE ADD CONSTRAINT fpk_CARE_SITE_location_id FOREIGN KEY (location_id) REFERENCES LOCATION (LOCATION_ID); +ALTER TABLE PROVIDER ADD CONSTRAINT fpk_PROVIDER_specialty_concept_id FOREIGN KEY (specialty_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PROVIDER ADD CONSTRAINT fpk_PROVIDER_care_site_id FOREIGN KEY (care_site_id) REFERENCES CARE_SITE (CARE_SITE_ID); +ALTER TABLE PROVIDER ADD CONSTRAINT fpk_PROVIDER_gender_concept_id FOREIGN KEY (gender_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PROVIDER ADD CONSTRAINT fpk_PROVIDER_specialty_source_concept_id FOREIGN KEY (specialty_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PROVIDER ADD CONSTRAINT fpk_PROVIDER_gender_source_concept_id FOREIGN KEY (gender_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PAYER_PLAN_PERIOD ADD CONSTRAINT fpk_PAYER_PLAN_PERIOD_payer_plan_period_id FOREIGN KEY (payer_plan_period_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE PAYER_PLAN_PERIOD ADD CONSTRAINT fpk_PAYER_PLAN_PERIOD_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE PAYER_PLAN_PERIOD ADD CONSTRAINT fpk_PAYER_PLAN_PERIOD_payer_concept_id FOREIGN KEY (payer_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PAYER_PLAN_PERIOD ADD CONSTRAINT fpk_PAYER_PLAN_PERIOD_payer_source_concept_id FOREIGN KEY (payer_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PAYER_PLAN_PERIOD ADD CONSTRAINT fpk_PAYER_PLAN_PERIOD_plan_concept_id FOREIGN KEY (plan_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PAYER_PLAN_PERIOD ADD CONSTRAINT fpk_PAYER_PLAN_PERIOD_plan_source_concept_id FOREIGN KEY (plan_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PAYER_PLAN_PERIOD ADD CONSTRAINT fpk_PAYER_PLAN_PERIOD_sponsor_concept_id FOREIGN KEY (sponsor_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PAYER_PLAN_PERIOD ADD CONSTRAINT fpk_PAYER_PLAN_PERIOD_sponsor_source_concept_id FOREIGN KEY (sponsor_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PAYER_PLAN_PERIOD ADD CONSTRAINT fpk_PAYER_PLAN_PERIOD_stop_reason_concept_id FOREIGN KEY (stop_reason_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE PAYER_PLAN_PERIOD ADD CONSTRAINT fpk_PAYER_PLAN_PERIOD_stop_reason_source_concept_id FOREIGN KEY (stop_reason_source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE COST ADD CONSTRAINT fpk_COST_cost_domain_id FOREIGN KEY (cost_domain_id) REFERENCES DOMAIN (DOMAIN_ID); +ALTER TABLE COST ADD CONSTRAINT fpk_COST_cost_type_concept_id FOREIGN KEY (cost_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE COST ADD CONSTRAINT fpk_COST_currency_concept_id FOREIGN KEY (currency_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE COST ADD CONSTRAINT fpk_COST_revenue_code_concept_id FOREIGN KEY (revenue_code_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE COST ADD CONSTRAINT fpk_COST_drg_concept_id FOREIGN KEY (drg_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DRUG_ERA ADD CONSTRAINT fpk_DRUG_ERA_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE DRUG_ERA ADD CONSTRAINT fpk_DRUG_ERA_drug_concept_id FOREIGN KEY (drug_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DOSE_ERA ADD CONSTRAINT fpk_DOSE_ERA_person_id FOREIGN KEY (person_id) REFERENCES PERSON (PERSON_ID); +ALTER TABLE DOSE_ERA ADD CONSTRAINT fpk_DOSE_ERA_drug_concept_id FOREIGN KEY (drug_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DOSE_ERA ADD CONSTRAINT fpk_DOSE_ERA_unit_concept_id FOREIGN KEY (unit_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONDITION_ERA ADD CONSTRAINT fpk_CONDITION_ERA_condition_concept_id FOREIGN KEY (condition_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE METADATA ADD CONSTRAINT fpk_METADATA_metadata_concept_id FOREIGN KEY (metadata_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE METADATA ADD CONSTRAINT fpk_METADATA_metadata_type_concept_id FOREIGN KEY (metadata_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE METADATA ADD CONSTRAINT fpk_METADATA_value_as_concept_id FOREIGN KEY (value_as_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONCEPT ADD CONSTRAINT fpk_CONCEPT_domain_id FOREIGN KEY (domain_id) REFERENCES DOMAIN (DOMAIN_ID); +ALTER TABLE CONCEPT ADD CONSTRAINT fpk_CONCEPT_vocabulary_id FOREIGN KEY (vocabulary_id) REFERENCES VOCABULARY (VOCABULARY_ID); +ALTER TABLE CONCEPT ADD CONSTRAINT fpk_CONCEPT_concept_class_id FOREIGN KEY (concept_class_id) REFERENCES CONCEPT_CLASS (CONCEPT_CLASS_ID); +ALTER TABLE VOCABULARY ADD CONSTRAINT fpk_VOCABULARY_vocabulary_concept_id FOREIGN KEY (vocabulary_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DOMAIN ADD CONSTRAINT fpk_DOMAIN_domain_concept_id FOREIGN KEY (domain_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONCEPT_CLASS ADD CONSTRAINT fpk_CONCEPT_CLASS_concept_class_concept_id FOREIGN KEY (concept_class_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONCEPT_RELATIONSHIP ADD CONSTRAINT fpk_CONCEPT_RELATIONSHIP_concept_id_1 FOREIGN KEY (concept_id_1) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONCEPT_RELATIONSHIP ADD CONSTRAINT fpk_CONCEPT_RELATIONSHIP_concept_id_2 FOREIGN KEY (concept_id_2) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONCEPT_RELATIONSHIP ADD CONSTRAINT fpk_CONCEPT_RELATIONSHIP_relationship_id FOREIGN KEY (relationship_id) REFERENCES RELATIONSHIP (RELATIONSHIP_ID); +ALTER TABLE RELATIONSHIP ADD CONSTRAINT fpk_RELATIONSHIP_relationship_concept_id FOREIGN KEY (relationship_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONCEPT_SYNONYM ADD CONSTRAINT fpk_CONCEPT_SYNONYM_concept_id FOREIGN KEY (concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONCEPT_SYNONYM ADD CONSTRAINT fpk_CONCEPT_SYNONYM_language_concept_id FOREIGN KEY (language_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONCEPT_ANCESTOR ADD CONSTRAINT fpk_CONCEPT_ANCESTOR_ancestor_concept_id FOREIGN KEY (ancestor_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE CONCEPT_ANCESTOR ADD CONSTRAINT fpk_CONCEPT_ANCESTOR_descendant_concept_id FOREIGN KEY (descendant_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE SOURCE_TO_CONCEPT_MAP ADD CONSTRAINT fpk_SOURCE_TO_CONCEPT_MAP_source_concept_id FOREIGN KEY (source_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE SOURCE_TO_CONCEPT_MAP ADD CONSTRAINT fpk_SOURCE_TO_CONCEPT_MAP_target_concept_id FOREIGN KEY (target_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE SOURCE_TO_CONCEPT_MAP ADD CONSTRAINT fpk_SOURCE_TO_CONCEPT_MAP_target_vocabulary_id FOREIGN KEY (target_vocabulary_id) REFERENCES VOCABULARY (VOCABULARY_ID); +ALTER TABLE DRUG_STRENGTH ADD CONSTRAINT fpk_DRUG_STRENGTH_drug_concept_id FOREIGN KEY (drug_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DRUG_STRENGTH ADD CONSTRAINT fpk_DRUG_STRENGTH_ingredient_concept_id FOREIGN KEY (ingredient_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DRUG_STRENGTH ADD CONSTRAINT fpk_DRUG_STRENGTH_amount_unit_concept_id FOREIGN KEY (amount_unit_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DRUG_STRENGTH ADD CONSTRAINT fpk_DRUG_STRENGTH_numerator_unit_concept_id FOREIGN KEY (numerator_unit_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE DRUG_STRENGTH ADD CONSTRAINT fpk_DRUG_STRENGTH_denominator_unit_concept_id FOREIGN KEY (denominator_unit_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE COHORT_DEFINITION ADD CONSTRAINT fpk_COHORT_DEFINITION_definition_type_concept_id FOREIGN KEY (definition_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE COHORT_DEFINITION ADD CONSTRAINT fpk_COHORT_DEFINITION_subject_concept_id FOREIGN KEY (subject_concept_id) REFERENCES CONCEPT (CONCEPT_ID); +ALTER TABLE ATTRIBUTE_DEFINITION ADD CONSTRAINT fpk_ATTRIBUTE_DEFINITION_attribute_type_concept_id FOREIGN KEY (attribute_type_concept_id) REFERENCES CONCEPT (CONCEPT_ID); \ No newline at end of file diff --git a/inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_ddl.sql b/inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_ddl.sql new file mode 100644 index 0000000..5770d5b --- /dev/null +++ b/inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_ddl.sql @@ -0,0 +1,475 @@ +--USE DATABASE snowflake54; + +--CREATE OR REPLACE SCHEMA cdm54; + +--snowflake CDM DDL Specification for OMOP Common Data Model 5.4 + +CREATE TABLE PERSON ( + person_id integer NOT NULL, + gender_concept_id integer NOT NULL, + year_of_birth integer NOT NULL, + month_of_birth integer NULL, + day_of_birth integer NULL, + birth_datetime TIMESTAMP 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 ); + +CREATE TABLE OBSERVATION_PERIOD ( + observation_period_id integer NOT NULL, + person_id integer NOT NULL, + observation_period_start_date date NOT NULL, + observation_period_end_date date NOT NULL, + period_type_concept_id integer NOT NULL ); + +CREATE TABLE VISIT_OCCURRENCE ( + visit_occurrence_id integer NOT NULL, + person_id integer NOT NULL, + visit_concept_id integer NOT NULL, + visit_start_date date NOT NULL, + visit_start_datetime TIMESTAMP NULL, + visit_end_date date NOT NULL, + visit_end_datetime TIMESTAMP NULL, + visit_type_concept_id Integer NOT NULL, + provider_id integer NULL, + care_site_id integer NULL, + visit_source_value varchar(50) NULL, + visit_source_concept_id integer NULL, + admitting_source_concept_id integer NULL, + admitting_source_value varchar(50) NULL, + discharge_to_concept_id integer NULL, + discharge_to_source_value varchar(50) NULL, + preceding_visit_occurrence_id integer NULL ); + +CREATE TABLE VISIT_DETAIL ( + visit_detail_id integer NOT NULL, + person_id integer NOT NULL, + visit_detail_concept_id integer NOT NULL, + visit_detail_start_date date NOT NULL, + visit_detail_start_datetime TIMESTAMP NULL, + visit_detail_end_date date NOT NULL, + visit_detail_end_datetime TIMESTAMP NULL, + visit_detail_type_concept_id integer NOT NULL, + provider_id integer NULL, + care_site_id integer NULL, + visit_detail_source_value varchar(50) NULL, + visit_detail_source_concept_id Integer NULL, + admitting_source_value Varchar(50) NULL, + admitting_source_concept_id Integer NULL, + discharge_to_source_value Varchar(50) NULL, + discharge_to_concept_id integer NULL, + preceding_visit_detail_id integer NULL, + visit_detail_parent_id integer NULL, + visit_occurrence_id integer NOT NULL ); + +CREATE TABLE CONDITION_OCCURRENCE ( + condition_occurrence_id integer NOT NULL, + person_id integer NOT NULL, + condition_concept_id integer NOT NULL, + condition_start_date date NOT NULL, + condition_start_datetime TIMESTAMP NULL, + condition_end_date date NULL, + condition_end_datetime TIMESTAMP 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 ); + +CREATE TABLE DRUG_EXPOSURE ( + drug_exposure_id integer NOT NULL, + person_id integer NOT NULL, + drug_concept_id integer NOT NULL, + drug_exposure_start_date date NOT NULL, + drug_exposure_start_datetime TIMESTAMP NULL, + drug_exposure_end_date date NOT NULL, + drug_exposure_end_datetime TIMESTAMP NULL, + verbatim_end_date date NULL, + drug_type_concept_id integer NOT NULL, + stop_reason varchar(20) NULL, + refills integer NULL, + quantity NUMERIC NULL, + days_supply integer NULL, + sig TEXT 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 ); + +CREATE TABLE PROCEDURE_OCCURRENCE ( + procedure_occurrence_id integer NOT NULL, + person_id integer NOT NULL, + procedure_concept_id integer NOT NULL, + procedure_date date NOT NULL, + procedure_datetime TIMESTAMP 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 ); + +CREATE TABLE DEVICE_EXPOSURE ( + device_exposure_id integer NOT NULL, + person_id integer NOT NULL, + device_concept_id integer NOT NULL, + device_exposure_start_date date NOT NULL, + device_exposure_start_datetime TIMESTAMP NULL, + device_exposure_end_date date NULL, + device_exposure_end_datetime TIMESTAMP 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(50) NULL, + device_source_concept_id integer NULL ); + +CREATE TABLE MEASUREMENT ( + measurement_id integer NOT NULL, + person_id integer NOT NULL, + measurement_concept_id integer NOT NULL, + measurement_date date NOT NULL, + measurement_datetime TIMESTAMP NULL, +-- measurement_time varchar(10) NULL, + measurement_type_concept_id integer NOT NULL, + operator_concept_id integer NULL, + value_as_number NUMERIC NULL, + value_as_concept_id integer NULL, + unit_concept_id integer NULL, + range_low NUMERIC NULL, + range_high NUMERIC 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 ); + +CREATE TABLE OBSERVATION ( + observation_id integer NOT NULL, + person_id integer NOT NULL, + observation_concept_id integer NOT NULL, + observation_date date NOT NULL, + observation_datetime TIMESTAMP NULL, + observation_type_concept_id integer NOT NULL, + value_as_number NUMERIC 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 integer NULL, + visit_detail_id integer 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 ); + +CREATE TABLE DEATH ( + person_id integer NOT NULL, + death_date date NOT NULL, + death_datetime TIMESTAMP NULL, + death_type_concept_id integer NULL, + cause_concept_id integer NULL, + cause_source_value varchar(50) NULL, + cause_source_concept_id integer NULL ); + +CREATE TABLE NOTE ( + note_id integer NOT NULL, + person_id integer NOT NULL, + note_date date NOT NULL, + note_datetime TIMESTAMP NULL, + note_type_concept_id integer NOT NULL, + note_class_concept_id integer NOT NULL, + note_title varchar(250) NULL, + note_text TEXT NOT 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 ); + +CREATE TABLE NOTE_NLP ( + note_nlp_id integer NOT NULL, + note_id integer NOT NULL, + section_concept_id integer NULL, + snippet varchar(250) NULL, + "offset" varchar(50) NULL, + lexical_variant varchar(250) NOT NULL, + note_nlp_concept_id integer NULL, + note_nlp_source_concept_id integer NULL, + nlp_system varchar(250) NULL, + nlp_date date NOT NULL, + nlp_datetime TIMESTAMP NULL, + term_exists varchar(1) NULL, + term_temporal varchar(50) NULL, + term_modifiers varchar(2000) NULL ); + +CREATE TABLE SPECIMEN ( + specimen_id integer NOT NULL, + person_id integer NOT NULL, + specimen_concept_id integer NOT NULL, + specimen_type_concept_id integer NOT NULL, + specimen_date date NOT NULL, + specimen_datetime TIMESTAMP NULL, + quantity NUMERIC 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 ); + +CREATE TABLE FACT_RELATIONSHIP ( + domain_concept_id_1 integer NOT NULL, + fact_id_1 integer NOT NULL, + domain_concept_id_2 integer NOT NULL, + fact_id_2 integer NOT NULL, + relationship_concept_id integer NOT NULL ); + +CREATE TABLE LOCATION ( + location_id integer 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, + location_source_value varchar(50) NULL ); + +CREATE TABLE CARE_SITE ( + care_site_id integer NOT NULL, + care_site_name varchar(255) NULL, + place_of_service_concept_id integer NULL, + location_id integer NULL, + care_site_source_value varchar(50) NULL, + place_of_service_source_value varchar(50) NULL ); + +CREATE TABLE PROVIDER ( + provider_id integer NOT NULL, + provider_name varchar(255) NULL, + npi varchar(20) NULL, + dea varchar(20) NULL, + specialty_concept_id integer NULL, + care_site_id integer 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 ); + +CREATE TABLE PAYER_PLAN_PERIOD ( + payer_plan_period_id integer NOT NULL, + person_id integer NOT NULL, + payer_plan_period_start_date date NOT NULL, + payer_plan_period_end_date date NOT NULL, + payer_concept_id integer NULL, + payer_source_value varchar(50) NULL, + payer_source_concept_id integer NULL, + plan_concept_id integer NULL, + plan_source_value varchar(50) NULL, + plan_source_concept_id integer NULL, + sponsor_concept_id integer NULL, + sponsor_source_value varchar(50) NULL, + sponsor_source_concept_id integer NULL, + family_source_value varchar(50) NULL, + stop_reason_concept_id integer NULL, + stop_reason_source_value varchar(50) NULL, + stop_reason_source_concept_id integer NULL ); + +CREATE TABLE COST ( + cost_id integer NOT NULL, + cost_event_id integer NOT NULL, + cost_domain_id varchar(20) NOT NULL, + cost_type_concept_id integer NOT NULL, + currency_concept_id integer NULL, + total_charge NUMERIC NULL, + total_cost NUMERIC NULL, + total_paid NUMERIC NULL, + paid_by_payer NUMERIC NULL, + paid_by_patient NUMERIC NULL, + paid_patient_copay NUMERIC NULL, + paid_patient_coinsurance NUMERIC NULL, + paid_patient_deductible NUMERIC NULL, + paid_by_primary NUMERIC NULL, + paid_ingredient_cost NUMERIC NULL, + paid_dispensing_fee NUMERIC NULL, + payer_plan_period_id integer NULL, + amount_allowed NUMERIC NULL, + revenue_code_concept_id integer NULL, +-- revenue_code_source_value varchar(50) NULL, + drg_concept_id integer NULL, + drg_source_value varchar(3) NULL ); + +CREATE TABLE DRUG_ERA ( + drug_era_id integer NOT NULL, + person_id integer NOT NULL, + drug_concept_id integer NOT NULL, + drug_era_start_date TIMESTAMP NOT NULL, + drug_era_end_date TIMESTAMP NOT NULL, + drug_exposure_count integer NULL, + gap_days integer NULL ); + +CREATE TABLE DOSE_ERA ( + dose_era_id integer NOT NULL, + person_id integer NOT NULL, + drug_concept_id integer NOT NULL, + unit_concept_id integer NOT NULL, + dose_value NUMERIC NOT NULL, + dose_era_start_date TIMESTAMP NOT NULL, + dose_era_end_date TIMESTAMP NOT NULL ); + +CREATE TABLE CONDITION_ERA ( + condition_era_id integer NOT NULL, + person_id integer NOT NULL, + condition_concept_id integer NOT NULL, + condition_era_start_date TIMESTAMP NOT NULL, + condition_era_end_date TIMESTAMP NOT NULL, + condition_occurrence_count integer NULL ); + +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(250) NULL, + value_as_concept_id integer NULL, + metadata_date date NULL, + metadata_datetime TIMESTAMP NULL ); + +CREATE TABLE CDM_SOURCE ( + cdm_source_name varchar(255) NOT NULL, + cdm_source_abbreviation varchar(25) NULL, + cdm_holder varchar(255) NULL, + source_description TEXT 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 ); + +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 ); + +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) NULL, + vocabulary_concept_id integer NOT NULL ); + +CREATE TABLE DOMAIN ( + domain_id varchar(20) NOT NULL, + domain_name varchar(255) NOT NULL, + domain_concept_id integer NOT NULL ); + +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 ); + +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 ); + +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 ); + +CREATE TABLE CONCEPT_SYNONYM ( + concept_id integer NOT NULL, + concept_synonym_name varchar(1000) NOT NULL, + language_concept_id integer NOT NULL ); + +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 ); + +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 ); + +CREATE TABLE DRUG_STRENGTH ( + drug_concept_id integer NOT NULL, + ingredient_concept_id integer NOT NULL, + amount_value NUMERIC NULL, + amount_unit_concept_id integer NULL, + numerator_value NUMERIC NULL, + numerator_unit_concept_id integer NULL, + denominator_value NUMERIC 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 ); + +CREATE TABLE COHORT_DEFINITION ( + cohort_definition_id integer NOT NULL, + cohort_definition_name varchar(255) NOT NULL, + cohort_definition_description TEXT NULL, + definition_type_concept_id integer NOT NULL, + cohort_definition_syntax TEXT NULL, + subject_concept_id integer NOT NULL, + cohort_initiation_date date NULL ); + +CREATE TABLE ATTRIBUTE_DEFINITION ( + attribute_definition_id integer NOT NULL, + attribute_name varchar(255) NOT NULL, + attribute_description TEXT NULL, + attribute_type_concept_id integer NOT NULL, + attribute_syntax TEXT NULL ); diff --git a/inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_indices.sql b/inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_indices.sql new file mode 100644 index 0000000..09de8a4 --- /dev/null +++ b/inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_indices.sql @@ -0,0 +1 @@ +-- snowflake does not support indexes diff --git a/inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_primary_keys.sql b/inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_primary_keys.sql new file mode 100644 index 0000000..a158630 --- /dev/null +++ b/inst/ddl/5.4/snowflake/OMOPCDM_snowflake_5.4_primary_keys.sql @@ -0,0 +1,26 @@ +ALTER TABLE PERSON ADD CONSTRAINT xpk_PERSON PRIMARY KEY (person_id); +ALTER TABLE OBSERVATION_PERIOD ADD CONSTRAINT xpk_OBSERVATION_PERIOD PRIMARY KEY (observation_period_id); +ALTER TABLE VISIT_OCCURRENCE ADD CONSTRAINT xpk_VISIT_OCCURRENCE PRIMARY KEY (visit_occurrence_id); +ALTER TABLE VISIT_DETAIL ADD CONSTRAINT xpk_VISIT_DETAIL PRIMARY KEY (visit_detail_id); +ALTER TABLE CONDITION_OCCURRENCE ADD CONSTRAINT xpk_CONDITION_OCCURRENCE PRIMARY KEY (condition_occurrence_id); +ALTER TABLE DRUG_EXPOSURE ADD CONSTRAINT xpk_DRUG_EXPOSURE PRIMARY KEY (drug_exposure_id); +ALTER TABLE PROCEDURE_OCCURRENCE ADD CONSTRAINT xpk_PROCEDURE_OCCURRENCE PRIMARY KEY (procedure_occurrence_id); +ALTER TABLE DEVICE_EXPOSURE ADD CONSTRAINT xpk_DEVICE_EXPOSURE PRIMARY KEY (device_exposure_id); +ALTER TABLE MEASUREMENT ADD CONSTRAINT xpk_MEASUREMENT PRIMARY KEY (measurement_id); +ALTER TABLE OBSERVATION ADD CONSTRAINT xpk_OBSERVATION PRIMARY KEY (observation_id); +ALTER TABLE NOTE ADD CONSTRAINT xpk_NOTE PRIMARY KEY (note_id); +ALTER TABLE NOTE_NLP ADD CONSTRAINT xpk_NOTE_NLP PRIMARY KEY (note_nlp_id); +ALTER TABLE SPECIMEN ADD CONSTRAINT xpk_SPECIMEN PRIMARY KEY (specimen_id); +ALTER TABLE LOCATION ADD CONSTRAINT xpk_LOCATION PRIMARY KEY (location_id); +ALTER TABLE CARE_SITE ADD CONSTRAINT xpk_CARE_SITE PRIMARY KEY (care_site_id); +ALTER TABLE PROVIDER ADD CONSTRAINT xpk_PROVIDER PRIMARY KEY (provider_id); +ALTER TABLE PAYER_PLAN_PERIOD ADD CONSTRAINT xpk_PAYER_PLAN_PERIOD PRIMARY KEY (payer_plan_period_id); +ALTER TABLE COST ADD CONSTRAINT xpk_COST PRIMARY KEY (cost_id); +ALTER TABLE DRUG_ERA ADD CONSTRAINT xpk_DRUG_ERA PRIMARY KEY (drug_era_id); +ALTER TABLE DOSE_ERA ADD CONSTRAINT xpk_DOSE_ERA PRIMARY KEY (dose_era_id); +ALTER TABLE CONDITION_ERA ADD CONSTRAINT xpk_CONDITION_ERA PRIMARY KEY (condition_era_id); +ALTER TABLE CONCEPT ADD CONSTRAINT xpk_CONCEPT PRIMARY KEY (concept_id); +ALTER TABLE VOCABULARY ADD CONSTRAINT xpk_VOCABULARY PRIMARY KEY (vocabulary_id); +ALTER TABLE DOMAIN ADD CONSTRAINT xpk_DOMAIN PRIMARY KEY (domain_id); +ALTER TABLE CONCEPT_CLASS ADD CONSTRAINT xpk_CONCEPT_CLASS PRIMARY KEY (concept_class_id); +ALTER TABLE RELATIONSHIP ADD CONSTRAINT xpk_RELATIONSHIP PRIMARY KEY (relationship_id); \ No newline at end of file