diff --git a/CodeExcerpts/DerivedTables/GenerateEra.sql b/CodeExcerpts/DerivedTables/GenerateEra.sql new file mode 100644 index 0000000..2db0e6f --- /dev/null +++ b/CodeExcerpts/DerivedTables/GenerateEra.sql @@ -0,0 +1,363 @@ +/********************************************************************************* +# Copyright 2017 Observational Health Data Sciences and Informatics +# +# +# Licensed under the Apache License, Version 2.0 (the "License"); +# you may not use this file except in compliance with the License. +# You may obtain a copy of the License at +# +# http://www.apache.org/licenses/LICENSE-2.0 +# +# Unless required by applicable law or agreed to in writing, software +# distributed under the License is distributed on an "AS IS" BASIS, +# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. +# See the License for the specific language governing permissions and +# limitations under the License. +********************************************************************************/ +/******************************************************************************* + +PURPOSE: Generate Era table (based on conversion script from V4 V5). + +last revised: Jun 2017 +authors: Patrick Ryan, Chris Knoll, Anthony Sena, Vojtech Huser + + +OHDSI-SQL File Instructions +----------------------------- + + 1. Set parameter name of schema that contains CDMv4 instance + (@SOURCE_CDMV4, @SOURCE_CDMV4_SCHEMA) + 2. Set parameter name of schema that contains CDMv5 instance + (@TARGET_CDMV5, @TARGET_CDMV5_SCHEMA) + 3. Run this script through SqlRender to produce a script that will work in your + source dialect. SqlRender can be found here: https://github.com/OHDSI/SqlRender + 4. Run the script produced by SQL Render on your target RDBDMS. + + File Instructions +------------------------- + + 1. This script will hold a number of placeholders for your CDM V4 and CDMV5 + database/schema. In order to make this file work in your environment, you + should plan to do a global "FIND AND REPLACE" on this file to fill in the + file with values that pertain to your environment. The following are the + tokens you should use when doing your "FIND AND REPLACE" operation: + + + [CMD] + [CDM].[CDMSCHEMA] + + +*********************************************************************************/ +/* SCRIPT PARAMETERS */ + + + {DEFAULT @TARGET_CDMV5 = '[CDM]' } -- The target CDMv5 database name + {DEFAULT @TARGET_CDMV5_SCHEMA = '[CDM].[CDMSCHEMA]' } -- the target CDMv5 database plus schema + +USE @TARGET_CDMV5; + + + +/**** + +DRUG ERA +Note: Eras derived from DRUG_EXPOSURE table, using 30d gap + + ****/ +IF OBJECT_ID('tempdb..#cteDrugTarget', 'U') IS NOT NULL + DROP TABLE #cteDrugTarget; + +/* / */ + +-- Normalize DRUG_EXPOSURE_END_DATE to either the existing drug exposure end date, or add days supply, or add 1 day to the start date +SELECT d.DRUG_EXPOSURE_ID + ,d.PERSON_ID + ,c.CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE + ,COALESCE(DRUG_EXPOSURE_END_DATE, DATEADD(day, DAYS_SUPPLY, DRUG_EXPOSURE_START_DATE), DATEADD(day, 1, DRUG_EXPOSURE_START_DATE)) AS DRUG_EXPOSURE_END_DATE + ,c.CONCEPT_ID AS INGREDIENT_CONCEPT_ID +INTO #cteDrugTarget +FROM @TARGET_CDMV5_SCHEMA.DRUG_EXPOSURE d +INNER JOIN @TARGET_CDMV5_SCHEMA.CONCEPT_ANCESTOR ca ON ca.DESCENDANT_CONCEPT_ID = d.DRUG_CONCEPT_ID +INNER JOIN @TARGET_CDMV5_SCHEMA.CONCEPT c ON ca.ANCESTOR_CONCEPT_ID = c.CONCEPT_ID +WHERE c.VOCABULARY_ID = 'RxNorm' + AND c.CONCEPT_CLASS_ID = 'Ingredient'; + +/* / */ + +IF OBJECT_ID('tempdb..#cteEndDates', 'U') IS NOT NULL + DROP TABLE #cteEndDates; + +/* / */ + +SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DATEADD(day, - 30, EVENT_DATE) AS END_DATE -- unpad the end date +INTO #cteEndDates +FROM ( + SELECT E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM ( + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM ( + -- select the start dates, assigning a row number to each + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,0 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM #cteDrugTarget + + UNION ALL + + -- add the end dates with NULL as the row number, padding the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DATEADD(day, 30, DRUG_EXPOSURE_END_DATE) + ,1 AS EVENT_TYPE + ,NULL + FROM #cteDrugTarget + ) RAWDATA + ) E1 + INNER JOIN ( + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM #cteDrugTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.INGREDIENT_CONCEPT_ID = E2.INGREDIENT_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E +WHERE 2 * E.START_ORDINAL - E.OVERALL_ORD = 0; + +/* / */ + +IF OBJECT_ID('tempdb..#cteDrugExpEnds', 'U') IS NOT NULL + DROP TABLE #cteDrugExpEnds; + +/* / */ + +SELECT d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE +INTO #cteDrugExpEnds +FROM #cteDrugTarget d +INNER JOIN #cteEndDates e ON d.PERSON_ID = e.PERSON_ID + AND d.INGREDIENT_CONCEPT_ID = e.INGREDIENT_CONCEPT_ID + AND e.END_DATE >= d.DRUG_EXPOSURE_START_DATE +GROUP BY d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE; + +/* / */ + +INSERT INTO @TARGET_CDMV5_SCHEMA.drug_era +SELECT row_number() OVER ( + ORDER BY person_id + ) AS drug_era_id + ,person_id + ,INGREDIENT_CONCEPT_ID + ,min(DRUG_EXPOSURE_START_DATE) AS drug_era_start_date + ,ERA_END_DATE + ,COUNT(*) AS DRUG_EXPOSURE_COUNT + ,30 AS gap_days +FROM #cteDrugExpEnds +GROUP BY person_id + ,INGREDIENT_CONCEPT_ID + ,drug_type_concept_id + ,ERA_END_DATE; + + + + + + + + + + + + + + + + + + + + + + + + + + + + + +/**** + +CONDITION ERA +Note: Eras derived from CONDITION_OCCURRENCE table, using 30d gap + + ****/ +IF OBJECT_ID('tempdb..#condition_era_phase_1', 'U') IS NOT NULL + DROP TABLE #condition_era_phase_1; + +/* / */ + +IF OBJECT_ID('tempdb..#cteConditionTarget', 'U') IS NOT NULL + DROP TABLE #cteConditionTarget; + +/* / */ + +-- create base eras from the concepts found in condition_occurrence +SELECT co.PERSON_ID + ,co.condition_concept_id + ,co.CONDITION_START_DATE + ,COALESCE(co.CONDITION_END_DATE, DATEADD(day, 1, CONDITION_START_DATE)) AS CONDITION_END_DATE +INTO #cteConditionTarget +FROM @TARGET_CDMV5_SCHEMA.CONDITION_OCCURRENCE co; + +/* / */ + +IF OBJECT_ID('tempdb..#cteCondEndDates', 'U') IS NOT NULL + DROP TABLE #cteCondEndDates; + +/* / */ + +SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,DATEADD(day, - 30, EVENT_DATE) AS END_DATE -- unpad the end date +INTO #cteCondEndDates +FROM ( + SELECT E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM ( + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM ( + -- select the start dates, assigning a row number to each + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,- 1 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM #cteConditionTarget + + UNION ALL + + -- pad the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,DATEADD(day, 30, CONDITION_END_DATE) + ,1 AS EVENT_TYPE + ,NULL + FROM #cteConditionTarget + ) RAWDATA + ) E1 + INNER JOIN ( + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM #cteConditionTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.CONDITION_CONCEPT_ID = E2.CONDITION_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E +WHERE (2 * E.START_ORDINAL) - E.OVERALL_ORD = 0; + +/* / */ + +IF OBJECT_ID('tempdb..#cteConditionEnds', 'U') IS NOT NULL + DROP TABLE #cteConditionEnds; + +/* / */ + +SELECT c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE +INTO #cteConditionEnds +FROM #cteConditionTarget c +INNER JOIN #cteCondEndDates e ON c.PERSON_ID = e.PERSON_ID + AND c.CONDITION_CONCEPT_ID = e.CONDITION_CONCEPT_ID + AND e.END_DATE >= c.CONDITION_START_DATE +GROUP BY c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE; + +/* / */ + +INSERT INTO @TARGET_CDMV5_SCHEMA.condition_era ( + condition_era_id + ,person_id + ,condition_concept_id + ,condition_era_start_date + ,condition_era_end_date + ,condition_occurrence_count + ) +SELECT row_number() OVER ( + ORDER BY person_id + ) AS condition_era_id + ,person_id + ,CONDITION_CONCEPT_ID + ,min(CONDITION_START_DATE) AS CONDITION_ERA_START_DATE + ,ERA_END_DATE AS CONDITION_ERA_END_DATE + ,COUNT(*) AS CONDITION_OCCURRENCE_COUNT +FROM #cteConditionEnds +GROUP BY person_id + ,CONDITION_CONCEPT_ID + ,ERA_END_DATE; + diff --git a/CodeExcerpts/DerivedTables/README.md b/CodeExcerpts/DerivedTables/README.md new file mode 100644 index 0000000..cd7bdad --- /dev/null +++ b/CodeExcerpts/DerivedTables/README.md @@ -0,0 +1,5 @@ +# Derived tables + +R script is used to take parametized sql (in this folder) and generate flavored SQL files (see respective flavor folder) + + diff --git a/CodeExcerpts/DerivedTables/TranslateSnippet.R b/CodeExcerpts/DerivedTables/TranslateSnippet.R new file mode 100644 index 0000000..e8cfd0f --- /dev/null +++ b/CodeExcerpts/DerivedTables/TranslateSnippet.R @@ -0,0 +1,66 @@ + + +library(SqlRender);library(RCurl) + +#specify URL of sql code written in parametized SQL (see some examples below) +# url<-'https://raw.githubusercontent.com/OHDSI/CommonDataModel/master/Version4%20To%20Version5%20Conversion/OMOP%20CDMv4%20to%20CDMv5%20-%20OHDSI-SQL.sql' +url<-'https://raw.githubusercontent.com/OHDSI/Achilles/master/inst/sql/sql_server/export_v5/drugera/sqlPrevalenceByGenderAgeYear.sql' + +#get the code +sql<-getURL(url) + + +#inspect what parameters are needed by searching for @ + +#decide your parameters +results='ccae' +vocab='public' + + +#fill in parameters +tta<-SqlRender::renderSql(sql,results_database_schema=results,vocab_database_schema=vocab) + + +#translate into target dialect + +ttb<-SqlRender::translateSql(tta$sql,targetDialect = 'postgresql') + + +#write final SQL to a local file +cat(ttb$sql,file='c:/temp/drug_era_2017.sql') +sql<-ttb$sql + + + + + + + +#loop for making flavors + +fname<-'GenerateEra.sql' +flavors<-c( +'oracle' +,'postgresql' +,'pdw' +,'redshift' +,'impala' +,'netezza' +,'bigquery') +#,'sql server') + + + +for (flavor in flavors){ + print(flavor) + sql<-readChar(fname, file.info(fname)$size) + tta<-SqlRender::renderSql(sql,results_database_schema='results',vocab_database_schema='vocab') + ttb<-SqlRender::translateSql(tta$sql,targetDialect = flavor) + dir.create(flavor) + cat(ttb$sql,file=file.path(flavor,paste0(fname))) + # sql<-ttb$sql + +} + + + diff --git a/CodeExcerpts/DerivedTables/impala/GenerateEra.sql b/CodeExcerpts/DerivedTables/impala/GenerateEra.sql new file mode 100644 index 0000000..73a42a0 --- /dev/null +++ b/CodeExcerpts/DerivedTables/impala/GenerateEra.sql @@ -0,0 +1,380 @@ +/********************************************************************************* +# Copyright 2017 Observational Health Data Sciences and Informatics +# +# +# Licensed under the Apache License, Version 2.0 (the "License"); +# you may not use this file except in compliance with the License. +# You may obtain a copy of the License at +# +# http://www.apache.org/licenses/LICENSE-2.0 +# +# Unless required by applicable law or agreed to in writing, software +# distributed under the License is distributed on an "AS IS" BASIS, +# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. +# See the License for the specific language governing permissions and +# limitations under the License. +********************************************************************************/ +/******************************************************************************* + +PURPOSE: Generate Era table (based on conversion script from V4 V5). + +last revised: Jun 2017 +authors: Patrick Ryan, Chris Knoll, Anthony Sena, Vojtech Huser + + +OHDSI-SQL File Instructions +----------------------------- + + 1. Set parameter name of schema that contains CDMv4 instance + (@SOURCE_CDMV4, @SOURCE_CDMV4_SCHEMA) + 2. Set parameter name of schema that contains CDMv5 instance + ([CDM], [CDM].[CDMSCHEMA]) + 3. Run this script through SqlRender to produce a script that will work in your + source dialect. SqlRender can be found here: https://github.com/OHDSI/SqlRender + 4. Run the script produced by SQL Render on your target RDBDMS. + + File Instructions +------------------------- + + 1. This script will hold a number of placeholders for your CDM V4 and CDMV5 + database/schema. In order to make this file work in your environment, you + should plan to do a global "FIND AND REPLACE" on this file to fill in the + file with values that pertain to your environment. The following are the + tokens you should use when doing your "FIND AND REPLACE" operation: + + + [CMD] + [CDM].[CDMSCHEMA] + + +*********************************************************************************/ +/* SCRIPT PARAMETERS */ + + + -- The target CDMv5 database name + -- the target CDMv5 database plus schema + +USE [CDM]; + + + +/**** + +DRUG ERA +Note: Eras derived from DRUG_EXPOSURE table, using 30d gap + + ****/ +DROP TABLE IF EXISTS iob2wlgwcteDrugTarget; + +/* / */ + +-- Normalize DRUG_EXPOSURE_END_DATE to either the existing drug exposure end date, or add days supply, or add 1 day to the start date +CREATE TABLE iob2wlgwcteDrugTarget + AS +SELECT +d.DRUG_EXPOSURE_ID + ,d.PERSON_ID + ,c.CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE + ,COALESCE(DRUG_EXPOSURE_END_DATE, DATE_ADD(CASE TYPEOF(DRUG_EXPOSURE_START_DATE ) WHEN 'TIMESTAMP' THEN CAST(DRUG_EXPOSURE_START_DATE AS TIMESTAMP) ELSE TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(DRUG_EXPOSURE_START_DATE AS STRING), 1, 4), SUBSTR(CAST(DRUG_EXPOSURE_START_DATE AS STRING), 5, 2), SUBSTR(CAST(DRUG_EXPOSURE_START_DATE AS STRING), 7, 2)), 'UTC') END, DAYS_SUPPLY), DATE_ADD(CASE TYPEOF(DRUG_EXPOSURE_START_DATE ) WHEN 'TIMESTAMP' THEN CAST(DRUG_EXPOSURE_START_DATE AS TIMESTAMP) ELSE TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(DRUG_EXPOSURE_START_DATE AS STRING), 1, 4), SUBSTR(CAST(DRUG_EXPOSURE_START_DATE AS STRING), 5, 2), SUBSTR(CAST(DRUG_EXPOSURE_START_DATE AS STRING), 7, 2)), 'UTC') END, 1)) AS DRUG_EXPOSURE_END_DATE + ,c.CONCEPT_ID AS INGREDIENT_CONCEPT_ID + +FROM +[CDM].[CDMSCHEMA].DRUG_EXPOSURE d +INNER JOIN [CDM].[CDMSCHEMA].CONCEPT_ANCESTOR ca ON ca.DESCENDANT_CONCEPT_ID = d.DRUG_CONCEPT_ID +INNER JOIN [CDM].[CDMSCHEMA].CONCEPT c ON ca.ANCESTOR_CONCEPT_ID = c.CONCEPT_ID +WHERE c.VOCABULARY_ID = 'RxNorm' + AND c.CONCEPT_CLASS_ID = 'Ingredient'; + +/* / */ + +DROP TABLE IF EXISTS iob2wlgwcteEndDates; + +/* / */ + +CREATE TABLE iob2wlgwcteEndDates + AS +SELECT +PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DATE_ADD(CASE TYPEOF(EVENT_DATE ) WHEN 'TIMESTAMP' THEN CAST(EVENT_DATE AS TIMESTAMP) ELSE TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(EVENT_DATE AS STRING), 1, 4), SUBSTR(CAST(EVENT_DATE AS STRING), 5, 2), SUBSTR(CAST(EVENT_DATE AS STRING), 7, 2)), 'UTC') END, - 30) AS END_DATE -- unpad the end date + +FROM +( + SELECT E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM ( + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM ( + -- select the start dates, assigning a row number to each + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,0 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM iob2wlgwcteDrugTarget + + UNION ALL + + -- add the end dates with NULL as the row number, padding the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DATE_ADD(CASE TYPEOF(DRUG_EXPOSURE_END_DATE ) WHEN 'TIMESTAMP' THEN CAST(DRUG_EXPOSURE_END_DATE AS TIMESTAMP) ELSE TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(DRUG_EXPOSURE_END_DATE AS STRING), 1, 4), SUBSTR(CAST(DRUG_EXPOSURE_END_DATE AS STRING), 5, 2), SUBSTR(CAST(DRUG_EXPOSURE_END_DATE AS STRING), 7, 2)), 'UTC') END, 30) + ,1 AS EVENT_TYPE + ,NULL + FROM iob2wlgwcteDrugTarget + ) RAWDATA + ) E1 + INNER JOIN ( + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM iob2wlgwcteDrugTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.INGREDIENT_CONCEPT_ID = E2.INGREDIENT_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E +WHERE 2 * E.START_ORDINAL - E.OVERALL_ORD = 0; + +/* / */ + +DROP TABLE IF EXISTS iob2wlgwcteDrugExpEnds; + +/* / */ + +CREATE TABLE iob2wlgwcteDrugExpEnds + AS +SELECT +d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM +iob2wlgwcteDrugTarget d +INNER JOIN iob2wlgwcteEndDates e ON d.PERSON_ID = e.PERSON_ID + AND d.INGREDIENT_CONCEPT_ID = e.INGREDIENT_CONCEPT_ID + AND e.END_DATE >= d.DRUG_EXPOSURE_START_DATE +GROUP BY d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE; + +/* / */ + +INSERT INTO [CDM].[CDMSCHEMA].drug_era +SELECT row_number() OVER ( + ORDER BY person_id + ) AS drug_era_id + ,person_id + ,INGREDIENT_CONCEPT_ID + ,min(DRUG_EXPOSURE_START_DATE) AS drug_era_start_date + ,ERA_END_DATE + ,COUNT(*) AS DRUG_EXPOSURE_COUNT + ,30 AS gap_days +FROM iob2wlgwcteDrugExpEnds +GROUP BY person_id + ,INGREDIENT_CONCEPT_ID + ,drug_type_concept_id + ,ERA_END_DATE; + + + + + + + + + + + + + + + + + + + + + + + + + + + + + +/**** + +CONDITION ERA +Note: Eras derived from CONDITION_OCCURRENCE table, using 30d gap + + ****/ +DROP TABLE IF EXISTS iob2wlgwcondition_era_phase_1; + +/* / */ + +DROP TABLE IF EXISTS iob2wlgwcteConditionTarget; + +/* / */ + +-- create base eras from the concepts found in condition_occurrence +CREATE TABLE iob2wlgwcteConditionTarget + AS +SELECT +co.PERSON_ID + ,co.condition_concept_id + ,co.CONDITION_START_DATE + ,COALESCE(co.CONDITION_END_DATE, DATE_ADD(CASE TYPEOF(CONDITION_START_DATE ) WHEN 'TIMESTAMP' THEN CAST(CONDITION_START_DATE AS TIMESTAMP) ELSE TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(CONDITION_START_DATE AS STRING), 1, 4), SUBSTR(CAST(CONDITION_START_DATE AS STRING), 5, 2), SUBSTR(CAST(CONDITION_START_DATE AS STRING), 7, 2)), 'UTC') END, 1)) AS CONDITION_END_DATE + +FROM +[CDM].[CDMSCHEMA].CONDITION_OCCURRENCE co; + +/* / */ + +DROP TABLE IF EXISTS iob2wlgwcteCondEndDates; + +/* / */ + +CREATE TABLE iob2wlgwcteCondEndDates + AS +SELECT +PERSON_ID + ,CONDITION_CONCEPT_ID + ,DATE_ADD(CASE TYPEOF(EVENT_DATE ) WHEN 'TIMESTAMP' THEN CAST(EVENT_DATE AS TIMESTAMP) ELSE TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(EVENT_DATE AS STRING), 1, 4), SUBSTR(CAST(EVENT_DATE AS STRING), 5, 2), SUBSTR(CAST(EVENT_DATE AS STRING), 7, 2)), 'UTC') END, - 30) AS END_DATE -- unpad the end date + +FROM +( + SELECT E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM ( + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM ( + -- select the start dates, assigning a row number to each + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,- 1 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM iob2wlgwcteConditionTarget + + UNION ALL + + -- pad the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,DATE_ADD(CASE TYPEOF(CONDITION_END_DATE ) WHEN 'TIMESTAMP' THEN CAST(CONDITION_END_DATE AS TIMESTAMP) ELSE TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(CONDITION_END_DATE AS STRING), 1, 4), SUBSTR(CAST(CONDITION_END_DATE AS STRING), 5, 2), SUBSTR(CAST(CONDITION_END_DATE AS STRING), 7, 2)), 'UTC') END, 30) + ,1 AS EVENT_TYPE + ,NULL + FROM iob2wlgwcteConditionTarget + ) RAWDATA + ) E1 + INNER JOIN ( + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM iob2wlgwcteConditionTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.CONDITION_CONCEPT_ID = E2.CONDITION_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E +WHERE (2 * E.START_ORDINAL) - E.OVERALL_ORD = 0; + +/* / */ + +DROP TABLE IF EXISTS iob2wlgwcteConditionEnds; + +/* / */ + +CREATE TABLE iob2wlgwcteConditionEnds + AS +SELECT +c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM +iob2wlgwcteConditionTarget c +INNER JOIN iob2wlgwcteCondEndDates e ON c.PERSON_ID = e.PERSON_ID + AND c.CONDITION_CONCEPT_ID = e.CONDITION_CONCEPT_ID + AND e.END_DATE >= c.CONDITION_START_DATE +GROUP BY c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE; + +/* / */ + +INSERT INTO [CDM].[CDMSCHEMA].condition_era ( + condition_era_id + ,person_id + ,condition_concept_id + ,condition_era_start_date + ,condition_era_end_date + ,condition_occurrence_count + ) +SELECT row_number() OVER ( + ORDER BY person_id + ) AS condition_era_id + ,person_id + ,CONDITION_CONCEPT_ID + ,min(CONDITION_START_DATE) AS CONDITION_ERA_START_DATE + ,ERA_END_DATE AS CONDITION_ERA_END_DATE + ,COUNT(*) AS CONDITION_OCCURRENCE_COUNT +FROM iob2wlgwcteConditionEnds +GROUP BY person_id + ,CONDITION_CONCEPT_ID + ,ERA_END_DATE; + diff --git a/CodeExcerpts/DerivedTables/netezza/GenerateEra.sql b/CodeExcerpts/DerivedTables/netezza/GenerateEra.sql new file mode 100644 index 0000000..cc0b8d6 --- /dev/null +++ b/CodeExcerpts/DerivedTables/netezza/GenerateEra.sql @@ -0,0 +1,386 @@ +/********************************************************************************* +# Copyright 2017 Observational Health Data Sciences and Informatics +# +# +# Licensed under the Apache License, Version 2.0 (the "License"); +# you may not use this file except in compliance with the License. +# You may obtain a copy of the License at +# +# http://www.apache.org/licenses/LICENSE-2.0 +# +# Unless required by applicable law or agreed to in writing, software +# distributed under the License is distributed on an "AS IS" BASIS, +# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. +# See the License for the specific language governing permissions and +# limitations under the License. +********************************************************************************/ +/******************************************************************************* + +PURPOSE: Generate Era table (based on conversion script from V4 V5). + +last revised: Jun 2017 +authors: Patrick Ryan, Chris Knoll, Anthony Sena, Vojtech Huser + + +OHDSI-SQL File Instructions +----------------------------- + + 1. Set parameter name of schema that contains CDMv4 instance + (@SOURCE_CDMV4, @SOURCE_CDMV4_SCHEMA) + 2. Set parameter name of schema that contains CDMv5 instance + ([CDM], [CDM].[CDMSCHEMA]) + 3. Run this script through SqlRender to produce a script that will work in your + source dialect. SqlRender can be found here: https://github.com/OHDSI/SqlRender + 4. Run the script produced by SQL Render on your target RDBDMS. + + File Instructions +------------------------- + + 1. This script will hold a number of placeholders for your CDM V4 and CDMV5 + database/schema. In order to make this file work in your environment, you + should plan to do a global "FIND AND REPLACE" on this file to fill in the + file with values that pertain to your environment. The following are the + tokens you should use when doing your "FIND AND REPLACE" operation: + + + [CMD] + [CDM].[CDMSCHEMA] + + +*********************************************************************************/ +/* SCRIPT PARAMETERS */ + + + -- The target CDMv5 database name + -- the target CDMv5 database plus schema + +SET search_path TO [CDM]; + + + +/**** + +DRUG ERA +Note: Eras derived from DRUG_EXPOSURE table, using 30d gap + + ****/ +DROP TABLE cteDrugTarget IF EXISTS; + +/* / */ + +-- Normalize DRUG_EXPOSURE_END_DATE to either the existing drug exposure end date, or add days supply, or add 1 day to the start date +CREATE TEMP TABLE cteDrugTarget + +AS +SELECT +d.DRUG_EXPOSURE_ID + ,d.PERSON_ID + ,c.CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE + ,COALESCE(DRUG_EXPOSURE_END_DATE, (DRUG_EXPOSURE_START_DATE + DAYS_SUPPLY), (DRUG_EXPOSURE_START_DATE + 1)) AS DRUG_EXPOSURE_END_DATE + ,c.CONCEPT_ID AS INGREDIENT_CONCEPT_ID + +FROM +[CDM].[CDMSCHEMA].DRUG_EXPOSURE d +INNER JOIN [CDM].[CDMSCHEMA].CONCEPT_ANCESTOR ca ON ca.DESCENDANT_CONCEPT_ID = d.DRUG_CONCEPT_ID +INNER JOIN [CDM].[CDMSCHEMA].CONCEPT c ON ca.ANCESTOR_CONCEPT_ID = c.CONCEPT_ID +WHERE c.VOCABULARY_ID = 'RxNorm' + AND c.CONCEPT_CLASS_ID = 'Ingredient'; + +/* / */ + +DROP TABLE cteEndDates IF EXISTS; + +/* / */ + +CREATE TEMP TABLE cteEndDates + +AS +SELECT +PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,(EVENT_DATE + - 30) AS END_DATE -- unpad the end date + +FROM +( + SELECT E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM ( + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM ( + -- select the start dates, assigning a row number to each + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,0 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM cteDrugTarget + + UNION ALL + + -- add the end dates with NULL as the row number, padding the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,(DRUG_EXPOSURE_END_DATE + 30) + ,1 AS EVENT_TYPE + ,NULL + FROM cteDrugTarget + ) RAWDATA + ) E1 + INNER JOIN ( + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM cteDrugTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.INGREDIENT_CONCEPT_ID = E2.INGREDIENT_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E +WHERE 2 * E.START_ORDINAL - E.OVERALL_ORD = 0; + +/* / */ + +DROP TABLE cteDrugExpEnds IF EXISTS; + +/* / */ + +CREATE TEMP TABLE cteDrugExpEnds + +AS +SELECT +d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM +cteDrugTarget d +INNER JOIN cteEndDates e ON d.PERSON_ID = e.PERSON_ID + AND d.INGREDIENT_CONCEPT_ID = e.INGREDIENT_CONCEPT_ID + AND e.END_DATE >= d.DRUG_EXPOSURE_START_DATE +GROUP BY d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE; + +/* / */ + +INSERT INTO [CDM].[CDMSCHEMA].drug_era +SELECT row_number() OVER ( + ORDER BY person_id + ) AS drug_era_id + ,person_id + ,INGREDIENT_CONCEPT_ID + ,min(DRUG_EXPOSURE_START_DATE) AS drug_era_start_date + ,ERA_END_DATE + ,COUNT(*) AS DRUG_EXPOSURE_COUNT + ,30 AS gap_days +FROM cteDrugExpEnds +GROUP BY person_id + ,INGREDIENT_CONCEPT_ID + ,drug_type_concept_id + ,ERA_END_DATE; + + + + + + + + + + + + + + + + + + + + + + + + + + + + + +/**** + +CONDITION ERA +Note: Eras derived from CONDITION_OCCURRENCE table, using 30d gap + + ****/ +DROP TABLE condition_era_phase_1 IF EXISTS; + +/* / */ + +DROP TABLE cteConditionTarget IF EXISTS; + +/* / */ + +-- create base eras from the concepts found in condition_occurrence +CREATE TEMP TABLE cteConditionTarget + +AS +SELECT +co.PERSON_ID + ,co.condition_concept_id + ,co.CONDITION_START_DATE + ,COALESCE(co.CONDITION_END_DATE, (CONDITION_START_DATE + 1)) AS CONDITION_END_DATE + +FROM +[CDM].[CDMSCHEMA].CONDITION_OCCURRENCE co; + +/* / */ + +DROP TABLE cteCondEndDates IF EXISTS; + +/* / */ + +CREATE TEMP TABLE cteCondEndDates + +AS +SELECT +PERSON_ID + ,CONDITION_CONCEPT_ID + ,(EVENT_DATE + - 30) AS END_DATE -- unpad the end date + +FROM +( + SELECT E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM ( + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM ( + -- select the start dates, assigning a row number to each + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,- 1 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM cteConditionTarget + + UNION ALL + + -- pad the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,(CONDITION_END_DATE + 30) + ,1 AS EVENT_TYPE + ,NULL + FROM cteConditionTarget + ) RAWDATA + ) E1 + INNER JOIN ( + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM cteConditionTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.CONDITION_CONCEPT_ID = E2.CONDITION_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E +WHERE (2 * E.START_ORDINAL) - E.OVERALL_ORD = 0; + +/* / */ + +DROP TABLE cteConditionEnds IF EXISTS; + +/* / */ + +CREATE TEMP TABLE cteConditionEnds + +AS +SELECT +c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM +cteConditionTarget c +INNER JOIN cteCondEndDates e ON c.PERSON_ID = e.PERSON_ID + AND c.CONDITION_CONCEPT_ID = e.CONDITION_CONCEPT_ID + AND e.END_DATE >= c.CONDITION_START_DATE +GROUP BY c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE; + +/* / */ + +INSERT INTO [CDM].[CDMSCHEMA].condition_era ( + condition_era_id + ,person_id + ,condition_concept_id + ,condition_era_start_date + ,condition_era_end_date + ,condition_occurrence_count + ) +SELECT row_number() OVER ( + ORDER BY person_id + ) AS condition_era_id + ,person_id + ,CONDITION_CONCEPT_ID + ,min(CONDITION_START_DATE) AS CONDITION_ERA_START_DATE + ,ERA_END_DATE AS CONDITION_ERA_END_DATE + ,COUNT(*) AS CONDITION_OCCURRENCE_COUNT +FROM cteConditionEnds +GROUP BY person_id + ,CONDITION_CONCEPT_ID + ,ERA_END_DATE; + diff --git a/CodeExcerpts/DerivedTables/oracle/GenerateEra.sql b/CodeExcerpts/DerivedTables/oracle/GenerateEra.sql new file mode 100644 index 0000000..0dfc1b3 --- /dev/null +++ b/CodeExcerpts/DerivedTables/oracle/GenerateEra.sql @@ -0,0 +1,426 @@ +/********************************************************************************* +# Copyright 2017 Observational Health Data Sciences and Informatics +# +# +# Licensed under the Apache License, Version 2.0 (the "License"); +# you may not use this file except in compliance with the License. +# You may obtain a copy of the License at +# +# http://www.apache.org/licenses/LICENSE-2.0 +# +# Unless required by applicable law or agreed to in writing, software +# distributed under the License is distributed on an "AS IS" BASIS, +# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. +# See the License for the specific language governing permissions and +# limitations under the License. +********************************************************************************/ +/******************************************************************************* + +PURPOSE: Generate Era table (based on conversion script from V4 V5). + +last revised: Jun 2017 +authors: Patrick Ryan, Chris Knoll, Anthony Sena, Vojtech Huser + + +OHDSI-SQL File Instructions +----------------------------- + + 1. Set parameter name of schema that contains CDMv4 instance + (@SOURCE_CDMV4, @SOURCE_CDMV4_SCHEMA) + 2. Set parameter name of schema that contains CDMv5 instance + ([CDM], [CDM].[CDMSCHEMA]) + 3. Run this script through SqlRender to produce a script that will work in your + source dialect. SqlRender can be found here: https://github.com/OHDSI/SqlRender + 4. Run the script produced by SQL Render on your target RDBDMS. + + File Instructions +------------------------- + + 1. This script will hold a number of placeholders for your CDM V4 and CDMV5 + database/schema. In order to make this file work in your environment, you + should plan to do a global "FIND AND REPLACE" on this file to fill in the + file with values that pertain to your environment. The following are the + tokens you should use when doing your "FIND AND REPLACE" operation: + + + [CMD] + [CDM].[CDMSCHEMA] + + +*********************************************************************************/ +/* SCRIPT PARAMETERS */ + + + -- The target CDMv5 database name + -- the target CDMv5 database plus schema + +ALTER SESSION SET current_schema = [CDM]; + + + +/**** + +DRUG ERA +Note: Eras derived from DRUG_EXPOSURE table, using 30d gap + + ****/ +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE iob2wlgwcteDrugTarget'; + EXECUTE IMMEDIATE 'DROP TABLE iob2wlgwcteDrugTarget'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/* / */ + +-- Normalize DRUG_EXPOSURE_END_DATE to either the existing drug exposure end date, or add days supply, or add 1 day to the start date +CREATE TABLE iob2wlgwcteDrugTarget + AS +SELECT +d.DRUG_EXPOSURE_ID + ,d.PERSON_ID + ,c.CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE + ,COALESCE(DRUG_EXPOSURE_END_DATE, (DRUG_EXPOSURE_START_DATE + NUMTODSINTERVAL(DAYS_SUPPLY, 'day')), (DRUG_EXPOSURE_START_DATE + NUMTODSINTERVAL(1, 'day'))) AS DRUG_EXPOSURE_END_DATE + ,c.CONCEPT_ID AS INGREDIENT_CONCEPT_ID + +FROM +[CDM].[CDMSCHEMA].DRUG_EXPOSURE d +INNER JOIN [CDM].[CDMSCHEMA].CONCEPT_ANCESTOR ca ON ca.DESCENDANT_CONCEPT_ID = d.DRUG_CONCEPT_ID +INNER JOIN [CDM].[CDMSCHEMA].CONCEPT c ON ca.ANCESTOR_CONCEPT_ID = c.CONCEPT_ID + WHERE c.VOCABULARY_ID = 'RxNorm' + AND c.CONCEPT_CLASS_ID = 'Ingredient' ; + +/* / */ + +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE iob2wlgwcteEndDates'; + EXECUTE IMMEDIATE 'DROP TABLE iob2wlgwcteEndDates'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/* / */ + +CREATE TABLE iob2wlgwcteEndDates + AS +SELECT +PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,(EVENT_DATE + NUMTODSINTERVAL(- 30, 'day')) AS END_DATE -- unpad the end date + +FROM +(SELECT E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM (SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM (SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,0 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM iob2wlgwcteDrugTarget + + UNION ALL + + -- add the end dates with NULL as the row number, padding the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,(DRUG_EXPOSURE_END_DATE + NUMTODSINTERVAL(30, 'day')) + ,1 AS EVENT_TYPE + ,NULL + FROM iob2wlgwcteDrugTarget + ) RAWDATA + ) E1 + INNER JOIN (SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM iob2wlgwcteDrugTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.INGREDIENT_CONCEPT_ID = E2.INGREDIENT_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E + WHERE 2 * E.START_ORDINAL - E.OVERALL_ORD = 0 ; + +/* / */ + +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE iob2wlgwcteDrugExpEnds'; + EXECUTE IMMEDIATE 'DROP TABLE iob2wlgwcteDrugExpEnds'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/* / */ + +CREATE TABLE iob2wlgwcteDrugExpEnds + AS +SELECT +d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM +iob2wlgwcteDrugTarget d +INNER JOIN iob2wlgwcteEndDates e ON d.PERSON_ID = e.PERSON_ID + AND d.INGREDIENT_CONCEPT_ID = e.INGREDIENT_CONCEPT_ID + AND e.END_DATE >= d.DRUG_EXPOSURE_START_DATE +GROUP BY d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE ; + +/* / */ + +INSERT INTO [CDM].[CDMSCHEMA].drug_era +SELECT row_number() OVER ( + ORDER BY person_id + ) AS drug_era_id + ,person_id + ,INGREDIENT_CONCEPT_ID + ,min(DRUG_EXPOSURE_START_DATE) AS drug_era_start_date + ,ERA_END_DATE + ,COUNT(*) AS DRUG_EXPOSURE_COUNT + ,30 AS gap_days + FROM iob2wlgwcteDrugExpEnds +GROUP BY person_id + ,INGREDIENT_CONCEPT_ID + ,drug_type_concept_id + ,ERA_END_DATE ; + + + + + + + + + + + + + + + + + + + + + + + + + + + + + +/**** + +CONDITION ERA +Note: Eras derived from CONDITION_OCCURRENCE table, using 30d gap + + ****/ +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE iob2wlgwcondition_era_phase_1'; + EXECUTE IMMEDIATE 'DROP TABLE iob2wlgwcondition_era_phase_1'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/* / */ + +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE iob2wlgwcteConditionTarget'; + EXECUTE IMMEDIATE 'DROP TABLE iob2wlgwcteConditionTarget'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/* / */ + +-- create base eras from the concepts found in condition_occurrence +CREATE TABLE iob2wlgwcteConditionTarget + AS +SELECT +co.PERSON_ID + ,co.condition_concept_id + ,co.CONDITION_START_DATE + ,COALESCE(co.CONDITION_END_DATE, (CONDITION_START_DATE + NUMTODSINTERVAL(1, 'day'))) AS CONDITION_END_DATE + +FROM +[CDM].[CDMSCHEMA].CONDITION_OCCURRENCE co ; + +/* / */ + +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE iob2wlgwcteCondEndDates'; + EXECUTE IMMEDIATE 'DROP TABLE iob2wlgwcteCondEndDates'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/* / */ + +CREATE TABLE iob2wlgwcteCondEndDates + AS +SELECT +PERSON_ID + ,CONDITION_CONCEPT_ID + ,(EVENT_DATE + NUMTODSINTERVAL(- 30, 'day')) AS END_DATE -- unpad the end date + +FROM +(SELECT E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM (SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM (SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,- 1 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM iob2wlgwcteConditionTarget + + UNION ALL + + -- pad the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,(CONDITION_END_DATE + NUMTODSINTERVAL(30, 'day')) + ,1 AS EVENT_TYPE + ,NULL + FROM iob2wlgwcteConditionTarget + ) RAWDATA + ) E1 + INNER JOIN (SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM iob2wlgwcteConditionTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.CONDITION_CONCEPT_ID = E2.CONDITION_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E + WHERE (2 * E.START_ORDINAL) - E.OVERALL_ORD = 0 ; + +/* / */ + +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE iob2wlgwcteConditionEnds'; + EXECUTE IMMEDIATE 'DROP TABLE iob2wlgwcteConditionEnds'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/* / */ + +CREATE TABLE iob2wlgwcteConditionEnds + AS +SELECT +c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM +iob2wlgwcteConditionTarget c +INNER JOIN iob2wlgwcteCondEndDates e ON c.PERSON_ID = e.PERSON_ID + AND c.CONDITION_CONCEPT_ID = e.CONDITION_CONCEPT_ID + AND e.END_DATE >= c.CONDITION_START_DATE +GROUP BY c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE ; + +/* / */ + +INSERT INTO [CDM].[CDMSCHEMA].condition_era ( + condition_era_id + ,person_id + ,condition_concept_id + ,condition_era_start_date + ,condition_era_end_date + ,condition_occurrence_count + ) +SELECT row_number() OVER ( + ORDER BY person_id + ) AS condition_era_id + ,person_id + ,CONDITION_CONCEPT_ID + ,min(CONDITION_START_DATE) AS CONDITION_ERA_START_DATE + ,ERA_END_DATE AS CONDITION_ERA_END_DATE + ,COUNT(*) AS CONDITION_OCCURRENCE_COUNT + FROM iob2wlgwcteConditionEnds +GROUP BY person_id + ,CONDITION_CONCEPT_ID + ,ERA_END_DATE ; + diff --git a/CodeExcerpts/DerivedTables/pdw/GenerateEra.sql b/CodeExcerpts/DerivedTables/pdw/GenerateEra.sql new file mode 100644 index 0000000..b057b2c --- /dev/null +++ b/CodeExcerpts/DerivedTables/pdw/GenerateEra.sql @@ -0,0 +1,374 @@ +/********************************************************************************* +# Copyright 2017 Observational Health Data Sciences and Informatics +# +# +# Licensed under the Apache License, Version 2.0 (the "License"); +# you may not use this file except in compliance with the License. +# You may obtain a copy of the License at +# +# http://www.apache.org/licenses/LICENSE-2.0 +# +# Unless required by applicable law or agreed to in writing, software +# distributed under the License is distributed on an "AS IS" BASIS, +# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. +# See the License for the specific language governing permissions and +# limitations under the License. +********************************************************************************/ +/******************************************************************************* + +PURPOSE: Generate Era table (based on conversion script from V4 V5). + +last revised: Jun 2017 +authors: Patrick Ryan, Chris Knoll, Anthony Sena, Vojtech Huser + + +OHDSI-SQL File Instructions +----------------------------- + + 1. Set parameter name of schema that contains CDMv4 instance + (@SOURCE_CDMV4, @SOURCE_CDMV4_SCHEMA) + 2. Set parameter name of schema that contains CDMv5 instance + ([CDM], [CDM].[CDMSCHEMA]) + 3. Run this script through SqlRender to produce a script that will work in your + source dialect. SqlRender can be found here: https://github.com/OHDSI/SqlRender + 4. Run the script produced by SQL Render on your target RDBDMS. + + File Instructions +------------------------- + + 1. This script will hold a number of placeholders for your CDM V4 and CDMV5 + database/schema. In order to make this file work in your environment, you + should plan to do a global "FIND AND REPLACE" on this file to fill in the + file with values that pertain to your environment. The following are the + tokens you should use when doing your "FIND AND REPLACE" operation: + + + [CMD] + [CDM].[CDMSCHEMA] + + +*********************************************************************************/ +/* SCRIPT PARAMETERS */ + + + -- The target CDMv5 database name + -- the target CDMv5 database plus schema + +USE [CDM]; + + + +/**** + +DRUG ERA +Note: Eras derived from DRUG_EXPOSURE table, using 30d gap + + ****/ +IF XACT_STATE() = 1 COMMIT; IF OBJECT_ID('tempdb..#cteDrugTarget', 'U') IS NOT NULL DROP TABLE #cteDrugTarget; + +/* / */ + +-- Normalize DRUG_EXPOSURE_END_DATE to either the existing drug exposure end date, or add days supply, or add 1 day to the start date +IF XACT_STATE() = 1 COMMIT; CREATE TABLE #cteDrugTarget + WITH (LOCATION = USER_DB, DISTRIBUTION = HASH(person_id)) AS +SELECT +d.DRUG_EXPOSURE_ID + ,d. person_id, c.CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE + ,COALESCE(DRUG_EXPOSURE_END_DATE, DATEADD(day, DAYS_SUPPLY, DRUG_EXPOSURE_START_DATE), DATEADD(day, 1, DRUG_EXPOSURE_START_DATE)) AS DRUG_EXPOSURE_END_DATE + ,c.CONCEPT_ID AS INGREDIENT_CONCEPT_ID + +FROM +[CDM].[CDMSCHEMA].DRUG_EXPOSURE d +INNER JOIN [CDM].[CDMSCHEMA].CONCEPT_ANCESTOR ca ON ca.DESCENDANT_CONCEPT_ID = d.DRUG_CONCEPT_ID +INNER JOIN [CDM].[CDMSCHEMA].CONCEPT c ON ca.ANCESTOR_CONCEPT_ID = c.CONCEPT_ID +WHERE c.VOCABULARY_ID = 'RxNorm' + AND c.CONCEPT_CLASS_ID = 'Ingredient'; + +/* / */ + +IF XACT_STATE() = 1 COMMIT; IF OBJECT_ID('tempdb..#cteEndDates', 'U') IS NOT NULL DROP TABLE #cteEndDates; + +/* / */ + +IF XACT_STATE() = 1 COMMIT; CREATE TABLE #cteEndDates + WITH (LOCATION = USER_DB, DISTRIBUTION = HASH(person_id)) AS +SELECT + person_id, INGREDIENT_CONCEPT_ID + ,DATEADD(day, - 30, EVENT_DATE) AS END_DATE -- unpad the end date + +FROM +( + SELECT E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM ( + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM ( + -- select the start dates, assigning a row number to each + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,0 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM #cteDrugTarget + + UNION ALL + + -- add the end dates with NULL as the row number, padding the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DATEADD(day, 30, DRUG_EXPOSURE_END_DATE) + ,1 AS EVENT_TYPE + ,NULL + FROM #cteDrugTarget + ) RAWDATA + ) E1 + INNER JOIN ( + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM #cteDrugTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.INGREDIENT_CONCEPT_ID = E2.INGREDIENT_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E +WHERE 2 * E.START_ORDINAL - E.OVERALL_ORD = 0; + +/* / */ + +IF XACT_STATE() = 1 COMMIT; IF OBJECT_ID('tempdb..#cteDrugExpEnds', 'U') IS NOT NULL DROP TABLE #cteDrugExpEnds; + +/* / */ + +IF XACT_STATE() = 1 COMMIT; CREATE TABLE #cteDrugExpEnds + WITH (LOCATION = USER_DB, DISTRIBUTION = HASH(person_id)) AS +SELECT +d. person_id, d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM +#cteDrugTarget d +INNER JOIN #cteEndDates e ON d.PERSON_ID = e.PERSON_ID + AND d.INGREDIENT_CONCEPT_ID = e.INGREDIENT_CONCEPT_ID + AND e.END_DATE >= d.DRUG_EXPOSURE_START_DATE +GROUP BY d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE; + +/* / */ + +INSERT INTO [CDM].[CDMSCHEMA].drug_era +SELECT row_number() OVER ( + ORDER BY person_id + ) AS drug_era_id + ,person_id + ,INGREDIENT_CONCEPT_ID + ,min(DRUG_EXPOSURE_START_DATE) AS drug_era_start_date + ,ERA_END_DATE + ,COUNT(*) AS DRUG_EXPOSURE_COUNT + ,30 AS gap_days +FROM #cteDrugExpEnds +GROUP BY person_id + ,INGREDIENT_CONCEPT_ID + ,drug_type_concept_id + ,ERA_END_DATE; + + + + + + + + + + + + + + + + + + + + + + + + + + + + + +/**** + +CONDITION ERA +Note: Eras derived from CONDITION_OCCURRENCE table, using 30d gap + + ****/ +IF XACT_STATE() = 1 COMMIT; IF OBJECT_ID('tempdb..#condition_era_phase_1', 'U') IS NOT NULL DROP TABLE #condition_era_phase_1; + +/* / */ + +IF XACT_STATE() = 1 COMMIT; IF OBJECT_ID('tempdb..#cteConditionTarget', 'U') IS NOT NULL DROP TABLE #cteConditionTarget; + +/* / */ + +-- create base eras from the concepts found in condition_occurrence +IF XACT_STATE() = 1 COMMIT; CREATE TABLE #cteConditionTarget + WITH (LOCATION = USER_DB, DISTRIBUTION = HASH(person_id)) AS +SELECT +co. person_id, co.condition_concept_id + ,co.CONDITION_START_DATE + ,COALESCE(co.CONDITION_END_DATE, DATEADD(day, 1, CONDITION_START_DATE)) AS CONDITION_END_DATE + +FROM +[CDM].[CDMSCHEMA].CONDITION_OCCURRENCE co; + +/* / */ + +IF XACT_STATE() = 1 COMMIT; IF OBJECT_ID('tempdb..#cteCondEndDates', 'U') IS NOT NULL DROP TABLE #cteCondEndDates; + +/* / */ + +IF XACT_STATE() = 1 COMMIT; CREATE TABLE #cteCondEndDates + WITH (LOCATION = USER_DB, DISTRIBUTION = HASH(person_id)) AS +SELECT + person_id, CONDITION_CONCEPT_ID + ,DATEADD(day, - 30, EVENT_DATE) AS END_DATE -- unpad the end date + +FROM +( + SELECT E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM ( + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM ( + -- select the start dates, assigning a row number to each + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,- 1 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM #cteConditionTarget + + UNION ALL + + -- pad the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,DATEADD(day, 30, CONDITION_END_DATE) + ,1 AS EVENT_TYPE + ,NULL + FROM #cteConditionTarget + ) RAWDATA + ) E1 + INNER JOIN ( + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM #cteConditionTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.CONDITION_CONCEPT_ID = E2.CONDITION_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E +WHERE (2 * E.START_ORDINAL) - E.OVERALL_ORD = 0; + +/* / */ + +IF XACT_STATE() = 1 COMMIT; IF OBJECT_ID('tempdb..#cteConditionEnds', 'U') IS NOT NULL DROP TABLE #cteConditionEnds; + +/* / */ + +IF XACT_STATE() = 1 COMMIT; CREATE TABLE #cteConditionEnds + WITH (LOCATION = USER_DB, DISTRIBUTION = HASH(person_id)) AS +SELECT +c. person_id, c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM +#cteConditionTarget c +INNER JOIN #cteCondEndDates e ON c.PERSON_ID = e.PERSON_ID + AND c.CONDITION_CONCEPT_ID = e.CONDITION_CONCEPT_ID + AND e.END_DATE >= c.CONDITION_START_DATE +GROUP BY c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE; + +/* / */ + +INSERT INTO [CDM].[CDMSCHEMA].condition_era ( + condition_era_id + ,person_id + ,condition_concept_id + ,condition_era_start_date + ,condition_era_end_date + ,condition_occurrence_count + ) +SELECT row_number() OVER ( + ORDER BY person_id + ) AS condition_era_id + ,person_id + ,CONDITION_CONCEPT_ID + ,min(CONDITION_START_DATE) AS CONDITION_ERA_START_DATE + ,ERA_END_DATE AS CONDITION_ERA_END_DATE + ,COUNT(*) AS CONDITION_OCCURRENCE_COUNT +FROM #cteConditionEnds +GROUP BY person_id + ,CONDITION_CONCEPT_ID + ,ERA_END_DATE; + diff --git a/CodeExcerpts/DerivedTables/postgresql/GenerateEra.sql b/CodeExcerpts/DerivedTables/postgresql/GenerateEra.sql new file mode 100644 index 0000000..58bf22d --- /dev/null +++ b/CodeExcerpts/DerivedTables/postgresql/GenerateEra.sql @@ -0,0 +1,386 @@ +/********************************************************************************* +# Copyright 2017 Observational Health Data Sciences and Informatics +# +# +# Licensed under the Apache License, Version 2.0 (the "License"); +# you may not use this file except in compliance with the License. +# You may obtain a copy of the License at +# +# http://www.apache.org/licenses/LICENSE-2.0 +# +# Unless required by applicable law or agreed to in writing, software +# distributed under the License is distributed on an "AS IS" BASIS, +# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. +# See the License for the specific language governing permissions and +# limitations under the License. +********************************************************************************/ +/******************************************************************************* + +PURPOSE: Generate Era table (based on conversion script from V4 V5). + +last revised: Jun 2017 +authors: Patrick Ryan, Chris Knoll, Anthony Sena, Vojtech Huser + + +OHDSI-SQL File Instructions +----------------------------- + + 1. Set parameter name of schema that contains CDMv4 instance + (@SOURCE_CDMV4, @SOURCE_CDMV4_SCHEMA) + 2. Set parameter name of schema that contains CDMv5 instance + ([CDM], [CDM].[CDMSCHEMA]) + 3. Run this script through SqlRender to produce a script that will work in your + source dialect. SqlRender can be found here: https://github.com/OHDSI/SqlRender + 4. Run the script produced by SQL Render on your target RDBDMS. + + File Instructions +------------------------- + + 1. This script will hold a number of placeholders for your CDM V4 and CDMV5 + database/schema. In order to make this file work in your environment, you + should plan to do a global "FIND AND REPLACE" on this file to fill in the + file with values that pertain to your environment. The following are the + tokens you should use when doing your "FIND AND REPLACE" operation: + + + [CMD] + [CDM].[CDMSCHEMA] + + +*********************************************************************************/ +/* SCRIPT PARAMETERS */ + + + -- The target CDMv5 database name + -- the target CDMv5 database plus schema + +SET search_path TO [CDM]; + + + +/**** + +DRUG ERA +Note: Eras derived from DRUG_EXPOSURE table, using 30d gap + + ****/ +DROP TABLE IF EXISTS cteDrugTarget; + +/* / */ + +-- Normalize DRUG_EXPOSURE_END_DATE to either the existing drug exposure end date, or add days supply, or add 1 day to the start date +CREATE TEMP TABLE cteDrugTarget + +AS +SELECT +d.DRUG_EXPOSURE_ID + ,d.PERSON_ID + ,c.CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE + ,COALESCE(DRUG_EXPOSURE_END_DATE, (DRUG_EXPOSURE_START_DATE + DAYS_SUPPLY*INTERVAL'1 day'), (DRUG_EXPOSURE_START_DATE + 1*INTERVAL'1 day')) AS DRUG_EXPOSURE_END_DATE + ,c.CONCEPT_ID AS INGREDIENT_CONCEPT_ID + +FROM +[CDM].[CDMSCHEMA].DRUG_EXPOSURE d +INNER JOIN [CDM].[CDMSCHEMA].CONCEPT_ANCESTOR ca ON ca.DESCENDANT_CONCEPT_ID = d.DRUG_CONCEPT_ID +INNER JOIN [CDM].[CDMSCHEMA].CONCEPT c ON ca.ANCESTOR_CONCEPT_ID = c.CONCEPT_ID +WHERE c.VOCABULARY_ID = 'RxNorm' + AND c.CONCEPT_CLASS_ID = 'Ingredient'; + +/* / */ + +DROP TABLE IF EXISTS cteEndDates; + +/* / */ + +CREATE TEMP TABLE cteEndDates + +AS +SELECT +PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,(EVENT_DATE + - 30*INTERVAL'1 day') AS END_DATE -- unpad the end date + +FROM +( + SELECT E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM ( + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM ( + -- select the start dates, assigning a row number to each + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,0 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM cteDrugTarget + + UNION ALL + + -- add the end dates with NULL as the row number, padding the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,(DRUG_EXPOSURE_END_DATE + 30*INTERVAL'1 day') + ,1 AS EVENT_TYPE + ,NULL + FROM cteDrugTarget + ) RAWDATA + ) E1 + INNER JOIN ( + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM cteDrugTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.INGREDIENT_CONCEPT_ID = E2.INGREDIENT_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E +WHERE 2 * E.START_ORDINAL - E.OVERALL_ORD = 0; + +/* / */ + +DROP TABLE IF EXISTS cteDrugExpEnds; + +/* / */ + +CREATE TEMP TABLE cteDrugExpEnds + +AS +SELECT +d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM +cteDrugTarget d +INNER JOIN cteEndDates e ON d.PERSON_ID = e.PERSON_ID + AND d.INGREDIENT_CONCEPT_ID = e.INGREDIENT_CONCEPT_ID + AND e.END_DATE >= d.DRUG_EXPOSURE_START_DATE +GROUP BY d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE; + +/* / */ + +INSERT INTO [CDM].[CDMSCHEMA].drug_era +SELECT row_number() OVER ( + ORDER BY person_id + ) AS drug_era_id + ,person_id + ,INGREDIENT_CONCEPT_ID + ,min(DRUG_EXPOSURE_START_DATE) AS drug_era_start_date + ,ERA_END_DATE + ,COUNT(*) AS DRUG_EXPOSURE_COUNT + ,30 AS gap_days +FROM cteDrugExpEnds +GROUP BY person_id + ,INGREDIENT_CONCEPT_ID + ,drug_type_concept_id + ,ERA_END_DATE; + + + + + + + + + + + + + + + + + + + + + + + + + + + + + +/**** + +CONDITION ERA +Note: Eras derived from CONDITION_OCCURRENCE table, using 30d gap + + ****/ +DROP TABLE IF EXISTS condition_era_phase_1; + +/* / */ + +DROP TABLE IF EXISTS cteConditionTarget; + +/* / */ + +-- create base eras from the concepts found in condition_occurrence +CREATE TEMP TABLE cteConditionTarget + +AS +SELECT +co.PERSON_ID + ,co.condition_concept_id + ,co.CONDITION_START_DATE + ,COALESCE(co.CONDITION_END_DATE, (CONDITION_START_DATE + 1*INTERVAL'1 day')) AS CONDITION_END_DATE + +FROM +[CDM].[CDMSCHEMA].CONDITION_OCCURRENCE co; + +/* / */ + +DROP TABLE IF EXISTS cteCondEndDates; + +/* / */ + +CREATE TEMP TABLE cteCondEndDates + +AS +SELECT +PERSON_ID + ,CONDITION_CONCEPT_ID + ,(EVENT_DATE + - 30*INTERVAL'1 day') AS END_DATE -- unpad the end date + +FROM +( + SELECT E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM ( + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM ( + -- select the start dates, assigning a row number to each + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,- 1 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM cteConditionTarget + + UNION ALL + + -- pad the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,(CONDITION_END_DATE + 30*INTERVAL'1 day') + ,1 AS EVENT_TYPE + ,NULL + FROM cteConditionTarget + ) RAWDATA + ) E1 + INNER JOIN ( + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM cteConditionTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.CONDITION_CONCEPT_ID = E2.CONDITION_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E +WHERE (2 * E.START_ORDINAL) - E.OVERALL_ORD = 0; + +/* / */ + +DROP TABLE IF EXISTS cteConditionEnds; + +/* / */ + +CREATE TEMP TABLE cteConditionEnds + +AS +SELECT +c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM +cteConditionTarget c +INNER JOIN cteCondEndDates e ON c.PERSON_ID = e.PERSON_ID + AND c.CONDITION_CONCEPT_ID = e.CONDITION_CONCEPT_ID + AND e.END_DATE >= c.CONDITION_START_DATE +GROUP BY c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE; + +/* / */ + +INSERT INTO [CDM].[CDMSCHEMA].condition_era ( + condition_era_id + ,person_id + ,condition_concept_id + ,condition_era_start_date + ,condition_era_end_date + ,condition_occurrence_count + ) +SELECT row_number() OVER ( + ORDER BY person_id + ) AS condition_era_id + ,person_id + ,CONDITION_CONCEPT_ID + ,min(CONDITION_START_DATE) AS CONDITION_ERA_START_DATE + ,ERA_END_DATE AS CONDITION_ERA_END_DATE + ,COUNT(*) AS CONDITION_OCCURRENCE_COUNT +FROM cteConditionEnds +GROUP BY person_id + ,CONDITION_CONCEPT_ID + ,ERA_END_DATE; + diff --git a/CodeExcerpts/DerivedTables/redshift/GenerateEra.sql b/CodeExcerpts/DerivedTables/redshift/GenerateEra.sql new file mode 100644 index 0000000..58bf22d --- /dev/null +++ b/CodeExcerpts/DerivedTables/redshift/GenerateEra.sql @@ -0,0 +1,386 @@ +/********************************************************************************* +# Copyright 2017 Observational Health Data Sciences and Informatics +# +# +# Licensed under the Apache License, Version 2.0 (the "License"); +# you may not use this file except in compliance with the License. +# You may obtain a copy of the License at +# +# http://www.apache.org/licenses/LICENSE-2.0 +# +# Unless required by applicable law or agreed to in writing, software +# distributed under the License is distributed on an "AS IS" BASIS, +# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. +# See the License for the specific language governing permissions and +# limitations under the License. +********************************************************************************/ +/******************************************************************************* + +PURPOSE: Generate Era table (based on conversion script from V4 V5). + +last revised: Jun 2017 +authors: Patrick Ryan, Chris Knoll, Anthony Sena, Vojtech Huser + + +OHDSI-SQL File Instructions +----------------------------- + + 1. Set parameter name of schema that contains CDMv4 instance + (@SOURCE_CDMV4, @SOURCE_CDMV4_SCHEMA) + 2. Set parameter name of schema that contains CDMv5 instance + ([CDM], [CDM].[CDMSCHEMA]) + 3. Run this script through SqlRender to produce a script that will work in your + source dialect. SqlRender can be found here: https://github.com/OHDSI/SqlRender + 4. Run the script produced by SQL Render on your target RDBDMS. + + File Instructions +------------------------- + + 1. This script will hold a number of placeholders for your CDM V4 and CDMV5 + database/schema. In order to make this file work in your environment, you + should plan to do a global "FIND AND REPLACE" on this file to fill in the + file with values that pertain to your environment. The following are the + tokens you should use when doing your "FIND AND REPLACE" operation: + + + [CMD] + [CDM].[CDMSCHEMA] + + +*********************************************************************************/ +/* SCRIPT PARAMETERS */ + + + -- The target CDMv5 database name + -- the target CDMv5 database plus schema + +SET search_path TO [CDM]; + + + +/**** + +DRUG ERA +Note: Eras derived from DRUG_EXPOSURE table, using 30d gap + + ****/ +DROP TABLE IF EXISTS cteDrugTarget; + +/* / */ + +-- Normalize DRUG_EXPOSURE_END_DATE to either the existing drug exposure end date, or add days supply, or add 1 day to the start date +CREATE TEMP TABLE cteDrugTarget + +AS +SELECT +d.DRUG_EXPOSURE_ID + ,d.PERSON_ID + ,c.CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE + ,COALESCE(DRUG_EXPOSURE_END_DATE, (DRUG_EXPOSURE_START_DATE + DAYS_SUPPLY*INTERVAL'1 day'), (DRUG_EXPOSURE_START_DATE + 1*INTERVAL'1 day')) AS DRUG_EXPOSURE_END_DATE + ,c.CONCEPT_ID AS INGREDIENT_CONCEPT_ID + +FROM +[CDM].[CDMSCHEMA].DRUG_EXPOSURE d +INNER JOIN [CDM].[CDMSCHEMA].CONCEPT_ANCESTOR ca ON ca.DESCENDANT_CONCEPT_ID = d.DRUG_CONCEPT_ID +INNER JOIN [CDM].[CDMSCHEMA].CONCEPT c ON ca.ANCESTOR_CONCEPT_ID = c.CONCEPT_ID +WHERE c.VOCABULARY_ID = 'RxNorm' + AND c.CONCEPT_CLASS_ID = 'Ingredient'; + +/* / */ + +DROP TABLE IF EXISTS cteEndDates; + +/* / */ + +CREATE TEMP TABLE cteEndDates + +AS +SELECT +PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,(EVENT_DATE + - 30*INTERVAL'1 day') AS END_DATE -- unpad the end date + +FROM +( + SELECT E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM ( + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM ( + -- select the start dates, assigning a row number to each + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,0 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM cteDrugTarget + + UNION ALL + + -- add the end dates with NULL as the row number, padding the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,(DRUG_EXPOSURE_END_DATE + 30*INTERVAL'1 day') + ,1 AS EVENT_TYPE + ,NULL + FROM cteDrugTarget + ) RAWDATA + ) E1 + INNER JOIN ( + SELECT PERSON_ID + ,INGREDIENT_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,INGREDIENT_CONCEPT_ID ORDER BY DRUG_EXPOSURE_START_DATE + ) AS START_ORDINAL + FROM cteDrugTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.INGREDIENT_CONCEPT_ID = E2.INGREDIENT_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.INGREDIENT_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E +WHERE 2 * E.START_ORDINAL - E.OVERALL_ORD = 0; + +/* / */ + +DROP TABLE IF EXISTS cteDrugExpEnds; + +/* / */ + +CREATE TEMP TABLE cteDrugExpEnds + +AS +SELECT +d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM +cteDrugTarget d +INNER JOIN cteEndDates e ON d.PERSON_ID = e.PERSON_ID + AND d.INGREDIENT_CONCEPT_ID = e.INGREDIENT_CONCEPT_ID + AND e.END_DATE >= d.DRUG_EXPOSURE_START_DATE +GROUP BY d.PERSON_ID + ,d.INGREDIENT_CONCEPT_ID + ,d.DRUG_TYPE_CONCEPT_ID + ,d.DRUG_EXPOSURE_START_DATE; + +/* / */ + +INSERT INTO [CDM].[CDMSCHEMA].drug_era +SELECT row_number() OVER ( + ORDER BY person_id + ) AS drug_era_id + ,person_id + ,INGREDIENT_CONCEPT_ID + ,min(DRUG_EXPOSURE_START_DATE) AS drug_era_start_date + ,ERA_END_DATE + ,COUNT(*) AS DRUG_EXPOSURE_COUNT + ,30 AS gap_days +FROM cteDrugExpEnds +GROUP BY person_id + ,INGREDIENT_CONCEPT_ID + ,drug_type_concept_id + ,ERA_END_DATE; + + + + + + + + + + + + + + + + + + + + + + + + + + + + + +/**** + +CONDITION ERA +Note: Eras derived from CONDITION_OCCURRENCE table, using 30d gap + + ****/ +DROP TABLE IF EXISTS condition_era_phase_1; + +/* / */ + +DROP TABLE IF EXISTS cteConditionTarget; + +/* / */ + +-- create base eras from the concepts found in condition_occurrence +CREATE TEMP TABLE cteConditionTarget + +AS +SELECT +co.PERSON_ID + ,co.condition_concept_id + ,co.CONDITION_START_DATE + ,COALESCE(co.CONDITION_END_DATE, (CONDITION_START_DATE + 1*INTERVAL'1 day')) AS CONDITION_END_DATE + +FROM +[CDM].[CDMSCHEMA].CONDITION_OCCURRENCE co; + +/* / */ + +DROP TABLE IF EXISTS cteCondEndDates; + +/* / */ + +CREATE TEMP TABLE cteCondEndDates + +AS +SELECT +PERSON_ID + ,CONDITION_CONCEPT_ID + ,(EVENT_DATE + - 30*INTERVAL'1 day') AS END_DATE -- unpad the end date + +FROM +( + SELECT E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,COALESCE(E1.START_ORDINAL, MAX(E2.START_ORDINAL)) START_ORDINAL + ,E1.OVERALL_ORD + FROM ( + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,EVENT_DATE + ,EVENT_TYPE + ,START_ORDINAL + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY EVENT_DATE + ,EVENT_TYPE + ) AS OVERALL_ORD -- this re-numbers the inner UNION so all rows are numbered ordered by the event date + FROM ( + -- select the start dates, assigning a row number to each + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,- 1 AS EVENT_TYPE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM cteConditionTarget + + UNION ALL + + -- pad the end dates by 30 to allow a grace period for overlapping ranges. + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,(CONDITION_END_DATE + 30*INTERVAL'1 day') + ,1 AS EVENT_TYPE + ,NULL + FROM cteConditionTarget + ) RAWDATA + ) E1 + INNER JOIN ( + SELECT PERSON_ID + ,CONDITION_CONCEPT_ID + ,CONDITION_START_DATE AS EVENT_DATE + ,ROW_NUMBER() OVER ( + PARTITION BY PERSON_ID + ,CONDITION_CONCEPT_ID ORDER BY CONDITION_START_DATE + ) AS START_ORDINAL + FROM cteConditionTarget + ) E2 ON E1.PERSON_ID = E2.PERSON_ID + AND E1.CONDITION_CONCEPT_ID = E2.CONDITION_CONCEPT_ID + AND E2.EVENT_DATE <= E1.EVENT_DATE + GROUP BY E1.PERSON_ID + ,E1.CONDITION_CONCEPT_ID + ,E1.EVENT_DATE + ,E1.START_ORDINAL + ,E1.OVERALL_ORD + ) E +WHERE (2 * E.START_ORDINAL) - E.OVERALL_ORD = 0; + +/* / */ + +DROP TABLE IF EXISTS cteConditionEnds; + +/* / */ + +CREATE TEMP TABLE cteConditionEnds + +AS +SELECT +c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM +cteConditionTarget c +INNER JOIN cteCondEndDates e ON c.PERSON_ID = e.PERSON_ID + AND c.CONDITION_CONCEPT_ID = e.CONDITION_CONCEPT_ID + AND e.END_DATE >= c.CONDITION_START_DATE +GROUP BY c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE; + +/* / */ + +INSERT INTO [CDM].[CDMSCHEMA].condition_era ( + condition_era_id + ,person_id + ,condition_concept_id + ,condition_era_start_date + ,condition_era_end_date + ,condition_occurrence_count + ) +SELECT row_number() OVER ( + ORDER BY person_id + ) AS condition_era_id + ,person_id + ,CONDITION_CONCEPT_ID + ,min(CONDITION_START_DATE) AS CONDITION_ERA_START_DATE + ,ERA_END_DATE AS CONDITION_ERA_END_DATE + ,COUNT(*) AS CONDITION_OCCURRENCE_COUNT +FROM cteConditionEnds +GROUP BY person_id + ,CONDITION_CONCEPT_ID + ,ERA_END_DATE; + diff --git a/Documentation/CommonDataModel_Wiki_Files/Home.md b/Documentation/CommonDataModel_Wiki_Files/Home.md index f0f4acf..dc39568 100644 --- a/Documentation/CommonDataModel_Wiki_Files/Home.md +++ b/Documentation/CommonDataModel_Wiki_Files/Home.md @@ -1,4 +1,5 @@ -***OMOP Common Data Model v5.1.1 Specifications*** +***OMOP Common Data Model v5.2 Specifications*** +
*Authors: Christian Reich, Patrick Ryan, Rimma Belenkaya, Karthik Natarajan, Clair Blacketer*
*12 July 2017* @@ -44,6 +45,7 @@ Welcome to the Common Data Model wiki! This wiki houses all of the documentation
[CONDITION_OCCURRENCE](wiki/CONDITION_OCCURRENCE)
[MEASUREMENT](wiki/MEASUREMENT)
[NOTE](wiki/NOTE) +
[NOTE_NLP](wiki/NOTE_NLP)
[OBSERVATION](wiki/OBSERVATION)
[FACT_RELATIONSHIP](wiki/FACT_RELATIONSHIP)
diff --git a/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/CONDITION_OCCURRENCE.md b/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/CONDITION_OCCURRENCE.md index 8006806..e20471d 100644 --- a/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/CONDITION_OCCURRENCE.md +++ b/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/CONDITION_OCCURRENCE.md @@ -16,8 +16,10 @@ Field|Required|Type|Description | stop_reason | No | varchar(20) | The reason that the condition was no longer present, as indicated in the source data. | | provider_id | No | integer | A foreign key to the Provider in the PROVIDER table who was responsible for capturing (diagnosing) the Condition. | | visit_occurrence_id | No | integer | A foreign key to the visit in the VISIT table during which the Condition was determined (diagnosed). | -| condition_source_concept_id | No | integer | A foreign key to a Condition Concept that refers to the code used in the source. | | condition_source_value | No | varchar(50) | The source code for the condition as it appears in the source data. This code is mapped to a standard condition concept in the Standardized Vocabularies and the original code is stored here for reference. | +| condition_source_concept_id | No | integer | A foreign key to a Condition Concept that refers to the code used in the source. | +| condition_status_source_value | No | varchar(50) | The source code for the condition status as it appears in the source data. | +| condition_status_concept_id | No | integer | A foreign key to the predefined concept in the standard vocabulary reflecting the condition status | | ### Conventions @@ -31,4 +33,8 @@ Field|Required|Type|Description * ICD-9-CM Secondary Diagnoses from inpatient and outpatient Claims * Diagnoses or problems recorded in an EHR. * The Stop Reason indicates why a Condition is no longer valid with respect to the purpose within the source data. Typical values include "Discharged", "Resolved", etc. Note that a Stop Reason does not necessarily imply that the condition is no longer occurring. - * Condition source codes are typically ICD-9-CM, Read or ICD-10 diagnosis codes from medical claims or discharge status/visit diagnosis codes from EHRs. \ No newline at end of file + * Condition source codes are typically ICD-9-CM, Read or ICD-10 diagnosis codes from medical claims or discharge status/visit diagnosis codes from EHRs. + * Presently, there is no designated vocabulary, domain, or class that represents condition status. The following concepts from SNOMED are recommended: + * Admitting diagnosis: 4203942 + * Final diagnosis: 4230359 � should also be used for �Discharge diagnosis� + * Preliminary diagnosis: 4033240 \ No newline at end of file diff --git a/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/DRUG_EXPOSURE.md b/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/DRUG_EXPOSURE.md index 4023d4e..23eac5b 100644 --- a/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/DRUG_EXPOSURE.md +++ b/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/DRUG_EXPOSURE.md @@ -14,8 +14,9 @@ Field|Required|Type|Description |drug_concept_id|Yes|integer|A foreign key that refers to a Standard Concept identifier in the Standardized Vocabularies for the Drug concept.| |drug_exposure_start_date|Yes|date|The start date for the current instance of Drug utilization. Valid entries include a start date of a prescription, the date a prescription was filled, or the date on which a Drug administration procedure was recorded.| |drug_exposure_start_datetime|No|datetime|The start date and time for the current instance of Drug utilization. Valid entries include a start date of a prescription, the date a prescription was filled, or the date on which a Drug administration procedure was recorded.| -|drug_exposure_end_date|No|date|The end date for the current instance of Drug utilization. It is not available from all sources.| +|drug_exposure_end_date|Yes|date|The end date for the current instance of Drug utilization. It is not available from all sources.| |drug_exposure_end_datetime|No|datetime|The end date and time for the current instance of Drug utilization. It is not available from all sources.| +|verbatim_end_date|No|date|The known end date of a drug_exposure as provided by the source| |drug_type_concept_id|Yes|integer| A foreign key to the predefined Concept identifier in the Standardized Vocabularies reflecting the type of Drug Exposure recorded. It indicates how the Drug Exposure was represented in the source data.| |stop_reason|No|varchar(20)|The reason the Drug was stopped. Reasons include regimen completed, changed, removed, etc.| |refills|No|integer|The number of refills after the initial prescription. The initial prescription is not counted, values start with 0.| @@ -23,8 +24,6 @@ Field|Required|Type|Description |days_supply|No|integer|The number of days of supply of the medication as recorded in the original prescription or dispensing record.| |sig|No|clob|The directions ("signetur") on the Drug prescription as recorded in the original prescription (and printed on the container) or dispensing record.| |route_concept_id|No|integer|A foreign key to a predefined concept in the Standardized Vocabularies reflecting the route of administration.| -|effective_drug_dose|No|float|Numerical value of Drug dose for this Drug Exposure record.| -|dose_unit_concept_ id|No|integer|A foreign key to a predefined concept in the Standardized Vocabularies reflecting the unit the effective_drug_dose value is expressed.| |lot_number|No|varchar(50)|An identifier assigned to a particular quantity or lot of Drug product from the manufacturer.| |provider_id|No|integer|A foreign key to the provider in the provider table who initiated (prescribed or administered) the Drug Exposure.| |visit_occurrence_id|No|integer|A foreign key to the visit in the visit table during which the Drug Exposure was initiated.| @@ -41,7 +40,7 @@ Field|Required|Type|Description * A Drug Type is assigned to each Drug Exposure to track from what source the information was drawn or inferred from. The valid domain_id for these Concepts is "Drug Type". * The content of the refills field determines the current number of refills, not the number of remaining refills. For example, for a drug prescription with 2 refills, the content of this field for the 3 Drug Exposure events are null, 1 and 2. * The route_concept_id refers to a Standard Concepts of the "Route" domain. Note: Route information can also be inferred from the Drug product itself by determining the Drug Form of the Concept, creating some partial overlap of the same type of information. However, the route_concept_id could resolve ambiguities of how a certain Drug Form is actually applied. For example, a "Solution" could be used orally or parentherally, and this field will make this determination. - * The Effective Drug Dose and the Dose Unit Concepts are provided in cases when dose information is explicitly provided, as it is typically for pediatric and chemotherapeutic treatments. The domain_id for the Dose Unit Concept is "Unit". Note: this information can only be present if the Drug contains a single active ingredient. Combination products which have doses for each ingredient need to be recorded as separate records. * The lot_number field contains an identifier assigned from the manufacturer of the Drug product. * If possible, the visit in which the drug was prescribed or delivered is recorded in the visit_occurrence_id field through a reference to the visit table. - * If possible, the prescribing or administering provider (physician or nurse) is recorded in the provider_id field through a reference to the provider table. \ No newline at end of file + * If possible, the prescribing or administering provider (physician or nurse) is recorded in the provider_id field through a reference to the provider table. + * The drug_exposure_end_date denotes the day the drug exposure ended for the patient. This could be that the duration of drug_supply was reached (in which case drug_exposure_end_date = drug_exposure_start_date + days_supply -1), or because the exposure was stopped (medication changed, medication discontinued, etc.) \ No newline at end of file diff --git a/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/NOTE.md b/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/NOTE.md index d26c68c..d03178d 100644 --- a/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/NOTE.md +++ b/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/NOTE.md @@ -7,7 +7,11 @@ Field|Required|Type|Description |note_date |Yes|date|The date the note was recorded.| |note_datetime|No|datetime|The date and time the note was recorded.| |note_type_concept_id|Yes|integer|A foreign key to the predefined Concept in the Standardized Vocabularies reflecting the type, origin or provenance of the Note.| +|note_class_concept_id| Yes| integer| A foreign key to the predefined Concept in the Standardized Vocabularies reflecting the HL7 LOINC Document Type Vocabulary classification of the note.| +|note_title |No| varchar(250)| The title of the Note as it appears in the source.| |note_text|Yes|RBDMS dependent text|The content of the Note.| +|encoding_concept_id |Yes |integer| A foreign key to the predefined Concept in the Standardized Vocabularies reflecting the note character encoding type| +|language_concept_id |Yes |integer |A foreign key to the predefined Concept in the Standardized Vocabularies reflecting the language of the note| |provider_id|No|integer|A foreign key to the Provider in the PROVIDER table who took the Note.| |note_source_value|No|varchar(50)|The source value associated with the origin of the note| |visit_occurrence_id|No|integer|Foreign key to the Visit in the VISIT_OCCURRENCE table when the Note was taken.| @@ -16,4 +20,112 @@ Field|Required|Type|Description * The NOTE table contains free text (in ASCII, or preferably in UTF8 format) taken by a healthcare Provider. * The Visit during which the note was written is recorded through a reference to the VISIT_OCCURRENCE table. This information is not always available. * The Provider making the note is recorded through a reference to the PROVIDER table. This information is not always available. - * The type of note_text is CLOB or string(MAX) depending on RDBMS + * The type of note_text is CLOB or varchar(MAX) depending on RDBMS + * note_class_concept_id is a foreign key to the CONCEPT table to describe a standardized combination of five LOINC axes (role, domain, setting, type of service, and document kind). See below for description. + +### Mapping of clinical documents to Clinical Document Ontology (CDO) and standard terminology + +HL7/LOINC CDO is a standard for consistent naming of documents to support a range of use cases: retrieval, organization, display, and exchange. It guides the creation of LOINC codes for clinical notes. CDO annotates each document with 5 dimensions: + +* **Kind of Document:** Characterizes the generalc structure of the document at a macro level (e.g. Anesthesia Consent) +* **Type of Service**: Characterizes the kind of service or activity (e.g. evaluations, consultations, and summaries). The notion of time sequence, e.g., at the beginning (admission) at the end (discharge) is subsumed in this axis. Example: Discharge Teaching. +* **Setting:** Setting is an extension of CMS�s definitions (e.g. Inpatient, Outpatient) +* **Subject Matter Domain (SMD):** Characterizes the subject matter domain of a note (e.g. Anesthesiology) +* **Role:** Characterizes the training or professional level of the author of the document, but does not break down to specialty or subspecialty (e.g. Physician) + +Each combination of these 5 dimensions should roll up to a unique LOINC code. For example, Dentistry Hygienist Outpatient Progress note (LOINC code 34127-1) has the following dimensions: + +* According to CDO requirements, only 2 of the 5 dimensions are required to properly annotate a document: Kind of Document and any one of the other 4 dimensions. +* However, not all the permutations of the CDO dimensions will necessarily yield an existing LOINC code.2 HL7/LOINC workforce is committed to establish new LOINC codes for each new encountered combination of CDO dimensions. 3 + +Automation of mapping of clinical notes to a standard terminology based on the note title is possible when it is driven by ontology (aka CDO). Mapping to individual LOINC codes which may or may not exist for a particular note type cannot be fully automated. To support mapping of clinical notes to CDO in OMOP CDM, we propose the following approach: + +#### 1. Add all LOINC concepts representing 5 CDO dimensions to the Concept table. For example: + +Field | Record 1 | Record 2 +:-- | :-- | :-- +concept_id | 55443322132 | 55443322175 +concept_name | Administrative note | Against medical advice note +concept_code | LP173418-7 | LP173388-2 +vocabulary_id | LOINC | LOINC + +#### 2. Represent CDO hierarchy in the Concept_Relationship table using the �Subsumes� � �Is a� relationship pair. For example: + +Field | Record 1 | Record 2 +:-- | :-- | :-- +concept_id_1 | 55443322132 | 55443322175 +concept_id_2 | 55443322175 | 55443322132 +relationship_id | Subsumes | Is a + +#### 3. Add LOINC document codes to the Concept table (e.g. Dentistry Hygienist Outpatient Progress note, LOINC code 34127-1). For example: + +Field | Record 1 | Record 2 +:-- | :-- | :-- +concept_id | 193240 | 193241 +concept_name | Dentistry Hygienist Outpatient Progress note | Consult note +concept_code | 34127-1 | 11488-4 +vocabulary_id | LOINC | LOINC + +#### 4. Represent dimensions of each document concept in Concept_Relationship table by its relationships to the respective concepts from CDO. + +* Use the �Member Of� � �Has Member� (new) relationship pair. +* Using example from the Dentistry Hygienist Outpatient Progress note (LOINC code 34127-1): + +concept_id_1 | concept_id_1 | relationship_id +:-- | :-- | :-- +193240 | 55443322132 | Member Of +55443322132 | 193240 | Has Member +193240 | 55443322175 | Member Of +55443322175 | 193240 | Has Member +193240 | 55443322166 | Member Of +55443322166 | 193240 | Has Member +193240 | 55443322107 | Member Of +55443322107 | 193240 | Has Member +193240 | 55443322146 | Member Of +55443322146 | 193240 | Has Member + +Where concept codes represent the following concepts: + +Content | Description +:---------- | :-------------------------------------------------------------------- +193240 | Corresponds to LOINC 34127-1, Dentistry Hygienist Outpatient Progress note +55443322132 | Corresponds to LOINC LP173418-7, Kind of Document = Note +55443322175 | Corresponds to LOINC LP173213-2, Type of Service = Progress +55443322166 | Corresponds to LOINC LP173051-6, Setting = Outpatient +55443322107 | Corresponds to LOINC LP172934-4, Subject Matter Domain �= Dentistry +55443322146 | Corresponds to LOINC LP173071-4, Role = Hygienist + +Most of the codes will not have all 5 dimensions. Therefore, they may be represented by 2-5 relationship pairs. + +#### 5. If LOINC does not have a code corresponding to a permutation of the 5 CDO encountered in the source, this code will be generated as OMOP vocabulary code. + +* Its relationships to the CDO dimensions will be represented exactly as those of existing LOINC concepts (as described above). If/when a proper LOINC code for this permutation is released, the old code should be deprecated. Transition between the old and new codes should be represented by �Concept replaces� � �Concept replaced by� pairs. + +#### 6. Mapping from the source data will be performed to the 2-5 CDO dimensions. + +Query below finds LOINC code for Dentistry Hygienist Outpatient Progress note (see example above) that has all 5 dimensions: + +```sql + SELECT + FROM Concept_Relationship + WHERE relationship_id = �Has Member� AND + (concept_id_1 = 55443322132 + OR concept_id_1 = 55443322175 + OR concept_id_1 = 55443322166 + OR concept_id_1 = 55443322107 + OR concept_id_1 = 55443322146) + GROUP BY concept_ID_2 +``` + +If less than 5 dimensions are available, `HAVING COUNT(n)` clause should be added to get a unique record at the intersection of these dimensions. n is the number of dimensions available: + +```sql + SELECT + FROM Concept_Relationship + WHERE relationship_id = �Has Member� AND + (concept_id_1 = 55443322132 + OR concept_id_1 = 55443322175 + OR concept_id_1 = 55443322146) + GROUP BY concept_ID_2 + HAVING COUNT(*) = 3 +``` \ No newline at end of file diff --git a/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/NOTE_NLP.md b/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/NOTE_NLP.md new file mode 100644 index 0000000..cf53f30 --- /dev/null +++ b/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/NOTE_NLP.md @@ -0,0 +1,50 @@ +The NOTE_NLP table will encode all output of NLP on clinical notes. Each row represents a single extracted term from a note. + +Field | Required | Type | Description +:------------------------------- | :-------- | :------------ | :--------------------------------------------------- +note_nlp_id | Yes | Big Integer | A unique identifier for each term extracted from a note. +note_id | Yes | integer | A foreign key to the Note table note the term was extracted from. +section_concept_id | No | integer | A foreign key to the predefined Concept in the Standardized Vocabularies representing the section of the extracted term. +snippet | No | varchar(250) | A small window of text surrounding the term. +offset | No | varchar(50) | Character offset of the extracted term in the input note. +lexical_variant | Yes | varchar(250) | Raw text extracted from the NLP tool. +note_nlp_concept_id | No | integer | A foreign key to the predefined Concept in the Standardized Vocabularies reflecting the normalized concept for the extracted term. Domain of the term is represented as part of the Concept table. +note_nlp_source_concept_id | no | integer | A foreign key to a Concept that refers to the code in the source vocabulary used by the NLP system +nlp_system | No | varchar(250) | Name and version of the NLP system that extracted the term.Useful for data provenance. +nlp_date | Yes | date | The date of the note processing.Useful for data provenance. +nlp_date_time | No | datetime | The date and time of the note processing. Useful for data provenance. +term_exists | No | varchar(1) | A summary modifier that signifies presence or absence of the term for a given patient. Useful for quick querying. * +term_temporal | No | varchar(50) | An optional time modifier associated with the extracted term. (for now “past” or “present” only). Standardize it later. +term_modifiers | No | varchar(2000) | A compact description of all the modifiers of the specific term extracted by the NLP system. (e.g. “son has rash” ? “negated=no,subject=family, certainty=undef,conditional=false,general=false”). + +### Conventions + +**Term_exists** +Term_exists is defined as a flag that indicates if the patient actually has or had the condition. Any of the following modifiers would make Term_exists false: + +* Negation = true +* Subject = [anything other than the patient] +* Conditional = true +* Rule_out = true +* Uncertain = very low certainty or any lower certainties + +A complete lack of modifiers would make Term_exists true. + +For the modifiers that are there, they would have to have these values: + +* Negation = false +* Subject = patient +* Conditional = false +* Rule_out = false +* Uncertain = true or high or moderate or even low (could argue about low) + +**Term_temporal** +Term_temporal is to indicate if a condition is “present” or just in the “past”. + +The following would be past: + +* History = true +* Concept_date = anything before the time of the report + +**Term_modifiers** +Term_modifiers will concatenate all modifiers for different types of entities (conditions, drugs, labs etc) into one string. Lab values will be saved as one of the modifiers. A list of allowable modifiers (e.g., signature for medications) and their possible values will be standardized later. diff --git a/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/Standardized-Clinical-Data-Tables.md b/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/Standardized-Clinical-Data-Tables.md index efff4a4..50e95cd 100644 --- a/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/Standardized-Clinical-Data-Tables.md +++ b/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/Standardized-Clinical-Data-Tables.md @@ -9,6 +9,7 @@ [CONDITION_OCCURRENCE](https://github.com/OHDSI/CommonDataModel/wiki/CONDITION_OCCURRENCE) [MEASUREMENT](https://github.com/OHDSI/CommonDataModel/wiki/MEASUREMENT) [NOTE](https://github.com/OHDSI/CommonDataModel/wiki/NOTE) +[NOTE_NLP](https://github.com/OHDSI/CommonDataModel/wiki/NOTE_NLP) [OBSERVATION](https://github.com/OHDSI/CommonDataModel/wiki/OBSERVATION) [FACT_RELATIONSHIP](https://github.com/OHDSI/CommonDataModel/wiki/FACT_RELATIONSHIP) diff --git a/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/VISIT_OCCURRENCE.md b/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/VISIT_OCCURRENCE.md index a156d7b..bb0b30b 100644 --- a/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/VISIT_OCCURRENCE.md +++ b/Documentation/CommonDataModel_Wiki_Files/StandardizedClinicalDataTables/VISIT_OCCURRENCE.md @@ -14,6 +14,11 @@ Field|Required|Type|Description |care_site_id|No|integer|A foreign key to the care site in the care site table that was visited.| |visit_source_value|No|string(50)|The source code for the visit as it appears in the source data.| |visit_source_concept_id|No|Integer|A foreign key to a Concept that refers to the code used in the source.| +|admitting_source_concept_id| |Integer |No |A foreign key to the predefined concept in the Place of Service Vocabulary reflecting the admitting source for a visit.| +|admitting_source_value |Varchar(50)| No| The source code for the admitting source as it appears in the source data.| +|discharge_to_concept_id| Integer |No |A foreign key to the predefined concept in the Place of Service Vocabulary reflecting the discharge disposition for a visit.| +|discharge_to_source_value| Varchar(50)| No| The source code for the discharge disposition as it appears in the source data.| +|preceding_visit_occurrence_id |Integer| No |A foreign key to the VISIT_OCCURRENCE table of the visit immediately preceding this visit| ### Conventions @@ -27,4 +32,11 @@ Field|Required|Type|Description * One visit may involve multiple Care Sites, in which case the ETL must specify how a single care_site id is selected or leave the care_site_id field null. * Visits are recorded in various data sources in different forms with varying levels of standardization. For example: * Medical Claims include Inpatient Admissions, Outpatient Services, and Emergency Room visits. - * Electronic Health Records may capture Person visits as part of the activities recorded depending whether the EHR system is used at the different Care Sites. \ No newline at end of file + * Electronic Health Records may capture Person visits as part of the activities recorded depending whether the EHR system is used at the different Care Sites. + * In addition to the "Place of Service" vocabulary the following SNOMED concepts for discharge disposition can be used: + * Patient died: 4216643 + * Absent without leave: 44814693 + * Patient self-discharge against medical advice: 4021968 + * In the case where a patient died during admission (Visit_Occurrence.discharge_disposition_concept_id = 4216643 �Patient died�), a record in the Death table should be created with death_type_concept_id = 44818516 (�EHR discharge status "Expired"). + * PRECEDING_VISIT_ID can be used to link a visit immediately preceding the current visit + * Some EMR systems combine emergency room followed by inpatient admission into one visit, and it is close to impossible to separate the two. To annotate this visit type, a new visit concept �Emergency Room and Inpatient Visit� was added (CONCEPT_ID 262). \ No newline at end of file diff --git a/Documentation/CommonDataModel_Wiki_Files/StandardizedDerivedElements/CONDITION_ERA.md b/Documentation/CommonDataModel_Wiki_Files/StandardizedDerivedElements/CONDITION_ERA.md index 4bf8789..bde5595 100644 --- a/Documentation/CommonDataModel_Wiki_Files/StandardizedDerivedElements/CONDITION_ERA.md +++ b/Documentation/CommonDataModel_Wiki_Files/StandardizedDerivedElements/CONDITION_ERA.md @@ -1,8 +1,10 @@ A Condition Era is defined as a span of time when the Person is assumed to have a given condition. Similar to Drug Eras, Condition Eras are chronological periods of Condition Occurrence. Combining individual Condition Occurrences into a single Condition Era serves two purposes: + * It allows aggregation of chronic conditions that require frequent ongoing care, instead of treating each Condition Occurrence as an independent event. * It allows aggregation of multiple, closely timed doctor visits for the same Condition to avoid double-counting the Condition Occurrences. -For example, consider a Person who visits her Primary Care Physician (PCP) and who is referred to a specialist. At a later time, the Person visits the specialist, who confirms the PCP’s original diagnosis and provides the appropriate treatment to resolve the condition. These two independent doctor visits should be aggregated into one Condition Era. + +For example, consider a Person who visits her Primary Care Physician (PCP) and who is referred to a specialist. At a later time, the Person visits the specialist, who confirms the PCP's original diagnosis and provides the appropriate treatment to resolve the condition. These two independent doctor visits should be aggregated into one Condition Era. Field|Required|Type|Description :----------------------------|:--------|:------------|:---------------------------------- @@ -16,7 +18,7 @@ Field|Required|Type|Description ### Conventions * Condition Era records will be derived from the records in the CONDITION_OCCURRENCE table using a standardized algorithm. * Each Condition Era corresponds to one or many Condition Occurrence records that form a continuous interval. -The condition_concept_id field contains Concepts that are identical to those of the CONDITION_OCCURRENCE table records that make up the Condition Era. In contrast to Drug Eras, Condition Eras are not aggregated to contain Conditions of different hierarchical layers. -The Condition Era Start Date is the start date of the first Condition Occurrence. -The Condition Era End Date is the end date of the last Condition Occurrence. + * The condition_concept_id field contains Concepts that are identical to those of the CONDITION_OCCURRENCE table records that make up the Condition Era. In contrast to Drug Eras, Condition Eras are not aggregated to contain Conditions of different hierarchical layers. + * The Condition Era Start Date is the start date of the first Condition Occurrence. + * The Condition Era End Date is the end date of the last Condition Occurrence. * Condition Eras are built with a Persistence Window of 30 days, meaning, if no occurence of the same condition_concept_id happens within 30 days of any one occurrence, it will be considered the condition_era_end_date. diff --git a/Documentation/CommonDataModel_Wiki_Files/StandardizedDerivedElements/Standardized-Derived-Elements.md b/Documentation/CommonDataModel_Wiki_Files/StandardizedDerivedElements/Standardized-Derived-Elements.md index 8b2d151..cb81a0e 100644 --- a/Documentation/CommonDataModel_Wiki_Files/StandardizedDerivedElements/Standardized-Derived-Elements.md +++ b/Documentation/CommonDataModel_Wiki_Files/StandardizedDerivedElements/Standardized-Derived-Elements.md @@ -1,3 +1,9 @@ +[COHORT](https://github.com/OHDSI/CommonDataModel/wiki/COHORT) +[COHORT_ATTRIBUTE](https://github.com/OHDSI/CommonDataModel/wiki/COHORT_ATTRIBUTE) +[DRUG_ERA](https://github.com/OHDSI/CommonDataModel/wiki/DRUG_ERA) +[DOSE_ERA](https://github.com/OHDSI/CommonDataModel/wiki/DOSE_ERA) +[CONDITION_ERA](https://github.com/OHDSI/CommonDataModel/wiki/CONDITION_ERA) + These tables contain information about the clinical events of a patient that are not obtained directly from the raw source data, but from other tables of the CDM. Below provides an entity-relationship diagram highlighting the tables within the Standardized Derived Elements portion of the OMOP Common Data Model: diff --git a/Documentation/CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/COST.md b/Documentation/CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/COST.md index b2c9cb3..5e98c1a 100644 --- a/Documentation/CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/COST.md +++ b/Documentation/CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/COST.md @@ -24,6 +24,8 @@ Field|Required|Type|Description |amount_allowed|No|float|The contracted amount agreed between the payer and provider.| |revenue_code_concept_id|No|integer|A foreign key referring to a Standard Concept ID in the Standardized Vocabularies for Revenue codes.| |revenue_code_source_value|No|string(50)|The source code for the Revenue code as it appears in the source data, stored here for reference.| +|drg_concept_id| integer| No |A foreign key to the predefined concept in the DRG Vocabulary reflecting the DRG for a visit.| +|drg_source_value| varchar(3)| No| The 3-digit DRG source code as it appears in the source data.| ### Conventions The COST table will store information reporting money or currency amounts. There are three types of cost data, defined in the cost_type_concept_id: 1) paid or reimbursed amounts, 2) charges or list prices (such as Average Wholesale Prices), and 3) costs or expenses incurred by the provider. The defined fields are variables found in almost all U.S.-based claims data sources, which is the most common data source for researchers. Non-U.S.-based data holders are encouraged to engage with OHDSI to adjust these tables to their needs. @@ -53,4 +55,5 @@ cost_domain_id|corresponding CDM table * paid_patient_deductible does contribute to the paid_by_patient variable. The paid_patient_deductible field is only used for reporting a patient's deductible amount reported on an insurance claim. * amount_allowed: This information is generally available in claims data. This is similar to the total_paid amount in that it shows what the payer expects the provider to be reimbursed after the payer and patient pay. This differs from the total_paid amount in that it is not a calculated field, but a field available directly in claims data. The field is payer-specific and the payer should be indicated by the payer_plan_id field. * paid_by_primary does contribute to the total_paid variable. The paid_by_primary field is only used for reporting a patient's primary insurance payment amount reported on the secondary payer insurance claim. If the source data has actual primary insurance payments (e.g. the primary insurance payment is not a derivative of the payer claim and there is verification another insurance company paid an amount to the provider), then the primary insurance payment should have its own cost record with a payer_plan_id set to the applicable payer, and the actual primary insurance payment should be noted under the paid_by_payer field. - * revenue_code_concept_id: Revenue codes are a method to charge for a class of procedures and conditions in the U.S. hospital system. \ No newline at end of file + * revenue_code_concept_id: Revenue codes are a method to charge for a class of procedures and conditions in the U.S. hospital system. + * drg_concept_id: Diagnosis Related Groups are US codes used to classify hospital cases into one of approximately 500 groups. Only the MS-DRG system should be used (mapped to vocabulary_id 'DRG) and all other DRG values should be mapped to 0. \ No newline at end of file diff --git a/Documentation/CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/Standardized-Health-Economics-Data-Tables.md b/Documentation/CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/Standardized-Health-Economics-Data-Tables.md index 26289dd..74f963a 100644 --- a/Documentation/CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/Standardized-Health-Economics-Data-Tables.md +++ b/Documentation/CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/Standardized-Health-Economics-Data-Tables.md @@ -1 +1,4 @@ +[PAYER_PLAN_PERIOD](https://github.com/OHDSI/CommonDataModel/wiki/PAYER_PLAN_PERIOD) +[COST](https://github.com/OHDSI/CommonDataModel/wiki/COST) + These tables contain cost information about healthcare. They are dependent on the healthcare delivery system the patient is involved in, which may vary significantly within a country and across different countries. However, the current model is focused on the US healthcare system. diff --git a/Documentation/CommonDataModel_Wiki_Files/StandardizedHealthSystemDataTables/Standardized-Health-System-Data-Tables.md b/Documentation/CommonDataModel_Wiki_Files/StandardizedHealthSystemDataTables/Standardized-Health-System-Data-Tables.md index a0d9d80..97db3c9 100644 --- a/Documentation/CommonDataModel_Wiki_Files/StandardizedHealthSystemDataTables/Standardized-Health-System-Data-Tables.md +++ b/Documentation/CommonDataModel_Wiki_Files/StandardizedHealthSystemDataTables/Standardized-Health-System-Data-Tables.md @@ -1,3 +1,7 @@ +[LOCATION](https://github.com/OHDSI/CommonDataModel/wiki/LOCATION) +[CARE_SITE](https://github.com/OHDSI/CommonDataModel/wiki/CARE_SITE) +[PROVIDER](https://github.com/OHDSI/CommonDataModel/wiki/PROVIDER) + These tables describe the healthcare provider system responsible for administering the healthcare of the patient, rather than the demographic or clinical events the patient experienced. Below provides an entity-relationship diagram highlighting the tables within the Standardized Health System portion of the OMOP Common Data Model: diff --git a/Documentation/CommonDataModel_Wiki_Files/StandardizedVocabularies/DRUG_STRENGTH.md b/Documentation/CommonDataModel_Wiki_Files/StandardizedVocabularies/DRUG_STRENGTH.md index c0f8f84..92fbd51 100644 --- a/Documentation/CommonDataModel_Wiki_Files/StandardizedVocabularies/DRUG_STRENGTH.md +++ b/Documentation/CommonDataModel_Wiki_Files/StandardizedVocabularies/DRUG_STRENGTH.md @@ -10,6 +10,7 @@ Field|Required|Type|Description |numerator_unit_concept_id|No|integer|A foreign key to the Concept in the CONCEPT table representing the identifier for the numerator Unit for the concentration of active ingredient.| |denominator_value|No|float|The amount of total liquid (or other divisible product, such as ointment, gel, spray, etc.).| |denominator_unit_concept_id|No|integer|A foreign key to the Concept in the CONCEPT table representing the identifier for the denominator Unit for the concentration of active ingredient.| +|box_size|No|integer|The number of units of Clinical of Branded Drug, or Quantified Clinical or Branded Drug contained in a box as dispensed to the patient| |valid_start_date|Yes|date|The date when the Concept was first recorded. The default value is 1-Jan-1970.| |valid_end_date|Yes|date|The date when the concept became invalid because it was deleted or superseded (updated) by a new Concept. The default value is 31-Dec-2099.| |invalid_reason|No|varchar(1)|Reason the concept was invalidated. Possible values are 'D' (deleted), 'U' (replaced with an update) or NULL when valid_end_date has the default value.| @@ -25,4 +26,5 @@ Field|Required|Type|Description * If the strength is provided in % (volume or mass-percent are not distinguished) it is stored in the numerator_value/numerator_unit_concept_id field combination, with both the denominator_value and denominator_unit_concept_id set to NULL. If it is a Quantified Drug the total amount of drug is provided in the denominator_value/denominator_unit_concept_id pair. E.g., the 30 G Isoconazole 2% Topical Cream is provided as 2% / in Clinical Drug and Clinical Drug Component, and as 2% /30 G. * Sometimes, one Ingredient is listed with different units within the same drug. This is very rare, and usually this happens if there are more than one Precise Ingredient. For example, 'Penicillin G, Benzathine 150000 UNT/ML / Penicillin G, Procaine 150000 MEQ/ML Injectable Suspension' contains Penicillin G in two different forms. * Sometimes, different ingredients in liquid drugs are listed with different units in the denominator_unit_concept_id. This is usually the case if the ingredients are liquids themselves (concentration provided as mL/mL) or solid substances (mg/mg). In these cases, the general assumptions is made that the density of the drug is that of water, and one can assume 1 g = 1 mL. - * All Drug vocabularies containing Standard Concepts have entries in the DRUG_STRENGTH table. \ No newline at end of file + * All Drug vocabularies containing Standard Concepts have entries in the DRUG_STRENGTH table. + * There is now a Concept Class for supplier information whose relationships can be found in CONCEPT_RELATIONSHIP with a relationship_id of 'Has supplier' and 'Supplier of' \ No newline at end of file diff --git a/Documentation/CommonDataModel_Wiki_Files/_Footer.md b/Documentation/CommonDataModel_Wiki_Files/_Footer.md index 6230684..0d10ef6 100644 --- a/Documentation/CommonDataModel_Wiki_Files/_Footer.md +++ b/Documentation/CommonDataModel_Wiki_Files/_Footer.md @@ -1 +1 @@ -***OMOP Common Data Model v5.1.1 Specifications*** \ No newline at end of file +***OMOP Common Data Model v5.2 Specifications*** \ No newline at end of file diff --git a/Documentation/CommonDataModel_Wiki_Files/_Sidebar.md b/Documentation/CommonDataModel_Wiki_Files/_Sidebar.md index 07b394a..5743af0 100644 --- a/Documentation/CommonDataModel_Wiki_Files/_Sidebar.md +++ b/Documentation/CommonDataModel_Wiki_Files/_Sidebar.md @@ -38,6 +38,7 @@ * [CONDITION_OCCURRENCE](https://github.com/OHDSI/CommonDataModel/wiki/CONDITION_OCCURRENCE) * [MEASUREMENT](https://github.com/OHDSI/CommonDataModel/wiki/MEASUREMENT) * [NOTE](https://github.com/OHDSI/CommonDataModel/wiki/NOTE) +* [NOTE_NLP](https://github.com/OHDSI/CommonDataModel/wiki/NOTE_NLP) * [OBSERVATION](https://github.com/OHDSI/CommonDataModel/wiki/OBSERVATION) * [FACT_RELATIONSHIP](https://github.com/OHDSI/CommonDataModel/wiki/FACT_RELATIONSHIP) diff --git a/Documentation/.Rhistory b/Documentation/CommonDataModel_pdf_create/.Rhistory similarity index 100% rename from Documentation/.Rhistory rename to Documentation/CommonDataModel_pdf_create/.Rhistory diff --git a/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/prop/49A263C2 b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/prop/49A263C2 new file mode 100644 index 0000000..7a73a41 --- /dev/null +++ b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/prop/49A263C2 @@ -0,0 +1,2 @@ +{ +} \ No newline at end of file diff --git a/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/prop/9FB0FECF b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/prop/9FB0FECF new file mode 100644 index 0000000..7a73a41 --- /dev/null +++ b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/prop/9FB0FECF @@ -0,0 +1,2 @@ +{ +} \ No newline at end of file diff --git a/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/prop/BC873E69 b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/prop/BC873E69 new file mode 100644 index 0000000..7a73a41 --- /dev/null +++ b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/prop/BC873E69 @@ -0,0 +1,2 @@ +{ +} \ No newline at end of file diff --git a/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/prop/INDEX b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/prop/INDEX new file mode 100644 index 0000000..64ab079 --- /dev/null +++ b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/prop/INDEX @@ -0,0 +1,5 @@ +C%3A%2FGit%2FGitHub%2FCDM_v5.2%2FCommonDataModel%2FDocumentation%2FCommonDataModel_pdf_create%2FMD_to_PDF_conversion.R="BBDD195" +C%3A%2FGit%2FGitHub%2FCDM_v5.2%2FCommonDataModel%2FDocumentation%2FCommonDataModel_pdf_create%2FOMOP_CDM_PDF.Rmd="4851A9DE" +C%3A%2FGit%2FGitHub%2FCommonDataModel%2FDocumentation%2FCommonDataModel_pdf_create%2F.Rhistory="49A263C2" +C%3A%2FGit%2FGitHub%2FCommonDataModel%2FDocumentation%2FCommonDataModel_pdf_create%2FMD_to_PDF_conversion.R="BC873E69" +C%3A%2FGit%2FGitHub%2FCommonDataModel%2FDocumentation%2FCommonDataModel_pdf_create%2FOMOP_CDM_PDF.Rmd="9FB0FECF" diff --git a/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/s-572B4995/87804256 b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/s-572B4995/87804256 new file mode 100644 index 0000000..1729446 --- /dev/null +++ b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/s-572B4995/87804256 @@ -0,0 +1,20 @@ +{ + "collab_server" : "", + "contents" : "---\ntitle: \"OMOP Common Data Model v5.2 Specifications\"\nauthor: \"Christian Reich, Patrick Ryan, Rimma Belenkaya, Karthik Natarajan and Clair Blacketer\"\ndate: \"`r Sys.Date()`\"\noutput:\n pdf_document:\n number_sections: yes\n toc: yes\nlinkcolor: blue\n---\n\n# License\n\n```{r child = '../CommonDataModel_Wiki_Files/License.md'}\n```\n\n# Background\n```{r child = '../CommonDataModel_Wiki_Files/Background/Background.md'}\n```\n\n## The Role of the Common Data Model\n```{r child = '../CommonDataModel_Wiki_Files/Background/The-Role-of-the-Common-Data-Model.md'}\n```\n\n## Design Principles\n```{r child = '../CommonDataModel_Wiki_Files/Background/Design-Principles.md'}\n```\n\n## Data Model Conventions\n```{r child = '../CommonDataModel_Wiki_Files/Background/Data-Model-Conventions.md'}\n```\n\n# Glossary of Terms\n```{r child = '../CommonDataModel_Wiki_Files/Glossary-of-Terms.md'}\n```\n\n# Standardized Vocabularies\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/Standardized-Vocabularies.md'}\n```\n\n## CONCEPT\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/CONCEPT.md'}\n```\n\n## VOCABULARY\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/VOCABULARY.md'}\n```\n\n## DOMAIN\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/DOMAIN.md'}\n```\n\n## CONCEPT_CLASS\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/CONCEPT_CLASS.md'}\n```\n\n## CONCEPT_RELATIONSHIP\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/CONCEPT_RELATIONSHIP.md'}\n```\n\n## RELATIONSHIP\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/RELATIONSHIP.md'}\n```\n\n## CONCEPT_SYNONYM\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/CONCEPT_SYNONYM.md'}\n```\n\n## CONCEPT_ANCESTOR\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/CONCEPT_ANCESTOR.md'}\n```\n\n## SOURCE_TO_CONCEPT_MAP\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/SOURCE_TO_CONCEPT_MAP.md'}\n```\n\n## DRUG_STRENGTH\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/DRUG_STRENGTH.md'}\n```\n\n## COHORT_DEFINITION\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/COHORT_DEFINITION.md'}\n```\n\n## ATTRIBUTE_DEFINITION\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/ATTRIBUTE_DEFINITION.md'}\n```\n\n# Standardized Metadata\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedMetadata/Standardized-Metadata.md'}\n```\n\n## CDM_SOURCE\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedMetadata/CDM_SOURCE.md'}\n```\n\n# Standardized Clinical Data Tables\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/Standardized-clinical-Data-Tables.md'}\n```\n\n## PERSON\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/PERSON.md'}\n```\n\n## OBSERVATION_PERIOD\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/OBSERVATION_PERIOD.md'}\n```\n\n## SPECIMEN\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/SPECIMEN.md'}\n```\n\n## DEATH\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/DEATH.md'}\n```\n\n## VISIT_OCCURRENCE\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/VISIT_OCCURRENCE.md'}\n```\n\n## PROCEDURE_OCCURRENCE\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/PROCEDURE_OCCURRENCE.md'}\n```\n\n## DRUG_EXPOSURE\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/DRUG_EXPOSURE.md'}\n```\n\n## DEVICE_EXPOSURE\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/DEVICE_EXPOSURE.md'}\n```\n\n## CONDITION_OCCURRENCE\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/CONDITION_OCCURRENCE.md'}\n```\n\n## MEASUREMENT\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/MEASUREMENT.md'}\n```\n\n## NOTE\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/NOTE.md'}\n```\n\n## NOTE_NLP\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/NOTE_NLP.md'}\n```\n\n## OBSERVATION\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/OBSERVATION.md'}\n```\n\n## FACT_RELATIONSHIP\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/FACT_RELATIONSHIP.md'}\n```\n\n# Standardized Health System Data Tables\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthSystemDataTables/Standardized-Health-System-Data-Tables.md'}\n```\n\n## LOCATION\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthSystemDataTables/LOCATION.md'}\n```\n\n## CARE_SITE\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthSystemDataTables/CARE_SITE.md'}\n```\n\n## PROVIDER\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthSystemDataTables/PROVIDER.md'}\n```\n\n# Standardized Health Economics Data Tables\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/Standardized-Health-Economics-Data-Tables.md'}\n```\n\n## PAYER_PLAN_PERIOD\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/PAYER_PLAN_PERIOD.md'}\n```\n\n## COST\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/COST.md'}\n```\n\n# Standardized Derived Elements\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedDerivedElements/Standardized-Derived-Elements.md'}\n```\n\n## COHORT\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedDerivedElements/COHORT.md'}\n```\n\n## COHORT_ATTRIBUTE\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedDerivedElements/COHORT_ATTRIBUTE.md'}\n```\n\n## DRUG_ERA\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedDerivedElements/DRUG_ERA.md'}\n```\n\n## DOSE_ERA\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedDerivedElements/DOSE_ERA.md'}\n```\n\n## CONDITION_ERA\n```{r child = '../CommonDataModel_Wiki_Files/StandardizedDerivedElements/CONDITION_ERA.md'}\n```", + "created" : 1500488103153.000, + "dirty" : false, + "encoding" : "UTF-8", + "folds" : "", + "hash" : "4194078453", + "id" : "87804256", + "lastKnownWriteTime" : 1500494221, + "last_content_update" : 1500494221444, + "path" : "C:/Git/GitHub/CDM_v5.2/CommonDataModel/Documentation/CommonDataModel_pdf_create/OMOP_CDM_PDF.Rmd", + "project_path" : "OMOP_CDM_PDF.Rmd", + "properties" : { + }, + "relative_order" : 2, + "source_on_save" : false, + "source_window" : "", + "type" : "r_markdown" +} \ No newline at end of file diff --git a/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/s-572B4995/C0F9B15 b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/s-572B4995/C0F9B15 new file mode 100644 index 0000000..7b55aa0 --- /dev/null +++ b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/s-572B4995/C0F9B15 @@ -0,0 +1,20 @@ +{ + "collab_server" : "", + "contents" : "## Run this code and point it to the .Rmd file so it can convert the markdown files on the wiki to a pdf\ninstall.packages(\"rmarkdown\")\n\nrmarkdown::render(input = \"OMOP_CDM_PDF.Rmd\", output_format = \"pdf_document\", output_file = \"OMOP_CDM_v5_2.pdf\")\n", + "created" : 1500488094416.000, + "dirty" : false, + "encoding" : "UTF-8", + "folds" : "", + "hash" : "4214385325", + "id" : "C0F9B15", + "lastKnownWriteTime" : 1500494244, + "last_content_update" : 1500494244700, + "path" : "C:/Git/GitHub/CDM_v5.2/CommonDataModel/Documentation/CommonDataModel_pdf_create/MD_to_PDF_conversion.R", + "project_path" : "MD_to_PDF_conversion.R", + "properties" : { + }, + "relative_order" : 2, + "source_on_save" : false, + "source_window" : "", + "type" : "r_source" +} \ No newline at end of file diff --git a/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/s-572B4995/lock_file b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/sdb/s-572B4995/lock_file new file mode 100644 index 0000000..e69de29 diff --git a/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/session-persistent-state b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/session-persistent-state new file mode 100644 index 0000000..f529a4a --- /dev/null +++ b/Documentation/CommonDataModel_pdf_create/.Rproj.user/C9B3802/session-persistent-state @@ -0,0 +1 @@ +virtual-session-id="FBCE731C" diff --git a/Documentation/CommonDataModel_pdf_create/.Rproj.user/shared/notebooks/paths b/Documentation/CommonDataModel_pdf_create/.Rproj.user/shared/notebooks/paths new file mode 100644 index 0000000..a3367b0 --- /dev/null +++ b/Documentation/CommonDataModel_pdf_create/.Rproj.user/shared/notebooks/paths @@ -0,0 +1 @@ +C:/Git/CommonDataModel/Documentation/CommonDataModel_pdf_create/OMOP_CDM_PDF.Rmd="71819BA2" diff --git a/Documentation/CommonDataModel_pdf_create/CommonDataModel_pdf_create.Rproj b/Documentation/CommonDataModel_pdf_create/CommonDataModel_pdf_create.Rproj new file mode 100644 index 0000000..734b20d --- /dev/null +++ b/Documentation/CommonDataModel_pdf_create/CommonDataModel_pdf_create.Rproj @@ -0,0 +1,13 @@ +Version: 1.0 + +RestoreWorkspace: Default +SaveWorkspace: Default +AlwaysSaveHistory: Default + +EnableCodeIndexing: Yes +UseSpacesForTab: Yes +NumSpacesForTab: 8 +Encoding: UTF-8 + +RnwWeave: Sweave +LaTeX: pdfLaTeX diff --git a/Documentation/CommonDataModel_pdf_create/MD_to_PDF_conversion.R b/Documentation/CommonDataModel_pdf_create/MD_to_PDF_conversion.R new file mode 100644 index 0000000..9de0ebe --- /dev/null +++ b/Documentation/CommonDataModel_pdf_create/MD_to_PDF_conversion.R @@ -0,0 +1,4 @@ +## Run this code and point it to the .Rmd file so it can convert the markdown files on the wiki to a pdf +install.packages("rmarkdown") + +rmarkdown::render(input = "OMOP_CDM_PDF.Rmd", output_format = "pdf_document", output_file = "../../OMOP_CDM_v5_2.pdf") diff --git a/Documentation/CommonDataModel_pdf_create/OMOP_CDM_PDF.Rmd b/Documentation/CommonDataModel_pdf_create/OMOP_CDM_PDF.Rmd new file mode 100644 index 0000000..9e87767 --- /dev/null +++ b/Documentation/CommonDataModel_pdf_create/OMOP_CDM_PDF.Rmd @@ -0,0 +1,207 @@ +--- +title: "OMOP Common Data Model v5.2 Specifications" +author: "Christian Reich, Patrick Ryan, Rimma Belenkaya, Karthik Natarajan and Clair Blacketer" +date: "`r Sys.Date()`" +output: + pdf_document: + number_sections: yes + toc: yes +linkcolor: blue +--- + +# License + +```{r child = '../CommonDataModel_Wiki_Files/License.md'} +``` + +# Background +```{r child = '../CommonDataModel_Wiki_Files/Background/Background.md'} +``` + +## The Role of the Common Data Model +```{r child = '../CommonDataModel_Wiki_Files/Background/The-Role-of-the-Common-Data-Model.md'} +``` + +## Design Principles +```{r child = '../CommonDataModel_Wiki_Files/Background/Design-Principles.md'} +``` + +## Data Model Conventions +```{r child = '../CommonDataModel_Wiki_Files/Background/Data-Model-Conventions.md'} +``` + +# Glossary of Terms +```{r child = '../CommonDataModel_Wiki_Files/Glossary-of-Terms.md'} +``` + +# Standardized Vocabularies +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/Standardized-Vocabularies.md'} +``` + +## CONCEPT +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/CONCEPT.md'} +``` + +## VOCABULARY +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/VOCABULARY.md'} +``` + +## DOMAIN +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/DOMAIN.md'} +``` + +## CONCEPT_CLASS +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/CONCEPT_CLASS.md'} +``` + +## CONCEPT_RELATIONSHIP +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/CONCEPT_RELATIONSHIP.md'} +``` + +## RELATIONSHIP +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/RELATIONSHIP.md'} +``` + +## CONCEPT_SYNONYM +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/CONCEPT_SYNONYM.md'} +``` + +## CONCEPT_ANCESTOR +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/CONCEPT_ANCESTOR.md'} +``` + +## SOURCE_TO_CONCEPT_MAP +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/SOURCE_TO_CONCEPT_MAP.md'} +``` + +## DRUG_STRENGTH +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/DRUG_STRENGTH.md'} +``` + +## COHORT_DEFINITION +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/COHORT_DEFINITION.md'} +``` + +## ATTRIBUTE_DEFINITION +```{r child = '../CommonDataModel_Wiki_Files/StandardizedVocabularies/ATTRIBUTE_DEFINITION.md'} +``` + +# Standardized Metadata +```{r child = '../CommonDataModel_Wiki_Files/StandardizedMetadata/Standardized-Metadata.md'} +``` + +## CDM_SOURCE +```{r child = '../CommonDataModel_Wiki_Files/StandardizedMetadata/CDM_SOURCE.md'} +``` + +# Standardized Clinical Data Tables +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/Standardized-clinical-Data-Tables.md'} +``` + +## PERSON +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/PERSON.md'} +``` + +## OBSERVATION_PERIOD +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/OBSERVATION_PERIOD.md'} +``` + +## SPECIMEN +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/SPECIMEN.md'} +``` + +## DEATH +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/DEATH.md'} +``` + +## VISIT_OCCURRENCE +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/VISIT_OCCURRENCE.md'} +``` + +## PROCEDURE_OCCURRENCE +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/PROCEDURE_OCCURRENCE.md'} +``` + +## DRUG_EXPOSURE +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/DRUG_EXPOSURE.md'} +``` + +## DEVICE_EXPOSURE +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/DEVICE_EXPOSURE.md'} +``` + +## CONDITION_OCCURRENCE +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/CONDITION_OCCURRENCE.md'} +``` + +## MEASUREMENT +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/MEASUREMENT.md'} +``` + +## NOTE +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/NOTE.md'} +``` + +## NOTE_NLP +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/NOTE_NLP.md'} +``` + +## OBSERVATION +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/OBSERVATION.md'} +``` + +## FACT_RELATIONSHIP +```{r child = '../CommonDataModel_Wiki_Files/StandardizedclinicalDataTables/FACT_RELATIONSHIP.md'} +``` + +# Standardized Health System Data Tables +```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthSystemDataTables/Standardized-Health-System-Data-Tables.md'} +``` + +## LOCATION +```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthSystemDataTables/LOCATION.md'} +``` + +## CARE_SITE +```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthSystemDataTables/CARE_SITE.md'} +``` + +## PROVIDER +```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthSystemDataTables/PROVIDER.md'} +``` + +# Standardized Health Economics Data Tables +```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/Standardized-Health-Economics-Data-Tables.md'} +``` + +## PAYER_PLAN_PERIOD +```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/PAYER_PLAN_PERIOD.md'} +``` + +## COST +```{r child = '../CommonDataModel_Wiki_Files/StandardizedHealthEconomicsDataTables/COST.md'} +``` + +# Standardized Derived Elements +```{r child = '../CommonDataModel_Wiki_Files/StandardizedDerivedElements/Standardized-Derived-Elements.md'} +``` + +## COHORT +```{r child = '../CommonDataModel_Wiki_Files/StandardizedDerivedElements/COHORT.md'} +``` + +## COHORT_ATTRIBUTE +```{r child = '../CommonDataModel_Wiki_Files/StandardizedDerivedElements/COHORT_ATTRIBUTE.md'} +``` + +## DRUG_ERA +```{r child = '../CommonDataModel_Wiki_Files/StandardizedDerivedElements/DRUG_ERA.md'} +``` + +## DOSE_ERA +```{r child = '../CommonDataModel_Wiki_Files/StandardizedDerivedElements/DOSE_ERA.md'} +``` + +## CONDITION_ERA +```{r child = '../CommonDataModel_Wiki_Files/StandardizedDerivedElements/CONDITION_ERA.md'} +``` \ No newline at end of file diff --git a/Documentation/MD_to_PDF_conversion.R b/Documentation/MD_to_PDF_conversion.R deleted file mode 100644 index b42f0e5..0000000 --- a/Documentation/MD_to_PDF_conversion.R +++ /dev/null @@ -1,3 +0,0 @@ -## Run this code and point it to the .Rmd file so it can convert the markdown files on the wiki to a pdf - -rmarkdown::render(input = "C:/Git/CommonDataModel/Documentation/OMOP_CDM_PDF.Rmd", output_format = "pdf_document", output_file = "C:/Git/CommonDataModel/OMOP_CDM_v5_1_0.pdf") diff --git a/Documentation/OMOP_CDM_PDF.Rmd b/Documentation/OMOP_CDM_PDF.Rmd deleted file mode 100644 index 6ed5c18..0000000 --- a/Documentation/OMOP_CDM_PDF.Rmd +++ /dev/null @@ -1,203 +0,0 @@ ---- -title: "OMOP Common Data Model v5.1 Specifications" -author: "Christian Reich, Patrick Ryan, Rimma Belenkaya, Karthik Natarajan and Clair Blacketer" -date: "`r Sys.Date()`" -output: - pdf_document: - number_sections: yes - toc: yes -linkcolor: blue ---- - -# License - -```{r child = 'C:/Git/CommonDataModel.wiki/License.md'} -``` - -# Background -```{r child = 'C:/Git/CommonDataModel.wiki/Background/Background.md'} -``` - -## The Role of the Common Data Model -```{r child = 'C:/Git/CommonDataModel.wiki/Background/The-Role-of-the-Common-Data-Model.md'} -``` - -## Design Principles -```{r child = 'C:/Git/CommonDataModel.wiki/Background/Design-Principles.md'} -``` - -## Data Model Conventions -```{r child = 'C:/Git/CommonDataModel.wiki/Background/Data-Model-Conventions.md'} -``` - -# Glossary of Terms -```{r child = 'C:/Git/CommonDataModel.wiki/Glossary-of-Terms.md'} -``` - -# Standardized Vocabularies -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/Standardized-Vocabularies.md'} -``` - -## CONCEPT -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/CONCEPT.md'} -``` - -## VOCABULARY -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/VOCABULARY.md'} -``` - -## DOMAIN -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/DOMAIN.md'} -``` - -## CONCEPT_CLASS -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/CONCEPT_CLASS.md'} -``` - -## CONCEPT_RELATIONSHIP -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/CONCEPT_RELATIONSHIP.md'} -``` - -## RELATIONSHIP -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/RELATIONSHIP.md'} -``` - -## CONCEPT_SYNONYM -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/CONCEPT_SYNONYM.md'} -``` - -## CONCEPT_ANCESTOR -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/CONCEPT_ANCESTOR.md'} -``` - -## SOURCE_TO_CONCEPT_MAP -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/SOURCE_TO_CONCEPT_MAP.md'} -``` - -## DRUG_STRENGTH -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/DRUG_STRENGTH.md'} -``` - -## COHORT_DEFINITION -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/COHORT_DEFINITION.md'} -``` - -## ATTRIBUTE_DEFINITION -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedVocabularies/ATTRIBUTE_DEFINITION.md'} -``` - -# Standardized Metadata -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedMetadata/Standardized-Metadata.md'} -``` - -## CDM_SOURCE -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedMetadata/CDM_SOURCE.md'} -``` - -# Standardized Clinical Data Tables -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/Standardized-clinical-Data-Tables.md'} -``` - -## PERSON -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/PERSON.md'} -``` - -## OBSERVATION_PERIOD -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/OBSERVATION_PERIOD.md'} -``` - -## SPECIMEN -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/SPECIMEN.md'} -``` - -## DEATH -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/DEATH.md'} -``` - -## VISIT_OCCURRENCE -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/VISIT_OCCURRENCE.md'} -``` - -## PROCEDURE_OCCURRENCE -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/PROCEDURE_OCCURRENCE.md'} -``` - -## DRUG_EXPOSURE -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/DRUG_EXPOSURE.md'} -``` - -## DEVICE_EXPOSURE -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/DEVICE_EXPOSURE.md'} -``` - -## CONDITION_OCCURRENCE -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/CONDITION_OCCURRENCE.md'} -``` - -## MEASUREMENT -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/MEASUREMENT.md'} -``` - -## NOTE -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/NOTE.md'} -``` - -## OBSERVATION -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/OBSERVATION.md'} -``` - -## FACT_RELATIONSHIP -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedclinicalDataTables/FACT_RELATIONSHIP.md'} -``` - -# Standardized Health System Data Tables -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedHealthSystemDataTables/Standardized-Health-System-Data-Tables.md'} -``` - -## LOCATION -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedHealthSystemDataTables/LOCATION.md'} -``` - -## CARE_SITE -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedHealthSystemDataTables/CARE_SITE.md'} -``` - -## PROVIDER -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedHealthSystemDataTables/PROVIDER.md'} -``` - -# Standardized Health Economics Data Tables -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedHealthEconomicsDataTables/Standardized-Health-Economics-Data-Tables.md'} -``` - -## PAYER_PLAN_PERIOD -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedHealthEconomicsDataTables/PAYER_PLAN_PERIOD.md'} -``` - -## COST -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedHealthEconomicsDataTables/COST.md'} -``` - -# Standardized Derived Elements -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedDerivedElements/Standardized-Derived-Elements.md'} -``` - -## COHORT -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedDerivedElements/COHORT.md'} -``` - -## COHORT_ATTRIBUTE -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedDerivedElements/COHORT_ATTRIBUTE.md'} -``` - -## DRUG_ERA -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedDerivedElements/DRUG_ERA.md'} -``` - -## DOSE_ERA -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedDerivedElements/DOSE_ERA.md'} -``` - -## CONDITION_ERA -```{r child = 'C:/Git/CommonDataModel.wiki/StandardizedDerivedElements/CONDITION_ERA.md'} -``` \ No newline at end of file diff --git a/Impala/OMOP_CDM_ddl_Impala.sql b/Impala/OMOP_CDM_ddl_Impala.sql index c5c3779..fe12260 100644 --- a/Impala/OMOP_CDM_ddl_Impala.sql +++ b/Impala/OMOP_CDM_ddl_Impala.sql @@ -17,16 +17,16 @@ /************************ - ####### # # ####### ###### ##### ###### # # ####### # ### - # # ## ## # # # # # # # # ## ## # # # ## # # - # # # # # # # # # # # # # # # # # # # # # # # # - # # # # # # # ###### # # # # # # # # ###### # # # - # # # # # # # # # # # # # # # ### # ### # # - # # # # # # # # # # # # # # # # # ### # ### # # - ####### # # ####### # ##### ###### # # ## ##### ### ##### ### ### + ####### # # ####### ###### ##### ###### # # ####### ##### + # # ## ## # # # # # # # # ## ## # # # # # + # # # # # # # # # # # # # # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### ##### + # # # # # # # # # # # # # # # ### # + # # # # # # # # # # # # # # # # # ### # + ####### # # ####### # ##### ###### # # ## ##### ### ####### -script to create OMOP common data model, version 5.1.0 for Hadoop (Hive/Impala) database +script to create OMOP common data model, version 5.2 for Hadoop (Hive/Impala) database Based on the PostgreSQL version, with the following changes: * NULL/NOT NULL is not used. @@ -248,7 +248,7 @@ CREATE TABLE person ( year_of_birth INTEGER, month_of_birth INTEGER, day_of_birth INTEGER, - time_of_birth VARCHAR(10), + birth_datetime VARCHAR(10), race_concept_id INTEGER, ethnicity_concept_id INTEGER, location_id INTEGER, @@ -289,7 +289,7 @@ CREATE TABLE specimen ( specimen_concept_id INTEGER, specimen_type_concept_id INTEGER, specimen_date VARCHAR(8), -- DATE - specimen_time VARCHAR(10), + specimen_datetime VARCHAR(10), quantity DOUBLE, -- NUMERIC unit_concept_id INTEGER, anatomic_site_concept_id INTEGER, @@ -323,14 +323,19 @@ CREATE TABLE visit_occurrence ( person_id INTEGER, visit_concept_id INTEGER, visit_start_date VARCHAR(8), -- DATE - visit_start_time VARCHAR(10), + visit_start_datetime VARCHAR(10), visit_end_date VARCHAR(8), -- DATE - visit_end_time VARCHAR(10), + visit_end_datetime VARCHAR(10), visit_type_concept_id INTEGER, provider_id INTEGER, care_site_id INTEGER, visit_source_value VARCHAR(50), - visit_source_concept_id INTEGER + visit_source_concept_id INTEGER, + admitting_source_concept_id INTEGER, + admitting_source_value VARCHAR(50), + discharge_to_concept_id INTEGER(50), + discharge_to_source_value VARCHAR(50), + preceding_visit_occurrence_id INTEGER ) ROW FORMAT DELIMITED FIELDS TERMINATED BY ',' TBLPROPERTIES ("skip.header.line.count"="1") @@ -364,6 +369,7 @@ CREATE TABLE drug_exposure ( drug_concept_id INTEGER, drug_exposure_start_date VARCHAR(8), -- DATE drug_exposure_end_date VARCHAR(8), -- DATE + verbatim_end_date VARCHAR(8), --DATE drug_type_concept_id INTEGER, stop_reason VARCHAR(20), refills INTEGER, @@ -371,8 +377,6 @@ CREATE TABLE drug_exposure ( days_supply INTEGER, sig STRING, -- TEXT route_concept_id INTEGER, - effective_drug_dose DOUBLE, -- NUMERIC - dose_unit_concept_id INTEGER, lot_number VARCHAR(50), provider_id INTEGER, visit_occurrence_id INTEGER, @@ -416,7 +420,9 @@ CREATE TABLE condition_occurrence ( provider_id INTEGER, visit_occurrence_id INTEGER, condition_source_value VARCHAR(50), - condition_source_concept_id INTEGER + condition_source_concept_id INTEGER, + condition_status_source_value VARCHAR(50), + condition_status_concept_id INTEGER ) ROW FORMAT DELIMITED FIELDS TERMINATED BY ',' TBLPROPERTIES ("skip.header.line.count"="1") @@ -429,7 +435,7 @@ CREATE TABLE measurement ( person_id INTEGER, measurement_concept_id INTEGER, measurement_date VARCHAR(8), -- DATE - measurement_time VARCHAR(10), + measurement_datetime VARCHAR(10), measurement_type_concept_id INTEGER, operator_concept_id INTEGER, value_as_number DOUBLE, -- NUMERIC @@ -454,9 +460,13 @@ CREATE TABLE note ( note_id INTEGER, person_id INTEGER, note_date VARCHAR(8), -- DATE - note_time VARCHAR(10), + note_datetime VARCHAR(10), note_type_concept_id INTEGER, + note_class_concept_id INTEGER, + note_title VARCHAR(250), note_text STRING, -- TEXT + encoding_concept_id INTEGER, + language_concept_id INTEGER, provider_id INTEGER, visit_occurrence_id INTEGER, note_source_value VARCHAR(50) @@ -464,13 +474,31 @@ CREATE TABLE note ( ; - +CREATE TABLE note_nlp ( + note_nlp_id BIGINT, + note_id INTEGER, + section_concept_id INTEGER, + snippet VARCHAR(250), + offset VARCHAR(250), + lexical_variant VARCHAR(250), + note_nlp_concept_id INTEGER, + note_nlp_source_concept_id INTEGER, + nlp_system VARCHAR(250), + nlp_date VARCHAR(8), + nlp_datetime VARCHAR(10), + term_exists VARCHAR(1), + term_temporal VARCHAR(50), + term_modifiers VARCHAR(2000) + ) + ; + + CREATE TABLE observation ( observation_id INTEGER, person_id INTEGER, observation_concept_id INTEGER, observation_date VARCHAR(8), -- DATE - observation_time VARCHAR(10), + observation_datetime VARCHAR(10), observation_type_concept_id INTEGER, value_as_number DOUBLE, -- NUMERIC value_as_string VARCHAR(60), @@ -581,83 +609,6 @@ CREATE TABLE payer_plan_period ( ; -/* The individual cost tables are being phased out and will disappear soon - -CREATE TABLE visit_cost ( - visit_cost_id INTEGER, - visit_occurrence_id INTEGER, - currency_concept_id INTEGER, - paid_copay DECIMAL(19,4), -- NUMERIC - paid_coinsurance DECIMAL(19,4), -- NUMERIC - paid_toward_deductible DECIMAL(19,4), -- NUMERIC - paid_by_payer DECIMAL(19,4), -- NUMERIC - paid_by_coordination_benefits DECIMAL(19,4), -- NUMERIC - total_out_of_pocket DECIMAL(19,4), -- NUMERIC - total_paid DECIMAL(19,4), -- NUMERIC - payer_plan_period_id INTEGER -) -; - - - -CREATE TABLE procedure_cost ( - procedure_cost_id INTEGER, - procedure_occurrence_id INTEGER, - currency_concept_id INTEGER, - paid_copay DECIMAL(19,4), -- NUMERIC - paid_coinsurance DECIMAL(19,4), -- NUMERIC - paid_toward_deductible DECIMAL(19,4), -- NUMERIC - paid_by_payer DECIMAL(19,4), -- NUMERIC - paid_by_coordination_benefits DECIMAL(19,4), -- NUMERIC - total_out_of_pocket DECIMAL(19,4), -- NUMERIC - total_paid DECIMAL(19,4), -- NUMERIC - revenue_code_concept_id INTEGER, - payer_plan_period_id INTEGER, - revenue_code_source_value VARCHAR(50) -) -; - - - -CREATE TABLE drug_cost ( - drug_cost_id INTEGER, - drug_exposure_id INTEGER, - currency_concept_id INTEGER, - paid_copay DECIMAL(19,4), -- NUMERIC - paid_coinsurance DECIMAL(19,4), -- NUMERIC - paid_toward_deductible DECIMAL(19,4), -- NUMERIC - paid_by_payer DECIMAL(19,4), -- NUMERIC - paid_by_coordination_benefits DECIMAL(19,4), -- NUMERIC - total_out_of_pocket DECIMAL(19,4), -- NUMERIC - total_paid DECIMAL(19,4), -- NUMERIC - ingredient_cost DECIMAL(19,4), -- NUMERIC - dispensing_fee DECIMAL(19,4), -- NUMERIC - average_wholesale_price DECIMAL(19,4), -- NUMERIC - payer_plan_period_id INTEGER -) -; - - - - - -CREATE TABLE device_cost ( - device_cost_id INTEGER, - device_exposure_id INTEGER, - currency_concept_id INTEGER, - paid_copay DECIMAL(19,4), -- NUMERIC - paid_coinsurance DECIMAL(19,4), -- NUMERIC - paid_toward_deductible DECIMAL(19,4), -- NUMERIC - paid_by_payer DECIMAL(19,4), -- NUMERIC - paid_by_coordination_benefits DECIMAL(19,4), -- NUMERIC - total_out_of_pocket DECIMAL(19,4), -- NUMERIC - total_paid DECIMAL(19,4), -- NUMERIC - payer_plan_period_id INTEGER -) -; -*/ - - CREATE TABLE cost ( cost_id INTEGER, cost_event_id INTEGER, @@ -678,7 +629,9 @@ CREATE TABLE cost ( payer_plan_period_id INTEGER, amount_allowed DECIMAL(19,4), -- NUMERIC revenue_code_concept_id INTEGER, - reveue_code_source_value VARCHAR(50) + reveue_code_source_value VARCHAR(50), + drg_concept_id INTEGER, + drg_source_value VARCHAR(3) ) ; diff --git a/Impala/OMOP_Parquet.sql b/Impala/OMOP_Parquet.sql index 62eabcc..cd4e615 100644 --- a/Impala/OMOP_Parquet.sql +++ b/Impala/OMOP_Parquet.sql @@ -220,7 +220,7 @@ SELECT person_id, drug_concept_id, TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(drug_exposure_start_date AS STRING), 1, 4), SUBSTR(CAST(drug_exposure_start_date AS STRING), 5, 2), SUBSTR(CAST(drug_exposure_start_date AS STRING), 7, 2)), 'UTC') AS drug_exposure_start_date, - TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(drug_exposure_end_date AS STRING), 1, 4), SUBSTR(CAST(drug_exposure_end_date AS STRING), 5, 2), SUBSTR(CAST(drug_exposure_end_date AS STRING), 7, 2)), 'UTC') AS drug_exposure_end_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(drug_exposure_end_date AS STRING), 1, 4), SUBSTR(CAST(drug_exposure_end_date AS STRING), 5, 2), SUBSTR(CAST(drug_exposure_end_date AS STRING), 7, 2)), 'UTC') AS drug_exposure_end_date, TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(verbatim_end_date AS STRING), 1, 4), SUBSTR(CAST(verbatim_end_date AS STRING), 5, 2), SUBSTR(CAST(verbatim_end_date AS STRING), 7, 2)), 'UTC') AS verbatim_end_date, drug_type_concept_id, stop_reason, refills, diff --git a/Impala/OMOP_Parquet_v5.2.sql b/Impala/OMOP_Parquet_v5.2.sql new file mode 100644 index 0000000..944b385 --- /dev/null +++ b/Impala/OMOP_Parquet_v5.2.sql @@ -0,0 +1,501 @@ +-- Use the search/replace regex in an editor to fix DATE columns: +-- ([^ ]+) VARCHAR\(8\), \-\- DATE +-- TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST($1 AS STRING), 1, 4), SUBSTR(CAST($1 AS STRING), 5, 2), SUBSTR(CAST($1 AS STRING), 7, 2)), 'UTC') AS $1, + +CREATE TABLE omop_cdm_parquet.concept +STORED AS PARQUET +AS +SELECT + concept_id, + concept_name, + domain_id, + vocabulary_id, + concept_class_id, + standard_concept, + concept_code, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(valid_start_date AS STRING), 1, 4), SUBSTR(CAST(valid_start_date AS STRING), 5, 2), SUBSTR(CAST(valid_start_date AS STRING), 7, 2)), 'UTC') AS valid_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(valid_end_date AS STRING), 1, 4), SUBSTR(CAST(valid_end_date AS STRING), 5, 2), SUBSTR(CAST(valid_end_date AS STRING), 7, 2)), 'UTC') AS valid_end_date, + nullif(invalid_reason, '') AS invalid_reason +FROM omop_cdm.concept; + +CREATE TABLE omop_cdm_parquet.vocabulary +STORED AS PARQUET +AS +SELECT * from omop_cdm.vocabulary; + +CREATE TABLE omop_cdm_parquet.domain +STORED AS PARQUET +AS +SELECT * from omop_cdm.domain; + +CREATE TABLE omop_cdm_parquet.concept_class +STORED AS PARQUET +AS +SELECT * from omop_cdm.concept_class; + +CREATE TABLE omop_cdm_parquet.concept_relationship +STORED AS PARQUET +AS +SELECT + concept_id_1, + concept_id_2, + relationship_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(valid_start_date AS STRING), 1, 4), SUBSTR(CAST(valid_start_date AS STRING), 5, 2), SUBSTR(CAST(valid_start_date AS STRING), 7, 2)), 'UTC') AS valid_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(valid_end_date AS STRING), 1, 4), SUBSTR(CAST(valid_end_date AS STRING), 5, 2), SUBSTR(CAST(valid_end_date AS STRING), 7, 2)), 'UTC') AS valid_end_date, + nullif(invalid_reason, '') AS invalid_reason +FROM omop_cdm.concept_relationship; + +CREATE TABLE omop_cdm_parquet.relationship +STORED AS PARQUET +AS +SELECT * from omop_cdm.relationship; + +CREATE TABLE omop_cdm_parquet.concept_synonym +STORED AS PARQUET +AS +SELECT * from omop_cdm.concept_synonym; + +CREATE TABLE omop_cdm_parquet.concept_ancestor +STORED AS PARQUET +AS +SELECT * from omop_cdm.concept_ancestor; + +CREATE TABLE omop_cdm_parquet.source_to_concept_map +STORED AS PARQUET +AS +SELECT + source_code, + source_concept_id, + source_vocabulary_id, + source_code_description, + target_concept_id, + target_vocabulary_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(valid_start_date AS STRING), 1, 4), SUBSTR(CAST(valid_start_date AS STRING), 5, 2), SUBSTR(CAST(valid_start_date AS STRING), 7, 2)), 'UTC') AS valid_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(valid_end_date AS STRING), 1, 4), SUBSTR(CAST(valid_end_date AS STRING), 5, 2), SUBSTR(CAST(valid_end_date AS STRING), 7, 2)), 'UTC') AS valid_end_date, + nullif(invalid_reason, '') AS invalid_reason +FROM omop_cdm.source_to_concept_map; + +CREATE TABLE omop_cdm_parquet.drug_strength +STORED AS PARQUET +AS +SELECT + drug_concept_id, + ingredient_concept_id, + amount_value, -- NUMERIC + amount_unit_concept_id, + numerator_value, -- NUMERIC + numerator_unit_concept_id, + denominator_value, -- NUMERIC + denominator_unit_concept_id, + box_size, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(valid_start_date AS STRING), 1, 4), SUBSTR(CAST(valid_start_date AS STRING), 5, 2), SUBSTR(CAST(valid_start_date AS STRING), 7, 2)), 'UTC') AS valid_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(valid_end_date AS STRING), 1, 4), SUBSTR(CAST(valid_end_date AS STRING), 5, 2), SUBSTR(CAST(valid_end_date AS STRING), 7, 2)), 'UTC') AS valid_end_date, + nullif(invalid_reason, '') AS invalid_reason +FROM omop_cdm.drug_strength; + +CREATE TABLE omop_cdm_parquet.cohort_definition +STORED AS PARQUET +AS +SELECT + cohort_definition_id, + cohort_definition_name, + cohort_definition_description, -- TEXT + definition_type_concept_id, + cohort_definition_syntax, -- TEXT + subject_concept_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(cohort_initiation_date AS STRING), 1, 4), SUBSTR(CAST(cohort_initiation_date AS STRING), 5, 2), SUBSTR(CAST(cohort_initiation_date AS STRING), 7, 2)), 'UTC') AS cohort_initiation_date +FROM omop_cdm.cohort_definition; + +CREATE TABLE omop_cdm_parquet.attribute_definition +STORED AS PARQUET +AS +SELECT * from omop_cdm.attribute_definition; + +CREATE TABLE omop_cdm_parquet.cdm_source +STORED AS PARQUET +AS +SELECT + cdm_source_name, + cdm_source_abbreviation, + cdm_holder, + source_description, -- TEXT + source_documentation_reference, + cdm_etl_reference, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(source_release_date AS STRING), 1, 4), SUBSTR(CAST(source_release_date AS STRING), 5, 2), SUBSTR(CAST(source_release_date AS STRING), 7, 2)), 'UTC') AS source_release_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(cdm_release_date AS STRING), 1, 4), SUBSTR(CAST(cdm_release_date AS STRING), 5, 2), SUBSTR(CAST(cdm_release_date AS STRING), 7, 2)), 'UTC') AS cdm_release_date, + cdm_version, + vocabulary_version +FROM omop_cdm.cdm_source; + +CREATE TABLE omop_cdm_parquet.person +STORED AS PARQUET +AS +SELECT + person_id, + gender_concept_id, + year_of_birth, + month_of_birth, + day_of_birth, + TO_UTC_TIMESTAMP(CONCAT_WS('-', CAST(year_of_birth AS STRING), SUBSTR(CONCAT('0', CAST(month_of_birth AS STRING)), -2), SUBSTR(CONCAT('0', CAST(day_of_birth AS STRING)), -2)), 'UTC') AS birth_datetime, + race_concept_id, + ethnicity_concept_id, + location_id, + provider_id, + care_site_id, + person_source_value, + gender_source_value, + gender_source_concept_id, + race_source_value, + race_source_concept_id, + ethnicity_source_value, + ethnicity_source_concept_id +FROM omop_cdm.person; + +CREATE TABLE omop_cdm_parquet.observation_period +STORED AS PARQUET +AS +SELECT + observation_period_id, + person_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(observation_period_start_date AS STRING), 1, 4), SUBSTR(CAST(observation_period_start_date AS STRING), 5, 2), SUBSTR(CAST(observation_period_start_date AS STRING), 7, 2)), 'UTC') AS observation_period_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(observation_period_start_date AS STRING), 1, 4), SUBSTR(CAST(observation_period_start_date AS STRING), 5, 2), SUBSTR(CAST(observation_period_start_date AS STRING), 7, 2)), 'UTC') AS observation_period_start_datetime, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(observation_period_end_date AS STRING), 1, 4), SUBSTR(CAST(observation_period_end_date AS STRING), 5, 2), SUBSTR(CAST(observation_period_end_date AS STRING), 7, 2)), 'UTC') AS observation_period_end_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(observation_period_end_date AS STRING), 1, 4), SUBSTR(CAST(observation_period_end_date AS STRING), 5, 2), SUBSTR(CAST(observation_period_end_date AS STRING), 7, 2)), 'UTC') AS observation_period_end_datetime, + period_type_concept_id +FROM omop_cdm.observation_period; + +CREATE TABLE omop_cdm_parquet.specimen +STORED AS PARQUET +AS +SELECT + specimen_id, + person_id, + specimen_concept_id, + specimen_type_concept_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(specimen_date AS STRING), 1, 4), SUBSTR(CAST(specimen_date AS STRING), 5, 2), SUBSTR(CAST(specimen_date AS STRING), 7, 2)), 'UTC') AS specimen_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(specimen_date AS STRING), 1, 4), SUBSTR(CAST(specimen_date AS STRING), 5, 2), SUBSTR(CAST(specimen_date AS STRING), 7, 2)), 'UTC') AS specimen_datetime, + quantity, -- NUMERIC + unit_concept_id, + anatomic_site_concept_id, + disease_status_concept_id, + specimen_source_id, + specimen_source_value, + unit_source_value, + anatomic_site_source_value, + disease_status_source_value +FROM omop_cdm.specimen; + +CREATE TABLE omop_cdm_parquet.death +STORED AS PARQUET +AS +SELECT + person_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(death_date AS STRING), 1, 4), SUBSTR(CAST(death_date AS STRING), 5, 2), SUBSTR(CAST(death_date AS STRING), 7, 2)), 'UTC') AS death_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(death_date AS STRING), 1, 4), SUBSTR(CAST(death_date AS STRING), 5, 2), SUBSTR(CAST(death_date AS STRING), 7, 2)), 'UTC') AS death_datetime, + death_type_concept_id, + cause_concept_id, + cause_source_value, + cause_source_concept_id +FROM omop_cdm.death; + +CREATE TABLE omop_cdm_parquet.visit_occurrence +STORED AS PARQUET +AS +SELECT + visit_occurrence_id, + person_id, + visit_concept_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(visit_start_date AS STRING), 1, 4), SUBSTR(CAST(visit_start_date AS STRING), 5, 2), SUBSTR(CAST(visit_start_date AS STRING), 7, 2)), 'UTC') AS visit_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(visit_start_date AS STRING), 1, 4), SUBSTR(CAST(visit_start_date AS STRING), 5, 2), SUBSTR(CAST(visit_start_date AS STRING), 7, 2)), 'UTC') AS visit_start_datetime, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(visit_end_date AS STRING), 1, 4), SUBSTR(CAST(visit_end_date AS STRING), 5, 2), SUBSTR(CAST(visit_end_date AS STRING), 7, 2)), 'UTC') AS visit_end_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(visit_end_date AS STRING), 1, 4), SUBSTR(CAST(visit_end_date AS STRING), 5, 2), SUBSTR(CAST(visit_end_date AS STRING), 7, 2)), 'UTC') AS visit_end_datetime, + visit_type_concept_id, + provider_id, + care_site_id, + visit_source_value, + visit_source_concept_id, + admitting_source_concept_id, + admitting_source_value, + discharge_to_concept_id, + discharge_to_source_value, + preceding_visit_occurrence_id +FROM omop_cdm.visit_occurrence; + +CREATE TABLE omop_cdm_parquet.procedure_occurrence +STORED AS PARQUET +AS +SELECT + procedure_occurrence_id, + person_id, + procedure_concept_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(procedure_date AS STRING), 1, 4), SUBSTR(CAST(procedure_date AS STRING), 5, 2), SUBSTR(CAST(procedure_date AS STRING), 7, 2)), 'UTC') AS procedure_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(procedure_date AS STRING), 1, 4), SUBSTR(CAST(procedure_date AS STRING), 5, 2), SUBSTR(CAST(procedure_date AS STRING), 7, 2)), 'UTC') AS procedure_datetime, + procedure_type_concept_id, + modifier_concept_id, + quantity, + provider_id, + visit_occurrence_id, + procedure_source_value, + procedure_source_concept_id, + qualifier_source_value +FROM omop_cdm.procedure_occurrence; + +CREATE TABLE omop_cdm_parquet.drug_exposure +STORED AS PARQUET +AS +SELECT + drug_exposure_id, + person_id, + drug_concept_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(drug_exposure_start_date AS STRING), 1, 4), SUBSTR(CAST(drug_exposure_start_date AS STRING), 5, 2), SUBSTR(CAST(drug_exposure_start_date AS STRING), 7, 2)), 'UTC') AS drug_exposure_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(drug_exposure_start_date AS STRING), 1, 4), SUBSTR(CAST(drug_exposure_start_date AS STRING), 5, 2), SUBSTR(CAST(drug_exposure_start_date AS STRING), 7, 2)), 'UTC') AS drug_exposure_start_datetime, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(drug_exposure_end_date AS STRING), 1, 4), SUBSTR(CAST(drug_exposure_end_date AS STRING), 5, 2), SUBSTR(CAST(drug_exposure_end_date AS STRING), 7, 2)), 'UTC') AS drug_exposure_end_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(drug_exposure_end_date AS STRING), 1, 4), SUBSTR(CAST(drug_exposure_end_date AS STRING), 5, 2), SUBSTR(CAST(drug_exposure_end_date AS STRING), 7, 2)), 'UTC') AS drug_exposure_end_datetime, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(verbatim_end_date AS STRING), 1, 4), SUBSTR(CAST(verbatim_end_date AS STRING), 5, 2), SUBSTR(CAST(verbatim_end_date AS STRING), 7, 2)), 'UTC') AS verbatim_end_date, + drug_type_concept_id, + stop_reason, + refills, + quantity, -- NUMERIC + days_supply, + sig, -- TEXT + route_concept_id, + lot_number, + provider_id, + visit_occurrence_id, + drug_source_value, + drug_source_concept_id, + route_source_value, + dose_unit_source_value +FROM omop_cdm.drug_exposure; + +CREATE TABLE omop_cdm_parquet.device_exposure +STORED AS PARQUET +AS +SELECT + device_exposure_id, + person_id, + device_concept_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(device_exposure_start_date AS STRING), 1, 4), SUBSTR(CAST(device_exposure_start_date AS STRING), 5, 2), SUBSTR(CAST(device_exposure_start_date AS STRING), 7, 2)), 'UTC') AS device_exposure_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(device_exposure_start_date AS STRING), 1, 4), SUBSTR(CAST(device_exposure_start_date AS STRING), 5, 2), SUBSTR(CAST(device_exposure_start_date AS STRING), 7, 2)), 'UTC') AS device_exposure_start_datetime, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(device_exposure_end_date AS STRING), 1, 4), SUBSTR(CAST(device_exposure_end_date AS STRING), 5, 2), SUBSTR(CAST(device_exposure_end_date AS STRING), 7, 2)), 'UTC') AS device_exposure_end_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(device_exposure_end_date AS STRING), 1, 4), SUBSTR(CAST(device_exposure_end_date AS STRING), 5, 2), SUBSTR(CAST(device_exposure_end_date AS STRING), 7, 2)), 'UTC') AS device_exposure_end_datetime, + device_type_concept_id, + unique_device_id, + quantity, + provider_id, + visit_occurrence_id, + device_source_value, + device_source_concept_id +FROM omop_cdm.device_exposure; + +CREATE TABLE omop_cdm_parquet.condition_occurrence +STORED AS PARQUET +AS +SELECT + condition_occurrence_id, + person_id, + condition_concept_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(condition_start_date AS STRING), 1, 4), SUBSTR(CAST(condition_start_date AS STRING), 5, 2), SUBSTR(CAST(condition_start_date AS STRING), 7, 2)), 'UTC') AS condition_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(condition_start_date AS STRING), 1, 4), SUBSTR(CAST(condition_start_date AS STRING), 5, 2), SUBSTR(CAST(condition_start_date AS STRING), 7, 2)), 'UTC') AS condition_start_datetime, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(condition_end_date AS STRING), 1, 4), SUBSTR(CAST(condition_end_date AS STRING), 5, 2), SUBSTR(CAST(condition_end_date AS STRING), 7, 2)), 'UTC') AS condition_end_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(condition_end_date AS STRING), 1, 4), SUBSTR(CAST(condition_end_date AS STRING), 5, 2), SUBSTR(CAST(condition_end_date AS STRING), 7, 2)), 'UTC') AS condition_end_datetime, + condition_type_concept_id, + stop_reason, + provider_id, + visit_occurrence_id, + condition_source_value, + condition_source_concept_id, + condition_status_source_value, + condition_status_concept_id +FROM omop_cdm.condition_occurrence; + +CREATE TABLE omop_cdm_parquet.measurement +STORED AS PARQUET +AS +SELECT + measurement_id, + person_id, + measurement_concept_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(measurement_date AS STRING), 1, 4), SUBSTR(CAST(measurement_date AS STRING), 5, 2), SUBSTR(CAST(measurement_date AS STRING), 7, 2)), 'UTC') AS measurement_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(measurement_date AS STRING), 1, 4), SUBSTR(CAST(measurement_date AS STRING), 5, 2), SUBSTR(CAST(measurement_date AS STRING), 7, 2)), 'UTC') AS measurement_datetime, + measurement_type_concept_id, + operator_concept_id, + value_as_number, -- NUMERIC + value_as_concept_id, + unit_concept_id, + range_low, -- NUMERIC + range_high, -- NUMERIC + provider_id, + visit_occurrence_id, + measurement_source_value, + measurement_source_concept_id, + unit_source_value, + value_source_value +FROM omop_cdm.measurement; + +CREATE TABLE omop_cdm_parquet.note +STORED AS PARQUET +AS +SELECT + note_id, + person_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(note_date AS STRING), 1, 4), SUBSTR(CAST(note_date AS STRING), 5, 2), SUBSTR(CAST(note_date AS STRING), 7, 2)), 'UTC') AS note_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(note_date AS STRING), 1, 4), SUBSTR(CAST(note_date AS STRING), 5, 2), SUBSTR(CAST(note_date AS STRING), 7, 2)), 'UTC') AS note_datetime, + note_type_concept_id, + note_class_concept_id, + note_title, + note_text, -- TEXT + encoding_concept_id, + language_concept_id, + provider_id, + visit_occurrence_id, + note_source_value +FROM omop_cdm.note; + +CREATE TABLE omop_cdm_parquet.note_nlp +STORED AS PARQUET +AS +SELECT + note_nlp_id, + note_id, + section_concept_id, + snippet, + offset, + lexical_variant, + note_nlp_concept_id, + note_nlp_source_concept_id, + nlp_system, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(nlp_date AS STRING), 1, 4), SUBSTR(CAST(nlp_date AS STRING), 5, 2), SUBSTR(CAST(nlp_date AS STRING), 7, 2)), 'UTC') AS nlp_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(nlp_date AS STRING), 1, 4), SUBSTR(CAST(nlp_date AS STRING), 5, 2), SUBSTR(CAST(nlp_date AS STRING), 7, 2)), 'UTC') AS nlp_datetime, + term_exists, + term_temporal, + term_modifiers +FROM omop_cdm.note_nlp; + + + + + +CREATE TABLE omop_cdm_parquet.observation +STORED AS PARQUET +AS +SELECT + observation_id, + person_id, + observation_concept_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(observation_date AS STRING), 1, 4), SUBSTR(CAST(observation_date AS STRING), 5, 2), SUBSTR(CAST(observation_date AS STRING), 7, 2)), 'UTC') AS observation_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(observation_date AS STRING), 1, 4), SUBSTR(CAST(observation_date AS STRING), 5, 2), SUBSTR(CAST(observation_date AS STRING), 7, 2)), 'UTC') AS observation_datetime, + observation_type_concept_id, + value_as_number, -- NUMERIC + value_as_string, + value_as_concept_id, + qualifier_concept_id, + unit_concept_id, + provider_id, + visit_occurrence_id, + observation_source_value, + observation_source_concept_id , + unit_source_value, + qualifier_source_value +FROM omop_cdm.observation; + +CREATE TABLE omop_cdm_parquet.fact_relationship +STORED AS PARQUET +AS +SELECT * from omop_cdm.fact_relationship; + +CREATE TABLE omop_cdm_parquet.`location` +STORED AS PARQUET +AS +SELECT * from omop_cdm.`location`; + +CREATE TABLE omop_cdm_parquet.care_site +STORED AS PARQUET +AS +SELECT * from omop_cdm.care_site; + +CREATE TABLE omop_cdm_parquet.provider +STORED AS PARQUET +AS +SELECT * from omop_cdm.provider; + +CREATE TABLE omop_cdm_parquet.payer_plan_period +STORED AS PARQUET +AS +SELECT + payer_plan_period_id, + person_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(payer_plan_period_start_date AS STRING), 1, 4), SUBSTR(CAST(payer_plan_period_start_date AS STRING), 5, 2), SUBSTR(CAST(payer_plan_period_start_date AS STRING), 7, 2)), 'UTC') AS payer_plan_period_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(payer_plan_period_end_date AS STRING), 1, 4), SUBSTR(CAST(payer_plan_period_end_date AS STRING), 5, 2), SUBSTR(CAST(payer_plan_period_end_date AS STRING), 7, 2)), 'UTC') AS payer_plan_period_end_date, + payer_source_value, + plan_source_value, + family_source_value +FROM omop_cdm.payer_plan_period; + + +CREATE TABLE omop_cdm_parquet.cost +STORED AS PARQUET +AS +SELECT * from omop_cdm.cost; + +CREATE TABLE omop_cdm_parquet.cohort +STORED AS PARQUET +AS +SELECT + cohort_definition_id, + subject_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(cohort_start_date AS STRING), 1, 4), SUBSTR(CAST(cohort_start_date AS STRING), 5, 2), SUBSTR(CAST(cohort_start_date AS STRING), 7, 2)), 'UTC') AS cohort_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(cohort_end_date AS STRING), 1, 4), SUBSTR(CAST(cohort_end_date AS STRING), 5, 2), SUBSTR(CAST(cohort_end_date AS STRING), 7, 2)), 'UTC') AS cohort_end_date +FROM omop_cdm.cohort; + +CREATE TABLE omop_cdm_parquet.cohort_attribute +STORED AS PARQUET +AS +SELECT + cohort_definition_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(cohort_start_date AS STRING), 1, 4), SUBSTR(CAST(cohort_start_date AS STRING), 5, 2), SUBSTR(CAST(cohort_start_date AS STRING), 7, 2)), 'UTC') AS cohort_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(cohort_end_date AS STRING), 1, 4), SUBSTR(CAST(cohort_end_date AS STRING), 5, 2), SUBSTR(CAST(cohort_end_date AS STRING), 7, 2)), 'UTC') AS cohort_end_date, + subject_id, + attribute_definition_id, + value_as_number, -- NUMERIC + value_as_concept_id +FROM omop_cdm.cohort_attribute; + +CREATE TABLE omop_cdm_parquet.drug_era +STORED AS PARQUET +AS +SELECT + drug_era_id, + person_id, + drug_concept_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(drug_era_start_date AS STRING), 1, 4), SUBSTR(CAST(drug_era_start_date AS STRING), 5, 2), SUBSTR(CAST(drug_era_start_date AS STRING), 7, 2)), 'UTC') AS drug_era_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(drug_era_end_date AS STRING), 1, 4), SUBSTR(CAST(drug_era_end_date AS STRING), 5, 2), SUBSTR(CAST(drug_era_end_date AS STRING), 7, 2)), 'UTC') AS drug_era_end_date, + drug_exposure_count, + gap_days +FROM omop_cdm.drug_era; + +CREATE TABLE omop_cdm_parquet.dose_era +STORED AS PARQUET +AS +SELECT + dose_era_id, + person_id, + drug_concept_id, + unit_concept_id, + dose_value, -- NUMERIC + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(dose_era_start_date AS STRING), 1, 4), SUBSTR(CAST(dose_era_start_date AS STRING), 5, 2), SUBSTR(CAST(dose_era_start_date AS STRING), 7, 2)), 'UTC') AS dose_era_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(dose_era_end_date AS STRING), 1, 4), SUBSTR(CAST(dose_era_end_date AS STRING), 5, 2), SUBSTR(CAST(dose_era_end_date AS STRING), 7, 2)), 'UTC') AS dose_era_end_date +FROM omop_cdm.dose_era; + +CREATE TABLE omop_cdm_parquet.condition_era +STORED AS PARQUET +AS +SELECT + condition_era_id, + person_id, + condition_concept_id, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(condition_era_start_date AS STRING), 1, 4), SUBSTR(CAST(condition_era_start_date AS STRING), 5, 2), SUBSTR(CAST(condition_era_start_date AS STRING), 7, 2)), 'UTC') AS condition_era_start_date, + TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(condition_era_end_date AS STRING), 1, 4), SUBSTR(CAST(condition_era_end_date AS STRING), 5, 2), SUBSTR(CAST(condition_era_end_date AS STRING), 7, 2)), 'UTC') AS condition_era_end_date, + condition_occurrence_count +FROM omop_cdm.condition_era; + diff --git a/OMOP_CDM_v5_1_1.pdf b/OMOP_CDM_v5_2.pdf similarity index 69% rename from OMOP_CDM_v5_1_1.pdf rename to OMOP_CDM_v5_2.pdf index e722494..e2d443f 100644 Binary files a/OMOP_CDM_v5_1_1.pdf and b/OMOP_CDM_v5_2.pdf differ diff --git a/Oracle/OMOP CDM constraints - Oracle.sql b/Oracle/OMOP CDM constraints - Oracle.sql index 85868aa..69ca56f 100644 --- a/Oracle/OMOP CDM constraints - Oracle.sql +++ b/Oracle/OMOP CDM constraints - Oracle.sql @@ -17,19 +17,19 @@ /************************ - ####### # # ####### ###### ##### ###### # # ####### # ### ##### - # # ## ## # # # # # # # # ## ## # # # ## # # # # #### # # #### ##### ##### ## # # # ##### #### - # # # # # # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # ## # # # - # # # # # # # ###### # # # # # # # # ###### # # # # # # # # # #### # # # # # # # # # # #### - # # # # # # # # # # # # # # # ### # ### # # # # # # # # # # ##### ###### # # # # # # - # # # # # # # # # # # # # # # # # ### # ### # # # # # # # ## # # # # # # # # # ## # # # - ####### # # ####### # ##### ###### # # ## ##### ### ##### ### ### ##### #### # # #### # # # # # # # # # #### + ####### # # ####### ###### ##### ###### # # ####### ##### ##### + # # ## ## # # # # # # # # ## ## # # # # # # # #### # # #### ##### ##### ## # # # ##### #### + # # # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # ## # # # + # # # # # # # ###### # # # # # # # # ###### ##### # # # # # # #### # # # # # # # # # # #### + # # # # # # # # # # # # # # # ### # # # # # # # # # ##### ###### # # # # # # + # # # # # # # # # # # # # # # # # ### # # # # # # ## # # # # # # # # # ## # # # + ####### # # ####### # ##### ###### # # ## ##### ### ####### ##### #### # # #### # # # # # # # # # #### -script to create constraints within OMOP common data model, version 5.1.0 for Oracle database +script to create constraints within OMOP common data model, version 5.2 for Oracle database -last revised: 12 Oct 2014 +last revised: 14 July 2017 author: Patrick Ryan @@ -126,6 +126,8 @@ ALTER TABLE measurement ADD CONSTRAINT xpk_measurement PRIMARY KEY ( measurement ALTER TABLE note ADD CONSTRAINT xpk_note PRIMARY KEY ( note_id ) ; +ALTER TABLE note_nlp ADD CONSTRAINT xpk_note_nlp PRIMARY KEY ( note_nlp_id ) ; + ALTER TABLE observation ADD CONSTRAINT xpk_observation PRIMARY KEY ( observation_id ) ; @@ -323,6 +325,10 @@ ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_care_site FOREIGN KEY (car ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_concept_s FOREIGN KEY (visit_source_concept_id) REFERENCES concept (concept_id); +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_admitting_s FOREIGN KEY (admitting_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_discharge FOREIGN KEY (discharge_to_concept_id) REFERENCES concept (concept_id); + ALTER TABLE procedure_occurrence ADD CONSTRAINT fpk_procedure_person FOREIGN KEY (person_id) REFERENCES person (person_id); @@ -381,6 +387,8 @@ ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_visit FOREIGN KEY ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_concept_s FOREIGN KEY (condition_source_concept_id) REFERENCES concept (concept_id); +ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_status_concept FOREIGN KEY (condition_status_concept_id) REFERENCES concept (concept_id); + ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_person FOREIGN KEY (person_id) REFERENCES person (person_id); @@ -405,11 +413,24 @@ ALTER TABLE note ADD CONSTRAINT fpk_note_person FOREIGN KEY (person_id) REFEREN ALTER TABLE note ADD CONSTRAINT fpk_note_type_concept FOREIGN KEY (note_type_concept_id) REFERENCES concept (concept_id); +ALTER TABLE note ADD CONSTRAINT fpk_note_class_concept FOREIGN KEY (note_class_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note ADD CONSTRAINT fpk_note_encoding_concept FOREIGN KEY (encoding_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note ADD CONSTRAINT fpk_language_concept FOREIGN KEY (language_concept_id) REFERENCES concept (concept_id); + ALTER TABLE note ADD CONSTRAINT fpk_note_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); ALTER TABLE note ADD CONSTRAINT fpk_note_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_note FOREIGN KEY (note_id) REFERENCES note (note_id); + +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_section_concept FOREIGN KEY (section_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_concept FOREIGN KEY (note_nlp_concept_id) REFERENCES concept (concept_id); + + ALTER TABLE observation ADD CONSTRAINT fpk_observation_person FOREIGN KEY (person_id) REFERENCES person (person_id); ALTER TABLE observation ADD CONSTRAINT fpk_observation_concept FOREIGN KEY (observation_concept_id) REFERENCES concept (concept_id); @@ -458,7 +479,7 @@ ALTER TABLE provider ADD CONSTRAINT fpk_provider_specialty_s FOREIGN KEY (specia ALTER TABLE provider ADD CONSTRAINT fpk_provider_gender_s FOREIGN KEY (gender_source_concept_id) REFERENCES concept (concept_id); - +ALTER TABLE cost ADD CONSTRAINT fpk_drg_concept FOREIGN KEY (drg_concept_id) REFERENCES concept (concept_id); /************************ @@ -474,6 +495,8 @@ ALTER TABLE cost ADD CONSTRAINT fpk_visit_cost_currency FOREIGN KEY (currency_co ALTER TABLE cost ADD CONSTRAINT fpk_visit_cost_period FOREIGN KEY (payer_plan_period_id) REFERENCES payer_plan_period (payer_plan_period_id); + + /************************ Standardized derived elements diff --git a/Oracle/OMOP CDM ddl - Oracle.sql b/Oracle/OMOP CDM ddl - Oracle.sql index 76ec451..cdfaf16 100644 --- a/Oracle/OMOP CDM ddl - Oracle.sql +++ b/Oracle/OMOP CDM ddl - Oracle.sql @@ -17,18 +17,18 @@ /************************ - ####### # # ####### ###### ##### ###### # # ####### # ### - # # ## ## # # # # # # # # ## ## # # # ## # # - # # # # # # # # # # # # # # # # # # # # # # # # - # # # # # # # ###### # # # # # # # # ###### # # # - # # # # # # # # # # # # # # # ### # ### # # - # # # # # # # # # # # # # # # # # ### # ### # # - ####### # # ####### # ##### ###### # # ## ##### ### ##### ### ### + ####### # # ####### ###### ##### ###### # # ####### ##### + # # ## ## # # # # # # # # ## ## # # # # # + # # # # # # # # # # # # # # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### ##### + # # # # # # # # # # # # # # # ### # + # # # # # # # # # # # # # # # # # ### # + ####### # # ####### # ##### ###### # # ## ##### ### ####### -script to create OMOP common data model, version 5.1.0 for Oracle database +script to create OMOP common data model, version 5.2 for Oracle database -last revised: 1-May-2016 +last revised: 14 July 2017 Authors: Patrick Ryan, Christian Reich @@ -312,7 +312,12 @@ CREATE TABLE visit_occurrence provider_id INTEGER NULL, care_site_id INTEGER NULL, visit_source_value VARCHAR(50) NULL, - visit_source_concept_id INTEGER NULL + visit_source_concept_id INTEGER NULL, + admitting_source_concept_id INTEGER NULL , + admitting_source_value VARCHAR(50) NULL , + discharge_to_concept_id INTEGER(50) NULL , + discharge_to_source_value VARCHAR(50) NULL , + preceding_visit_occurrence_id INTEGER NULL ) ; @@ -344,18 +349,17 @@ CREATE TABLE drug_exposure person_id INTEGER NOT NULL , drug_concept_id INTEGER NOT NULL , drug_exposure_start_date DATE NOT NULL , - drug_exposure_start_datetime TIMESTAMP WITH TIME ZONE NOT NULL , - drug_exposure_end_date DATE NULL , - drug_exposure_end_datetime TIMESTAMP WITH TIME ZONE NULL , - drug_type_concept_id INTEGER NOT NULL , + drug_exposure_start_datetime TIMESTAMP WITH TIME ZONE NOT NULL , + drug_exposure_end_date DATE NOT NULL , + drug_exposure_end_datetime TIMESTAMP WITH TIME ZONE NULL , + verbatim_end_date DATE NULL , + drug_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , refills INTEGER NULL , quantity FLOAT NULL , days_supply INTEGER NULL , sig CLOB NULL , route_concept_id INTEGER NULL , - effective_drug_dose FLOAT NULL , - dose_unit_concept_id INTEGER NULL , lot_number VARCHAR(50) NULL , provider_id INTEGER NULL , visit_occurrence_id INTEGER NULL , @@ -401,7 +405,9 @@ CREATE TABLE condition_occurrence provider_id INTEGER NULL , visit_occurrence_id INTEGER NULL , condition_source_value VARCHAR(50) NULL , - condition_source_concept_id INTEGER NULL + condition_source_concept_id INTEGER NULL , + condition_status_source_value VARCHAR(50) NULL , + condition_status_concept_id INTEGER NULL ) ; @@ -439,7 +445,11 @@ CREATE TABLE note note_date DATE NOT NULL , note_datetime TIMESTAMP WITH TIME ZONE NULL , note_type_concept_id INTEGER NOT NULL , + note_class_concept_id INTEGER NOT NULL , + note_title VARCHAR(250) NULL , note_text CLOB NOT NULL , + encoding_concept_id INTEGER NOT NULL , + language_concept_id INTEGER NOT NULL , provider_id INTEGER NULL , visit_occurrence_id INTEGER NULL , note_source_value VARCHAR(50) NULL @@ -447,6 +457,25 @@ CREATE TABLE note ; +/*This table is new in CDM v5.2*/ +CREATE TABLE note_nlp +( + note_nlp_id NUMBER(19) NOT NULL , + note_id INTEGER NOT NULL , + section_concept_id INTEGER NULL , + snippet VARCHAR(250) NULL , + offset VARCHAR(250) NULL , + lexical_variant VARCHAR(250) NOT NULL , + note_nlp_concept_id INTEGER NULL , + note_nlp_source_concept_id INTEGER NULL , + nlp_system VARCHAR(250) NULL , + nlp_date DATE NOT NULL , + nlp_datetime TIMESTAMP WITH TIME ZONE NULL , + term_exists VARCHAR(1) NULL , + term_temporal VARCHAR(50) NULL , + term_modifiers VARCHAR(2000) NULL +) +; CREATE TABLE observation ( @@ -562,86 +591,6 @@ CREATE TABLE payer_plan_period ; --- The individual cost tables are phased out and will be removed -/* -CREATE TABLE visit_cost - ( - visit_cost_id INTEGER NOT NULL , - visit_occurrence_id INTEGER NOT NULL , - currency_concept_id INTEGER NULL , - paid_copay FLOAT NULL , - paid_coinsurance FLOAT NULL , - paid_toward_deductible FLOAT NULL , - paid_by_payer FLOAT NULL , - paid_by_coordination_benefits FLOAT NULL , - total_out_of_pocket FLOAT NULL , - total_paid FLOAT NULL , - payer_plan_period_id INTEGER NULL - ) -; - - - -CREATE TABLE procedure_cost - ( - procedure_cost_id INTEGER NOT NULL , - procedure_occurrence_id INTEGER NOT NULL , - currency_concept_id INTEGER NULL , - paid_copay FLOAT NULL , - paid_coinsurance FLOAT NULL , - paid_toward_deductible FLOAT NULL , - paid_by_payer FLOAT NULL , - paid_by_coordination_benefits FLOAT NULL , - total_out_of_pocket FLOAT NULL , - total_paid FLOAT NULL , - revenue_code_concept_id INTEGER NULL , - payer_plan_period_id INTEGER NULL , - revenue_code_source_value VARCHAR(50) NULL - ) -; - - - -CREATE TABLE drug_cost - ( - drug_cost_id INTEGER NOT NULL , - drug_exposure_id INTEGER NOT NULL , - currency_concept_id INTEGER NULL , - paid_copay FLOAT NULL , - paid_coinsurance FLOAT NULL , - paid_toward_deductible FLOAT NULL , - paid_by_payer FLOAT NULL , - paid_by_coordination_benefits FLOAT NULL , - total_out_of_pocket FLOAT NULL , - total_paid FLOAT NULL , - ingredient_cost FLOAT NULL , - dispensing_fee FLOAT NULL , - average_wholesale_price FLOAT NULL , - payer_plan_period_id INTEGER NULL - ) -; - - - - - -CREATE TABLE device_cost - ( - device_cost_id INTEGER NOT NULL , - device_exposure_id INTEGER NOT NULL , - currency_concept_id INTEGER NULL , - paid_copay FLOAT NULL , - paid_coinsurance FLOAT NULL , - paid_toward_deductible FLOAT NULL , - paid_by_payer FLOAT NULL , - paid_by_coordination_benefits FLOAT NULL , - total_out_of_pocket FLOAT NULL , - total_paid FLOAT NULL , - payer_plan_period_id INTEGER NULL - ) -; -*/ - CREATE TABLE cost ( @@ -664,7 +613,9 @@ CREATE TABLE cost payer_plan_period_id INTEGER NULL , amount_allowed FLOAT NULL , revenue_code_concept_id INTEGER NULL , - reveue_code_source_value VARCHAR2(50) NULL + reveue_code_source_value VARCHAR2(50) NULL , + drg_concept_id INTEGER NULL, + drg_source_value VARCHAR(3) NULL ) ; diff --git a/Oracle/OMOP CDM indexes required - Oracle - With constraints.sql b/Oracle/OMOP CDM indexes required - Oracle - With constraints.sql index 1d24c9d..f0a013c 100644 --- a/Oracle/OMOP CDM indexes required - Oracle - With constraints.sql +++ b/Oracle/OMOP CDM indexes required - Oracle - With constraints.sql @@ -17,18 +17,18 @@ /************************ - ####### # # ####### ###### ##### ###### # # ####### # ### ### - # # ## ## # # # # # # # # ## ## # # # ## # # # # # ##### ###### # # ###### #### - # # # # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # - # # # # # # # ###### # # # # # # # # ###### # # # # # # # # # ##### ## ##### #### - # # # # # # # # # # # # # # # ### # ### # # # # # # # # # ## # # - # # # # # # # # # # # # # # # # # ### # ### # # # # ## # # # # # # # # - ####### # # ####### # ##### ###### # # ## ##### ### ##### ### ### ### # # ##### ###### # # ###### #### + ####### # # ####### ###### ##### ###### # # ####### ##### ### + # # ## ## # # # # # # # # ## ## # # # # # # # # ##### ###### # # ###### #### + # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### ##### # # # # # # ##### ## ##### #### + # # # # # # # # # # # # # # # ### # # # # # # # # ## # # + # # # # # # # # # # # # # # # # # ### # # # ## # # # # # # # # + ####### # # ####### # ##### ###### # # ## ##### ### ####### ### # # ##### ###### # # ###### #### -script to create the required indexes within OMOP common data model, version 5.1.0 for Oracle database +script to create the required indexes within OMOP common data model, version 5.2 for Oracle database -last revised: 12 Oct 2014 +last revised: 17 July 2017 author: Patrick Ryan @@ -113,6 +113,10 @@ CREATE INDEX idx_note_person_id ON note (person_id ASC); CREATE INDEX idx_note_concept_id ON note (note_type_concept_id ASC); CREATE INDEX idx_note_visit_id ON note (visit_occurrence_id ASC); +CREATE INDEX idx_note_nlp_person_id ON note_nlp (person_id ASC); +CREATE INDEX idx_note_nlp_note_id ON note_nlp (note_id ASC); +CREATE INDEX idx_note_nlp_concept_id ON note_nlp (note_nlp_concept_id ASC); + CREATE INDEX idx_observation_person_id ON observation (person_id ASC); CREATE INDEX idx_observation_concept_id ON observation (observation_concept_id ASC); CREATE INDEX idx_observation_visit_id ON observation (visit_occurrence_id ASC); diff --git a/Oracle/OMOP CDM indexes required - Oracle - Without constraints.sql b/Oracle/OMOP CDM indexes required - Oracle - Without constraints.sql index 73ed627..c28f05d 100644 --- a/Oracle/OMOP CDM indexes required - Oracle - Without constraints.sql +++ b/Oracle/OMOP CDM indexes required - Oracle - Without constraints.sql @@ -17,18 +17,18 @@ /************************ - ####### # # ####### ###### ##### ###### # # ####### # ### ### - # # ## ## # # # # # # # # ## ## # # # ## # # # # # ##### ###### # # ###### #### - # # # # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # - # # # # # # # ###### # # # # # # # # ###### # # # # # # # # # ##### ## ##### #### - # # # # # # # # # # # # # # # ### # ### # # # # # # # # # ## # # - # # # # # # # # # # # # # # # # # ### # ### # # # # ## # # # # # # # # - ####### # # ####### # ##### ###### # # ## ##### ### ##### ### ### ### # # ##### ###### # # ###### #### + ####### # # ####### ###### ##### ###### # # ####### ##### ### + # # ## ## # # # # # # # # ## ## # # # # # # # # ##### ###### # # ###### #### + # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### ##### # # # # # # ##### ## ##### #### + # # # # # # # # # # # # # # # ### # # # # # # # # ## # # + # # # # # # # # # # # # # # # # # ### # # # ## # # # # # # # # + ####### # # ####### # ##### ###### # # ## ##### ### ####### ### # # ##### ###### # # ###### #### -script to create the required indexes within OMOP common data model, version 5.1.0 for Oracle database +script to create the required indexes within OMOP common data model, version 5.2 for Oracle database -last revised: 12 Oct 2014 +last revised: 14 July 2017 author: Patrick Ryan @@ -132,6 +132,10 @@ CREATE INDEX idx_note_person_id ON note (person_id ASC); CREATE INDEX idx_note_concept_id ON note (note_type_concept_id ASC); CREATE INDEX idx_note_visit_id ON note (visit_occurrence_id ASC); +CREATE INDEX idx_note_nlp_person_id ON note_nlp (person_id ASC); +CREATE INDEX idx_note_nlp_note_id ON note_nlp (note_id ASC); +CREATE INDEX idx_note_nlp_concept_id ON note_nlp (note_nlp_concept_id ASC); + CREATE INDEX idx_observation_person_id ON observation (person_id ASC); CREATE INDEX idx_observation_concept_id ON observation (observation_concept_id ASC); CREATE INDEX idx_observation_visit_id ON observation (visit_occurrence_id ASC); diff --git a/PostgreSQL/OMOP CDM constraints - PostgreSQL.sql b/PostgreSQL/OMOP CDM constraints - PostgreSQL.sql index f4842e3..161bc50 100644 --- a/PostgreSQL/OMOP CDM constraints - PostgreSQL.sql +++ b/PostgreSQL/OMOP CDM constraints - PostgreSQL.sql @@ -17,18 +17,18 @@ /************************ - ####### # # ####### ###### ##### ###### # # ####### # ### ##### - # # ## ## # # # # # # # # ## ## # # # ## # # # # #### # # #### ##### ##### ## # # # ##### #### - # # # # # # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # ## # # # - # # # # # # # ###### # # # # # # # # ###### # # # # # # # # # #### # # # # # # # # # # #### - # # # # # # # # # # # # # # # ### # ### # # # # # # # # # # ##### ###### # # # # # # - # # # # # # # # # # # # # # # # # ### # ### # # # # # # # ## # # # # # # # # # ## # # # - ####### # # ####### # ##### ###### # # ## ##### ### ##### ### ### ##### #### # # #### # # # # # # # # # #### + ####### # # ####### ###### ##### ###### # # ####### ##### ##### + # # ## ## # # # # # # # # ## ## # # # # # # # #### # # #### ##### ##### ## # # # ##### #### + # # # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # ## # # # + # # # # # # # ###### # # # # # # # # ###### ##### # # # # # # #### # # # # # # # # # # #### + # # # # # # # # # # # # # # # ### # # # # # # # # # ##### ###### # # # # # # + # # # # # # # # # # # # # # # # # ### # # # # # # ## # # # # # # # # # ## # # # + ####### # # ####### # ##### ###### # # ## ##### ### ####### ##### #### # # #### # # # # # # # # # #### -script to create constraints within OMOP common data model, version 5.1.0 for PostgreSQL database +script to create constraints within OMOP common data model, version 5.2 for PostgreSQL database -last revised: 12 Oct 2014 +last revised: 14 July 2017 author: Patrick Ryan @@ -126,6 +126,8 @@ ALTER TABLE measurement ADD CONSTRAINT xpk_measurement PRIMARY KEY ( measurement ALTER TABLE note ADD CONSTRAINT xpk_note PRIMARY KEY ( note_id ) ; +ALTER TABLE note_nlp ADD CONSTRAINT xpk_note_nlp PRIMARY KEY NONCLUSTERED ( note_nlp_id ) ; + ALTER TABLE observation ADD CONSTRAINT xpk_observation PRIMARY KEY ( observation_id ) ; @@ -322,6 +324,10 @@ ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_care_site FOREIGN KEY (car ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_concept_s FOREIGN KEY (visit_source_concept_id) REFERENCES concept (concept_id); +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_admitting_s FOREIGN KEY (admitting_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_discharge FOREIGN KEY (discharge_to_concept_id) REFERENCES concept (concept_id); + ALTER TABLE procedure_occurrence ADD CONSTRAINT fpk_procedure_person FOREIGN KEY (person_id) REFERENCES person (person_id); @@ -380,6 +386,8 @@ ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_visit FOREIGN KEY ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_concept_s FOREIGN KEY (condition_source_concept_id) REFERENCES concept (concept_id); +ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_status_concept FOREIGN KEY (condition_status_concept_id) REFERENCES concept (concept_id); + ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_person FOREIGN KEY (person_id) REFERENCES person (person_id); @@ -404,11 +412,24 @@ ALTER TABLE note ADD CONSTRAINT fpk_note_person FOREIGN KEY (person_id) REFEREN ALTER TABLE note ADD CONSTRAINT fpk_note_type_concept FOREIGN KEY (note_type_concept_id) REFERENCES concept (concept_id); +ALTER TABLE note ADD CONSTRAINT fpk_note_class_concept FOREIGN KEY (note_class_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note ADD CONSTRAINT fpk_note_encoding_concept FOREIGN KEY (encoding_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note ADD CONSTRAINT fpk_language_concept FOREIGN KEY (language_concept_id) REFERENCES concept (concept_id); + ALTER TABLE note ADD CONSTRAINT fpk_note_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); ALTER TABLE note ADD CONSTRAINT fpk_note_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_note FOREIGN KEY (note_id) REFERENCES note (note_id); + +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_section_concept FOREIGN KEY (section_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_concept FOREIGN KEY (note_nlp_concept_id) REFERENCES concept (concept_id); + + ALTER TABLE observation ADD CONSTRAINT fpk_observation_person FOREIGN KEY (person_id) REFERENCES person (person_id); ALTER TABLE observation ADD CONSTRAINT fpk_observation_concept FOREIGN KEY (observation_concept_id) REFERENCES concept (concept_id); @@ -472,6 +493,8 @@ ALTER TABLE cost ADD CONSTRAINT fpk_visit_cost_currency FOREIGN KEY (currency_co ALTER TABLE cost ADD CONSTRAINT fpk_visit_cost_period FOREIGN KEY (payer_plan_period_id) REFERENCES payer_plan_period (payer_plan_period_id); +ALTER TABLE cost ADD CONSTRAINT fpk_drg_concept FOREIGN KEY (drg_concept_id) REFERENCES concept (concept_id); + /************************ diff --git a/PostgreSQL/OMOP CDM ddl - PostgreSQL.sql b/PostgreSQL/OMOP CDM ddl - PostgreSQL.sql index fb0bd18..442c934 100644 --- a/PostgreSQL/OMOP CDM ddl - PostgreSQL.sql +++ b/PostgreSQL/OMOP CDM ddl - PostgreSQL.sql @@ -17,18 +17,18 @@ /************************ - ####### # # ####### ###### ##### ###### # # ####### # ### - # # ## ## # # # # # # # # ## ## # # # ## # # - # # # # # # # # # # # # # # # # # # # # # # # # - # # # # # # # ###### # # # # # # # # ###### # # # - # # # # # # # # # # # # # # # ### # ### # # - # # # # # # # # # # # # # # # # # ### # ### # # - ####### # # ####### # ##### ###### # # ## ##### ### ##### ### ### + ####### # # ####### ###### ##### ###### # # ####### ##### + # # ## ## # # # # # # # # ## ## # # # # # + # # # # # # # # # # # # # # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### ##### + # # # # # # # # # # # # # # # ### # + # # # # # # # # # # # # # # # # # ### # + ####### # # ####### # ##### ###### # # ## ##### ### ####### -script to create OMOP common data model, version 5.1.0 for PostgreSQL database +script to create OMOP common data model, version 5.2 for PostgreSQL database -last revised: 1-May-2016 +last revised: 14 July 2017 Authors: Patrick Ryan, Christian Reich @@ -305,14 +305,19 @@ CREATE TABLE visit_occurrence person_id INTEGER NOT NULL , visit_concept_id INTEGER NOT NULL , visit_start_date DATE NOT NULL , - visit_start_datetime TIMESTAMP NULL , + visit_start_datetime TIMESTAMP NULL , visit_end_date DATE NOT NULL , - visit_end_datetime TIMESTAMP NULL , + visit_end_datetime TIMESTAMP NULL , visit_type_concept_id INTEGER NOT NULL , provider_id INTEGER NULL, care_site_id INTEGER NULL, visit_source_value VARCHAR(50) NULL, - visit_source_concept_id INTEGER NULL + visit_source_concept_id INTEGER NULL , + admitting_source_concept_id INTEGER NULL , + admitting_source_value VARCHAR(50) NULL , + discharge_to_concept_id INTEGER(50) NULL , + discharge_to_source_value VARCHAR(50) NULL , + preceding_visit_occurrence_id INTEGER NULL ) ; @@ -344,18 +349,17 @@ CREATE TABLE drug_exposure person_id INTEGER NOT NULL , drug_concept_id INTEGER NOT NULL , drug_exposure_start_date DATE NOT NULL , - drug_exposure_start_datetime TIMESTAMP NOT NULL , - drug_exposure_end_date DATE NULL , - drug_exposure_end_datetime TIMESTAMP NULL , - drug_type_concept_id INTEGER NOT NULL , + drug_exposure_start_datetime TIMESTAMP NOT NULL , + drug_exposure_end_date DATE NOT NULL , + drug_exposure_end_datetime TIMESTAMP NULL , + verbatim_end_date DATE NULL , + drug_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , refills INTEGER NULL , quantity NUMERIC NULL , days_supply INTEGER NULL , sig TEXT NULL , route_concept_id INTEGER NULL , - effective_drug_dose NUMERIC NULL , - dose_unit_concept_id INTEGER NULL , lot_number VARCHAR(50) NULL , provider_id INTEGER NULL , visit_occurrence_id INTEGER NULL , @@ -401,7 +405,9 @@ CREATE TABLE condition_occurrence provider_id INTEGER NULL , visit_occurrence_id INTEGER NULL , condition_source_value VARCHAR(50) NULL , - condition_source_concept_id INTEGER NULL + condition_source_concept_id INTEGER NULL , + condition_status_source_value VARCHAR(50) NULL , + condition_status_concept_id INTEGER NULL ) ; @@ -439,7 +445,11 @@ CREATE TABLE note note_date DATE NOT NULL , note_datetime TIMESTAMP NULL , note_type_concept_id INTEGER NOT NULL , - note_text TEXT NOT NULL , + note_class_concept_id INTEGER NOT NULL , + note_title VARCHAR(250) NULL , + note_text TEXT NOT NULL , + encoding_concept_id INTEGER NOT NULL , + language_concept_id INTEGER NOT NULL , provider_id INTEGER NULL , visit_occurrence_id INTEGER NULL , note_source_value VARCHAR(50) NULL @@ -448,6 +458,27 @@ CREATE TABLE note +/*This table is new in CDM v5.2*/ +CREATE TABLE note_nlp +( + note_nlp_id BIGINT NOT NULL , + note_id INTEGER NOT NULL , + section_concept_id INTEGER NULL , + snippet VARCHAR(250) NULL , + offset VARCHAR(250) NULL , + lexical_variant VARCHAR(250) NOT NULL , + note_nlp_concept_id INTEGER NULL , + note_nlp_source_concept_id INTEGER NULL , + nlp_system VARCHAR(250) NULL , + nlp_date DATE NOT NULL , + nlp_datetime TIMESTAMP NULL , + term_exists VARCHAR(1) NULL , + term_temporal VARCHAR(50) NULL , + term_modifiers VARCHAR(2000) NULL +) +; + + CREATE TABLE observation ( observation_id INTEGER NOT NULL , @@ -562,85 +593,6 @@ CREATE TABLE payer_plan_period ; -/* The individual cost tables are being phased out and will disappear soon - -CREATE TABLE visit_cost - ( - visit_cost_id INTEGER NOT NULL , - visit_occurrence_id INTEGER NOT NULL , - currency_concept_id INTEGER NULL , - paid_copay NUMERIC NULL , - paid_coinsurance NUMERIC NULL , - paid_toward_deductible NUMERIC NULL , - paid_by_payer NUMERIC NULL , - paid_by_coordination_benefits NUMERIC NULL , - total_out_of_pocket NUMERIC NULL , - total_paid NUMERIC NULL , - payer_plan_period_id INTEGER NULL - ) -; - - - -CREATE TABLE procedure_cost - ( - procedure_cost_id INTEGER NOT NULL , - procedure_occurrence_id INTEGER NOT NULL , - currency_concept_id INTEGER NULL , - paid_copay NUMERIC NULL , - paid_coinsurance NUMERIC NULL , - paid_toward_deductible NUMERIC NULL , - paid_by_payer NUMERIC NULL , - paid_by_coordination_benefits NUMERIC NULL , - total_out_of_pocket NUMERIC NULL , - total_paid NUMERIC NULL , - revenue_code_concept_id INTEGER NULL , - payer_plan_period_id INTEGER NULL , - revenue_code_source_value VARCHAR(50) NULL - ) -; - - - -CREATE TABLE drug_cost - ( - drug_cost_id INTEGER NOT NULL , - drug_exposure_id INTEGER NOT NULL , - currency_concept_id INTEGER NULL , - paid_copay NUMERIC NULL , - paid_coinsurance NUMERIC NULL , - paid_toward_deductible NUMERIC NULL , - paid_by_payer NUMERIC NULL , - paid_by_coordination_benefits NUMERIC NULL , - total_out_of_pocket NUMERIC NULL , - total_paid NUMERIC NULL , - ingredient_cost NUMERIC NULL , - dispensing_fee NUMERIC NULL , - average_wholesale_price NUMERIC NULL , - payer_plan_period_id INTEGER NULL - ) -; - - - - - -CREATE TABLE device_cost - ( - device_cost_id INTEGER NOT NULL , - device_exposure_id INTEGER NOT NULL , - currency_concept_id INTEGER NULL , - paid_copay NUMERIC NULL , - paid_coinsurance NUMERIC NULL , - paid_toward_deductible NUMERIC NULL , - paid_by_payer NUMERIC NULL , - paid_by_coordination_benefits NUMERIC NULL , - total_out_of_pocket NUMERIC NULL , - total_paid NUMERIC NULL , - payer_plan_period_id INTEGER NULL - ) -; -*/ CREATE TABLE cost @@ -664,7 +616,9 @@ CREATE TABLE cost payer_plan_period_id INTEGER NULL , amount_allowed NUMERIC NULL , revenue_code_concept_id INTEGER NULL , - reveue_code_source_value VARCHAR(50) NULL + reveue_code_source_value VARCHAR(50) NULL , + drg_concept_id INTEGER NULL, + drg_source_value VARCHAR(3) NULL ) ; diff --git a/PostgreSQL/OMOP CDM indexes required - PostgreSQL.sql b/PostgreSQL/OMOP CDM indexes required - PostgreSQL.sql index 837e003..fb7aeaf 100644 --- a/PostgreSQL/OMOP CDM indexes required - PostgreSQL.sql +++ b/PostgreSQL/OMOP CDM indexes required - PostgreSQL.sql @@ -17,18 +17,18 @@ /************************ - ####### # # ####### ###### ##### ###### # # ####### # ### ### - # # ## ## # # # # # # # # ## ## # # # ## # # # # # ##### ###### # # ###### #### - # # # # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # - # # # # # # # ###### # # # # # # # # ###### # # # # # # # # # ##### ## ##### #### - # # # # # # # # # # # # # # # ### # ### # # # # # # # # # ## # # - # # # # # # # # # # # # # # # # # ### # ### # # # # ## # # # # # # # # - ####### # # ####### # ##### ###### # # ## ##### ### ##### ### ### ### # # ##### ###### # # ###### #### + ####### # # ####### ###### ##### ###### # # ####### ##### ### + # # ## ## # # # # # # # # ## ## # # # # # # # # ##### ###### # # ###### #### + # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### ##### # # # # # # ##### ## ##### #### + # # # # # # # # # # # # # # # ### # # # # # # # # ## # # + # # # # # # # # # # # # # # # # # ### # # # ## # # # # # # # # + ####### # # ####### # ##### ###### # # ## ##### ### ####### ### # # ##### ###### # # ###### #### -script to create the required indexes within OMOP common data model, version 5.1.0 for PostgreSQL database +script to create the required indexes within OMOP common data model, version 5.2 for PostgreSQL database -last revised: 12 Oct 2014 +last revised: 14 July 2017 author: Patrick Ryan @@ -153,6 +153,11 @@ CLUSTER note USING idx_note_person_id ; CREATE INDEX idx_note_concept_id ON note (note_type_concept_id ASC); CREATE INDEX idx_note_visit_id ON note (visit_occurrence_id ASC); +CREATE INDEX idx_note_nlp_person_id ON note_nlp (person_id ASC); +CLUSTER note_nlp USING idx_note_nlp_person_id ; +CREATE INDEX idx_note_nlp_note_id ON note_nlp (note_id ASC); +CREATE INDEX idx_note_nlp_concept_id ON note_nlp (note_nlp_concept_id ASC); + CREATE INDEX idx_observation_person_id ON observation (person_id ASC); CLUSTER observation USING idx_observation_person_id ; CREATE INDEX idx_observation_concept_id ON observation (observation_concept_id ASC); diff --git a/README.md b/README.md index 6374406..db6a674 100644 --- a/README.md +++ b/README.md @@ -1,60 +1,46 @@ -Common Data Model v5.1.1 +Common Data Model v5.2 ================= -See full CDM specification file on our github [wiki](https://github.com/OHDSI/CommonDataModel/wiki) or in the [CDM V5.1.1 PDF](https://github.com/OHDSI/CommonDataModel/blob/master/OMOP_CDM_v5_1_1.pdf) +See full CDM specification file on our github [wiki](https://github.com/OHDSI/CommonDataModel/wiki) or in the [CDM V5.2 PDF](https://github.com/OHDSI/CommonDataModel/blob/master/OMOP_CDM_v5_2.pdf) -Release Notes for v5.1.1 + +Release Notes for v5.2.0 ============= -This version has a small bug-fix for impala to make it compatible with ATLAS cohort generation. +This version is based on the CDM working group proposals: +* [#71](https://github.com/OHDSI/CommonDataModel/issues/71) Adds the field VERBATIM_END_DATE to DRUG_EXPOSURE and makes DRUG_EXPOSURE_END_DATE a required field +* [#73](https://github.com/OHDSI/CommonDataModel/issues/73) Removes EFFECTIVE_DRUG_DOSE and DOSE_UNIT_CONCEPT_ID from DRUG_EXPOSURE +* [#75](https://github.com/OHDSI/CommonDataModel/issues/75) Adds the field BOX_SIZE to DRUG_STRENGTH +* [#83](https://github.com/OHDSI/CommonDataModel/issues/83) Adds the following fields to VISIT_OCCURRENCE: + * ADMITTING_SOURCE_CONCEPT_ID + * ADMITTING_SOURCE_VALUE + * DISCHARGE_TO_CONCEPT_ID + * DISCHARGE_TO_SOURCE_VALUE + * PRECEDING_VISIT_OCCURRENCE_ID +* [#84](https://github.com/OHDSI/CommonDataModel/issues/84) Adds the following fields to CONDITION_OCCURRENCE: + * CONDITION_STATUS_CONCEPT_ID + * CONDITION_STATUS_SOURCE_VALUE +* [#69](https://github.com/OHDSI/CommonDataModel/issues/69) Adds the following fields to COST: + * DRG_CONCEPT_ID + * DRG_SOURCE_VALUE +* [#85](https://github.com/OHDSI/CommonDataModel/issues/85) Adds the NOTE_NLP table and the following fields to NOTE: + * NOTE_CLASS_CONCEPT_ID + * NOTE_TITLE + * ENCODING_CONCEPT_ID + * LANGUAGE_CONCEPT_ID + +Additional Updates +================== -Release Notes for v5.1.0 -============= -This version is based on the CDM working group proposal [#60](https://github.com/OHDSI/CommonDataModel/issues/60) and [#59](https://github.com/OHDSI/CommonDataModel/issues/59) and is **backwards compatibile with v5.0.1**. The proposed and accepted changes include adding a datetime field to every table that had a date column and adding field DENOMINATOR_VALUE to the DRUG_STRENGTH table. These were the new columns added: +* Files to generate the '_ERA' tables are now availalbe in the [CodeExcerpts](https://github.com/OHDSI/CommonDataModel/tree/master/CodeExcerpts) folder +* Redshift DDLs are now available -**PERSON** -* birth_datetime, not required +This version is **backwards compatibile with v5.0.1**. -**SPECIMEN** -* specimen_datetime, not required - -**DEATH** -* death_datetime, not required - -**VISIT_OCCURRENCE** -* visit_start_datetime, not required -* visit_end_datetime, not required - -**PROCEDURE_OCCURRENCE** -* procedure_datetime, not required - -**DRUG_EXPOSURE** -* drug_exposure_start_datetime, not required -* drug_exposure_end_datetime, not required - -**DRUG_STRENGTH** -* DENOMINATOR_VALUE, not required - -**DEVICE_EXPOSURE** -* device_exposure_start_datetime, not required -* device_exposure_end_datetime, not required - -**CONDITION_OCCURRENCE** -* condition_start_datetime, not required -* condition_end_datetime, not required - -**MEASUREMENT** -* measurement_datetime as time, not required - -**OBSERVATION** -* observation_datetime, not required - -**NOTE** -* note_datetime, not required - -There are additional changes listed on the [OHDSI wiki](http://www.ohdsi.org/web/wiki/doku.php?id=documentation:next_cdm) that have been accepted but are not listed in this version because after being accepted they were never added to the DDL. Version 5.1.0 as it is now is being used by members of the community and any changes would cause problems so the additional accepted proposals will be added in subsequent versions. --------- + This repo contains the definition of the OMOP Common Data Model. It supports the 5 SQL technologies: Impala, Oracle, Postgres, Redshift, and SQL Server. For each, the DDL, constraints and indexes (if appropriate) are defined. + Versions are defined using tagging and versioning. Full versions (V6, 7 etc.) are released each year (1-Jan) and are not backwards compatible. Minor versions (V5.1, 5.2 etc.) are released each quarter (1-Apr, 1-Jul and 1-Sep) and are not guaranteed to be backwards compatible though an effort is made to make sure that current queries will not break. Micro versions (V5.1.1, V5.1.2 etc.) are released irregularly and often, and contain small hot fixes or backward compatible changes to the last minor version. diff --git a/Sql Server/OMOP CDM constraints - SQL Server.sql b/Sql Server/OMOP CDM constraints - SQL Server.sql index a79f20f..484ea06 100644 --- a/Sql Server/OMOP CDM constraints - SQL Server.sql +++ b/Sql Server/OMOP CDM constraints - SQL Server.sql @@ -17,13 +17,13 @@ /************************ - ####### # # ####### ###### ##### ###### # # ####### # ### ##### - # # ## ## # # # # # # # # ## ## # # # ## # # # # #### # # #### ##### ##### ## # # # ##### #### - # # # # # # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # ## # # # - # # # # # # # ###### # # # # # # # # ###### # # # # # # # # # #### # # # # # # # # # # #### - # # # # # # # # # # # # # # # ### # ### # # # # # # # # # # ##### ###### # # # # # # - # # # # # # # # # # # # # # # # # ### # ### # # # # # # # ## # # # # # # # # # ## # # # - ####### # # ####### # ##### ###### # # ## ##### ### ##### ### ### ##### #### # # #### # # # # # # # # # #### + ####### # # ####### ###### ##### ###### # # ####### ##### ##### + # # ## ## # # # # # # # # ## ## # # # # # # # #### # # #### ##### ##### ## # # # ##### #### + # # # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # ## # # # + # # # # # # # ###### # # # # # # # # ###### ##### # # # # # # #### # # # # # # # # # # #### + # # # # # # # # # # # # # # # ### # # # # # # # # # ##### ###### # # # # # # + # # # # # # # # # # # # # # # # # ### # # # # # # ## # # # # # # # # # ## # # # + ####### # # ####### # ##### ###### # # ## ##### ### ####### ##### #### # # #### # # # # # # # # # #### script to create constraints within OMOP common data model, version 5.1.0 for SQL Server database @@ -126,6 +126,8 @@ ALTER TABLE measurement ADD CONSTRAINT xpk_measurement PRIMARY KEY NONCLUSTERED ALTER TABLE note ADD CONSTRAINT xpk_note PRIMARY KEY NONCLUSTERED ( note_id ) ; +ALTER TABLE note_nlp ADD CONSTRAINT xpk_note_nlp PRIMARY KEY NONCLUSTERED ( note_nlp_id ) ; + ALTER TABLE observation ADD CONSTRAINT xpk_observation PRIMARY KEY NONCLUSTERED ( observation_id ) ; @@ -322,6 +324,10 @@ ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_care_site FOREIGN KEY (car ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_concept_s FOREIGN KEY (visit_source_concept_id) REFERENCES concept (concept_id); +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_admitting_s FOREIGN KEY (admitting_source_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE visit_occurrence ADD CONSTRAINT fpk_visit_discharge FOREIGN KEY (discharge_to_concept_id) REFERENCES concept (concept_id); + ALTER TABLE procedure_occurrence ADD CONSTRAINT fpk_procedure_person FOREIGN KEY (person_id) REFERENCES person (person_id); @@ -380,6 +386,8 @@ ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_visit FOREIGN KEY ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_concept_s FOREIGN KEY (condition_source_concept_id) REFERENCES concept (concept_id); +ALTER TABLE condition_occurrence ADD CONSTRAINT fpk_condition_status_concept FOREIGN KEY (condition_status_concept_id) REFERENCES concept (concept_id); + ALTER TABLE measurement ADD CONSTRAINT fpk_measurement_person FOREIGN KEY (person_id) REFERENCES person (person_id); @@ -404,11 +412,25 @@ ALTER TABLE note ADD CONSTRAINT fpk_note_person FOREIGN KEY (person_id) REFEREN ALTER TABLE note ADD CONSTRAINT fpk_note_type_concept FOREIGN KEY (note_type_concept_id) REFERENCES concept (concept_id); +ALTER TABLE note ADD CONSTRAINT fpk_note_class_concept FOREIGN KEY (note_class_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note ADD CONSTRAINT fpk_note_encoding_concept FOREIGN KEY (encoding_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note ADD CONSTRAINT fpk_language_concept FOREIGN KEY (language_concept_id) REFERENCES concept (concept_id); + ALTER TABLE note ADD CONSTRAINT fpk_note_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id); ALTER TABLE note ADD CONSTRAINT fpk_note_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id); +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_note FOREIGN KEY (note_id) REFERENCES note (note_id); + +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_section_concept FOREIGN KEY (section_concept_id) REFERENCES concept (concept_id); + +ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_concept FOREIGN KEY (note_nlp_concept_id) REFERENCES concept (concept_id); + + + ALTER TABLE observation ADD CONSTRAINT fpk_observation_person FOREIGN KEY (person_id) REFERENCES person (person_id); ALTER TABLE observation ADD CONSTRAINT fpk_observation_concept FOREIGN KEY (observation_concept_id) REFERENCES concept (concept_id); @@ -472,6 +494,7 @@ ALTER TABLE cost ADD CONSTRAINT fpk_visit_cost_currency FOREIGN KEY (currency_co ALTER TABLE cost ADD CONSTRAINT fpk_visit_cost_period FOREIGN KEY (payer_plan_period_id) REFERENCES payer_plan_period (payer_plan_period_id); +ALTER TABLE cost ADD CONSTRAINT fpk_drg_concept FOREIGN KEY (drg_concept_id) REFERENCES concept (concept_id); /************************ diff --git a/Sql Server/OMOP CDM ddl - SQL Server.sql b/Sql Server/OMOP CDM ddl - SQL Server.sql index 20f4f27..44770c9 100644 --- a/Sql Server/OMOP CDM ddl - SQL Server.sql +++ b/Sql Server/OMOP CDM ddl - SQL Server.sql @@ -17,18 +17,18 @@ /************************ - ####### # # ####### ###### ##### ###### # # ####### # ### - # # ## ## # # # # # # # # ## ## # # # ## # # - # # # # # # # # # # # # # # # # # # # # # # # # - # # # # # # # ###### # # # # # # # # ###### # # # - # # # # # # # # # # # # # # # ### # ### # # - # # # # # # # # # # # # # # # # # ### # ### # # - ####### # # ####### # ##### ###### # # ## ##### ### ##### ### ### + ####### # # ####### ###### ##### ###### # # ####### ##### + # # ## ## # # # # # # # # ## ## # # # # # + # # # # # # # # # # # # # # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### ##### + # # # # # # # # # # # # # # # ### # + # # # # # # # # # # # # # # # # # ### # + ####### # # ####### # ##### ###### # # ## ##### ### ####### -script to create OMOP common data model, version 5.1.0 for SQL Server database +script to create OMOP common data model, version 5.2 for SQL Server database -last revised: 1-May-2016 +last revised: 14-July-2017 Authors: Patrick Ryan, Christian Reich @@ -227,9 +227,9 @@ CREATE TABLE person person_id INTEGER NOT NULL , gender_concept_id INTEGER NOT NULL , year_of_birth INTEGER NOT NULL , - month_of_birth INTEGER NULL, + month_of_birth INTEGER NULL, day_of_birth INTEGER NULL, - birth_datetime DATETIME2 NULL, + birth_datetime DATETIME2 NULL, race_concept_id INTEGER NOT NULL, ethnicity_concept_id INTEGER NOT NULL, location_id INTEGER NULL, @@ -239,8 +239,8 @@ CREATE TABLE person gender_source_value VARCHAR(50) NULL, gender_source_concept_id INTEGER NULL, race_source_value VARCHAR(50) NULL, - race_source_concept_id INTEGER NULL, - ethnicity_source_value VARCHAR(50) NULL, + race_source_concept_id INTEGER NULL, + ethnicity_source_value VARCHAR(50) NULL, ethnicity_source_concept_id INTEGER NULL ) ; @@ -254,10 +254,10 @@ CREATE TABLE observation_period observation_period_id INTEGER NOT NULL , person_id INTEGER NOT NULL , observation_period_start_date DATE NOT NULL , - observation_period_start_datetime DATETIME2 NOT NULL , + observation_period_start_datetime DATETIME2 NOT NULL , observation_period_end_date DATE NOT NULL , - observation_period_end_datetime DATETIME2 NOT NULL , - period_type_concept_id INTEGER NOT NULL + observation_period_end_datetime DATETIME2 NOT NULL , + period_type_concept_id INTEGER NOT NULL ) ; @@ -270,15 +270,15 @@ CREATE TABLE specimen specimen_concept_id INTEGER NOT NULL , specimen_type_concept_id INTEGER NOT NULL , specimen_date DATE NOT NULL , - specimen_datetime DATETIME2 NULL , + specimen_datetime DATETIME2 NULL , quantity FLOAT NULL , unit_concept_id INTEGER NULL , anatomic_site_concept_id INTEGER NULL , disease_status_concept_id INTEGER NULL , - specimen_source_id VARCHAR(50) NULL , + specimen_source_id VARCHAR(50) NULL , specimen_source_value VARCHAR(50) NULL , unit_source_value VARCHAR(50) NULL , - anatomic_site_source_value VARCHAR(50) NULL , + anatomic_site_source_value VARCHAR(50) NULL , disease_status_source_value VARCHAR(50) NULL ) ; @@ -313,6 +313,11 @@ CREATE TABLE visit_occurrence care_site_id INTEGER NULL, visit_source_value VARCHAR(50) NULL, visit_source_concept_id INTEGER NULL + admitting_source_concept_id INTEGER NULL , + admitting_source_value VARCHAR(50) NULL , + discharge_to_concept_id INTEGER(50) NULL , + discharge_to_source_value VARCHAR(50) NULL , + preceding_visit_occurrence_id INTEGER NULL ) ; @@ -323,16 +328,16 @@ CREATE TABLE procedure_occurrence procedure_occurrence_id INTEGER NOT NULL , person_id INTEGER NOT NULL , procedure_concept_id INTEGER NOT NULL , - procedure_date DATE NOT NULL , - procedure_datetime DATETIME2 NOT NULL , + procedure_date DATE NOT NULL , + procedure_datetime DATETIME2 NOT NULL , procedure_type_concept_id INTEGER NOT NULL , modifier_concept_id INTEGER NULL , quantity INTEGER NULL , provider_id INTEGER NULL , visit_occurrence_id INTEGER NULL , - procedure_source_value VARCHAR(50) NULL , + procedure_source_value VARCHAR(50) NULL , procedure_source_concept_id INTEGER NULL , - qualifier_source_value VARCHAR(50) NULL + qualifier_source_value VARCHAR(50) NULL ) ; @@ -344,9 +349,10 @@ CREATE TABLE drug_exposure person_id INTEGER NOT NULL , drug_concept_id INTEGER NOT NULL , drug_exposure_start_date DATE NOT NULL , - drug_exposure_start_datetime DATETIME2 NOT NULL , - drug_exposure_end_date DATE NULL , - drug_exposure_end_datetime DATETIME2 NULL , + drug_exposure_start_datetime DATETIME2 NOT NULL , + drug_exposure_end_date DATE NOT NULL , + drug_exposure_end_datetime DATETIME2 NULL , + verbatim_end_date DATE NULL , drug_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , refills INTEGER NULL , @@ -354,29 +360,27 @@ CREATE TABLE drug_exposure days_supply INTEGER NULL , sig VARCHAR(MAX) NULL , route_concept_id INTEGER NULL , - effective_drug_dose FLOAT NULL , - dose_unit_concept_id INTEGER NULL , - lot_number VARCHAR(50) NULL , + lot_number VARCHAR(50) NULL , provider_id INTEGER NULL , visit_occurrence_id INTEGER NULL , drug_source_value VARCHAR(50) NULL , - drug_source_concept_id INTEGER NULL , - route_source_value VARCHAR(50) NULL , - dose_unit_source_value VARCHAR(50) NULL + drug_source_concept_id INTEGER NULL , + route_source_value VARCHAR(50) NULL , + dose_unit_source_value VARCHAR(50) NULL ) ; CREATE TABLE device_exposure ( - device_exposure_id INTEGER NOT NULL , + device_exposure_id INTEGER NOT NULL , person_id INTEGER NOT NULL , device_concept_id INTEGER NOT NULL , - device_exposure_start_date DATE NOT NULL , - device_exposure_start_datetime DATETIME2 NOT NULL , + device_exposure_start_date DATE NOT NULL , + device_exposure_start_datetime DATETIME2 NOT NULL , device_exposure_end_date DATE NULL , - device_exposure_end_datetime DATETIME2 NULL , - device_type_concept_id INTEGER NOT NULL , + device_exposure_end_datetime DATETIME2 NULL , + device_type_concept_id INTEGER NOT NULL , unique_device_id VARCHAR(50) NULL , quantity INTEGER NULL , provider_id INTEGER NULL , @@ -393,15 +397,17 @@ CREATE TABLE condition_occurrence person_id INTEGER NOT NULL , condition_concept_id INTEGER NOT NULL , condition_start_date DATE NOT NULL , - condition_start_datetime DATETIME2 NOT NULL , - condition_end_date DATE NULL , - condition_end_datetime DATETIME2 NULL , + condition_start_datetime DATETIME2 NOT NULL , + condition_end_date DATE NULL , + condition_end_datetime DATETIME2 NULL , condition_type_concept_id INTEGER NOT NULL , stop_reason VARCHAR(20) NULL , provider_id INTEGER NULL , visit_occurrence_id INTEGER NULL , - condition_source_value VARCHAR(50) NULL , - condition_source_concept_id INTEGER NULL + condition_source_value VARCHAR(50) NULL , + condition_source_concept_id INTEGER NULL , + condition_status_source_value VARCHAR(50) NULL , + condition_status_concept_id INTEGER NULL ) ; @@ -409,24 +415,24 @@ CREATE TABLE condition_occurrence CREATE TABLE measurement ( - measurement_id INTEGER NOT NULL , + measurement_id INTEGER NOT NULL , person_id INTEGER NOT NULL , - measurement_concept_id INTEGER NOT NULL , + measurement_concept_id INTEGER NOT NULL , measurement_date DATE NOT NULL , - measurement_datetime DATETIME2 NULL , + measurement_datetime DATETIME2 NULL , measurement_type_concept_id INTEGER NOT NULL , operator_concept_id INTEGER NULL , value_as_number FLOAT NULL , value_as_concept_id INTEGER NULL , unit_concept_id INTEGER NULL , range_low FLOAT NULL , - range_high FLOAT NULL , + range_high FLOAT NULL , provider_id INTEGER NULL , visit_occurrence_id INTEGER NULL , measurement_source_value VARCHAR(50) NULL , measurement_source_concept_id INTEGER NULL , unit_source_value VARCHAR(50) NULL , - value_source_value VARCHAR(50) NULL + value_source_value VARCHAR(50) NULL ) ; @@ -437,9 +443,13 @@ CREATE TABLE note note_id INTEGER NOT NULL , person_id INTEGER NOT NULL , note_date DATE NOT NULL , - note_datetime DATETIME2 NULL , + note_datetime DATETIME2 NULL , note_type_concept_id INTEGER NOT NULL , - note_text VARCHAR(MAX) NOT NULL , + note_class_concept_id INTEGER NOT NULL , + note_title VARCHAR(250) NULL , + note_text VARCHAR(MAX) NULL , + encoding_concept_id INTEGER NOT NULL , + language_concept_id INTEGER NOT NULL , provider_id INTEGER NULL , visit_occurrence_id INTEGER NULL , note_source_value VARCHAR(50) NULL @@ -447,6 +457,26 @@ CREATE TABLE note ; +/*This table is new in CDM v5.2*/ +CREATE TABLE note_nlp +( + note_nlp_id BIGINT NOT NULL , + note_id INTEGER NOT NULL , + section_concept_id INTEGER NULL , + snippet VARCHAR(250) NULL , + offset VARCHAR(250) NULL , + lexical_variant VARCHAR(250) NOT NULL , + note_nlp_concept_id INTEGER NULL , + note_nlp_source_concept_id INTEGER NULL , + nlp_system VARCHAR(250) NULL , + nlp_date DATE NOT NULL , + nlp_datetime DATETIME2 NULL , + term_exists VARCHAR(1) NULL , + term_temporal VARCHAR(50) NULL , + term_modifiers VARCHAR(2000) NULL +) +; + CREATE TABLE observation ( @@ -562,85 +592,6 @@ CREATE TABLE payer_plan_period ; -/* The individual cost tables are being phased out and will disappear - -CREATE TABLE visit_cost - ( - visit_cost_id INTEGER NOT NULL , - visit_occurrence_id INTEGER NOT NULL , - currency_concept_id INTEGER NULL , - paid_copay FLOAT NULL , - paid_coinsurance FLOAT NULL , - paid_toward_deductible FLOAT NULL , - paid_by_payer FLOAT NULL , - paid_by_coordination_benefits FLOAT NULL , - total_out_of_pocket FLOAT NULL , - total_paid FLOAT NULL , - payer_plan_period_id INTEGER NULL - ) -; - - - -CREATE TABLE procedure_cost - ( - procedure_cost_id INTEGER NOT NULL , - procedure_occurrence_id INTEGER NOT NULL , - currency_concept_id INTEGER NULL , - paid_copay FLOAT NULL , - paid_coinsurance FLOAT NULL , - paid_toward_deductible FLOAT NULL , - paid_by_payer FLOAT NULL , - paid_by_coordination_benefits FLOAT NULL , - total_out_of_pocket FLOAT NULL , - total_paid FLOAT NULL , - revenue_code_concept_id INTEGER NULL , - payer_plan_period_id INTEGER NULL , - revenue_code_source_value VARCHAR(50) NULL - ) -; - - - -CREATE TABLE drug_cost - ( - drug_cost_id INTEGER NOT NULL , - drug_exposure_id INTEGER NOT NULL , - currency_concept_id INTEGER NULL , - paid_copay FLOAT NULL , - paid_coinsurance FLOAT NULL , - paid_toward_deductible FLOAT NULL , - paid_by_payer FLOAT NULL , - paid_by_coordination_benefits FLOAT NULL , - total_out_of_pocket FLOAT NULL , - total_paid FLOAT NULL , - ingredient_cost FLOAT NULL , - dispensing_fee FLOAT NULL , - average_wholesale_price FLOAT NULL , - payer_plan_period_id INTEGER NULL - ) -; - - - -CREATE TABLE device_cost - ( - device_cost_id INTEGER NOT NULL , - device_exposure_id INTEGER NOT NULL , - currency_concept_id INTEGER NULL , - paid_copay FLOAT NULL , - paid_coinsurance FLOAT NULL , - paid_toward_deductible FLOAT NULL , - paid_by_payer FLOAT NULL , - paid_by_coordination_benefits FLOAT NULL , - total_out_of_pocket FLOAT NULL , - total_paid FLOAT NULL , - payer_plan_period_id INTEGER NULL - ) -; -*/ - - CREATE TABLE cost ( cost_id INTEGER NOT NULL , @@ -662,7 +613,9 @@ CREATE TABLE cost payer_plan_period_id INTEGER NULL , amount_allowed FLOAT NULL , revenue_code_concept_id INTEGER NULL , - reveue_code_source_value VARCHAR(50) NULL + reveue_code_source_value VARCHAR(50) NULL, + drg_concept_id INTEGER NULL, + drg_source_value VARCHAR(3) NULL ) ; diff --git a/Sql Server/OMOP CDM indexes required - SQL Server.sql b/Sql Server/OMOP CDM indexes required - SQL Server.sql index ae42eb1..60b24d0 100644 --- a/Sql Server/OMOP CDM indexes required - SQL Server.sql +++ b/Sql Server/OMOP CDM indexes required - SQL Server.sql @@ -17,18 +17,18 @@ /************************ - ####### # # ####### ###### ##### ###### # # ####### # ### ### - # # ## ## # # # # # # # # ## ## # # # ## # # # # # ##### ###### # # ###### #### - # # # # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # - # # # # # # # ###### # # # # # # # # ###### # # # # # # # # # ##### ## ##### #### - # # # # # # # # # # # # # # # ### # ### # # # # # # # # # ## # # - # # # # # # # # # # # # # # # # # ### # ### # # # # ## # # # # # # # # - ####### # # ####### # ##### ###### # # ## ##### ### ##### ### ### ### # # ##### ###### # # ###### #### + ####### # # ####### ###### ##### ###### # # ####### ##### ### + # # ## ## # # # # # # # # ## ## # # # # # # # # ##### ###### # # ###### #### + # # # # # # # # # # # # # # # # # # # # # # ## # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### ##### # # # # # # ##### ## ##### #### + # # # # # # # # # # # # # # # ### # # # # # # # # ## # # + # # # # # # # # # # # # # # # # # ### # # # ## # # # # # # # # + ####### # # ####### # ##### ###### # # ## ##### ### ####### ### # # ##### ###### # # ###### #### -script to create the required indexes within OMOP common data model, version 5.1.0 for SQL Server database +script to create the required indexes within OMOP common data model, version 5.2 for SQL Server database -last revised: 12 Oct 2014 +last revised: 14-July-2017 author: Patrick Ryan @@ -131,6 +131,10 @@ CREATE CLUSTERED INDEX idx_note_person_id ON note (person_id ASC); CREATE INDEX idx_note_concept_id ON note (note_type_concept_id ASC); CREATE INDEX idx_note_visit_id ON note (visit_occurrence_id ASC); +CREATE CLUSTERED INDEX idx_note_nlp_person_id ON note_nlp (person_id ASC); +CREATE INDEX idx_note_nlp_note_id ON note_nlp (note_id ASC); +CREATE INDEX idx_note_nlp_concept_id ON note_nlp (note_nlp_concept_id ASC); + CREATE CLUSTERED INDEX idx_observation_person_id ON observation (person_id ASC); CREATE INDEX idx_observation_concept_id ON observation (observation_concept_id ASC); CREATE INDEX idx_observation_visit_id ON observation (visit_occurrence_id ASC);