Merge pull request #469 from OHDSI/v5.4_conversions

CDM v5.3 to v5.4 conversion scripts
This commit is contained in:
clairblacketer 2025-03-06 09:14:41 -05:00 committed by GitHub
commit f8c78f882c
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
13 changed files with 2127 additions and 0 deletions

View File

@ -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.

View File

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

View File

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

View File

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

View File

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

View File

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

View File

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

View File

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

View File

@ -0,0 +1,23 @@
with cdm_v540 as (
select *
from information_schema.columns
where table_schema = 'cdm_v540' --> ENTER YOUR V5.4 CDM HERE
and table_name not in ('cohort','cohort_attribute','cohort_definition')
), cdm_v601 as (
select *
from information_schema.columns
where table_schema = 'cdm_v601' --> ENTER YOUR V6.0 CDM HERE
and table_name not in ('cohort','cohort_attribute','cohort_definition')
)
select a.table_name,
a.column_name,
a.is_nullable v54_nullable,
b.is_nullable v60_nullable,
a.data_type v54_datatype,
b.data_type v60_datatype
from cdm_v540 a
join cdm_v601 b
on a.table_name = b.table_name
and a.column_name = b.column_name
and (a.is_nullable != b.is_nullable or a.data_type != b.data_type)
order by 1,2;

View File

@ -0,0 +1,45 @@
--
-- RETRIEVE TABLE AND COLUMN NAMES FOR V5.4 AND V6.0 CDMS.
-- SUPPLY THE NAME OF EACH SCHEMA WHERE INDICATED.
-- THE "STATUS" COLUMN:
-- "IN BOTH": INDICATES COLUMN IS IN BOTH 5.4 AND 6.0
-- "MISSING FROM v6.0.1": INDICATES COLUMN IS IN BOTH 5.4 BUT NOT 6.0 AND NEEDS TO BE ADDED OR RENAMED
-- "MISSING FROM v5.4.0": INDICATES COLUMN IS IN BOTH 6.0 BUT NOT 5.4 AND NEED TO BE DROPPED OR RENAMED
with cdm_v540 as (
select *
from information_schema.columns
where table_schema = 'cdm_v540' --> YOUR V5.4 CDM SCHEMA NAME HERE
and table_name not in ('_version','cohort','cohort_attribute','cohort_definition')
), cdm_v601 as (
select *
from information_schema.columns
where table_schema = 'cdm_v601' --> YOUR V6.0 CDM SCHEMA NAME HERE
and table_name not in ('_version','cohort','cohort_attribute','cohort_definition')
)
select a.table_name,
a.column_name,
'IN BOTH' status
from cdm_v540 a
join cdm_v601 b
on a.table_name = b.table_name
and a.column_name = b.column_name
union all
select a.table_name,
a.column_name,
'MISSING FROM v6.0.1' status
from cdm_v540 a
left join cdm_v601 b
on a.table_name = b.table_name
and a.column_name = b.column_name
where b.column_name is null
union all
select b.table_name,
b.column_name,
'MISSING FROM v5.4.0' status
from cdm_v540 a
right join cdm_v601 b
on a.table_name = b.table_name
and a.column_name = b.column_name
where a.column_name is null
order by 1,3;

View File

@ -0,0 +1,182 @@
table_name | column_name | v54_nullable | v60_nullable | v54_datatype | v60_datatype
----------------------+--------------------------------+--------------+--------------+-----------------------------+----------------------------
care_site | care_site_id | YES | NO | bigint | bigint
care_site | place_of_service_concept_id | YES | NO | integer | integer
cdm_source | cdm_holder | NO | YES | character varying | character varying
cdm_source | cdm_release_date | NO | YES | date | date
cdm_source | cdm_source_abbreviation | NO | YES | character varying | character varying
cdm_source | source_release_date | NO | YES | date | date
cdm_source | vocabulary_version | NO | YES | character varying | character varying
concept | concept_class_id | YES | NO | character varying | character varying
concept | concept_code | YES | NO | character varying | character varying
concept | concept_id | YES | NO | integer | integer
concept | concept_name | YES | NO | character varying | character varying
concept | domain_id | YES | NO | character varying | character varying
concept | valid_end_date | YES | NO | date | date
concept | valid_start_date | YES | NO | date | date
concept | vocabulary_id | YES | NO | character varying | character varying
concept_ancestor | ancestor_concept_id | YES | NO | integer | integer
concept_ancestor | descendant_concept_id | YES | NO | integer | integer
concept_ancestor | max_levels_of_separation | YES | NO | integer | integer
concept_ancestor | min_levels_of_separation | YES | NO | integer | integer
concept_class | concept_class_concept_id | YES | NO | integer | integer
concept_class | concept_class_id | YES | NO | character varying | character varying
concept_class | concept_class_name | YES | NO | character varying | character varying
concept_relationship | concept_id_1 | YES | NO | integer | integer
concept_relationship | concept_id_2 | YES | NO | integer | integer
concept_relationship | relationship_id | YES | NO | character varying | character varying
concept_relationship | valid_end_date | YES | NO | date | date
concept_relationship | valid_start_date | YES | NO | date | date
concept_synonym | concept_id | YES | NO | integer | integer
concept_synonym | concept_synonym_name | YES | NO | character varying | character varying
concept_synonym | language_concept_id | YES | NO | integer | integer
condition_era | condition_concept_id | YES | NO | integer | integer
condition_era | condition_era_id | YES | NO | bigint | bigint
condition_era | person_id | YES | NO | bigint | bigint
condition_occurrence | condition_concept_id | YES | NO | integer | integer
condition_occurrence | condition_occurrence_id | YES | NO | bigint | bigint
condition_occurrence | condition_source_concept_id | YES | NO | integer | integer
condition_occurrence | condition_start_date | YES | NO | date | date
condition_occurrence | condition_status_concept_id | YES | NO | integer | integer
condition_occurrence | condition_type_concept_id | YES | NO | integer | integer
condition_occurrence | person_id | YES | NO | bigint | bigint
cost | cost_event_id | YES | NO | bigint | bigint
cost | cost_id | YES | NO | bigint | bigint
cost | payer_plan_period_id | YES | YES | integer | bigint
device_exposure | device_concept_id | YES | NO | integer | integer
device_exposure | device_exposure_id | YES | NO | bigint | bigint
device_exposure | device_exposure_start_date | YES | NO | date | date
device_exposure | device_source_concept_id | YES | NO | integer | integer
device_exposure | device_type_concept_id | YES | NO | integer | integer
device_exposure | person_id | YES | NO | bigint | bigint
domain | domain_concept_id | YES | NO | integer | integer
domain | domain_id | YES | NO | character varying | character varying
domain | domain_name | YES | NO | character varying | character varying
dose_era | dose_era_id | YES | NO | bigint | bigint
dose_era | dose_value | YES | NO | double precision | double precision
dose_era | drug_concept_id | YES | NO | integer | integer
dose_era | person_id | YES | NO | bigint | bigint
dose_era | unit_concept_id | YES | NO | integer | integer
drug_era | drug_concept_id | YES | NO | integer | integer
drug_era | drug_era_id | YES | NO | bigint | bigint
drug_era | person_id | YES | NO | bigint | bigint
drug_exposure | drug_concept_id | YES | NO | integer | integer
drug_exposure | drug_exposure_end_date | YES | NO | date | date
drug_exposure | drug_exposure_id | YES | NO | bigint | bigint
drug_exposure | drug_exposure_start_date | YES | NO | date | date
drug_exposure | drug_source_concept_id | YES | NO | integer | integer
drug_exposure | drug_type_concept_id | YES | NO | integer | integer
drug_exposure | person_id | YES | NO | bigint | bigint
drug_strength | drug_concept_id | YES | NO | integer | integer
drug_strength | ingredient_concept_id | YES | NO | integer | integer
drug_strength | valid_end_date | YES | NO | date | date
drug_strength | valid_start_date | YES | NO | date | date
fact_relationship | domain_concept_id_1 | YES | NO | integer | integer
fact_relationship | domain_concept_id_2 | YES | NO | integer | integer
fact_relationship | fact_id_1 | YES | NO | bigint | bigint
fact_relationship | fact_id_2 | YES | NO | bigint | bigint
fact_relationship | relationship_concept_id | YES | NO | integer | integer
location | location_id | YES | NO | bigint | bigint
measurement | measurement_concept_id | YES | NO | integer | integer
measurement | measurement_date | YES | NO | date | date
measurement | measurement_id | YES | NO | bigint | bigint
measurement | measurement_source_concept_id | YES | NO | integer | integer
measurement | measurement_time | YES | YES | timestamp without time zone | character varying
measurement | measurement_type_concept_id | YES | NO | integer | integer
measurement | person_id | YES | NO | bigint | bigint
metadata | metadata_concept_id | YES | NO | integer | integer
metadata | metadata_type_concept_id | YES | NO | integer | integer
metadata | name | YES | NO | character varying | character varying
note | encoding_concept_id | YES | NO | integer | integer
note | language_concept_id | YES | NO | integer | integer
note | note_class_concept_id | YES | NO | integer | integer
note | note_date | YES | NO | date | date
note | note_id | YES | NO | bigint | integer
note | note_text | YES | NO | character varying | character varying
note | note_type_concept_id | YES | NO | integer | integer
note | person_id | YES | NO | bigint | bigint
note | provider_id | YES | YES | integer | bigint
note_nlp | lexical_variant | YES | NO | character varying | character varying
note_nlp | nlp_date | YES | NO | date | date
note_nlp | note_id | YES | NO | bigint | integer
note_nlp | note_nlp_id | YES | NO | bigint | bigint
observation | observation_concept_id | YES | NO | integer | integer
observation | observation_datetime | YES | NO | timestamp without time zone | timestamp without time zone
observation | observation_id | YES | NO | bigint | bigint
observation | observation_source_concept_id | YES | NO | integer | integer
observation | observation_type_concept_id | YES | NO | integer | integer
observation | person_id | YES | NO | bigint | bigint
observation_period | observation_period_end_date | YES | NO | date | date
observation_period | observation_period_id | YES | NO | bigint | bigint
observation_period | observation_period_start_date | YES | NO | date | date
observation_period | period_type_concept_id | YES | NO | integer | integer
observation_period | person_id | YES | NO | bigint | bigint
payer_plan_period | payer_concept_id | YES | NO | integer | integer
payer_plan_period | payer_plan_period_end_date | YES | NO | date | date
payer_plan_period | payer_plan_period_id | YES | NO | integer | bigint
payer_plan_period | payer_plan_period_start_date | YES | NO | date | date
payer_plan_period | payer_source_concept_id | YES | NO | integer | integer
payer_plan_period | person_id | YES | NO | integer | bigint
payer_plan_period | plan_concept_id | YES | NO | integer | integer
payer_plan_period | plan_source_concept_id | YES | NO | integer | integer
payer_plan_period | sponsor_concept_id | YES | NO | integer | integer
person | ethnicity_concept_id | YES | NO | integer | integer
person | ethnicity_source_concept_id | YES | NO | integer | integer
person | gender_concept_id | YES | NO | integer | integer
person | gender_source_concept_id | YES | NO | integer | integer
person | person_id | YES | NO | bigint | bigint
person | race_concept_id | YES | NO | integer | integer
person | race_source_concept_id | YES | NO | integer | integer
person | year_of_birth | YES | NO | integer | integer
procedure_occurrence | person_id | YES | NO | bigint | bigint
procedure_occurrence | procedure_concept_id | YES | NO | integer | integer
procedure_occurrence | procedure_datetime | YES | NO | timestamp without time zone | timestamp without time zone
procedure_occurrence | procedure_occurrence_id | YES | NO | bigint | bigint
procedure_occurrence | procedure_source_concept_id | YES | NO | integer | integer
procedure_occurrence | procedure_type_concept_id | YES | NO | integer | integer
provider | gender_concept_id | YES | NO | integer | integer
provider | gender_source_concept_id | YES | NO | integer | integer
provider | provider_id | YES | NO | bigint | bigint
provider | specialty_concept_id | YES | NO | integer | integer
provider | specialty_source_concept_id | YES | NO | integer | integer
provider | year_of_birth | YES | YES | bigint | integer
relationship | defines_ancestry | YES | NO | character varying | character varying
relationship | is_hierarchical | YES | NO | character varying | character varying
relationship | relationship_concept_id | YES | NO | integer | integer
relationship | relationship_id | YES | NO | character varying | character varying
relationship | relationship_name | YES | NO | character varying | character varying
relationship | reverse_relationship_id | YES | NO | character varying | character varying
source_to_concept_map | source_code | YES | NO | character varying | character varying
source_to_concept_map | source_concept_id | YES | NO | integer | integer
source_to_concept_map | source_vocabulary_id | YES | NO | character varying | character varying
source_to_concept_map | target_concept_id | YES | NO | integer | integer
source_to_concept_map | target_vocabulary_id | YES | NO | character varying | character varying
source_to_concept_map | valid_end_date | YES | NO | date | date
source_to_concept_map | valid_start_date | YES | NO | date | date
specimen | person_id | YES | NO | bigint | bigint
specimen | specimen_concept_id | YES | NO | integer | integer
specimen | specimen_date | YES | NO | date | date
specimen | specimen_id | YES | NO | bigint | bigint
specimen | specimen_type_concept_id | YES | NO | integer | integer
visit_detail | admitted_from_concept_id | YES | YES | integer | character varying
visit_detail | admitted_from_source_value | YES | NO | character varying | integer
visit_detail | care_site_id | YES | YES | integer | bigint
visit_detail | person_id | YES | NO | bigint | bigint
visit_detail | preceding_visit_detail_id | YES | YES | integer | bigint
visit_detail | provider_id | YES | YES | integer | bigint
visit_detail | visit_detail_concept_id | YES | NO | integer | integer
visit_detail | visit_detail_end_date | YES | NO | date | date
visit_detail | visit_detail_id | YES | NO | bigint | bigint
visit_detail | visit_detail_source_concept_id | YES | NO | integer | integer
visit_detail | visit_detail_start_date | YES | NO | date | date
visit_detail | visit_detail_type_concept_id | YES | NO | integer | integer
visit_detail | visit_occurrence_id | YES | NO | bigint | bigint
visit_occurrence | admitted_from_concept_id | YES | NO | integer | integer
visit_occurrence | person_id | YES | NO | bigint | bigint
visit_occurrence | visit_concept_id | YES | NO | integer | integer
visit_occurrence | visit_end_datetime | YES | NO | timestamp without time zone | timestamp without time zone
visit_occurrence | visit_occurrence_id | YES | NO | bigint | bigint
visit_occurrence | visit_source_concept_id | YES | NO | integer | integer
visit_occurrence | visit_start_datetime | YES | NO | timestamp without time zone | timestamp without time zone
visit_occurrence | visit_type_concept_id | YES | NO | integer | integer
vocabulary | vocabulary_reference | YES | NO | character varying | character varying

View File

@ -0,0 +1,481 @@
table_name | column_name | status
----------------------+--------------------------------+--------------------
care_site | care_site_id | IN BOTH
care_site | place_of_service_concept_id | IN BOTH
care_site | location_id | IN BOTH
care_site | care_site_name | IN BOTH
care_site | care_site_source_value | IN BOTH
care_site | place_of_service_source_value | IN BOTH
cdm_source | cdm_source_name | IN BOTH
cdm_source | cdm_source_abbreviation | IN BOTH
cdm_source | cdm_holder | IN BOTH
cdm_source | source_description | IN BOTH
cdm_source | source_documentation_reference | IN BOTH
cdm_source | cdm_etl_reference | IN BOTH
cdm_source | source_release_date | IN BOTH
cdm_source | cdm_release_date | IN BOTH
cdm_source | cdm_version | IN BOTH
cdm_source | vocabulary_version | IN BOTH
cdm_source | cdm_version_concept_id | MISSING FROM v6.0.1
concept | concept_id | IN BOTH
concept | valid_start_date | IN BOTH
concept | valid_end_date | IN BOTH
concept | concept_name | IN BOTH
concept | domain_id | IN BOTH
concept | vocabulary_id | IN BOTH
concept | concept_class_id | IN BOTH
concept | standard_concept | IN BOTH
concept | concept_code | IN BOTH
concept | invalid_reason | IN BOTH
concept_ancestor | ancestor_concept_id | IN BOTH
concept_ancestor | descendant_concept_id | IN BOTH
concept_ancestor | min_levels_of_separation | IN BOTH
concept_ancestor | max_levels_of_separation | IN BOTH
concept_class | concept_class_concept_id | IN BOTH
concept_class | concept_class_id | IN BOTH
concept_class | concept_class_name | IN BOTH
concept_relationship | concept_id_1 | IN BOTH
concept_relationship | concept_id_2 | IN BOTH
concept_relationship | valid_start_date | IN BOTH
concept_relationship | valid_end_date | IN BOTH
concept_relationship | relationship_id | IN BOTH
concept_relationship | invalid_reason | IN BOTH
concept_synonym | concept_id | IN BOTH
concept_synonym | language_concept_id | IN BOTH
concept_synonym | concept_synonym_name | IN BOTH
condition_era | condition_era_id | IN BOTH
condition_era | person_id | IN BOTH
condition_era | condition_concept_id | IN BOTH
condition_era | condition_occurrence_count | IN BOTH
condition_era | condition_era_start_datetime | MISSING FROM v5.4.0
condition_era | condition_era_end_datetime | MISSING FROM v5.4.0
condition_era | condition_era_start_date | MISSING FROM v6.0.1
condition_era | condition_era_end_date | MISSING FROM v6.0.1
condition_occurrence | condition_occurrence_id | IN BOTH
condition_occurrence | person_id | IN BOTH
condition_occurrence | condition_concept_id | IN BOTH
condition_occurrence | condition_start_date | IN BOTH
condition_occurrence | condition_start_datetime | IN BOTH
condition_occurrence | condition_end_date | IN BOTH
condition_occurrence | condition_end_datetime | IN BOTH
condition_occurrence | condition_type_concept_id | IN BOTH
condition_occurrence | provider_id | IN BOTH
condition_occurrence | visit_occurrence_id | IN BOTH
condition_occurrence | visit_detail_id | IN BOTH
condition_occurrence | condition_source_concept_id | IN BOTH
condition_occurrence | condition_status_concept_id | IN BOTH
condition_occurrence | stop_reason | IN BOTH
condition_occurrence | condition_source_value | IN BOTH
condition_occurrence | condition_status_source_value | IN BOTH
cost | cost_id | IN BOTH
cost | cost_event_id | IN BOTH
cost | cost_type_concept_id | IN BOTH
cost | currency_concept_id | IN BOTH
cost | payer_plan_period_id | IN BOTH
cost | revenue_code_concept_id | IN BOTH
cost | drg_concept_id | IN BOTH
cost | drg_source_value | IN BOTH
cost | person_id | MISSING FROM v5.4.0
cost | cost_event_field_concept_id | MISSING FROM v5.4.0
cost | cost_concept_id | MISSING FROM v5.4.0
cost | cost_source_concept_id | MISSING FROM v5.4.0
cost | cost_source_value | MISSING FROM v5.4.0
cost | cost | MISSING FROM v5.4.0
cost | incurred_date | MISSING FROM v5.4.0
cost | billed_date | MISSING FROM v5.4.0
cost | paid_date | MISSING FROM v5.4.0
cost | revenue_code_source_value | MISSING FROM v5.4.0
cost | total_charge | MISSING FROM v6.0.1
cost | total_cost | MISSING FROM v6.0.1
cost | total_paid | MISSING FROM v6.0.1
cost | paid_by_payer | MISSING FROM v6.0.1
cost | paid_by_patient | MISSING FROM v6.0.1
cost | paid_patient_copay | MISSING FROM v6.0.1
cost | paid_patient_coinsurance | MISSING FROM v6.0.1
cost | paid_patient_deductible | MISSING FROM v6.0.1
cost | paid_by_primary | MISSING FROM v6.0.1
cost | paid_ingredient_cost | MISSING FROM v6.0.1
cost | paid_dispensing_fee | MISSING FROM v6.0.1
cost | amount_allowed | MISSING FROM v6.0.1
cost | cost_domain_id | MISSING FROM v6.0.1
cost | reveue_code_source_value | MISSING FROM v6.0.1
death | person_id | MISSING FROM v6.0.1
death | death_date | MISSING FROM v6.0.1
death | death_datetime | MISSING FROM v6.0.1
death | death_type_concept_id | MISSING FROM v6.0.1
death | cause_concept_id | MISSING FROM v6.0.1
death | cause_source_concept_id | MISSING FROM v6.0.1
death | cause_source_value | MISSING FROM v6.0.1
device_exposure | device_exposure_id | IN BOTH
device_exposure | person_id | IN BOTH
device_exposure | device_concept_id | IN BOTH
device_exposure | device_exposure_start_date | IN BOTH
device_exposure | device_exposure_start_datetime | IN BOTH
device_exposure | device_exposure_end_date | IN BOTH
device_exposure | device_exposure_end_datetime | IN BOTH
device_exposure | device_type_concept_id | IN BOTH
device_exposure | quantity | IN BOTH
device_exposure | provider_id | IN BOTH
device_exposure | visit_occurrence_id | IN BOTH
device_exposure | visit_detail_id | IN BOTH
device_exposure | device_source_concept_id | IN BOTH
device_exposure | device_source_value | IN BOTH
device_exposure | unique_device_id | IN BOTH
device_exposure | production_id | MISSING FROM v6.0.1
device_exposure | unit_concept_id | MISSING FROM v6.0.1
device_exposure | unit_source_value | MISSING FROM v6.0.1
device_exposure | unit_source_concept_id | MISSING FROM v6.0.1
domain | domain_concept_id | IN BOTH
domain | domain_id | IN BOTH
domain | domain_name | IN BOTH
dose_era | dose_era_id | IN BOTH
dose_era | person_id | IN BOTH
dose_era | drug_concept_id | IN BOTH
dose_era | unit_concept_id | IN BOTH
dose_era | dose_value | IN BOTH
dose_era | dose_era_start_datetime | MISSING FROM v5.4.0
dose_era | dose_era_end_datetime | MISSING FROM v5.4.0
dose_era | dose_era_start_date | MISSING FROM v6.0.1
dose_era | dose_era_end_date | MISSING FROM v6.0.1
drug_era | drug_era_id | IN BOTH
drug_era | person_id | IN BOTH
drug_era | drug_concept_id | IN BOTH
drug_era | drug_exposure_count | IN BOTH
drug_era | gap_days | IN BOTH
drug_era | drug_era_start_datetime | MISSING FROM v5.4.0
drug_era | drug_era_end_datetime | MISSING FROM v5.4.0
drug_era | drug_era_start_date | MISSING FROM v6.0.1
drug_era | drug_era_end_date | MISSING FROM v6.0.1
drug_exposure | drug_exposure_id | IN BOTH
drug_exposure | person_id | IN BOTH
drug_exposure | drug_concept_id | IN BOTH
drug_exposure | drug_exposure_start_date | IN BOTH
drug_exposure | drug_exposure_start_datetime | IN BOTH
drug_exposure | drug_exposure_end_date | IN BOTH
drug_exposure | drug_exposure_end_datetime | IN BOTH
drug_exposure | verbatim_end_date | IN BOTH
drug_exposure | drug_type_concept_id | IN BOTH
drug_exposure | refills | IN BOTH
drug_exposure | quantity | IN BOTH
drug_exposure | days_supply | IN BOTH
drug_exposure | route_concept_id | IN BOTH
drug_exposure | provider_id | IN BOTH
drug_exposure | visit_occurrence_id | IN BOTH
drug_exposure | visit_detail_id | IN BOTH
drug_exposure | drug_source_concept_id | IN BOTH
drug_exposure | stop_reason | IN BOTH
drug_exposure | sig | IN BOTH
drug_exposure | lot_number | IN BOTH
drug_exposure | drug_source_value | IN BOTH
drug_exposure | route_source_value | IN BOTH
drug_exposure | dose_unit_source_value | IN BOTH
drug_strength | drug_concept_id | IN BOTH
drug_strength | ingredient_concept_id | IN BOTH
drug_strength | amount_value | IN BOTH
drug_strength | amount_unit_concept_id | IN BOTH
drug_strength | numerator_value | IN BOTH
drug_strength | numerator_unit_concept_id | IN BOTH
drug_strength | denominator_value | IN BOTH
drug_strength | denominator_unit_concept_id | IN BOTH
drug_strength | box_size | IN BOTH
drug_strength | valid_start_date | IN BOTH
drug_strength | valid_end_date | IN BOTH
drug_strength | invalid_reason | IN BOTH
episode | episode_id | MISSING FROM v6.0.1
episode | person_id | MISSING FROM v6.0.1
episode | episode_concept_id | MISSING FROM v6.0.1
episode | episode_start_date | MISSING FROM v6.0.1
episode | episode_start_datetime | MISSING FROM v6.0.1
episode | episode_end_date | MISSING FROM v6.0.1
episode | episode_end_datetime | MISSING FROM v6.0.1
episode | episode_parent_id | MISSING FROM v6.0.1
episode | episode_number | MISSING FROM v6.0.1
episode | episode_object_concept_id | MISSING FROM v6.0.1
episode | episode_type_concept_id | MISSING FROM v6.0.1
episode | episode_source_value | MISSING FROM v6.0.1
episode | episode_source_concept_id | MISSING FROM v6.0.1
episode_event | episode_id | MISSING FROM v6.0.1
episode_event | event_id | MISSING FROM v6.0.1
episode_event | episode_event_field_concept_id | MISSING FROM v6.0.1
fact_relationship | domain_concept_id_1 | IN BOTH
fact_relationship | fact_id_1 | IN BOTH
fact_relationship | domain_concept_id_2 | IN BOTH
fact_relationship | fact_id_2 | IN BOTH
fact_relationship | relationship_concept_id | IN BOTH
location | location_id | IN BOTH
location | address_1 | IN BOTH
location | address_2 | IN BOTH
location | city | IN BOTH
location | state | IN BOTH
location | zip | IN BOTH
location | county | IN BOTH
location | location_source_value | IN BOTH
location | latitude | IN BOTH
location | longitude | IN BOTH
location | country_concept_id | MISSING FROM v6.0.1
location | country_source_value | MISSING FROM v6.0.1
location_history | location_id | MISSING FROM v5.4.0
location_history | relationship_type_concept_id | MISSING FROM v5.4.0
location_history | domain_id | MISSING FROM v5.4.0
location_history | entity_id | MISSING FROM v5.4.0
location_history | start_date | MISSING FROM v5.4.0
location_history | end_date | MISSING FROM v5.4.0
measurement | measurement_id | IN BOTH
measurement | person_id | IN BOTH
measurement | measurement_concept_id | IN BOTH
measurement | measurement_date | IN BOTH
measurement | measurement_datetime | IN BOTH
measurement | measurement_time | IN BOTH
measurement | measurement_type_concept_id | IN BOTH
measurement | operator_concept_id | IN BOTH
measurement | value_as_number | IN BOTH
measurement | value_as_concept_id | IN BOTH
measurement | unit_concept_id | IN BOTH
measurement | range_low | IN BOTH
measurement | range_high | IN BOTH
measurement | provider_id | IN BOTH
measurement | visit_occurrence_id | IN BOTH
measurement | visit_detail_id | IN BOTH
measurement | measurement_source_concept_id | IN BOTH
measurement | measurement_source_value | IN BOTH
measurement | unit_source_value | IN BOTH
measurement | value_source_value | IN BOTH
measurement | unit_source_id | MISSING FROM v6.0.1
measurement | measurement_event_id | MISSING FROM v6.0.1
measurement | meas_event_field_concept_id | MISSING FROM v6.0.1
metadata | metadata_concept_id | IN BOTH
metadata | metadata_type_concept_id | IN BOTH
metadata | value_as_concept_id | IN BOTH
metadata | metadata_date | IN BOTH
metadata | metadata_datetime | IN BOTH
metadata | name | IN BOTH
metadata | value_as_string | IN BOTH
metadata | metadata_id | MISSING FROM v6.0.1
metadata | value_as_number | MISSING FROM v6.0.1
note | note_id | IN BOTH
note | person_id | IN BOTH
note | note_date | IN BOTH
note | note_datetime | IN BOTH
note | note_type_concept_id | IN BOTH
note | note_class_concept_id | IN BOTH
note | encoding_concept_id | IN BOTH
note | language_concept_id | IN BOTH
note | provider_id | IN BOTH
note | visit_occurrence_id | IN BOTH
note | visit_detail_id | IN BOTH
note | note_title | IN BOTH
note | note_text | IN BOTH
note | note_source_value | IN BOTH
note | note_event_id | IN BOTH
note | note_event_field_concept_id | IN BOTH
note_nlp | note_nlp_id | IN BOTH
note_nlp | note_id | IN BOTH
note_nlp | section_concept_id | IN BOTH
note_nlp | note_nlp_concept_id | IN BOTH
note_nlp | note_nlp_source_concept_id | IN BOTH
note_nlp | nlp_date | IN BOTH
note_nlp | nlp_datetime | IN BOTH
note_nlp | snippet | IN BOTH
note_nlp | offset | IN BOTH
note_nlp | lexical_variant | IN BOTH
note_nlp | nlp_system | IN BOTH
note_nlp | term_exists | IN BOTH
note_nlp | term_temporal | IN BOTH
note_nlp | term_modifiers | IN BOTH
observation | observation_id | IN BOTH
observation | person_id | IN BOTH
observation | observation_concept_id | IN BOTH
observation | observation_date | IN BOTH
observation | observation_datetime | IN BOTH
observation | observation_type_concept_id | IN BOTH
observation | value_as_number | IN BOTH
observation | value_as_concept_id | IN BOTH
observation | qualifier_concept_id | IN BOTH
observation | unit_concept_id | IN BOTH
observation | provider_id | IN BOTH
observation | visit_occurrence_id | IN BOTH
observation | visit_detail_id | IN BOTH
observation | observation_source_concept_id | IN BOTH
observation | value_as_string | IN BOTH
observation | observation_source_value | IN BOTH
observation | unit_source_value | IN BOTH
observation | qualifier_source_value | IN BOTH
observation | observation_event_id | IN BOTH
observation | obs_event_field_concept_id | IN BOTH
observation | value_as_datetime | MISSING FROM v5.4.0
observation | value_source_value | MISSING FROM v6.0.1
observation_period | observation_period_id | IN BOTH
observation_period | person_id | IN BOTH
observation_period | observation_period_start_date | IN BOTH
observation_period | observation_period_end_date | IN BOTH
observation_period | period_type_concept_id | IN BOTH
payer_plan_period | payer_plan_period_id | IN BOTH
payer_plan_period | person_id | IN BOTH
payer_plan_period | payer_plan_period_start_date | IN BOTH
payer_plan_period | payer_plan_period_end_date | IN BOTH
payer_plan_period | payer_concept_id | IN BOTH
payer_plan_period | payer_source_concept_id | IN BOTH
payer_plan_period | plan_concept_id | IN BOTH
payer_plan_period | plan_source_concept_id | IN BOTH
payer_plan_period | sponsor_concept_id | IN BOTH
payer_plan_period | sponsor_source_concept_id | IN BOTH
payer_plan_period | stop_reason_concept_id | IN BOTH
payer_plan_period | stop_reason_source_concept_id | IN BOTH
payer_plan_period | payer_source_value | IN BOTH
payer_plan_period | plan_source_value | IN BOTH
payer_plan_period | sponsor_source_value | IN BOTH
payer_plan_period | family_source_value | IN BOTH
payer_plan_period | stop_reason_source_value | IN BOTH
payer_plan_period | contract_person_id | MISSING FROM v5.4.0
payer_plan_period | contract_concept_id | MISSING FROM v5.4.0
payer_plan_period | contract_source_value | MISSING FROM v5.4.0
payer_plan_period | contract_source_concept_id | MISSING FROM v5.4.0
person | person_id | IN BOTH
person | gender_concept_id | IN BOTH
person | year_of_birth | IN BOTH
person | month_of_birth | IN BOTH
person | day_of_birth | IN BOTH
person | birth_datetime | IN BOTH
person | race_concept_id | IN BOTH
person | ethnicity_concept_id | IN BOTH
person | location_id | IN BOTH
person | provider_id | IN BOTH
person | care_site_id | IN BOTH
person | gender_source_concept_id | IN BOTH
person | race_source_concept_id | IN BOTH
person | ethnicity_source_concept_id | IN BOTH
person | person_source_value | IN BOTH
person | gender_source_value | IN BOTH
person | race_source_value | IN BOTH
person | ethnicity_source_value | IN BOTH
person | death_datetime | MISSING FROM v5.4.0
procedure_occurrence | procedure_occurrence_id | IN BOTH
procedure_occurrence | person_id | IN BOTH
procedure_occurrence | procedure_concept_id | IN BOTH
procedure_occurrence | procedure_date | IN BOTH
procedure_occurrence | procedure_datetime | IN BOTH
procedure_occurrence | procedure_type_concept_id | IN BOTH
procedure_occurrence | modifier_concept_id | IN BOTH
procedure_occurrence | quantity | IN BOTH
procedure_occurrence | provider_id | IN BOTH
procedure_occurrence | visit_occurrence_id | IN BOTH
procedure_occurrence | visit_detail_id | IN BOTH
procedure_occurrence | procedure_source_concept_id | IN BOTH
procedure_occurrence | procedure_source_value | IN BOTH
procedure_occurrence | modifier_source_value | IN BOTH
procedure_occurrence | procedure_end_date | MISSING FROM v6.0.1
procedure_occurrence | procedure_end_datetime | MISSING FROM v6.0.1
provider | provider_id | IN BOTH
provider | specialty_concept_id | IN BOTH
provider | care_site_id | IN BOTH
provider | year_of_birth | IN BOTH
provider | gender_concept_id | IN BOTH
provider | specialty_source_concept_id | IN BOTH
provider | gender_source_concept_id | IN BOTH
provider | provider_name | IN BOTH
provider | npi | IN BOTH
provider | dea | IN BOTH
provider | provider_source_value | IN BOTH
provider | specialty_source_value | IN BOTH
provider | gender_source_value | IN BOTH
relationship | relationship_concept_id | IN BOTH
relationship | relationship_id | IN BOTH
relationship | relationship_name | IN BOTH
relationship | is_hierarchical | IN BOTH
relationship | defines_ancestry | IN BOTH
relationship | reverse_relationship_id | IN BOTH
source_to_concept_map | source_concept_id | IN BOTH
source_to_concept_map | target_concept_id | IN BOTH
source_to_concept_map | valid_start_date | IN BOTH
source_to_concept_map | valid_end_date | IN BOTH
source_to_concept_map | source_code | IN BOTH
source_to_concept_map | source_vocabulary_id | IN BOTH
source_to_concept_map | source_code_description | IN BOTH
source_to_concept_map | target_vocabulary_id | IN BOTH
source_to_concept_map | invalid_reason | IN BOTH
specimen | specimen_id | IN BOTH
specimen | person_id | IN BOTH
specimen | specimen_concept_id | IN BOTH
specimen | specimen_type_concept_id | IN BOTH
specimen | specimen_date | IN BOTH
specimen | specimen_datetime | IN BOTH
specimen | quantity | IN BOTH
specimen | unit_concept_id | IN BOTH
specimen | anatomic_site_concept_id | IN BOTH
specimen | disease_status_concept_id | IN BOTH
specimen | specimen_source_id | IN BOTH
specimen | specimen_source_value | IN BOTH
specimen | unit_source_value | IN BOTH
specimen | anatomic_site_source_value | IN BOTH
specimen | disease_status_source_value | IN BOTH
survey_conduct | survey_conduct_id | MISSING FROM v5.4.0
survey_conduct | person_id | MISSING FROM v5.4.0
survey_conduct | survey_concept_id | MISSING FROM v5.4.0
survey_conduct | survey_start_date | MISSING FROM v5.4.0
survey_conduct | survey_start_datetime | MISSING FROM v5.4.0
survey_conduct | survey_end_date | MISSING FROM v5.4.0
survey_conduct | survey_end_datetime | MISSING FROM v5.4.0
survey_conduct | provider_id | MISSING FROM v5.4.0
survey_conduct | assisted_concept_id | MISSING FROM v5.4.0
survey_conduct | respondent_type_concept_id | MISSING FROM v5.4.0
survey_conduct | timing_concept_id | MISSING FROM v5.4.0
survey_conduct | collection_method_concept_id | MISSING FROM v5.4.0
survey_conduct | assisted_source_value | MISSING FROM v5.4.0
survey_conduct | respondent_type_source_value | MISSING FROM v5.4.0
survey_conduct | timing_source_value | MISSING FROM v5.4.0
survey_conduct | collection_method_source_value | MISSING FROM v5.4.0
survey_conduct | survey_source_value | MISSING FROM v5.4.0
survey_conduct | survey_source_concept_id | MISSING FROM v5.4.0
survey_conduct | survey_source_identifier | MISSING FROM v5.4.0
survey_conduct | validated_survey_concept_id | MISSING FROM v5.4.0
survey_conduct | validated_survey_source_value | MISSING FROM v5.4.0
survey_conduct | survey_version_number | MISSING FROM v5.4.0
survey_conduct | visit_occurrence_id | MISSING FROM v5.4.0
survey_conduct | response_visit_occurrence_id | MISSING FROM v5.4.0
visit_detail | visit_detail_id | IN BOTH
visit_detail | person_id | IN BOTH
visit_detail | visit_detail_concept_id | IN BOTH
visit_detail | visit_detail_start_date | IN BOTH
visit_detail | visit_detail_start_datetime | IN BOTH
visit_detail | visit_detail_end_date | IN BOTH
visit_detail | visit_detail_end_datetime | IN BOTH
visit_detail | visit_detail_type_concept_id | IN BOTH
visit_detail | provider_id | IN BOTH
visit_detail | care_site_id | IN BOTH
visit_detail | preceding_visit_detail_id | IN BOTH
visit_detail | visit_detail_source_concept_id | IN BOTH
visit_detail | visit_occurrence_id | IN BOTH
visit_detail | visit_detail_source_value | IN BOTH
visit_detail | admitted_from_concept_id | IN BOTH
visit_detail | admitted_from_source_value | IN BOTH
visit_detail | discharge_to_source_value | MISSING FROM v5.4.0
visit_detail | discharge_to_concept_id | MISSING FROM v5.4.0
visit_detail | visit_detail_parent_id | MISSING FROM v5.4.0
visit_detail | discharged_to_concept_id | MISSING FROM v6.0.1
visit_detail | discharged_to_source_value | MISSING FROM v6.0.1
visit_detail | parent_visit_detail_id | MISSING FROM v6.0.1
visit_occurrence | visit_occurrence_id | IN BOTH
visit_occurrence | person_id | IN BOTH
visit_occurrence | visit_concept_id | IN BOTH
visit_occurrence | visit_start_date | IN BOTH
visit_occurrence | visit_start_datetime | IN BOTH
visit_occurrence | visit_end_date | IN BOTH
visit_occurrence | visit_end_datetime | IN BOTH
visit_occurrence | visit_type_concept_id | IN BOTH
visit_occurrence | provider_id | IN BOTH
visit_occurrence | care_site_id | IN BOTH
visit_occurrence | visit_source_concept_id | IN BOTH
visit_occurrence | preceding_visit_occurrence_id | IN BOTH
visit_occurrence | visit_source_value | IN BOTH
visit_occurrence | admitted_from_concept_id | IN BOTH
visit_occurrence | admitted_from_source_value | IN BOTH
visit_occurrence | discharge_to_concept_id | MISSING FROM v5.4.0
visit_occurrence | discharge_to_source_value | MISSING FROM v5.4.0
visit_occurrence | discharged_to_concept_id | MISSING FROM v6.0.1
visit_occurrence | discharged_to_source_value | MISSING FROM v6.0.1
vocabulary | vocabulary_id | IN BOTH
vocabulary | vocabulary_name | IN BOTH
vocabulary | vocabulary_reference | IN BOTH
vocabulary | vocabulary_version | IN BOTH
vocabulary | vocabulary_concept_id | IN BOTH

View File

@ -0,0 +1,134 @@
-- DEATH
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 )
DISTKEY(person_id);
-- EPISODE
CREATE TABLE 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 )
DISTKEY(person_id);
-- EPISODE_EVENT
CREATE TABLE EPISODE_EVENT (episode_id bigint NOT NULL,
event_id bigint NOT NULL,
episode_event_field_concept_id integer NOT NULL )
DISTSTYLE ALL;
-- PERSON
alter table person drop column death_datetime;
-- VISIT_OCCURRENCE
alter table visit_occurrence rename column discharge_to_concept_id to discharged_to_concept_id;
alter table visit_occurrence rename column discharge_to_source_value to discharged_to_source_value;
-- VISIT_DETAIL
alter table visit_detail rename column discharge_to_concept_id to discharged_to_concept_id;
alter table visit_detail rename column discharge_to_source_value to discharged_to_source_value;
alter table visit_detail rename column visit_detail_parent_id to parent_visit_detail_id;
-- PROCEDURE_OCCURRENCE
alter table procedure_occurrence add column procedure_end_date date;
alter table procedure_occurrence add column procedure_end_datetime timestamp;
-- DEVICE_EXPOSURE
alter table device_exposure add column production_id varchar(255);
alter table device_exposure add column unit_concept_id integer;
alter table device_exposure add column unit_source_value varchar(50);
alter table device_exposure add column unit_source_concept_id integer;
-- MEASUREMENT
alter table measurement add column unit_source_id integer;
alter table measurement add column measurement_event_id bigint;
alter table measurement add column meas_event_field_concept_id integer;
-- OBSERVATION
alter table observation add column value_source_value varchar(50);
alter table observation drop column value_as_datetime;
-- LOCATION
alter location add column country_concept_id integer;
alter location add column country_source_value varchar(80);
-- PAYER_PLAN_PERIOD
alter table payer_plan_period drop column contract_person_id;
alter table payer_plan_period drop column contract_concept_id;
alter table payer_plan_period drop column contract_source_value;
alter table payer_plan_period drop column contract_source_concept_id;
-- COST
alter table cost drop column person_id;
alter table cost drop column cost_event_field_concept_id;
alter table cost drop column cost_concept_id;
alter table cost drop column cost_source_concept_id;
alter table cost drop column cost_source_value;
alter table cost drop column cost;
alter table cost drop column incurred_date;
alter table cost drop column billed_date;
alter table cost drop column paid_date;
alter table cost drop column revenue_code_source_value;
alter cost add column total_charge float;
alter cost add column total_cost float;
alter cost add column total_paid float;
alter cost add column paid_by_payer float;
alter cost add column paid_by_patient float;
alter cost add column paid_by_primary float;
alter cost add column paid_patient_copay float;
alter cost add column paid_patient_coinsurance float;
alter cost add column paid_patient_deductible float;
alter cost add column paid_ingredient_cost float;
alter cost add column paid_dispensing_fee float;
alter cost add column amount_allowed float;
alter cost add column cost_domain_id varchar(20);
alter cost add column revenue_code_source_value varchar(50);
-- DRUG_ERA
alter table drug_era rename column drug_era_start_datetime to drug_era_start_date;
alter table drug_era rename column drug_era_end_datetime to drug_era_end_date;
alter table drug_era alter column drug_era_start_date date;
alter table drug_era alter column drug_era_end_date date;
-- DOSE_ERA
alter table dose_era rename column dose_era_start_datetime to dose_era_start_date;
alter table dose_era rename column dose_era_end_datetime to dose_era_end_date;
alter table dose_era alter column dose_era_start_date date;
alter table dose_era alter column dose_era_end_date date;
-- CONDITION_ERA
alter table condition_era rename column condition_era_start_datetime to condition_era_start_date;
alter table condition_era rename column condition_era_end_datetime to condition_era_end_date;
alter table condition_era alter column condition_era_start_date date;
alter table condition_era alter column condition_era_end_date date;
-- METADATA
alter table metadata add column metadata_id integer;
alter table metadata add column value_as_number float;
-- CDM_SOURCE
alter table cdm_source add column cdm_version_concept_id integer;