From 2456c66c628ba80df6ce054b8ea78dac8f9935f0 Mon Sep 17 00:00:00 2001 From: AnthonyMolinaro <31700317+AnthonyMolinaro@users.noreply.github.com> Date: Thu, 6 Jan 2022 16:08:16 -0500 Subject: [PATCH] CDM v5.3 to v5.4 conversion scripts, initial commit --- extras/v53_v54_conversion/README.txt | 13 ++ .../v53_v54_conversion/bigquery_migration.sql | 188 ++++++++++++++++++ .../v53_v54_conversion/impala_migration.sql | 176 ++++++++++++++++ .../v53_v54_conversion/netezza_migration.sql | 176 ++++++++++++++++ .../v53_v54_conversion/oracle_migration.sql | 179 +++++++++++++++++ .../postgresql_migration.sql | 175 ++++++++++++++++ .../v53_v54_conversion/redshift_migration.sql | 176 ++++++++++++++++ .../sqlserver_migration.sql | 179 +++++++++++++++++ 8 files changed, 1262 insertions(+) create mode 100644 extras/v53_v54_conversion/README.txt create mode 100644 extras/v53_v54_conversion/bigquery_migration.sql create mode 100644 extras/v53_v54_conversion/impala_migration.sql create mode 100644 extras/v53_v54_conversion/netezza_migration.sql create mode 100644 extras/v53_v54_conversion/oracle_migration.sql create mode 100644 extras/v53_v54_conversion/postgresql_migration.sql create mode 100644 extras/v53_v54_conversion/redshift_migration.sql create mode 100644 extras/v53_v54_conversion/sqlserver_migration.sql diff --git a/extras/v53_v54_conversion/README.txt b/extras/v53_v54_conversion/README.txt new file mode 100644 index 0000000..f621330 --- /dev/null +++ b/extras/v53_v54_conversion/README.txt @@ -0,0 +1,13 @@ + +README +------ + +v5.3 to v5.4 CDM conversion + +NOTES +----- + +The *_v53_to_v54_migration.sql scripts are SQL scripts that migrate a v5.3 CDM to a v5.4 CDM. +The changes implemented are found here: http://ohdsi.github.io/CommonDataModel/cdm54Changes.html. +Please replace @cdmDatabaseSchema with your schema name. +Links to database documentation are included in each script to facilitate debugging. \ No newline at end of file diff --git a/extras/v53_v54_conversion/bigquery_migration.sql b/extras/v53_v54_conversion/bigquery_migration.sql new file mode 100644 index 0000000..757629c --- /dev/null +++ b/extras/v53_v54_conversion/bigquery_migration.sql @@ -0,0 +1,188 @@ +-- http://ohdsi.github.io/CommonDataModel/cdm54Changes.html +-- BigQuery SQL references: +-- https://cloud.google.com/bigquery/docs/reference/standard-sql/data-definition-language#creating_a_new_table_from_an_existing_table +-- https://cloud.google.com/bigquery/docs/manually-changing-schemas +-- https://cloud.google.com/bigquery/docs/reference/standard-sql/data-definition-language#alter_column_set_data_type_statement +-- https://cloud.google.com/bigquery/docs/managing-tables#renaming-table +-- + +-- VISIT_OCCURRENCE +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value + +alter table @cdmDatabaseSchema.visit_occurrence rename to visit_occurrence_old; +create table @cdmDatabaseSchema.visit_occurrence +as +select * EXCEPT(admitting_source_concept_id,admitting_source_value,discharge_to_concept_id,discharge_to_source_value), + admitting_source_concept_id as admitted_from_concept_id, + admitting_source_value as admitted_from_source_value, + discharge_to_concept_id as discharged_to_concept_id, + discharge_to_source_value as discharged_to_source_value +from visit_occurrence_old; + +-- +-- VISIT_DETAIL +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value +-- visit_detail_parent_id -> parent_visit_detail_id + +alter table @cdmDatabaseSchema.visit_detail rename to visit_detail_old; +create table @cdmDatabaseSchema.visit_occurrence +as +select * EXCEPT(admitting_source_concept_id,admitting_source_value,discharge_to_concept_id,discharge_to_source_value,visit_detail_parent_id), + admitting_source_concept_id as admitted_from_concept_id, + admitting_source_value as admitted_from_source_value, + discharge_to_concept_id as discharged_to_concept_id, + discharge_to_source_value as discharged_to_source_value, + visit_detail_parent_id as parent_visit_detail_id +from visit_detail_old; + +-- PROCEDURE_OCCURRENCE +-- + Procedure_end_date +-- + Procedure_end_datetime + +alter table @cdmDatabaseSchema.procedure_occurrence add column procedure_end_date date; +alter table @cdmDatabaseSchema.procedure_occurrence add column procedure_end_datetime datetime; + +-- DEVICE_EXPOSURE +-- Unique_device_id -> Changed to varchar(255) (already a STRING on bigquery) +-- + Production_id +-- + Unit_concept_id +-- + Unit_source_value +-- + Unit_source_concept_id + +alter table @cdmDatabaseSchema.device_exposure add column production_id int64; +alter table @cdmDatabaseSchema.device_exposure add column unit_concept_id int64; +alter table @cdmDatabaseSchema.device_exposure add column unit_source_value string; +alter table @cdmDatabaseSchema.device_exposure add column unit_source_concept_id int64; + +-- MEASUREMENT +-- + Unit_source_concept_id +-- + Measurement_event_id +-- + Meas_event_field_concept_id + +alter table @cdmDatabaseSchema.measurement add column unit_source_id int64; +alter table @cdmDatabaseSchema.measurement add column measurement_event_id int64; +alter table @cdmDatabaseSchema.measurement add column meas_event_field_concept_id int64; + +-- OBSERVATION +-- + Value_source_value +-- + Observation_event_id +-- + Obs_event_field_concept_id + +alter table @cdmDatabaseSchema.observation add column value_source_value string; +alter table @cdmDatabaseSchema.observation add column observation_event_id int64; +alter table @cdmDatabaseSchema.observation add column obs_event_field_concept_id int64; + +-- NOTE +-- + Note_event_id +-- + Note_event_field_concept_id + +alter table @cdmDatabaseSchema.note add column note_event_id int64; +alter table @cdmDatabaseSchema.note add column note_event_field_concept_id int64; + +-- LOCATION +-- + Country_concept_id +-- + Country_source_value +-- + Latitude +-- + Longitude + +alter table @cdmDatabaseSchema.location add column country_concept_id int64; +alter table @cdmDatabaseSchema.location add column country_source_value string; +alter table @cdmDatabaseSchema.location add column latitude float64; +alter table @cdmDatabaseSchema.location add column longitude float64; + +-- EPISODE +create table @cdmDatabaseSchema.episode ( + episode_id INT64 not null, + person_id INT64 not null, + episode_concept_id INT64 not null, + episode_start_date date not null, + episode_start_datetime datetime null, + episode_end_date date null, + episode_end_datetime datetime null, + episode_parent_id INT64, + episode_number INT64, + episode_object_concept_id INT64 not null, + episode_type_concept_id INT64 not null, + episode_source_value STRING, + episode_source_concept_id INT64 ); + +-- EPISODE_EVENT +CREATE TABLE @cdmDatabaseSchema.EPISODE_EVENT ( + episode_id int64 NOT NULL, + event_id int64 NOT NULL, + episode_event_field_concept_id int64 NOT NULL ); + + +-- METADATA +-- + Metadata_id +-- + Value_as_number + +alter table @cdmDatabaseSchema.metadata add column metadata_id int64; +alter table @cdmDatabaseSchema.metadata add column value_as_number float64; + +-- CDM_SOURCE +-- Cdm_source_name -> Mandatory field +-- Cdm_source_abbreviation -> Mandatory field +-- Cdm_holder -> Mandatory field +-- Source_release_date -> Mandatory field +-- Cdm_release_date -> Mandatory field +-- + Cdm_version_concept_id + +alter table @cdmDatabaseSchema.cdm_source rename to cdm_source_v53; + +CREATE TABLE @cdmDatabaseSchema.cdm_source ( + cdm_source_name string NOT NULL, + cdm_source_abbreviation string NOT NULL, + cdm_holder string NOT NULL, + source_description string NULL, + source_documentation_reference string NULL, + cdm_etl_reference string NULL, + source_release_date datetime NOT NULL, + cdm_release_date datetime NOT NULL, + cdm_version string NULL, + cdm_version_concept_id int64 NOT NULL, + vocabulary_version string NOT NULL ); + +insert into @cdmDatabaseSchema.cdm_source +select cdm_source_name,cdm_source_abbreviation,cdm_holder, + source_description,source_documentation_reference,cdm_etl_reference, + source_release_date,cdm_release_date,'5.4', + 756265,vocabulary_version +from @cdmDatabaseSchema.cdm_source_v53; + + +-- VOCABULARY +-- Vocabulary_reference -> Non-mandatory field +-- Vocabulary_version -> Non-mandatory field +alter table @cdmDatabaseSchema.vocabulary rename to vocabulary_v53; + +CREATE TABLE @cdmDatabaseSchema.vocabulary ( + vocabulary_id string NOT NULL, + vocabulary_name string NOT NULL, + vocabulary_reference string NULL, + vocabulary_version string NULL, + vocabulary_concept_id int64 NOT NULL ); + +insert into @cdmDatabaseSchema.vocabulary +select vocabulary_id,vocabulary_name,vocabulary_reference, + vocabulary_version, vocabulary_concept_id +from @cdmDatabaseSchema.vocabulary_v53; + + +-- ATTRIBUTE_DEFINITION +drop table @cdmDatabaseSchema.attribute_definition; + +-- COHORT +CREATE TABLE @cdmDatabaseSchema.cohort ( + cohort_definition_id int64 NOT NULL, + subject_id int64 NOT NULL, + cohort_start_date datetime NOT NULL, + cohort_end_date datetime NOT NULL ); + + diff --git a/extras/v53_v54_conversion/impala_migration.sql b/extras/v53_v54_conversion/impala_migration.sql new file mode 100644 index 0000000..f7fc26e --- /dev/null +++ b/extras/v53_v54_conversion/impala_migration.sql @@ -0,0 +1,176 @@ +-- http://ohdsi.github.io/CommonDataModel/cdm54Changes.html +-- Impala SQL references: +-- https://docs.cloudera.com/documentation/enterprise/6/6.3/topics/impala_alter_table.html +-- +-- VISIT_OCCURRENCE +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value + +alter table @cdmDatabaseSchema.visit_occurrence change admitting_source_concept_id admitted_from_concept_id int; +alter table @cdmDatabaseSchema.visit_occurrence change admitting_source_value admitted_from_source_value int; +alter table @cdmDatabaseSchema.visit_occurrence change discharge_to_concept_id discharged_to_concept_id int; +alter table @cdmDatabaseSchema.visit_occurrence change discharge_to_source_value discharged_to_source_value int; + +-- +-- VISIT_DETAIL +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value +-- visit_detail_parent_id -> parent_visit_detail_id + +alter table @cdmDatabaseSchema.visit_detail change admitting_source_concept_id admitted_from_concept_id int; +alter table @cdmDatabaseSchema.visit_detail change admitting_source_value admitted_from_source_value int; +alter table @cdmDatabaseSchema.visit_detail change discharge_to_concept_id discharged_to_concept_id int; +alter table @cdmDatabaseSchema.visit_detail change discharge_to_source_value discharged_to_source_value int; +alter table @cdmDatabaseSchema.visit_detail change visit_detail_parent_id parent_visit_detail_id int; + +-- PROCEDURE_OCCURRENCE +-- + Procedure_end_date +-- + Procedure_end_datetime + +alter table @cdmDatabaseSchema.procedure_occurrence add columns (procedure_end_date timestamp); +alter table @cdmDatabaseSchema.procedure_occurrence add columns (procedure_end_datetime timestamp); + +-- DEVICE_EXPOSURE +-- Unique_device_id -> Changed to varchar(255) +-- + Production_id +-- + Unit_concept_id +-- + Unit_source_value +-- + Unit_source_concept_id + +alter table @cdmDatabaseSchema.device_exposure change unique_device_id unique_device_id varchar(300); +alter table @cdmDatabaseSchema.device_exposure add columns (production_id int); +alter table @cdmDatabaseSchema.device_exposure add columns (unit_concept_id int); +alter table @cdmDatabaseSchema.device_exposure add columns (unit_source_value int); +alter table @cdmDatabaseSchema.device_exposure add columns (unit_source_concept_id int); + +-- MEASUREMENT +-- + Unit_source_concept_id +-- + Measurement_event_id +-- + Meas_event_field_concept_id + +alter table @cdmDatabaseSchema.measurement add columns (unit_source_id int); +alter table @cdmDatabaseSchema.measurement add columns (measurement_event_id int); +alter table @cdmDatabaseSchema.measurement add columns (meas_event_field_concept_id int); + +-- OBSERVATION +-- + Value_source_value +-- + Observation_event_id +-- + Obs_event_field_concept_id + +alter table @cdmDatabaseSchema.observation add columns (value_source_value varchar(50)); +alter table @cdmDatabaseSchema.observation add columns (observation_event_id int); +alter table @cdmDatabaseSchema.observation add columns (obs_event_field_concept_id int); + +-- NOTE +-- + Note_event_id +-- + Note_event_field_concept_id + +alter table @cdmDatabaseSchema.note add columns (note_event_id int); +alter table @cdmDatabaseSchema.note add columns (note_event_field_concept_id int); + +-- LOCATION +-- + Country_concept_id +-- + Country_source_value +-- + Latitude +-- + Longitude + +alter table @cdmDatabaseSchema.location add columns (country_concept_id int); +alter table @cdmDatabaseSchema.location add columns (country_source_value varchar(80)); +alter table @cdmDatabaseSchema.location add columns (latitude float); +alter table @cdmDatabaseSchema.location add columns (longitude float); + +-- EPISODE +CREATE TABLE @cdmDatabaseSchema.EPISODE ( + episode_id int, + person_id int, + episode_concept_id int, + episode_start_date timestamp, + episode_start_datetime TIMESTAMP, + episode_end_date timestamp, + episode_end_datetime timestamp, + episode_parent_id int, + episode_number int, + episode_object_concept_id int, + episode_type_concept_id int, + episode_source_value varchar(50), + episode_source_concept_id int ); + +-- EPISODE_EVENT +CREATE TABLE @cdmDatabaseSchema.EPISODE_EVENT ( + episode_id int, + event_id int, + episode_event_field_concept_id int ); + + +-- METADATA +-- + Metadata_id +-- + Value_as_number + +alter table @cdmDatabaseSchema.metadata add columns (metadata_id int); +alter table @cdmDatabaseSchema.metadata add columns (value_as_number float); + +-- CDM_SOURCE +-- Cdm_source_name -> Mandatory field +-- Cdm_source_abbreviation -> Mandatory field +-- Cdm_holder -> Mandatory field +-- Source_release_date -> Mandatory field +-- Cdm_release_date -> Mandatory field +-- + Cdm_version_concept_id + +alter table @cdmDatabaseSchema.cdm_source rename to cdm_source_v53; + +CREATE TABLE @cdmDatabaseSchema.cdm_source ( + cdm_source_name varchar(255), + cdm_source_abbreviation varchar(25), + cdm_holder varchar(255), + source_description varchar(max), + source_documentation_reference varchar(255), + cdm_etl_reference varchar(255), + source_release_date timestamp, + cdm_release_date timestamp, + cdm_version varchar(10), + cdm_version_concept_id int, + vocabulary_version varchar(20)); + +insert into @cdmDatabaseSchema.cdm_source +select cdm_source_name,cdm_source_abbreviation,cdm_holder, + source_description,source_documentation_reference,cdm_etl_reference, + source_release_date,cdm_release_date,'5.4', + 756265,vocabulary_version +from @cdmDatabaseSchema.cdm_source_v53; + + +-- VOCABULARY +-- Vocabulary_reference -> Non-mandatory field +-- Vocabulary_version -> Non-mandatory field + +alter table @cdmDatabaseSchema.vocabulary rename to vocabulary_v53; + +CREATE TABLE @cdmDatabaseSchema.vocabulary ( + vocabulary_id varchar(20), + vocabulary_name varchar(255), + vocabulary_reference varchar(255), + vocabulary_version varchar(255), + vocabulary_concept_id int ); + +insert into @cdmDatabaseSchema.vocabulary +select vocabulary_id,vocabulary_name,vocabulary_reference, + vocabulary_version, vocabulary_concept_id +from @cdmDatabaseSchema.vocabulary_v53; + + +-- ATTRIBUTE_DEFINITION +drop table @cdmDatabaseSchema.attribute_definition; + +-- COHORT +CREATE TABLE @cdmDatabaseSchema.cohort ( + cohort_definition_id int, + subject_id int, + cohort_start_date timestamp, + cohort_end_date timestamp ); + + diff --git a/extras/v53_v54_conversion/netezza_migration.sql b/extras/v53_v54_conversion/netezza_migration.sql new file mode 100644 index 0000000..1af4181 --- /dev/null +++ b/extras/v53_v54_conversion/netezza_migration.sql @@ -0,0 +1,176 @@ +-- http://ohdsi.github.io/CommonDataModel/cdm54Changes.html +-- Netezza SQL references: +-- https://www.ibm.com/docs/en/psfa/7.2.1?topic=reference-alter-table +-- https://www.ibm.com/docs/en/psfa/7.2.1?topic=tables-add-drop-column +-- +-- VISIT_OCCURRENCE +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value + +alter table @cdmDatabaseSchema.visit_occurrence rename column admitting_source_concept_id to admitted_from_concept_id; +alter table @cdmDatabaseSchema.visit_occurrence rename column admitting_source_value to admitted_from_source_value; +alter table @cdmDatabaseSchema.visit_occurrence rename column discharge_to_concept_id to discharged_to_concept_id; +alter table @cdmDatabaseSchema.visit_occurrence rename column discharge_to_source_value to discharged_to_source_value; + +-- +-- VISIT_DETAIL +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value +-- visit_detail_parent_id -> parent_visit_detail_id + +alter table @cdmDatabaseSchema.visit_detail rename column admitting_source_concept_id to admitted_from_concept_id; +alter table @cdmDatabaseSchema.visit_detail rename column admitting_source_value to admitted_from_source_value; +alter table @cdmDatabaseSchema.visit_detail rename column discharge_to_concept_id to discharged_to_concept_id; +alter table @cdmDatabaseSchema.visit_detail rename column discharge_to_source_value to discharged_to_source_value; +alter table @cdmDatabaseSchema.visit_detail rename column visit_detail_parent_id to parent_visit_detail_id; + +-- PROCEDURE_OCCURRENCE +-- + Procedure_end_date +-- + Procedure_end_datetime + +alter table @cdmDatabaseSchema.procedure_occurrence add column procedure_end_date timestamp null; +alter table @cdmDatabaseSchema.procedure_occurrence add column procedure_end_datetime timestamp null; + +-- DEVICE_EXPOSURE +-- Unique_device_id -> Changed to varchar(255) +-- + Production_id +-- + Unit_concept_id +-- + Unit_source_value +-- + Unit_source_concept_id + +alter table @cdmDatabaseSchema.device_exposure modify column (unique_device_id varchar(300); +alter table @cdmDatabaseSchema.device_exposure add column production_id integer null; +alter table @cdmDatabaseSchema.device_exposure add column unit_concept_id integer null; +alter table @cdmDatabaseSchema.device_exposure add column unit_source_value varchar(50) null; +alter table @cdmDatabaseSchema.device_exposure add column unit_source_concept_id integer null; + +-- MEASUREMENT +-- + Unit_source_concept_id +-- + Measurement_event_id +-- + Meas_event_field_concept_id + +alter table @cdmDatabaseSchema.measurement add column unit_source_id integer default null; +alter table @cdmDatabaseSchema.measurement add column measurement_event_id bigint null; +alter table @cdmDatabaseSchema.measurement add column meas_event_field_concept_id integer null; + +-- OBSERVATION +-- + Value_source_value +-- + Observation_event_id +-- + Obs_event_field_concept_id + +alter table @cdmDatabaseSchema.observation add column value_source_value varchar(50) null; +alter table @cdmDatabaseSchema.observation add column observation_event_id bigint null; +alter table @cdmDatabaseSchema.observation add column obs_event_field_concept_id integer null; + +-- NOTE +-- + Note_event_id +-- + Note_event_field_concept_id + +alter table @cdmDatabaseSchema.note add column note_event_id bigint null; +alter table @cdmDatabaseSchema.note add column note_event_field_concept_id integer null; + +-- LOCATION +-- + Country_concept_id +-- + Country_source_value +-- + Latitude +-- + Longitude + +alter table @cdmDatabaseSchema.location add column country_concept_id integer null; +alter table @cdmDatabaseSchema.location add column country_source_value varchar(80) null; +alter table @cdmDatabaseSchema.location add column latitude float null; +alter table @cdmDatabaseSchema.location add column longitude float null; + +-- EPISODE +CREATE TABLE @cdmDatabaseSchema.EPISODE ( + episode_id bigint NOT NULL, + person_id bigint NOT NULL, + episode_concept_id integer NOT NULL, + episode_start_date timestamp NOT NULL, + episode_start_datetime TIMESTAMP NULL, + episode_end_date timestamp NULL, + episode_end_datetime TIMESTAMP NULL, + episode_parent_id bigint NULL, + episode_number integer NULL, + episode_object_concept_id integer NOT NULL, + episode_type_concept_id integer NOT NULL, + episode_source_value varchar(50) NULL, + episode_source_concept_id integer NULL ); + +-- EPISODE_EVENT +CREATE TABLE @cdmDatabaseSchema.EPISODE_EVENT ( + episode_id bigint NOT NULL, + event_id bigint NOT NULL, + episode_event_field_concept_id integer NOT NULL ); + + +-- METADATA +-- + Metadata_id +-- + Value_as_number + +alter table @cdmDatabaseSchema.metadata add column metadata_id integer null; +alter table @cdmDatabaseSchema.metadata add column value_as_number float null; + +-- CDM_SOURCE +-- Cdm_source_name -> Mandatory field +-- Cdm_source_abbreviation -> Mandatory field +-- Cdm_holder -> Mandatory field +-- Source_release_date -> Mandatory field +-- Cdm_release_date -> Mandatory field +-- + Cdm_version_concept_id + +alter table @cdmDatabaseSchema.cdm_source rename to cdm_source_v53; + +CREATE TABLE @cdmDatabaseSchema.cdm_source ( + cdm_source_name varchar(255) NOT NULL, + cdm_source_abbreviation varchar(25) NOT NULL, + cdm_holder varchar(255) NOT NULL, + source_description varchar(1000) NULL, + source_documentation_reference varchar(255) NULL, + cdm_etl_reference varchar(255) NULL, + source_release_date timestamp NOT NULL, + cdm_release_date timestamp NOT NULL, + cdm_version varchar(10) NULL, + cdm_version_concept_id integer NOT NULL, + vocabulary_version varchar(20) NOT NULL ); + +insert into @cdmDatabaseSchema.cdm_source +select cdm_source_name,cdm_source_abbreviation,cdm_holder, + source_description,source_documentation_reference,cdm_etl_reference, + source_release_date,cdm_release_date,'5.4', + 756265,vocabulary_version +from @cdmDatabaseSchema.cdm_source_v53; + + +-- VOCABULARY +-- Vocabulary_reference -> Non-mandatory field +-- Vocabulary_version -> Non-mandatory field +alter table @cdmDatabaseSchema.vocabulary rename to vocabulary_v53; + +CREATE TABLE @cdmDatabaseSchema.vocabulary ( + vocabulary_id varchar(20) NOT NULL, + vocabulary_name varchar(255) NOT NULL, + vocabulary_reference varchar(255) NULL, + vocabulary_version varchar(255) NULL, + vocabulary_concept_id integer NOT NULL ); + +insert into @cdmDatabaseSchema.vocabulary +select vocabulary_id,vocabulary_name,vocabulary_reference, + vocabulary_version, vocabulary_concept_id +from @cdmDatabaseSchema.vocabulary_v53; + + +-- ATTRIBUTE_DEFINITION +drop table @cdmDatabaseSchema.attribute_definition; + +-- COHORT +CREATE TABLE @cdmDatabaseSchema.cohort ( + cohort_definition_id integer NOT NULL, + subject_id integer NOT NULL, + cohort_start_date timestamp NOT NULL, + cohort_end_date timestamp NOT NULL ); + + diff --git a/extras/v53_v54_conversion/oracle_migration.sql b/extras/v53_v54_conversion/oracle_migration.sql new file mode 100644 index 0000000..a195176 --- /dev/null +++ b/extras/v53_v54_conversion/oracle_migration.sql @@ -0,0 +1,179 @@ +-- http://ohdsi.github.io/CommonDataModel/cdm54Changes.html +-- Oracle SQL references: +-- https://docs.oracle.com/en/database/oracle/oracle-database/19/sqlrf/ALTER-TABLE.html#GUID-552E7373-BF93-477D-9DA3-B2C9386F2877 +-- https://docs.oracle.com/en/database/oracle/oracle-database/19/sqlrf/Data-Types.html#GUID-0DC7FFAA-F03F-4448-8487-F2592496A510 +-- https://docs.oracle.com/en/database/oracle/oracle-database/19/sqlrf/RENAME.html#GUID-573347CE-3EB8-42E5-B4D5-EF71CA06FAFC +-- +-- VISIT_OCCURRENCE +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value + +alter table @cdmDatabaseSchema.visit_occurrence rename column admitting_source_concept_id to admitted_from_concept_id; +alter table @cdmDatabaseSchema.visit_occurrence rename column admitting_source_value to admitted_from_source_value; +alter table @cdmDatabaseSchema.visit_occurrence rename column discharge_to_concept_id to discharged_to_concept_id; +alter table @cdmDatabaseSchema.visit_occurrence rename column discharge_to_source_value to discharged_to_source_value; + +-- +-- VISIT_DETAIL +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value +-- visit_detail_parent_id -> parent_visit_detail_id + +alter table @cdmDatabaseSchema.visit_detail rename column admitting_source_concept_id to admitted_from_concept_id; +alter table @cdmDatabaseSchema.visit_detail rename column admitting_source_value to admitted_from_source_value; +alter table @cdmDatabaseSchema.visit_detail rename column discharge_to_concept_id to discharged_to_concept_id; +alter table @cdmDatabaseSchema.visit_detail rename column discharge_to_source_value to discharged_to_source_value; +alter table @cdmDatabaseSchema.visit_detail rename column visit_detail_parent_id to parent_visit_detail_id; + +-- PROCEDURE_OCCURRENCE +-- + Procedure_end_date +-- + Procedure_end_datetime + +alter table @cdmDatabaseSchema.procedure_occurrence add (procedure_end_date date default null); +alter table @cdmDatabaseSchema.procedure_occurrence add (procedure_end_datetime timestamp default null); + +-- DEVICE_EXPOSURE +-- Unique_device_id -> Changed to varchar(255) +-- + Production_id +-- + Unit_concept_id +-- + Unit_source_value +-- + Unit_source_concept_id + +alter table @cdmDatabaseSchema.device_exposure modify (unique_device_id varchar2(300)); +alter table @cdmDatabaseSchema.device_exposure add (production_id number default null); +alter table @cdmDatabaseSchema.device_exposure add (unit_concept_id number default null); +alter table @cdmDatabaseSchema.device_exposure add (unit_source_value varchar2(50) default null); +alter table @cdmDatabaseSchema.device_exposure add (unit_source_concept_id number default null); + +-- MEASUREMENT +-- + Unit_source_concept_id +-- + Measurement_event_id +-- + Meas_event_field_concept_id + +alter table @cdmDatabaseSchema.measurement add (unit_source_id number default null); +alter table @cdmDatabaseSchema.measurement add (measurement_event_id number default null); +alter table @cdmDatabaseSchema.measurement add (meas_event_field_concept_id number default null); + +-- OBSERVATION +-- + Value_source_value +-- + Observation_event_id +-- + Obs_event_field_concept_id + +alter table @cdmDatabaseSchema.observation add (value_source_value varchar2(50) default null); +alter table @cdmDatabaseSchema.observation add (observation_event_id number default null); +alter table @cdmDatabaseSchema.observation add (obs_event_field_concept_id number default null); + +-- NOTE +-- + Note_event_id +-- + Note_event_field_concept_id + +alter table @cdmDatabaseSchema.note add (note_event_id number default null); +alter table @cdmDatabaseSchema.note add (note_event_field_concept_id number default null); + +-- LOCATION +-- + Country_concept_id +-- + Country_source_value +-- + Latitude +-- + Longitude + +alter table @cdmDatabaseSchema.location add (country_concept_id number default null); +alter table @cdmDatabaseSchema.location add (country_source_value varchar2(80) default null); +alter table @cdmDatabaseSchema.location add (latitude float default null); +alter table @cdmDatabaseSchema.location add (longitude float default null); + +-- EPISODE +CREATE TABLE @cdmDatabaseSchema.EPISODE ( + episode_id number NOT NULL, + person_id number NOT NULL, + episode_concept_id number NOT NULL, + episode_start_date date NOT NULL, + episode_start_datetime TIMESTAMP NULL, + episode_end_date date NULL, + episode_end_datetime TIMESTAMP NULL, + episode_parent_id number NULL, + episode_number number NULL, + episode_object_concept_id number NOT NULL, + episode_type_concept_id number NOT NULL, + episode_source_value varchar2(50) NULL, + episode_source_concept_id number NULL ); + +-- EPISODE_EVENT +CREATE TABLE @cdmDatabaseSchema.EPISODE_EVENT ( + episode_id number NOT NULL, + event_id number NOT NULL, + episode_event_field_concept_id number NOT NULL ); + + +-- METADATA +-- + Metadata_id +-- + Value_as_number + +alter table @cdmDatabaseSchema.metadata add (metadata_id number default null); +alter table @cdmDatabaseSchema.metadata add (value_as_number float default null); + +-- CDM_SOURCE +-- Cdm_source_name -> Mandatory field +-- Cdm_source_abbreviation -> Mandatory field +-- Cdm_holder -> Mandatory field +-- Source_release_date -> Mandatory field +-- Cdm_release_date -> Mandatory field +-- + Cdm_version_concept_id + +rename @cdmDatabaseSchema.cdm_source to cdm_source_v53; + +CREATE TABLE @cdmDatabaseSchema.cdm_source ( + cdm_source_name varchar2(255) NOT NULL, + cdm_source_abbreviation varchar2(25) NOT NULL, + cdm_holder varchar2(255) NOT NULL, + -- 32767 bytes if MAX_STRING_SIZE = EXTENDED + -- 4000 bytes if MAX_STRING_SIZE = STANDARD + source_description varchar2(32767) NULL, + source_documentation_reference varchar2(255) NULL, + cdm_etl_reference varchar2(255) NULL, + source_release_date date NOT NULL, + cdm_release_date date NOT NULL, + cdm_version varchar2(10) NULL, + cdm_version_concept_id number NOT NULL, + vocabulary_version varchar2(20) NOT NULL ); + +insert into @cdmDatabaseSchema.cdm_source +select cdm_source_name,cdm_source_abbreviation,cdm_holder, + source_description,source_documentation_reference,cdm_etl_reference, + source_release_date,cdm_release_date,'5.4', + 756265,vocabulary_version +from @cdmDatabaseSchema.cdm_source_v53; + + +-- VOCABULARY +-- Vocabulary_reference -> Non-mandatory field +-- Vocabulary_version -> Non-mandatory field +rename @cdmDatabaseSchema.vocabulary to vocabulary_v53; + +CREATE TABLE @cdmDatabaseSchema.vocabulary ( + vocabulary_id varchar2(20) NOT NULL, + vocabulary_name varchar2(255) NOT NULL, + vocabulary_reference varchar2(255) NULL, + vocabulary_version varchar2(255) NULL, + vocabulary_concept_id number NOT NULL ); + +insert into @cdmDatabaseSchema.vocabulary +select vocabulary_id,vocabulary_name,vocabulary_reference, + vocabulary_version, vocabulary_concept_id +from @cdmDatabaseSchema.vocabulary_v53; + + +-- ATTRIBUTE_DEFINITION +drop table @cdmDatabaseSchema.attribute_definition; + +-- COHORT +CREATE TABLE @cdmDatabaseSchema.cohort ( + cohort_definition_id number NOT NULL, + subject_id number NOT NULL, + cohort_start_date date NOT NULL, + cohort_end_date date NOT NULL ); + + diff --git a/extras/v53_v54_conversion/postgresql_migration.sql b/extras/v53_v54_conversion/postgresql_migration.sql new file mode 100644 index 0000000..9e8e202 --- /dev/null +++ b/extras/v53_v54_conversion/postgresql_migration.sql @@ -0,0 +1,175 @@ +-- http://ohdsi.github.io/CommonDataModel/cdm54Changes.html +-- PostgreSQL SQL references: +-- https://www.postgresql.org/docs/current/sql-altertable.html +-- +-- VISIT_OCCURRENCE +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value + +alter table @cdmDatabaseSchema.visit_occurrence rename column admitting_source_concept_id to admitted_from_concept_id; +alter table @cdmDatabaseSchema.visit_occurrence rename column admitting_source_value to admitted_from_source_value; +alter table @cdmDatabaseSchema.visit_occurrence rename column discharge_to_concept_id to discharged_to_concept_id; +alter table @cdmDatabaseSchema.visit_occurrence rename column discharge_to_source_value to discharged_to_source_value; + +-- +-- VISIT_DETAIL +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value +-- visit_detail_parent_id -> parent_visit_detail_id + +alter table @cdmDatabaseSchema.visit_detail rename column admitting_source_concept_id to admitted_from_concept_id; +alter table @cdmDatabaseSchema.visit_detail rename column admitting_source_value to admitted_from_source_value; +alter table @cdmDatabaseSchema.visit_detail rename column discharge_to_concept_id to discharged_to_concept_id; +alter table @cdmDatabaseSchema.visit_detail rename column discharge_to_source_value to discharged_to_source_value; +alter table @cdmDatabaseSchema.visit_detail rename column visit_detail_parent_id to parent_visit_detail_id; + +-- PROCEDURE_OCCURRENCE +-- + Procedure_end_date +-- + Procedure_end_datetime + +alter table @cdmDatabaseSchema.procedure_occurrence add column procedure_end_date date default null; +alter table @cdmDatabaseSchema.procedure_occurrence add column procedure_end_datetime timestamp default null; + +-- DEVICE_EXPOSURE +-- Unique_device_id -> Changed to varchar(255) +-- + Production_id +-- + Unit_concept_id +-- + Unit_source_value +-- + Unit_source_concept_id + +alter table @cdmDatabaseSchema.device_exposure alter column unique_device_id type varchar(300); +alter table @cdmDatabaseSchema.device_exposure add column production_id integer default null; +alter table @cdmDatabaseSchema.device_exposure add column unit_concept_id integer default null; +alter table @cdmDatabaseSchema.device_exposure add column unit_source_value varchar(50) default null; +alter table @cdmDatabaseSchema.device_exposure add column unit_source_concept_id integer default null; + +-- MEASUREMENT +-- + Unit_source_concept_id +-- + Measurement_event_id +-- + Meas_event_field_concept_id + +alter table @cdmDatabaseSchema.measurement add column unit_source_id integer default null; +alter table @cdmDatabaseSchema.measurement add column measurement_event_id bigint default null; +alter table @cdmDatabaseSchema.measurement add column meas_event_field_concept_id integer default null; + +-- OBSERVATION +-- + Value_source_value +-- + Observation_event_id +-- + Obs_event_field_concept_id + +alter table @cdmDatabaseSchema.observation add column value_source_value varchar(50) default null; +alter table @cdmDatabaseSchema.observation add column observation_event_id bigint default null; +alter table @cdmDatabaseSchema.observation add column obs_event_field_concept_id integer default null; + +-- NOTE +-- + Note_event_id +-- + Note_event_field_concept_id + +alter table @cdmDatabaseSchema.note add column note_event_id bigint default null; +alter table @cdmDatabaseSchema.note add column note_event_field_concept_id integer default null; + +-- LOCATION +-- + Country_concept_id +-- + Country_source_value +-- + Latitude +-- + Longitude + +alter table @cdmDatabaseSchema.location add column country_concept_id integer default null; +alter table @cdmDatabaseSchema.location add column country_source_value varchar(80) default null; +alter table @cdmDatabaseSchema.location add column latitude numeric default null; +alter table @cdmDatabaseSchema.location add column longitude numeric default null; + +-- EPISODE +CREATE TABLE @cdmDatabaseSchema.EPISODE ( + episode_id bigint NOT NULL, + person_id bigint NOT NULL, + episode_concept_id integer NOT NULL, + episode_start_date date NOT NULL, + episode_start_datetime TIMESTAMP NULL, + episode_end_date date NULL, + episode_end_datetime TIMESTAMP NULL, + episode_parent_id bigint NULL, + episode_number integer NULL, + episode_object_concept_id integer NOT NULL, + episode_type_concept_id integer NOT NULL, + episode_source_value varchar(50) NULL, + episode_source_concept_id integer NULL ); + +-- EPISODE_EVENT +CREATE TABLE @cdmDatabaseSchema.EPISODE_EVENT ( + episode_id bigint NOT NULL, + event_id bigint NOT NULL, + episode_event_field_concept_id integer NOT NULL ); + + +-- METADATA +-- + Metadata_id +-- + Value_as_number + +alter table @cdmDatabaseSchema.metadata add column metadata_id integer default null; +alter table @cdmDatabaseSchema.metadata add column value_as_number numeric default null; + +-- CDM_SOURCE +-- Cdm_source_name -> Mandatory field +-- Cdm_source_abbreviation -> Mandatory field +-- Cdm_holder -> Mandatory field +-- Source_release_date -> Mandatory field +-- Cdm_release_date -> Mandatory field +-- + Cdm_version_concept_id + +alter table @cdmDatabaseSchema.cdm_source rename to cdm_source_v53; + +CREATE TABLE @cdmDatabaseSchema.cdm_source ( + cdm_source_name varchar(255) NOT NULL, + cdm_source_abbreviation varchar(25) NOT NULL, + cdm_holder varchar(255) NOT NULL, + source_description text NULL, + source_documentation_reference varchar(255) NULL, + cdm_etl_reference varchar(255) NULL, + source_release_date date NOT NULL, + cdm_release_date date NOT NULL, + cdm_version varchar(10) NULL, + cdm_version_concept_id integer NOT NULL, + vocabulary_version varchar(20) NOT NULL ); + +insert into @cdmDatabaseSchema.cdm_source +select cdm_source_name,cdm_source_abbreviation,cdm_holder, + source_description,source_documentation_reference,cdm_etl_reference, + source_release_date,cdm_release_date,'5.4', + 756265,vocabulary_version +from @cdmDatabaseSchema.cdm_source_v53; + + +-- VOCABULARY +-- Vocabulary_reference -> Non-mandatory field +-- Vocabulary_version -> Non-mandatory field +alter table @cdmDatabaseSchema.vocabulary rename to vocabulary_v53; + +CREATE TABLE @cdmDatabaseSchema.vocabulary ( + vocabulary_id varchar(20) NOT NULL, + vocabulary_name varchar(255) NOT NULL, + vocabulary_reference varchar(255) NULL, + vocabulary_version varchar(255) NULL, + vocabulary_concept_id integer NOT NULL ); + +insert into @cdmDatabaseSchema.vocabulary +select vocabulary_id,vocabulary_name,vocabulary_reference, + vocabulary_version, vocabulary_concept_id +from @cdmDatabaseSchema.vocabulary_v53; + + +-- ATTRIBUTE_DEFINITION +drop table @cdmDatabaseSchema.attribute_definition; + +-- COHORT +CREATE TABLE @cdmDatabaseSchema.cohort ( + cohort_definition_id integer NOT NULL, + subject_id integer NOT NULL, + cohort_start_date date NOT NULL, + cohort_end_date date NOT NULL ); + + diff --git a/extras/v53_v54_conversion/redshift_migration.sql b/extras/v53_v54_conversion/redshift_migration.sql new file mode 100644 index 0000000..3b757fe --- /dev/null +++ b/extras/v53_v54_conversion/redshift_migration.sql @@ -0,0 +1,176 @@ +-- http://ohdsi.github.io/CommonDataModel/cdm54Changes.html +-- Redshift SQL references: +-- https://docs.aws.amazon.com/redshift/latest/dg/r_ALTER_TABLE_examples_basic.html +-- https://docs.aws.amazon.com/redshift/latest/dg/r_ALTER_TABLE_COL_ex-add-drop.html +-- +-- VISIT_OCCURRENCE +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value + +alter table @cdmDatabaseSchema.visit_occurrence rename column admitting_source_concept_id to admitted_from_concept_id; +alter table @cdmDatabaseSchema.visit_occurrence rename column admitting_source_value to admitted_from_source_value; +alter table @cdmDatabaseSchema.visit_occurrence rename column discharge_to_concept_id to discharged_to_concept_id; +alter table @cdmDatabaseSchema.visit_occurrence rename column discharge_to_source_value to discharged_to_source_value; + +-- +-- VISIT_DETAIL +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value +-- visit_detail_parent_id -> parent_visit_detail_id + +alter table @cdmDatabaseSchema.visit_detail rename column admitting_source_concept_id to admitted_from_concept_id; +alter table @cdmDatabaseSchema.visit_detail rename column admitting_source_value to admitted_from_source_value; +alter table @cdmDatabaseSchema.visit_detail rename column discharge_to_concept_id to discharged_to_concept_id; +alter table @cdmDatabaseSchema.visit_detail rename column discharge_to_source_value to discharged_to_source_value; +alter table @cdmDatabaseSchema.visit_detail rename column visit_detail_parent_id to parent_visit_detail_id; + +-- PROCEDURE_OCCURRENCE +-- + Procedure_end_date +-- + Procedure_end_datetime + +alter table @cdmDatabaseSchema.procedure_occurrence add column procedure_end_date date default null; +alter table @cdmDatabaseSchema.procedure_occurrence add column procedure_end_datetime timestamp default null; + +-- DEVICE_EXPOSURE +-- Unique_device_id -> Changed to varchar(255) +-- + Production_id +-- + Unit_concept_id +-- + Unit_source_value +-- + Unit_source_concept_id + +alter table @cdmDatabaseSchema.device_exposure alter column unique_device_id varchar(300); +alter table @cdmDatabaseSchema.device_exposure add column production_id integer default null; +alter table @cdmDatabaseSchema.device_exposure add column unit_concept_id integer default null; +alter table @cdmDatabaseSchema.device_exposure add column unit_source_value varchar(50) default null; +alter table @cdmDatabaseSchema.device_exposure add column unit_source_concept_id integer default null; + +-- MEASUREMENT +-- + Unit_source_concept_id +-- + Measurement_event_id +-- + Meas_event_field_concept_id + +alter table @cdmDatabaseSchema.measurement add column unit_source_id integer default null; +alter table @cdmDatabaseSchema.measurement add column measurement_event_id bigint default null; +alter table @cdmDatabaseSchema.measurement add column meas_event_field_concept_id integer default null; + +-- OBSERVATION +-- + Value_source_value +-- + Observation_event_id +-- + Obs_event_field_concept_id + +alter table @cdmDatabaseSchema.observation add column value_source_value varchar(50) default null; +alter table @cdmDatabaseSchema.observation add column observation_event_id bigint default null; +alter table @cdmDatabaseSchema.observation add column obs_event_field_concept_id integer default null; + +-- NOTE +-- + Note_event_id +-- + Note_event_field_concept_id + +alter table @cdmDatabaseSchema.note add column note_event_id bigint default null; +alter table @cdmDatabaseSchema.note add column note_event_field_concept_id integer default null; + +-- LOCATION +-- + Country_concept_id +-- + Country_source_value +-- + Latitude +-- + Longitude + +alter table @cdmDatabaseSchema.location add column country_concept_id integer default null; +alter table @cdmDatabaseSchema.location add column country_source_value varchar(80) default null; +alter table @cdmDatabaseSchema.location add column latitude float default null; +alter table @cdmDatabaseSchema.location add column longitude float default null; + +-- EPISODE +CREATE TABLE @cdmDatabaseSchema.EPISODE ( + episode_id bigint NOT NULL, + person_id bigint NOT NULL, + episode_concept_id integer NOT NULL, + episode_start_date date NOT NULL, + episode_start_datetime TIMESTAMP NULL, + episode_end_date date NULL, + episode_end_datetime TIMESTAMP NULL, + episode_parent_id bigint NULL, + episode_number integer NULL, + episode_object_concept_id integer NOT NULL, + episode_type_concept_id integer NOT NULL, + episode_source_value varchar(50) NULL, + episode_source_concept_id integer NULL ); + +-- EPISODE_EVENT +CREATE TABLE @cdmDatabaseSchema.EPISODE_EVENT ( + episode_id bigint NOT NULL, + event_id bigint NOT NULL, + episode_event_field_concept_id integer NOT NULL ); + + +-- METADATA +-- + Metadata_id +-- + Value_as_number + +alter table @cdmDatabaseSchema.metadata add column metadata_id integer default null; +alter table @cdmDatabaseSchema.metadata add column value_as_number float default null; + +-- CDM_SOURCE +-- Cdm_source_name -> Mandatory field +-- Cdm_source_abbreviation -> Mandatory field +-- Cdm_holder -> Mandatory field +-- Source_release_date -> Mandatory field +-- Cdm_release_date -> Mandatory field +-- + Cdm_version_concept_id + +alter table @cdmDatabaseSchema.cdm_source rename to cdm_source_v53; + +CREATE TABLE @cdmDatabaseSchema.cdm_source ( + cdm_source_name varchar(255) NOT NULL, + cdm_source_abbreviation varchar(25) NOT NULL, + cdm_holder varchar(255) NOT NULL, + source_description varchar(MAX) NULL, + source_documentation_reference varchar(255) NULL, + cdm_etl_reference varchar(255) NULL, + source_release_date date NOT NULL, + cdm_release_date date NOT NULL, + cdm_version varchar(10) NULL, + cdm_version_concept_id integer NOT NULL, + vocabulary_version varchar(20) NOT NULL ); + +insert into @cdmDatabaseSchema.cdm_source +select cdm_source_name,cdm_source_abbreviation,cdm_holder, + source_description,source_documentation_reference,cdm_etl_reference, + source_release_date,cdm_release_date,'5.4', + 756265,vocabulary_version +from @cdmDatabaseSchema.cdm_source_v53; + + +-- VOCABULARY +-- Vocabulary_reference -> Non-mandatory field +-- Vocabulary_version -> Non-mandatory field +alter table @cdmDatabaseSchema.vocabulary rename to vocabulary_v53; + +CREATE TABLE @cdmDatabaseSchema.vocabulary ( + vocabulary_id varchar(20) NOT NULL, + vocabulary_name varchar(255) NOT NULL, + vocabulary_reference varchar(255) NULL, + vocabulary_version varchar(255) NULL, + vocabulary_concept_id integer NOT NULL ); + +insert into @cdmDatabaseSchema.vocabulary +select vocabulary_id,vocabulary_name,vocabulary_reference, + vocabulary_version, vocabulary_concept_id +from @cdmDatabaseSchema.vocabulary_v53; + + +-- ATTRIBUTE_DEFINITION +drop table @cdmDatabaseSchema.attribute_definition; + +-- COHORT +CREATE TABLE @cdmDatabaseSchema.cohort ( + cohort_definition_id integer NOT NULL, + subject_id integer NOT NULL, + cohort_start_date date NOT NULL, + cohort_end_date date NOT NULL ); + + diff --git a/extras/v53_v54_conversion/sqlserver_migration.sql b/extras/v53_v54_conversion/sqlserver_migration.sql new file mode 100644 index 0000000..f692992 --- /dev/null +++ b/extras/v53_v54_conversion/sqlserver_migration.sql @@ -0,0 +1,179 @@ +-- http://ohdsi.github.io/CommonDataModel/cdm54Changes.html +-- SQL SERVER SQL References: +-- https://docs.microsoft.com/en-us/sql/relational-databases/tables/rename-columns-database-engine?view=sql-server-ver15 +-- https://docs.microsoft.com/en-us/sql/relational-databases/system-stored-procedures/sp-rename-transact-sql?view=sql-server-ver15 +-- https://docs.microsoft.com/en-us/sql/relational-databases/tables/add-columns-to-a-table-database-engine?view=sql-server-ver15 +-- https://docs.microsoft.com/en-us/sql/relational-databases/tables/modify-columns-database-engine?view=sql-server-ver15 +-- https://docs.microsoft.com/en-us/sql/t-sql/data-types/data-types-transact-sql?view=sql-server-ver15 +-- +-- VISIT_OCCURRENCE +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value + +EXEC sp_rename '@cdmDatabaseSchema.visit_occurrence.admitting_source_concept_id', 'admitted_from_concept_id', 'COLUMN'; +EXEC sp_rename '@cdmDatabaseSchema.visit_occurrence.admitting_source_value', 'admitted_from_source_value', 'COLUMN'; +EXEC sp_rename '@cdmDatabaseSchema.visit_occurrence.discharge_to_concept_id', 'discharged_to_concept_id', 'COLUMN'; +EXEC sp_rename '@cdmDatabaseSchema.visit_occurrence.discharge_to_source_value', 'discharged_to_source_value', 'COLUMN'; + +-- +-- VISIT_DETAIL +-- admitting_source_concept_id -> admitted_from_concept_id +-- admitting_source_value -> admitted_from_source_value +-- discharge_to_concept_id -> discharged_to_concept_id +-- discharge_to_source_value -> discharged_to_source_value +-- visit_detail_parent_id -> parent_visit_detail_id + +EXEC sp_rename '@cdmDatabaseSchema.visit_detail.admitting_source_concept_id', 'admitted_from_concept_id', 'COLUMN'; +EXEC sp_rename '@cdmDatabaseSchema.visit_detail.admitting_source_value', 'admitted_from_source_value', 'COLUMN'; +EXEC sp_rename '@cdmDatabaseSchema.visit_detail.discharge_to_concept_id', 'discharged_to_concept_id', 'COLUMN'; +EXEC sp_rename '@cdmDatabaseSchema.visit_detail.discharge_to_source_value', 'discharged_to_source_value', 'COLUMN'; +EXEC sp_rename '@cdmDatabaseSchema.visit_detail.visit_detail_parent_id', 'parent_visit_detail_id', 'COLUMN'; + +-- PROCEDURE_OCCURRENCE +-- + Procedure_end_date +-- + Procedure_end_datetime + +alter table @cdmDatabaseSchema.procedure_occurrence add procedure_end_date date null; +alter table @cdmDatabaseSchema.procedure_occurrence add procedure_end_datetime datetime null; + +-- DEVICE_EXPOSURE +-- Unique_device_id -> Changed to varchar(255) +-- + Production_id +-- + Unit_concept_id +-- + Unit_source_value +-- + Unit_source_concept_id + +alter table @cdmDatabaseSchema.device_exposure alter column unique_device_id varchar(300); +alter table @cdmDatabaseSchema.device_exposure add production_id int null; +alter table @cdmDatabaseSchema.device_exposure add unit_concept_id int null; +alter table @cdmDatabaseSchema.device_exposure add unit_source_value varchar(50) null; +alter table @cdmDatabaseSchema.device_exposure add unit_source_concept_id int null; + +-- MEASUREMENT +-- + Unit_source_concept_id +-- + Measurement_event_id +-- + Meas_event_field_concept_id + +alter table @cdmDatabaseSchema.measurement add unit_source_id int null; +alter table @cdmDatabaseSchema.measurement add measurement_event_id bigint null; +alter table @cdmDatabaseSchema.measurement add meas_event_field_concept_id int null; + +-- OBSERVATION +-- + Value_source_value +-- + Observation_event_id +-- + Obs_event_field_concept_id + +alter table @cdmDatabaseSchema.observation add value_source_value varchar(50) null; +alter table @cdmDatabaseSchema.observation add observation_event_id bigint null; +alter table @cdmDatabaseSchema.observation add obs_event_field_concept_id int null; + +-- NOTE +-- + Note_event_id +-- + Note_event_field_concept_id + +alter table @cdmDatabaseSchema.note add note_event_id bigint null; +alter table @cdmDatabaseSchema.note add note_event_field_concept_id int null; + +-- LOCATION +-- + Country_concept_id +-- + Country_source_value +-- + Latitude +-- + Longitude + +alter table @cdmDatabaseSchema.location add country_concept_id int null; +alter table @cdmDatabaseSchema.location add country_source_value varchar(80) null; +alter table @cdmDatabaseSchema.location add latitude numeric null; +alter table @cdmDatabaseSchema.location add longitude numeric null; + +-- EPISODE +CREATE TABLE @cdmDatabaseSchema.EPISODE ( + episode_id bigint NOT NULL, + person_id bigint NOT NULL, + episode_concept_id int NOT NULL, + episode_start_date date NOT NULL, + episode_start_datetime datetime NULL, + episode_end_date date NULL, + episode_end_datetime datetime NULL, + episode_parent_id bigint NULL, + episode_number int NULL, + episode_object_concept_id int NOT NULL, + episode_type_concept_id int NOT NULL, + episode_source_value varchar(50) NULL, + episode_source_concept_id int NULL ); + +-- EPISODE_EVENT +CREATE TABLE @cdmDatabaseSchema.EPISODE_EVENT ( + episode_id bigint NOT NULL, + event_id bigint NOT NULL, + episode_event_field_concept_id int NOT NULL ); + + +-- METADATA +-- + Metadata_id +-- + Value_as_number + +alter table @cdmDatabaseSchema.metadata add metadata_id int null; +alter table @cdmDatabaseSchema.metadata add value_as_number numeric null; + +-- CDM_SOURCE +-- Cdm_source_name -> Mandatory field +-- Cdm_source_abbreviation -> Mandatory field +-- Cdm_holder -> Mandatory field +-- Source_release_date -> Mandatory field +-- Cdm_release_date -> Mandatory field +-- + Cdm_version_concept_id + +EXEC sp_rename '@cdmDatabaseSchema.cdm_source', 'cdm_source_v53'; + +CREATE TABLE @cdmDatabaseSchema.cdm_source ( + cdm_source_name varchar(255) NOT NULL, + cdm_source_abbreviation varchar(25) NOT NULL, + cdm_holder varchar(255) NOT NULL, + source_description varchar(MAX) NULL, + source_documentation_reference varchar(255) NULL, + cdm_etl_reference varchar(255) NULL, + source_release_date date NOT NULL, + cdm_release_date date NOT NULL, + cdm_version varchar(10) NULL, + cdm_version_concept_id int NOT NULL, + vocabulary_version varchar(20) NOT NULL ); + +insert into @cdmDatabaseSchema.cdm_source +select cdm_source_name,cdm_source_abbreviation,cdm_holder, + source_description,source_documentation_reference,cdm_etl_reference, + source_release_date,cdm_release_date,'5.4', + 756265,vocabulary_version +from @cdmDatabaseSchema.cdm_source_v53; + + +-- VOCABULARY +-- Vocabulary_reference -> Non-mandatory field +-- Vocabulary_version -> Non-mandatory field +EXEC sp_rename '@cdmDatabaseSchema.vocabulary', 'vocabulary_v53'; + +CREATE TABLE @cdmDatabaseSchema.vocabulary ( + vocabulary_id varchar(20) NOT NULL, + vocabulary_name varchar(255) NOT NULL, + vocabulary_reference varchar(255) NULL, + vocabulary_version varchar(255) NULL, + vocabulary_concept_id int NOT NULL ); + +insert into @cdmDatabaseSchema.vocabulary +select vocabulary_id,vocabulary_name,vocabulary_reference, + vocabulary_version, vocabulary_concept_id +from @cdmDatabaseSchema.vocabulary_v53; + + +-- ATTRIBUTE_DEFINITION +drop table @cdmDatabaseSchema.attribute_definition; + +-- COHORT +CREATE TABLE @cdmDatabaseSchema.cohort ( + cohort_definition_id int NOT NULL, + subject_id int NOT NULL, + cohort_start_date date NOT NULL, + cohort_end_date date NOT NULL ); + +