From bac9cebf33609a0f42c4afe076988a1a5f456059 Mon Sep 17 00:00:00 2001 From: Anthony Sena Date: Wed, 5 Aug 2015 15:07:59 -0400 Subject: [PATCH] Improvements to scripts, documentation and inclusion of DRG conversion. --- .../Conversion-QA - Sql Server.sql | 152 - .../Conversion-QA-Part-2 - Sql Server.sql | 304 -- .../OMOP CDMv4 to CDMv5 - OHDSI-SQL.sql | 2358 ++++++++++ .../OMOP CDMv4 to CDMv5 - templateSQL.sql | 1956 --------- .../Oracle/OMOP CDMv4 to CDMv5 - Oracle.sql | 3807 ++++++++++------- .../OMOP CDMv4 to CDMv5 - PostgreSQL.sql | 3671 +++++++++------- .../QA-Results.xlsx | Bin 0 -> 17494 bytes Version4 To Version5 Conversion/README.md | 49 +- .../OMOP CDMv4 to CDMv5 - SQL Server.sql | 3614 +++++++++------- 9 files changed, 8623 insertions(+), 7288 deletions(-) delete mode 100644 Version4 To Version5 Conversion/Conversion-QA - Sql Server.sql delete mode 100644 Version4 To Version5 Conversion/Conversion-QA-Part-2 - Sql Server.sql create mode 100644 Version4 To Version5 Conversion/OMOP CDMv4 to CDMv5 - OHDSI-SQL.sql delete mode 100644 Version4 To Version5 Conversion/OMOP CDMv4 to CDMv5 - templateSQL.sql create mode 100644 Version4 To Version5 Conversion/QA-Results.xlsx diff --git a/Version4 To Version5 Conversion/Conversion-QA - Sql Server.sql b/Version4 To Version5 Conversion/Conversion-QA - Sql Server.sql deleted file mode 100644 index 2012c96..0000000 --- a/Version4 To Version5 Conversion/Conversion-QA - Sql Server.sql +++ /dev/null @@ -1,152 +0,0 @@ -/********************************************************************************* -# Copyright 2015 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: Use this script is used to help perform Quality Assurance activities - after you convert your OMOP V4 common data model to CDM V5. - -last revised: 01 July 2015 -author: Anthony Sena - -This script was authored against SQL Server and will require conversion to other -dialects. Please keep this in mind if you plan to use this against another RDBMS. - -General Notes ---------------- - -This script will use the metadata tables from the V4 and V5 tables to get a list -of all of the tables from each database and the rowcounts for each table in an -effort to help you see how your data has changed through the conversion process. - -In the results, we include a column to identify the tables that were part of -the migration process in an effort to hone in on the key tables. - -There is a Part 2 of this QA script which will also show you how data moved -amongst some specific tables. - - -INSTRUCTIONS ------------- - - 1. This script has 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: - - a. [SOURCE_CDMV4] - b. [TARGET_CDMV5] - - 2. Run the resulting script on your target RDBDMS. - -*********************************************************************************/ ---USE [TARGET_CDMV5] -USE [CDMV5_Conversion_Target] -GO - -IF OBJECT_ID('tempdb..#v5_stats', 'U') IS NOT NULL - DROP TABLE #v5_stats; - -SELECT - DB_NAME() as DBName, - t.NAME AS TableName, - p.[Rows] -INTO #v5_stats -FROM - sys.tables t -INNER JOIN - sys.indexes i ON t.OBJECT_ID = i.object_id -INNER JOIN - sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id -INNER JOIN - sys.allocation_units a ON p.partition_id = a.container_id -WHERE - t.NAME NOT LIKE 'dt%' AND - i.OBJECT_ID > 255 AND - i.index_id <= 1 -GROUP BY - t.NAME, i.object_id, i.index_id, i.name, p.[Rows] -ORDER BY - object_name(i.object_id) - ---USE [SOURCE_CDMV4] -USE [CDM_TRUVEN_CCAE_6k] -GO - -IF OBJECT_ID('tempdb..#v4_stats', 'U') IS NOT NULL - DROP TABLE #v4_stats; - -SELECT - DB_NAME() as DBName, - t.NAME AS TableName, - p.[Rows] -INTO #v4_stats -FROM - sys.tables t -INNER JOIN - sys.indexes i ON t.OBJECT_ID = i.object_id -INNER JOIN - sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id -INNER JOIN - sys.allocation_units a ON p.partition_id = a.container_id -WHERE - t.NAME NOT LIKE 'dt%' AND - i.OBJECT_ID > 255 AND - i.index_id <= 1 -GROUP BY - t.NAME, i.object_id, i.index_id, i.name, p.[Rows] -ORDER BY - object_name(i.object_id) - -DECLARE @MigrationTarget TABLE (TableName varchar(100)) - -INSERT INTO @MigrationTarget SELECT 'care_site' -INSERT INTO @MigrationTarget SELECT 'condition_era' -INSERT INTO @MigrationTarget SELECT 'condition_occurrence' -INSERT INTO @MigrationTarget SELECT 'death' -INSERT INTO @MigrationTarget SELECT 'device_exposure' -INSERT INTO @MigrationTarget SELECT 'drug_cost' -INSERT INTO @MigrationTarget SELECT 'drug_era' -INSERT INTO @MigrationTarget SELECT 'drug_exposure' -INSERT INTO @MigrationTarget SELECT 'location' -INSERT INTO @MigrationTarget SELECT 'measurement' -INSERT INTO @MigrationTarget SELECT 'observation' -INSERT INTO @MigrationTarget SELECT 'observation_period' -INSERT INTO @MigrationTarget SELECT 'payer_plan_period' -INSERT INTO @MigrationTarget SELECT 'person' -INSERT INTO @MigrationTarget SELECT 'procedure_cost' -INSERT INTO @MigrationTarget SELECT 'procedure_occurrence' -INSERT INTO @MigrationTarget SELECT 'provider' -INSERT INTO @MigrationTarget SELECT 'visit_occurrence' - -select - ISNULL(V4.DBName, 'No V4 Table Equivalent') as "Database Name", - v4.TableName, - v4.rows, - ISNULL(V5.DBName, 'No V5 Table Equivalent') as "Database Name", - v5.TableName, - v5.rows, - CASE WHEN mt.TableName IS NULL THEN 'N' ELSE 'Y' END AS "Migration Target", - ISNULL(v5.Rows, 0) - ISNULL(v4.Rows, 0) AS "Row Count Change" -from #v4_stats as v4 -full outer join #v5_stats as v5 ON v4.TableName = v5.TableName -left join @MigrationTarget mt on v5.TableName = mt.TableName -order by v5.TableName - - - diff --git a/Version4 To Version5 Conversion/Conversion-QA-Part-2 - Sql Server.sql b/Version4 To Version5 Conversion/Conversion-QA-Part-2 - Sql Server.sql deleted file mode 100644 index a379db8..0000000 --- a/Version4 To Version5 Conversion/Conversion-QA-Part-2 - Sql Server.sql +++ /dev/null @@ -1,304 +0,0 @@ -/********************************************************************************* -# Copyright 2015 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: Use this script is used to help perform Quality Assurance activities - after you convert your OMOP V4 common data model to CDM V5. - -last revised: 01 July 2015 -author: Anthony Sena - -This script was authored against SQL Server and will require conversion to other -dialects. Please keep this in mind if you plan to use this against another RDBMS. - -General Notes ---------------- - -The V4 to V5 conversion script utilizes the standard vocabularies to map data -from the V4 source tables to the V5 target tables. As a result, comparing the -rowcounts for the following tables is not adviseable since we are expecting -certain entries to move from their source table to a different target: - -Condition_Occurrence -Drug_Exposure -Observation -Measurement -Procedure_Occurrence - -This script will produce 2 tables: - -Table 1: This will contain the source table name (i.e. Condition_Occurrence), - the target domain_id from the V5 vocabulary and the expected rowcount - from the conversion. When there is no target defined in the V5 vocabulary, - the source data is carried over to the same target table in V5 with - a concept_id of 0. For example: - - TableName Domain RowCount - --------- ------ -------- - Condition_Occurrence condition 464849 - Condition_Occurrence measurement 8416 - Condition_Occurrence observation 31522 - Condition_Occurrence procedure 24298 - -Table 2: This will contain a summary of the V5 Target Domains and Rowcounts. - I found this helpful to tie out the expected rowcounts and what actually - happened during the conversion. - -INSTRUCTIONS ------------- - - 1. This script has 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: - - a. [SOURCE_CDMV4] - b. [TARGET_CDMV5] - - 2. Run the resulting script on your target RDBDMS. - -*********************************************************************************/ - -USE [TARGET_CDMV5] -GO - -/* - * CONCEPT MAP - */ -IF OBJECT_ID('tempdb..#concept_map', 'U') IS NOT NULL - DROP TABLE #concept_map; - ---standard concepts -SELECT concept_id AS source_concept_id - ,concept_id AS target_concept_id - ,domain_id - ,NULL AS source_concept_mapping_occurrence -INTO #concept_map -FROM dbo.concept -WHERE standard_concept = 'S' - AND invalid_reason IS NULL - -UNION - ---concepts with 'map to' standard -SELECT DISTINCT c1.concept_id AS source_concept_id - ,c2.concept_id AS target_concept_id - ,c2.domain_id - ,NULL -FROM ( - SELECT concept_id - FROM dbo.concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL - ) - ) c1 -INNER JOIN dbo.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 -INNER JOIN dbo.concept c2 ON cr1.concept_id_2 = c2.concept_id -WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ('Maps to') - AND cr1.invalid_reason IS NULL - -UNION - ---concepts without 'map to' standard with another non 'is a' relation to standard -SELECT DISTINCT c1.concept_id AS source_concept_id - ,c2.concept_id AS target_concept_id - ,c2.domain_id - ,NULL -FROM ( - SELECT concept_id - FROM dbo.concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL - ) - AND concept_id NOT IN ( - SELECT DISTINCT c1.concept_id - FROM ( - SELECT concept_id - FROM dbo.concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL - ) - ) c1 - INNER JOIN dbo.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 - INNER JOIN dbo.concept c2 ON cr1.concept_id_2 = c2.concept_id - WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ('Maps to') - AND cr1.invalid_reason IS NULL - ) - ) c1 -INNER JOIN dbo.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 -INNER JOIN dbo.concept c2 ON cr1.concept_id_2 = c2.concept_id -WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ( - 'RxNorm replaced by' - ,'SNOMED replaced by' - ,'UCUM replaced by' - ,'Concept replaced by' - ,'ICD9P replaced by' - ,'LOINC replaced by' - ,'Concept same_as to' - ,'Concept was_a to' - ,'Concept alt_to to' - ) - AND cr1.invalid_reason IS NULL - -UNION - ---concepts without 'map to' standard with 'is a' relation to standard -SELECT DISTINCT c1.concept_id AS source_concept_id - ,c2.concept_id AS target_concept_id - ,c2.domain_id - ,NULL -FROM ( - SELECT concept_id - FROM dbo.concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL - ) - AND concept_id NOT IN ( - SELECT DISTINCT c1.concept_id - FROM ( - SELECT concept_id - FROM dbo.concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL - ) - ) c1 - INNER JOIN dbo.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 - INNER JOIN dbo.concept c2 ON cr1.concept_id_2 = c2.concept_id - WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ( - 'Maps to' - ,'RxNorm replaced by' - ,'SNOMED replaced by' - ,'UCUM replaced by' - ,'Concept replaced by' - ,'ICD9P replaced by' - ,'LOINC replaced by' - ,'Concept same_as to' - ,'Concept was_a to' - ,'Concept alt_to to' - ) - AND cr1.invalid_reason IS NULL - ) - ) c1 -INNER JOIN dbo.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 -INNER JOIN dbo.concept c2 ON cr1.concept_id_2 = c2.concept_id -WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ('Is a') - AND cr1.invalid_reason IS NULL; -GO - --- Update the source_concept_mapping_occurrence column --- to contain a count to indicate the number of target_concept_ids --- map to that source_concept_id. This will be used elsewhere in --- the script to ensure that we generate new primary keys --- for the target tables when applicable -UPDATE #concept_map -SET #concept_map.source_concept_mapping_occurrence = A.[Rowcount] -FROM #concept_map - ,( - SELECT source_concept_id - ,domain_id - ,count(*) AS "rowcount" - FROM #concept_map - GROUP BY source_concept_id - ,domain_id - ) AS A -WHERE #concept_map.source_concept_id = A.source_concept_id - AND #concept_map.domain_id = A.domain_id - -IF OBJECT_ID('tempdb..#concept_map_distinct', 'U') IS NOT NULL - DROP TABLE #concept_map_distinct; - -SELECT DISTINCT source_concept_id - ,domain_id - ,COUNT(*) AS "rowcount" -INTO #concept_map_distinct -FROM #concept_map -GROUP BY source_concept_id - ,domain_id - - -/* - * V4 - Condition_Occurrence summary and mapping to #concept_map - */ -IF OBJECT_ID('tempdb..#classification_map', 'U') IS NOT NULL - DROP TABLE #classification_map; - -SELECT * -INTO #classification_map -FROM -( - SELECT 'Condition_Occurrence' as TableName, ISNULL(LOWER(cm.domain_id), 'condition') AS "Domain", COUNT(*) AS "RowCount" - FROM [SOURCE_CDMV4].[dbo].[Condition_Occurrence] as CO - LEFT JOIN #concept_map as CM ON co.condition_concept_id = cm.source_concept_id - GROUP BY ISNULL(LOWER(cm.domain_id), 'condition') - UNION - SELECT 'Drug_Exposure' as TableName, ISNULL(LOWER(cm.domain_id), 'drug') AS "Domain", COUNT(*) AS "RowCount" - FROM [SOURCE_CDMV4].[dbo].[Drug_Exposure] as de - LEFT JOIN #concept_map as CM ON de.drug_concept_id = cm.source_concept_id - GROUP BY ISNULL(LOWER(cm.domain_id), 'drug') - UNION - SELECT 'Observation' as TableName, ISNULL(LOWER(cm.domain_id), 'observation') AS "Domain", COUNT(*) AS "RowCount" - FROM [SOURCE_CDMV4].[dbo].[Observation] as o - LEFT JOIN #concept_map as CM ON o.observation_concept_id = cm.source_concept_id - GROUP BY ISNULL(LOWER(cm.domain_id), 'observation') - UNION - SELECT 'Procedure_Occurrence' as TableName, ISNULL(LOWER(cm.domain_id), 'procedure') AS "Domain", COUNT(*) AS "RowCount" - FROM [SOURCE_CDMV4].[dbo].[Procedure_Occurrence] as po - LEFT JOIN #concept_map as CM ON po.PROCEDURE_CONCEPT_ID = cm.source_concept_id - GROUP BY ISNULL(LOWER(cm.domain_id), 'procedure') -) AS A -ORDER by A.[TableName], A.[Domain] - -select * -from #classification_map -order by [TableName], [Domain] - -select domain, SUM([RowCount]) -from #classification_map -group by domain -order by domain \ No newline at end of file diff --git a/Version4 To Version5 Conversion/OMOP CDMv4 to CDMv5 - OHDSI-SQL.sql b/Version4 To Version5 Conversion/OMOP CDMv4 to CDMv5 - OHDSI-SQL.sql new file mode 100644 index 0000000..30e8aed --- /dev/null +++ b/Version4 To Version5 Conversion/OMOP CDMv4 to CDMv5 - OHDSI-SQL.sql @@ -0,0 +1,2358 @@ +/********************************************************************************* +# Copyright 2015 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: Use this script to convert your OMOP V4 common data model to CDM V5. + +last revised: 04 August 2015 +authors: Patrick Ryan, Chris Knoll, Anthony Sena + +!!!!!!!!!!!!!!!!!!!!! PLEASE READ THESE INSTRUCTIONS !!!!!!!!!!!!!!!!!!!!!!!!!!! + +This script was authored using OHDSI-SQL which will require you to run this +script through SqlRender to creat a version that is compatible with your target +RDBMS. We have pre-generated these scripts using SQL Render and have placed +them in folders for each RDBMS. Depending on which script you are viewing, your +instructions will be slightly different. + +General Assumptions +------------------- + +This script assumes that your V4 and V5 database are located on the same +RDBMS server. It also assumes that the V4 and V5 databases were created +using the standard data definition scripts for these databases. If you +altered your V4 database in any way, this script will likely require +some mo + +Getting Started +--------------- + +Before you can use this script, there are some prerequisites: + + 1. Create a target CDMv5 database on your database server using the + appropriate script from https://github.com/OHDSI/CommonDataModel + 2. Load VocabV5 into the target database/schema that will contain CDMv5 using + Athena: http://ohdsi.org/web/ATHENA + +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: + + a. [SOURCE_CDMV4] + b. [SOURCE_CDMV4].[SCHEMA] + c. [TARGET_CDMV5] + d. [TARGET_CDMV5].[SCHEMA] + + 2. Run the resulting script on your target RDBDMS. + +*********************************************************************************/ +/* SCRIPT PARAMETERS */ +{DEFAULT @SOURCE_CDMV4 = '[SOURCE_CDMV4]' } -- The CDMv4 database name + {DEFAULT @SOURCE_CDMV4_SCHEMA = '[SOURCE_CDMV4].[SCHEMA]' } -- The CDMv4 database plus schema + {DEFAULT @TARGET_CDMV5 = '[TARGET_CDMV5]' } -- The target CDMv5 database name + {DEFAULT @TARGET_CDMV5_SCHEMA = '[TARGET_CDMV5].[SCHEMA]' } -- the target CDMv5 database plus schema + +USE @TARGET_CDMV5; + +/* + * The #concept_map table will hold the mapping of source_concept_ids to target_concept_ids + * and their respective domain_ids. As a result, the results of this table will have + * some source_concept_ids that map to multiple target_concept_ids which is expected. + * + * In some of the conversion queries below, we will use the distinct values from the + * #concept_map table since our need in those instances is to understand the domain_id + * that will provide the destination table in the target V5 database. To make the code + * easier to read, we dervied a #concept_map_distinct table that holds the distinct + * source_concept_id and target domain_id. + * + * As of the dateof this script, the following domains contain source_concept_ids that + * map to multiple target_concept_ids: + * + * Condition + * Device + * Drug + * Measurement + * Observation + * Procedure + * Spec Anatomic Site + * + * Also, as of the date which this script was authored, no source_concept_ids map to multiple domains + */ +IF OBJECT_ID('tempdb..#concept_map', 'U') IS NOT NULL + DROP TABLE #concept_map; + +/* / */ + +SELECT concept_id AS source_concept_id + ,concept_id AS target_concept_id + ,domain_id AS domain_id +INTO #concept_map +FROM @TARGET_CDMV5_SCHEMA.concept +WHERE 1 = 0; + +/* / */ + +INSERT INTO #concept_map +--standard concepts +SELECT concept_id AS source_concept_id + ,concept_id AS target_concept_id + ,domain_id +FROM @TARGET_CDMV5_SCHEMA.concept +WHERE standard_concept = 'S' + AND invalid_reason IS NULL + +UNION + +--concepts with 'map to' standard +SELECT DISTINCT c1.concept_id AS source_concept_id + ,c2.concept_id AS target_concept_id + ,c2.domain_id +FROM ( + SELECT concept_id + FROM @TARGET_CDMV5_SCHEMA.concept + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL + ) + OR invalid_reason IS NOT NULL + ) + ) c1 +INNER JOIN @TARGET_CDMV5_SCHEMA.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 +INNER JOIN @TARGET_CDMV5_SCHEMA.concept c2 ON cr1.concept_id_2 = c2.concept_id +WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ('Maps to') + AND cr1.invalid_reason IS NULL + +UNION + +--concepts without 'map to' standard with another non 'is a' relation to standard +SELECT DISTINCT c1.concept_id AS source_concept_id + ,c2.concept_id AS target_concept_id + ,c2.domain_id +FROM ( + SELECT A.concept_id + FROM @TARGET_CDMV5_SCHEMA.concept A + LEFT JOIN ( + SELECT DISTINCT c1.concept_id + FROM ( + SELECT concept_id + FROM @TARGET_CDMV5_SCHEMA.concept + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL + ) + OR invalid_reason IS NOT NULL + ) + ) c1 + INNER JOIN @TARGET_CDMV5_SCHEMA.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 + INNER JOIN @TARGET_CDMV5_SCHEMA.concept c2 ON cr1.concept_id_2 = c2.concept_id + WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ('Maps to') + AND cr1.invalid_reason IS NULL + ) B ON A.concept_id = B.concept_id + WHERE ( + ( + A.standard_concept <> 'S' + OR A.standard_concept IS NULL + ) + OR A.invalid_reason IS NOT NULL + ) + AND B.concept_id IS NULL + ) c1 +INNER JOIN @TARGET_CDMV5_SCHEMA.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 +INNER JOIN @TARGET_CDMV5_SCHEMA.concept c2 ON cr1.concept_id_2 = c2.concept_id +WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ( + 'RxNorm replaced by' + ,'SNOMED replaced by' + ,'UCUM replaced by' + ,'Concept replaced by' + ,'ICD9P replaced by' + ,'LOINC replaced by' + ,'Concept same_as to' + ,'Concept was_a to' + ,'Concept alt_to to' + ) + AND cr1.invalid_reason IS NULL + +UNION + +--concepts without 'map to' standard with 'is a' relation to standard +SELECT DISTINCT c1.concept_id AS source_concept_id + ,c2.concept_id AS target_concept_id + ,c2.domain_id +FROM ( + SELECT A.concept_id + FROM @TARGET_CDMV5_SCHEMA.concept A + LEFT JOIN ( + SELECT DISTINCT c1.concept_id + FROM ( + SELECT concept_id + FROM @TARGET_CDMV5_SCHEMA.concept + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL + ) + OR invalid_reason IS NOT NULL + ) + ) c1 + INNER JOIN @TARGET_CDMV5_SCHEMA.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 + INNER JOIN @TARGET_CDMV5_SCHEMA.concept c2 ON cr1.concept_id_2 = c2.concept_id + WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ( + 'Maps to' + ,'RxNorm replaced by' + ,'SNOMED replaced by' + ,'UCUM replaced by' + ,'Concept replaced by' + ,'ICD9P replaced by' + ,'LOINC replaced by' + ,'Concept same_as to' + ,'Concept was_a to' + ,'Concept alt_to to' + ) + AND cr1.invalid_reason IS NULL + ) B ON A.concept_id = B.concept_id + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL + ) + OR invalid_reason IS NOT NULL + ) + AND B.concept_id IS NULL + ) c1 +INNER JOIN @TARGET_CDMV5_SCHEMA.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 +INNER JOIN @TARGET_CDMV5_SCHEMA.concept c2 ON cr1.concept_id_2 = c2.concept_id +WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ('Is a') + AND cr1.invalid_reason IS NULL; + +IF OBJECT_ID('tempdb..#concept_map_distinct', 'U') IS NOT NULL + DROP TABLE #concept_map_distinct; + +/* / */ + +SELECT source_concept_id + ,domain_id + ,COUNT(*) AS targetConceptCount +INTO #concept_map_distinct +FROM #concept_map +WHERE 1 = 0 +GROUP BY source_concept_id + ,domain_id; + +/* / */ + +INSERT INTO #concept_map_distinct +SELECT source_concept_id + ,domain_id + ,COUNT(*) +FROM #concept_map +GROUP BY source_concept_id + ,domain_id; + +IF OBJECT_ID('@TARGET_CDMV5_SCHEMA.ETL_WARNINGS', 'U') IS NOT NULL + DROP TABLE @TARGET_CDMV5_SCHEMA.ETL_WARNINGS; + +/* / */ + +CREATE TABLE @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE VARCHAR(4000)); +/* / */ + +/**** + +CDM_SOURCE + + ****/ +INSERT INTO @TARGET_CDMV5_SCHEMA.cdm_source ( + cdm_source_name + ,cdm_version + ,vocabulary_version + ,cdm_release_date + ) +SELECT '@TARGET_CDMV5' + ,'V5' + ,v.vocabulary_version + ,getDate() +FROM @TARGET_CDMV5_SCHEMA.vocabulary v +WHERE vocabulary_id = 'Vocabulary'; + +/**** + +LOCATION + + ****/ +INSERT INTO @TARGET_CDMV5_SCHEMA.location +SELECT location_id + ,address_1 + ,address_2 + ,city + ,STATE + ,zip + ,county + ,location_source_value +FROM @SOURCE_CDMV4_SCHEMA.LOCATION; + +/**** + +CARE_SITE + + ****/ +INSERT INTO @TARGET_CDMV5_SCHEMA.care_site +SELECT care_site_id + ,cast(NULL AS VARCHAR(255)) AS care_site_name + ,place_of_service_concept_id + ,location_id + ,care_site_source_value + ,place_of_service_source_value +FROM @SOURCE_CDMV4_SCHEMA.CARE_SITE; + +/**** + +Provider + +****/ +INSERT INTO @TARGET_CDMV5_SCHEMA.provider +SELECT provider_id + ,cast(NULL AS VARCHAR(255)) AS provider_name + ,NPI + ,DEA + ,specialty_concept_id + ,care_site_id + ,cast(NULL AS INT) AS year_of_birth + ,cast(NULL AS INT) AS gender_concept_id + ,provider_source_value + ,specialty_source_value + ,0 AS specialty_source_concept_id + ,cast(NULL AS VARCHAR(50)) AS gender_source_value + ,cast(NULL AS INT) AS gender_source_concept_id +FROM @SOURCE_CDMV4_SCHEMA.provider; + +/**** + + PERSON + + ****/ +INSERT INTO @TARGET_CDMV5_SCHEMA.person +SELECT person_id + ,coalesce(gender.target_concept_id, 0) AS gender_concept_id + ,year_of_birth + ,month_of_birth + ,day_of_birth + ,CAST(NULL AS VARCHAR(10)) time_of_birth + ,coalesce(race.target_concept_id, 0) AS race_concept_id + ,coalesce(ethnicity.target_concept_id, 0) AS ethnicity_concept_id + ,location_id + ,provider_id + ,care_site_id + ,person_source_value + ,gender_source_value + ,CAST(NULL AS INT) gender_source_concept_id + ,CAST(NULL AS INT) race_source_value + ,CAST(NULL AS INT) race_source_concept_id + ,ethnicity_source_value + ,CAST(NULL AS INT) ethnicity_source_concept_id +FROM @SOURCE_CDMV4_SCHEMA.PERSON p +LEFT JOIN #concept_map gender ON LOWER(gender.DOMAIN_ID) IN ('gender') + AND p.gender_concept_id = gender.source_concept_id +LEFT JOIN #concept_map race ON LOWER(race.DOMAIN_ID) IN ('race') + AND p.race_concept_id = race.source_concept_id +LEFT JOIN #concept_map ethnicity ON LOWER(ethnicity.DOMAIN_ID) IN ('ethnicity') + AND p.ETHNICITY_CONCEPT_ID = ethnicity.source_concept_id; + +INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PERSON: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid GENDER_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM @SOURCE_CDMV4_SCHEMA.PERSON + WHERE GENDER_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM @TARGET_CDMV5_SCHEMA.CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('gender') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PERSON: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid RACE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM @SOURCE_CDMV4_SCHEMA.PERSON + WHERE RACE_CONCEPT_ID IS NOT NULL + AND RACE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM @TARGET_CDMV5_SCHEMA.CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('race') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PERSON: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid ETHNICITY_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM @SOURCE_CDMV4_SCHEMA.PERSON + WHERE ETHNICITY_CONCEPT_ID IS NOT NULL + AND ETHNICITY_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM @TARGET_CDMV5_SCHEMA.CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('ethnicity') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** + + OBSERVATION_PERIOD + + ****/ +INSERT INTO @TARGET_CDMV5_SCHEMA.observation_period +SELECT observation_period_id + ,person_id + ,observation_period_start_date + ,observation_period_end_date + ,44814722 AS period_type_concept_id +FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION_PERIOD; + +/**** + + DEATH + + ****/ +INSERT INTO @TARGET_CDMV5_SCHEMA.death +SELECT person_id + ,death_date + ,COALESCE(death_type_concept_id, 0) AS death_type_concept_id + ,cause_of_death_concept_id AS cause_concept_id + ,cause_of_death_source_value AS cause_source_value + ,CAST(NULL AS INT) AS cause_source_concept_id +FROM @SOURCE_CDMV4_SCHEMA.DEATH +LEFT JOIN #concept_map_distinct cm1 ON DEATH.DEATH_TYPE_CONCEPT_ID = CM1.SOURCE_CONCEPT_ID + AND LOWER(DOMAIN_ID) IN ('death type'); + +INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'DEATH: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid DEATH_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM @SOURCE_CDMV4_SCHEMA.DEATH + WHERE DEATH_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM @TARGET_CDMV5_SCHEMA.CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('death type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** + + VISIT_OCCURRENCE + + ****/ +INSERT INTO @TARGET_CDMV5_SCHEMA.visit_occurrence +SELECT visit_occurrence_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS visit_concept_id + ,visit_start_date + ,CAST(NULL AS VARCHAR(10)) visit_start_time + ,visit_end_date + ,CAST(NULL AS VARCHAR(10)) visit_end_time + ,44818517 AS visit_type_concept_id + ,CAST(NULL AS INT) provider_id + ,care_site_id + ,place_of_service_source_value AS visit_source_value + ,CAST(NULL AS INT) visit_source_concept_id +FROM @SOURCE_CDMV4_SCHEMA.VISIT_OCCURRENCE +LEFT JOIN #concept_map cm1 ON VISIT_OCCURRENCE.PLACE_OF_SERVICE_CONCEPT_ID = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('visit'); + +INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'VISIT_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid VISIT_CONCEPT_ID (from the CDMv4 PLACE_OF_SERVICE_CONCEPT_ID field)' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM @SOURCE_CDMV4_SCHEMA.VISIT_OCCURRENCE + WHERE PLACE_OF_SERVICE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM @TARGET_CDMV5_SCHEMA.CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('visit') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** + + PROCEDURE_OCCURRENCE + + ****/ +IF OBJECT_ID('tempdb..#po_map', 'U') IS NOT NULL + DROP TABLE #po_map; + +/* / */ + +SELECT po.procedure_occurrence_id + ,po.person_id + ,po.procedure_concept_id + ,po.procedure_date + ,po.procedure_type_concept_id + ,po.modifier_concept_id + ,po.quantity + ,po.provider_id + ,po.visit_occurrence_id + ,po.procedure_source_value + ,po.procedure_source_concept_id + ,po.qualifier_source_value + ,de.drug_exposure_id AS origional_drug_id +INTO #po_map +FROM @TARGET_CDMV5_SCHEMA.procedure_occurrence po +LEFT JOIN @TARGET_CDMV5_SCHEMA.drug_exposure de ON 1 = 0 +WHERE 0 = 1; + +/* / */ + +--find valid procedures from procedure table +INSERT INTO #po_map +SELECT procedure_occurrence_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS procedure_concept_id + ,procedure_date + ,COALESCE(cm2.target_concept_id, 0) AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id +FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE +INNER JOIN #concept_map cm1 ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') +INNER JOIN #concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount = 1 +LEFT JOIN #concept_map cm2 ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('procedure type') +LEFT JOIN #concept_map_distinct cmdis2 ON cm2.source_concept_id = cmdis2.source_concept_id + AND cm2.domain_id = cmdis2.domain_id + AND cmdis2.targetConceptCount = 1 + +UNION ALL + +-- All procedures that did not map to a standard concept in V4 should also carry over to V5 +SELECT procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) procedure_source_concept_id + ,NULL qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id +FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE +WHERE procedure_concept_id = 0 + +UNION ALL + +-- All PROCEDURE_OCCURRENCE that do not map to a standard concept in V5 should also carry over with procedure_concept_id = 0 +SELECT procedure_occurrence_id + ,person_id + ,0 AS procedure_concept_id + ,procedure_date + ,COALESCE(cm2.target_concept_id, 0) AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) procedure_source_concept_id + ,NULL qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id +FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE +LEFT JOIN #concept_map cm1 ON procedure_concept_id = cm1.source_concept_id +LEFT JOIN #concept_map cm2 ON procedure_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('procedure type') +WHERE procedure_concept_id <> 0 + AND cm1.domain_id IS NULL + +UNION ALL + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,modifier_concept_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,procedure_source_value + ,procedure_source_concept_id + ,qualifier_source_value + ,origional_drug_id +FROM ( + --find valid procedures from procedure table that map to more than 1 + --target concept in V5 + SELECT person_id + ,COALESCE(cm1.target_concept_id, 0) AS procedure_concept_id + ,procedure_date + ,COALESCE(cm2.target_concept_id, 0) AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) procedure_source_concept_id + ,NULL qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + ,CAST(NULL AS INT) AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE + INNER JOIN #concept_map cm1 ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + INNER JOIN #concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount > 1 + LEFT JOIN #concept_map cm2 ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('procedure type') + + UNION ALL + + --find procedures that were previously classified as condition + SELECT person_id + ,cm1.target_concept_id AS procedure_concept_id + ,condition_start_date AS procedure_date + ,0 AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value AS procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + ,condition_occurrence_id AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE + INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + + UNION ALL + + --find procedures that were previously classified as drug + SELECT person_id + ,cm1.target_concept_id AS procedure_concept_id + ,drug_exposure_start_date AS procedure_date + ,0 AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value AS procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,drug_exposure_id AS origional_drug_id + ,drug_exposure_id AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE + INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + --find procedures that were previously classified as observation + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS procedure_concept_id + ,observation_date AS procedure_date + ,0 AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,observation_source_value AS procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + ,OBSERVATION_ID AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION + INNER JOIN #concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + ) OTHERS + ,( + SELECT MAX(PROCEDURE_OCCURRENCE_ID) AS MAXROWID + FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE + ) MAXROW; + +INSERT INTO @TARGET_CDMV5_SCHEMA.procedure_occurrence ( + procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,modifier_concept_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,procedure_source_value + ,procedure_source_concept_id + ,qualifier_source_value + ) +SELECT procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,modifier_concept_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,procedure_source_value + ,procedure_source_concept_id + ,qualifier_source_value +FROM #po_map; + +--warnings of invalid records +INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PROCEDURE_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid PROCOEDURE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE + WHERE PROCEDURE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM @TARGET_CDMV5_SCHEMA.CONCEPT + WHERE CONCEPT_ID = 0 + OR STANDARD_CONCEPT = 'S' + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PROCEDURE_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid PROCOEDURE_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE + WHERE PROCEDURE_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM @TARGET_CDMV5_SCHEMA.CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('procedure type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** + + DRUG_EXPOSURE + + ****/ +--find valid drugs from drug_exposure table +IF OBJECT_ID('tempdb..#drgexp_map', 'U') IS NOT NULL + DROP TABLE #drgexp_map; + +/* / */ + +SELECT de.drug_exposure_id + ,de.person_id + ,de.drug_concept_id + ,de.drug_exposure_start_date + ,de.drug_exposure_end_date + ,de.drug_type_concept_id + ,de.stop_reason + ,de.refills + ,de.quantity + ,de.days_supply + ,de.sig + ,de.route_concept_id + ,de.effective_drug_dose + ,de.dose_unit_concept_id + ,de.lot_number + ,de.provider_id + ,de.visit_occurrence_id + ,de.drug_source_value + ,de.drug_source_concept_id + ,de.route_source_value + ,de.dose_unit_source_value + ,po.procedure_occurrence_id AS origional_procedure_id +INTO #drgexp_map +FROM @TARGET_CDMV5_SCHEMA.drug_exposure de +LEFT JOIN @TARGET_CDMV5_SCHEMA.procedure_occurrence po ON 1 = 0 +WHERE 0 = 1; + +/* / */ + +INSERT INTO #drgexp_map +SELECT drug_exposure_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,COALESCE(cm2.target_concept_id, 0) drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id +FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE +INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') +INNER JOIN #concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount = 1 +LEFT JOIN #concept_map cm2 ON drug_exposure.drug_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('drug type') +INNER JOIN #concept_map_distinct cmdis2 ON cm2.source_concept_id = cmdis2.source_concept_id + AND cm2.domain_id = cmdis2.domain_id + AND cmdis2.targetConceptCount = 1 +WHERE drug_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 + +UNION ALL + +-- All drug exposures that did not map to a standard concept in V4 should also carry over to V5 +SELECT drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id +FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE +WHERE drug_concept_id = 0 + +UNION ALL + +-- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 +SELECT drug_exposure_id + ,person_id + ,0 + ,drug_exposure_start_date + ,drug_exposure_end_date + ,COALESCE(cm2.target_concept_id, 0) drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id +FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE +LEFT JOIN #concept_map cm1 ON drug_concept_id = cm1.source_concept_id +LEFT JOIN #concept_map cm2 ON drug_exposure.drug_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('drug type') +WHERE drug_concept_id <> 0 + AND cm1.domain_id IS NULL + +UNION ALL + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,route_concept_id + ,effective_drug_dose + ,dose_unit_concept_id + ,lot_number + ,provider_id + ,visit_occurrence_id + ,drug_source_value + ,drug_source_concept_id + ,route_source_value + ,dose_unit_source_value + ,origional_procedure_id +FROM ( + --find valid drugs from drug_exposure table that map to > 1 target concept + SELECT person_id + ,COALESCE(cm1.target_concept_id, 0) AS drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,COALESCE(cm2.target_concept_id, 0) drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + ,CAST(NULL AS INT) AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE + INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + INNER JOIN #concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount > 1 + LEFT JOIN #concept_map cm2 ON drug_exposure.drug_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('drug type') + + UNION ALL + + --find drugs that were previously classified as condition + SELECT person_id + ,cm1.target_concept_id AS drug_concept_id + ,condition_start_date AS drug_exposure_start_date + ,NULL AS drug_exposure_end_date + ,0 AS drug_type_concept_id + ,NULL AS stop_reason + ,CAST(NULL AS INT) AS refills + ,CAST(NULL AS FLOAT) AS quantity + ,CAST(NULL AS INT) AS days_supply + ,NULL AS sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,condition_source_value AS drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + ,condition_occurrence_id AS occurrence_id + FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE + INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + --find drugs that were previously classified as procedure + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS drug_concept_id + ,procedure_date AS drug_exposure_start_date + ,CAST(NULL AS DATE) AS drug_exposure_end_date + ,0 AS drug_type_concept_id + ,NULL AS stop_reason + ,CAST(NULL AS INT) AS refills + ,CAST(NULL AS FLOAT) AS quantity + ,CAST(NULL AS INT) AS days_supply + ,NULL AS sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,procedure_occurrence_id AS origional_procedure_id + ,procedure_occurrence_id AS occurrence_id + FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE + INNER JOIN #concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + --find drugs that were previously classified as observation + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS drug_concept_id + ,observation_date AS drug_exposure_start_date + ,CAST(NULL AS DATE) AS drug_exposure_end_date + ,0 AS drug_type_concept_id + ,NULL AS stop_reason + ,CAST(NULL AS INT) AS refills + ,CAST(NULL AS FLOAT) AS quantity + ,CAST(NULL AS INT) AS days_supply + ,NULL AS sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,observation_source_value AS drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + ,observation_id AS occurrence_id + FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION + INNER JOIN #concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + ) OTHERS + ,( + SELECT MAX(DRUG_EXPOSURE_ID) AS MAXROWID + FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE + ) MAXROW; + +INSERT INTO @TARGET_CDMV5_SCHEMA.drug_exposure ( + drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,route_concept_id + ,effective_drug_dose + ,dose_unit_concept_id + ,lot_number + ,provider_id + ,visit_occurrence_id + ,drug_source_value + ,drug_source_concept_id + ,route_source_value + ,dose_unit_source_value + ) +SELECT drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,route_concept_id + ,effective_drug_dose + ,dose_unit_concept_id + ,lot_number + ,provider_id + ,visit_occurrence_id + ,drug_source_value + ,drug_source_concept_id + ,route_source_value + ,dose_unit_source_value +FROM #drgexp_map; + +--warnings of invalid records +INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'DRUG_EXPOSURE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid DRUG_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE + WHERE DRUG_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM @TARGET_CDMV5_SCHEMA.CONCEPT + WHERE CONCEPT_ID = 0 + OR STANDARD_CONCEPT = 'S' + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'DRUG_EXPOSURE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid DRUG_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE + WHERE DRUG_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM @TARGET_CDMV5_SCHEMA.CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('drug type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** + + CONDITION_OCCURRENCE + + ****/ +--find valid conditions from condition_occurrence table +INSERT INTO @TARGET_CDMV5_SCHEMA.condition_occurrence +SELECT condition_occurrence_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(cm2.target_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id +FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE +INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') +INNER JOIN #concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount = 1 +LEFT JOIN #concept_map cm2 ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('condition type') +WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 + +UNION ALL + +-- All conditions that did not map to a standard concept in V4 should also carry over to V5 +SELECT condition_occurrence_id + ,person_id + ,condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(condition_type_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id +FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE +WHERE condition_concept_id = 0 + +UNION ALL + +-- All conditions that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 +SELECT condition_occurrence_id + ,person_id + ,0 AS condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(cm2.target_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id +FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE +LEFT JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id +LEFT JOIN #concept_map cm2 ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('condition type') +WHERE condition_concept_id <> 0 + AND cm1.domain_id IS NULL + +UNION ALL + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS drug_exposure_id + ,person_id + ,condition_concept_id + ,condition_start_date + ,condition_end_date + ,condition_type_concept_id + ,stop_reason + ,provider_id + ,visit_occurrence_id + ,condition_source_value + ,condition_source_concept_id +FROM ( + --find valid conditions from condition_occurrence table that map to > 1 target concept + SELECT person_id + ,COALESCE(cm1.target_concept_id, 0) AS condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(cm2.target_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,NULL AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE + INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + INNER JOIN #concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount > 1 + LEFT JOIN #concept_map cm2 ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('condition type') + WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 + + UNION ALL + + --find conditions that were previously classified as procedure + SELECT person_id + ,cm1.target_concept_id AS condition_concept_id + ,procedure_date AS condition_start_date + ,NULL AS condition_end_date + ,0 AS condition_type_concept_id + ,NULL AS stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,procedure_occurrence_id AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE + INNER JOIN #concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + --find conditions that were previously classified as drug + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS condition_concept_id + ,drug_exposure_start_date AS condition_start_date + ,NULL AS condition_end_date + ,0 AS condition_type_concept_id + ,NULL AS stop_reason + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value AS condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,drug_exposure_id AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE + INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + --find conditions that were previously classified as observation + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS condition_concept_id + ,observation_date AS condition_start_date + ,NULL AS condition_end_date + ,0 AS condition_type_concept_id + ,NULL AS stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,observation_source_value AS condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,observation_id AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION + INNER JOIN #concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + ) OTHERS + ,( + SELECT MAX(condition_occurrence_id) AS MAXROWID + FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE + ) MAXROW; + +--warnings of invalid records +INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'CONDITION_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid CONDITION_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE + WHERE CONDITION_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM @TARGET_CDMV5_SCHEMA.CONCEPT + WHERE CONCEPT_ID = 0 + OR STANDARD_CONCEPT = 'S' + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'CONDIITON_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid CONDITION_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE + WHERE CONDITION_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM @TARGET_CDMV5_SCHEMA.CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('condition type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** + + DEVICE_EXPOSURE + + ****/ +INSERT INTO @TARGET_CDMV5_SCHEMA.device_exposure +SELECT row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS device_exposure_id + ,person_id + ,device_concept_id + ,device_exposure_start_date + ,device_exposure_end_date + ,device_type_concept_id + ,unique_device_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,device_source_value + ,device_source_concept_id +FROM ( + --find devices that were previously classified as procedures + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,PROCEDURE_DATE AS DEVICE_EXPOSURE_START_DATE + ,CAST(NULL AS DATE) AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,CAST(NULL AS VARCHAR(50)) unique_device_id + ,CAST(NULL AS INT) quantity + ,ASSOCIATED_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,PROCEDURE_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,PROCEDURE_OCCURRENCE_ID AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE + INNER JOIN #concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') + --find devices that were previously classified as drug exposure + + UNION ALL + + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS DEVICE_EXPOSURE_START_DATE + ,CAST(NULL AS DATE) AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,CAST(NULL AS VARCHAR(50)) unique_device_id + ,quantity + ,PRESCRIBING_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,DRUG_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,DRUG_EXPOSURE_ID AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE + INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') + --find devices that were previously classified as conditions + + UNION ALL + + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,CONDITION_START_DATE AS DEVICE_EXPOSURE_START_DATE + ,CAST(NULL AS DATE) AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,CAST(NULL AS VARCHAR(50)) unique_device_id + ,CAST(NULL AS INT) quantity + ,ASSOCIATED_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,CONDITION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,CONDITION_OCCURRENCE_ID AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE + INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') + --find devices that were previously classified as observations + + UNION ALL + + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,OBSERVATION_DATE AS DEVICE_EXPOSURE_START_DATE + ,CAST(NULL AS DATE) AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,CAST(NULL AS VARCHAR(50)) unique_device_id + ,CAST(NULL AS INT) quantity + ,ASSOCIATED_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,OBSERVATION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,OBSERVATION_ID AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION + INNER JOIN #concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') + ) OTHERS; + +/**** + + MEASUREMENT + + ****/ +--find valid measurements from observation table +INSERT INTO @TARGET_CDMV5_SCHEMA.measurement +SELECT row_number() OVER ( + ORDER BY occurrence_id + ) AS measurement_id + ,person_id + ,measurement_concept_id + ,measurement_date + ,measurement_time + ,measurement_type_concept_id + ,operator_concept_id + ,value_as_number + ,value_as_concept_id + ,unit_concept_id + ,range_low + ,range_high + ,provider_id + ,visit_occurrence_id + ,measurement_source_value + ,measurement_source_concept_id + ,unit_source_value + ,value_source_value +FROM ( + --find mesaurements that were previously classified as observations + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,OBSERVATION_DATE AS measurement_date + ,CAST(OBSERVATION_TIME AS VARCHAR(50)) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) operator_concept_id + ,value_as_number + ,value_as_concept_id + ,COALESCE(cm2.target_concept_id, 0) AS unit_concept_id + ,range_low + ,range_high + ,ASSOCIATED_PROVIDER_ID AS provider_id + ,visit_occurrence_id + ,OBSERVATION_SOURCE_VALUE AS measurement_source_value + ,CAST(NULL AS INT) measurement_source_concept_id + ,unit_source_value AS unit_source_value + ,cast(NULL AS VARCHAR(50)) AS value_source_value + ,observation_id AS occurrence_id + FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION + INNER JOIN #concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + LEFT JOIN #concept_map cm2 ON observation.unit_concept_id = cm2.source_concept_id + AND LOWER(cm1.domain_id) IN ('unit') + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,procedure_date AS measurement_date + ,CAST(NULL AS VARCHAR(50)) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) AS operator_concept_id + ,CAST(NULL AS INT) AS value_as_number + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS range_low + ,CAST(NULL AS INT) AS range_high + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS measurement_source_value + ,CAST(NULL AS INT) AS measurement_source_concept_id + ,CAST(NULL AS VARCHAR(50)) AS unit_source_value + ,CAST(NULL AS VARCHAR(50)) AS value_source_value + ,procedure_occurrence_id AS occurrence_id + FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE + INNER JOIN #concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,condition_start_date AS measurement_date + ,CAST(NULL AS VARCHAR(50)) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) AS operator_concept_id + ,CAST(NULL AS INT) AS value_as_number + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS range_low + ,CAST(NULL AS INT) AS range_high + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value AS measurement_source_value + ,CAST(NULL AS INT) AS measurement_source_concept_id + ,CAST(NULL AS VARCHAR(50)) AS unit_source_value + ,CAST(NULL AS VARCHAR(50)) AS value_source_value + ,condition_occurrence_id AS occurrence_id + FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE + INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,drug_exposure_start_date AS measurement_date + ,CAST(NULL AS VARCHAR(50)) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) AS operator_concept_id + ,CAST(NULL AS INT) AS value_as_number + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS range_low + ,CAST(NULL AS INT) AS range_high + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value AS measurement_source_value + ,CAST(NULL AS INT) AS measurement_source_concept_id + ,CAST(NULL AS VARCHAR(50)) AS unit_source_value + ,CAST(NULL AS VARCHAR(50)) AS value_source_value + ,drug_exposure_id AS occurrence_id + FROM @SOURCE_CDMV4_SCHEMA.drug_exposure + INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + ) OTHERS; + +/**** + + OBSERVATION + + ****/ +--find valid observation from observation table +INSERT INTO @TARGET_CDMV5_SCHEMA.observation +SELECT observation_id + ,person_id + ,observation_concept_id + ,observation_date + ,CAST(observation_time AS VARCHAR(50)) AS observation_time + ,observation_type_concept_id + ,value_as_number + ,value_as_string + ,value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,unit_concept_id + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value +FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION +WHERE observation_concept_id NOT IN ( + SELECT source_concept_id + FROM #concept_map_distinct + WHERE LOWER(domain_id) IN ( + 'condition' + ,'drug' + ,'procedure' + ,'device' + ,'measurement' + ) + ) +--find observations that were previously classified as procedure + +UNION ALL + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS observation_id + ,person_id + ,observation_concept_id + ,observation_date + ,observation_time + ,observation_type_concept_id + ,value_as_number + ,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 ( + SELECT person_id + ,cm1.target_concept_id AS observation_concept_id + ,procedure_date AS observation_date + ,CAST(NULL AS VARCHAR(50)) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS FLOAT) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,NULL AS unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value + ,procedure_occurrence_id AS occurrence_id + FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE + INNER JOIN #concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + --find observations that were previously classified as condition + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS observation_concept_id + ,condition_start_date AS observation_date + ,CAST(NULL AS VARCHAR(50)) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS FLOAT) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value AS observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,NULL AS unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value + ,condition_occurrence_id AS occurrence_id + FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE + INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + + UNION ALL + + --find DRG observations that were previously classified as procedure_cost + SELECT po.person_id + ,cm1.target_concept_id AS observation_concept_id + ,po.procedure_date AS observation_date + ,CAST(NULL AS VARCHAR(50)) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS FLOAT) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,po.associated_provider_id AS provider_id + ,po.visit_occurrence_id + ,pc.DISEASE_CLASS_SOURCE_VALUE AS observation_source_value + ,cm1.source_concept_id as observation_source_concept_id + ,NULL AS unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value + ,po.procedure_occurrence_id AS occurrence_id + FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_COST pc + INNER JOIN @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE po ON pc.PROCEDURE_OCCURRENCE_ID = po.PROCEDURE_OCCURRENCE_ID + INNER JOIN #concept_map cm1 ON pc.disease_class_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + + UNION ALL + + --find observations that were previously classified as drug exposure + SELECT person_id + ,cm1.target_concept_id AS observation_concept_id + ,drug_exposure_start_date AS observation_date + ,CAST(NULL AS VARCHAR(10)) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS FLOAT) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,drug_source_value AS observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,NULL AS unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value + ,drug_exposure_id AS occurrence_id + FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE + INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + ) OTHERS + ,( + SELECT MAX(OBSERVATION_ID) AS MAXROWID + FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION + ) MAXROW; + +/**** + + PAYER_PLAN_PERIOD + + ****/ +INSERT INTO @TARGET_CDMV5_SCHEMA.payer_plan_period +SELECT payer_plan_period_id + ,person_id + ,payer_plan_period_start_date + ,payer_plan_period_end_date + ,payer_source_value + ,plan_source_value + ,family_source_value +FROM @SOURCE_CDMV4_SCHEMA.PAYER_PLAN_PERIOD; + +/**** + + DRUG_COST + + note : if there were invalid drug concepts in DRUG_EXPOSURE, those records may not enter CDMv5 but costs will persist + + ****/ +INSERT INTO @TARGET_CDMV5_SCHEMA.drug_cost +SELECT drug_cost_id + ,dc.drug_exposure_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,ingredient_cost + ,dispensing_fee + ,average_wholesale_price + ,payer_plan_period_id +FROM @SOURCE_CDMV4_SCHEMA.DRUG_COST dc; + +-- insert procedure costs for procedures that were inserted into the drug_exposure table +INSERT INTO @TARGET_CDMV5_SCHEMA.drug_cost +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS drug_cost_id + ,drug_exposure_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,ingredient_cost + ,dispensing_fee + ,average_wholesale_price + ,payer_plan_period_id +FROM ( + SELECT drug_exposure_id + ,po.person_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,CAST(NULL AS FLOAT) AS ingredient_cost + ,CAST(NULL AS FLOAT) AS dispensing_fee + ,CAST(NULL AS FLOAT) AS average_wholesale_price + ,payer_plan_period_id + ,procedure_cost_id AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE po + INNER JOIN @SOURCE_CDMV4_SCHEMA.PROCEDURE_COST pc ON po.procedure_occurrence_id = pc.procedure_occurrence_id + --JOIN dbo.drug_exposure de on de.person_id = po.person_id and pc.procedure_occurrence_id = de.origional_procedure_id + INNER JOIN #drgexp_map de ON de.person_id = po.person_id + AND pc.procedure_occurrence_id = de.origional_procedure_id + ) OTHERS + ,( + SELECT MAX(drug_cost_id) AS MAXROWID + FROM @SOURCE_CDMV4_SCHEMA.DRUG_COST + ) MAXROW; + +/**** + + PROCEDURE_COST + + note : if there were invalid procedure concepts in PROCEDURE_OCCURRENCE, those records may not enter CDMv5 but costs will persist + + + ****/ +INSERT INTO @TARGET_CDMV5_SCHEMA.procedure_cost +SELECT procedure_cost_id + ,procedure_occurrence_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,payer_plan_period_id + ,revenue_code_concept_id + ,revenue_code_source_value +FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_COST; + +-- insert drug costs for drugs that were inserted into the procedure_occurrence table +INSERT INTO @TARGET_CDMV5_SCHEMA.procedure_cost +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS procedure_cost_id + ,procedure_occurrence_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,payer_plan_period_id + ,revenue_code_concept_id + ,revenue_code_source_value +FROM ( + SELECT po.procedure_occurrence_id + ,po.person_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,CAST(NULL AS FLOAT) AS ingredient_cost + ,CAST(NULL AS FLOAT) AS dispensing_fee + ,CAST(NULL AS FLOAT) AS average_wholesale_price + ,payer_plan_period_id + ,CAST(NULL AS INT) AS revenue_code_concept_id + ,CAST(NULL AS INT) AS revenue_code_source_value + ,drug_cost_id AS OCCURRENCE_ID + FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE de + INNER JOIN @SOURCE_CDMV4_SCHEMA.DRUG_COST dc ON de.drug_exposure_id = dc.drug_exposure_id + --JOIN dbo.procedure_occurrence po on de.person_id = po.person_id and de.drug_exposure_id = po.origional_drug_id + INNER JOIN #po_map po ON de.person_id = po.person_id + AND de.drug_exposure_id = po.origional_drug_id + ) OTHERS + ,( + SELECT MAX(drug_cost_id) AS MAXROWID + FROM @SOURCE_CDMV4_SCHEMA.DRUG_COST + ) MAXROW; + +/**** + +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; + +/**** + +QUALITY ASSURANCE OUTPUT + +Note: These queries are used to provide some basic stats around row counts between your V4 and V5 database + to ensure that all of the data has migrated as expected. + + ****/ + +IF OBJECT_ID('tempdb..#v5_stats', 'U') IS NOT NULL + DROP TABLE #v5_stats; + +/* / */ + +IF OBJECT_ID('tempdb..#v4_stats', 'U') IS NOT NULL + DROP TABLE #v4_stats; + +/* / */ + +-- Get the row counts for each table that is in scope for the migration +SELECT * +INTO #v4_stats +FROM +( + SELECT '@SOURCE_CDMV4' AS DBName, 'care_site' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.care_site + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'condition_era' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.condition_era + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'condition_occurrence' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.condition_occurrence + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'death' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.death + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'drug_cost' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.drug_cost + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'drug_era' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.drug_era + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'drug_exposure' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.drug_exposure + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'location' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.location + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'observation' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.observation + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'observation_period' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.observation_period + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'payer_plan_period' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.payer_plan_period + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'person' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.person + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'procedure_cost' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.procedure_cost + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'procedure_occurrence' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.procedure_occurrence + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'provider' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.provider + UNION + SELECT '@SOURCE_CDMV4' AS DBName, 'visit_occurrence' AS TableName, COUNT(*) as row_count FROM @SOURCE_CDMV4_SCHEMA.visit_occurrence +) v4_stats; + +/* / */ + +SELECT * +INTO #v5_stats +FROM +( + SELECT '@TARGET_CDMV5' AS DBName, 'care_site' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.care_site + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'condition_era' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.condition_era + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'condition_occurrence' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.condition_occurrence + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'death' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.death + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'device_exposure' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.device_exposure + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'drug_cost' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.drug_cost + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'drug_era' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.drug_era + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'drug_exposure' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.drug_exposure + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'location' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.location + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'measurement' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.measurement + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'observation' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.observation + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'observation_period' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.observation_period + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'payer_plan_period' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.payer_plan_period + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'person' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.person + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'procedure_cost' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.procedure_cost + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'procedure_occurrence' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.procedure_occurrence + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'provider' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.provider + UNION + SELECT '@TARGET_CDMV5' AS DBName, 'visit_occurrence' AS TableName, COUNT(*) as row_count FROM @TARGET_CDMV5_SCHEMA.visit_occurrence +) v5_stats; + +/* / */ + +-- Show the results +select + 'Rowcounts for each database and table', + ISNULL(V4.DBName, 'None') v4_database_name, + v4.TableName v4_table_name, + v4.row_count v4_row_count, + ISNULL(v5.DBName, 'None') v5_database_name, + v5.TableName v5_table_name, + v5.row_count v5_row_count, + ISNULL(v5.row_count, 0) - ISNULL(v4.row_count, 0) row_count_change +from #v4_stats v4 +full outer join #v5_stats v5 ON v4.TableName = v5.TableName +order by v5.TableName; + +/* + * Determine how the vocabulary/domains helped to map from the V4 source + * tables to the V5 destinations + */ +IF OBJECT_ID('tempdb..#classification_map', 'U') IS NOT NULL + DROP TABLE #classification_map; + +/* / */ + +SELECT * +INTO #classification_map +FROM +( + SELECT 'Condition_Occurrence' TableName, ISNULL(LOWER(cm.domain_id), 'condition') domain_id, COUNT(*) row_count + FROM @SOURCE_CDMV4_SCHEMA.Condition_Occurrence CO + LEFT JOIN #concept_map CM ON co.condition_concept_id = cm.source_concept_id + GROUP BY ISNULL(LOWER(cm.domain_id), 'condition') + UNION + SELECT 'Drug_Exposure' TableName, ISNULL(LOWER(cm.domain_id), 'drug') domain_id, COUNT(*) row_count + FROM @SOURCE_CDMV4_SCHEMA.Drug_Exposure de + LEFT JOIN #concept_map CM ON de.drug_concept_id = cm.source_concept_id + GROUP BY ISNULL(LOWER(cm.domain_id), 'drug') + UNION + SELECT 'Observation' TableName, ISNULL(LOWER(cm.domain_id), 'observation') domain_id, COUNT(*) row_count + FROM @SOURCE_CDMV4_SCHEMA.Observation o + LEFT JOIN #concept_map CM ON o.observation_concept_id = cm.source_concept_id + GROUP BY ISNULL(LOWER(cm.domain_id), 'observation') + UNION + SELECT 'Procedure_Occurrence' TableName, ISNULL(LOWER(cm.domain_id), 'procedure') domain_id, COUNT(*) row_count + FROM @SOURCE_CDMV4_SCHEMA.Procedure_Occurrence po + LEFT JOIN #concept_map CM ON po.PROCEDURE_CONCEPT_ID = cm.source_concept_id + GROUP BY ISNULL(LOWER(cm.domain_id), 'procedure') +) A +ORDER by A.TableName, A.domain_id; + +/* / */ + +select * +from #classification_map +order by tablename, domain_id; + +select domain_id, SUM(row_count) +from #classification_map +group by domain_id +order by domain_id; \ No newline at end of file diff --git a/Version4 To Version5 Conversion/OMOP CDMv4 to CDMv5 - templateSQL.sql b/Version4 To Version5 Conversion/OMOP CDMv4 to CDMv5 - templateSQL.sql deleted file mode 100644 index 347f4df..0000000 --- a/Version4 To Version5 Conversion/OMOP CDMv4 to CDMv5 - templateSQL.sql +++ /dev/null @@ -1,1956 +0,0 @@ -/********************************************************************************* -# Copyright 2015 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: Use this script to convert your OMOP V4 common data model to CDM V5. - -last revised: 09 July 2015 -author: Patrick Ryan, Chris Knoll -editor: Anthony Sena - -!!!!!!!!!!!!!!!!!!!!! PLEASE READ THESE INSTRUCTIONS !!!!!!!!!!!!!!!!!!!!!!!!!!! - -This script was authored using TemplateSQL which will require you to run this -script through SqlRender to creat a version that is compatible with your target -RDBMS. We have pre-generated these scripts using SQL Render and have placed -them in folders for each RDBMS. Depending on which script you are viewing, your -instructions will be slightly different. - -General Assumptions -------------------- - -This script assumes that your V4 and V5 database are located on the same -RDBMS server. - -Getting Started ---------------- - -Before you can use this script, there are some prerequisites: - - 1. Create a target CDMv5 database on your server using the appropriate script - from https://github.com/OHDSI/CommonDataModel - 2. Load VocabV5 into the target database/schema that will contain CDMv5 using - Athena: http://ohdsi.org/web/ATHENA - -TemplateSQL 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: - - a. [SOURCE_CDMV4] - b. [SOURCE_CDMV4].[SCHEMA] - c. [TARGET_CDMV5] - d. [TARGET_CDMV5].[SCHEMA] - - 2. Run the resulting script on your target RDBDMS. - -*********************************************************************************/ - -/* SCRIPT PARAMETERS */ -{DEFAULT @SOURCE_CDMV4 = '[SOURCE_CDMV4]'} -- The CDMv4 database name -{DEFAULT @SOURCE_CDMV4_SCHEMA = '[SOURCE_CDMV4].[SCHEMA]'} -- The CDMv4 database plus schema -{DEFAULT @TARGET_CDMV5 = '[TARGET_CDMV5]'} -- The target CDMv5 database name -{DEFAULT @TARGET_CDMV5_SCHEMA = '[TARGET_CDMV5].[SCHEMA]'} -- the target CDMv5 database plus schema - -USE @TARGET_CDMV5; - -/* - * The #concept_map table will hold the mapping of source_concept_ids to target_concept_ids - * and their respective domain_ids. As a result, the results of this table will have - * some source_concept_ids that map to multiple target_concept_ids which is expected. - * - * In some of the conversion queries below, we will use the distinct values from the - * #concept_map table since our need in those instances is to understand the domain_id - * that will provide the destination table in the target V5 database. To make the code - * easier to read, we dervied a #concept_map_distinct table that holds the distinct - * source_concept_id and target domain_id. - * - * As of the dateof this script, the following domains contain source_concept_ids that - * map to multiple target_concept_ids: - * - * Condition - * Device - * Drug - * Measurement - * Observation - * Procedure - * Spec Anatomic Site - * - * Also, as of the date which this script was authored, no source_concept_ids map to multiple domains - */ -IF OBJECT_ID('tempdb..#concept_map', 'U') IS NOT NULL - DROP TABLE #concept_map; - -CREATE TABLE #concept_map -( - source_concept_id int, - target_concept_id int, - domain_id varchar(20) -); - ---standard concepts -INSERT INTO #concept_map (source_concept_id, target_concept_id, domain_id) -select concept_id as source_concept_id, - concept_id as target_concept_id, - domain_id -from @TARGET_CDMV5_SCHEMA.concept -where standard_concept = 'S' -and invalid_reason is null - -union - ---concepts with 'map to' standard -select distinct c1.concept_id as source_concept_id, - c2.concept_id as target_concept_id, - c2.domain_id -from -( -select concept_id -from @TARGET_CDMV5_SCHEMA.concept -where ((standard_concept <> 'S' or standard_concept is null) -or invalid_reason is not null -) -) c1 -inner join -@TARGET_CDMV5_SCHEMA.concept_relationship cr1 -on c1.concept_id = cr1.concept_id_1 -inner join -@TARGET_CDMV5_SCHEMA.concept c2 -on cr1.concept_id_2 = c2.concept_id -where c2.standard_concept = 'S' -and c2.invalid_reason is null -and cr1.relationship_id in ('Maps to') -and cr1.invalid_reason is null - - -union - ---concepts without 'map to' standard with another non 'is a' relation to standard -select distinct c1.concept_id as source_concept_id, - c2.concept_id as target_concept_id, - c2.domain_id -from -( - SELECT A.concept_id - FROM @TARGET_CDMV5_SCHEMA.concept A - LEFT JOIN - ( - SELECT DISTINCT c1.concept_id - FROM ( - SELECT concept_id - FROM @TARGET_CDMV5_SCHEMA.concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL - ) - ) c1 - INNER JOIN @TARGET_CDMV5_SCHEMA.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 - INNER JOIN @TARGET_CDMV5_SCHEMA.concept c2 ON cr1.concept_id_2 = c2.concept_id - WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ('Maps to') - AND cr1.invalid_reason IS NULL - ) B ON A.concept_id = B.concept_id - WHERE ( - ( - A.standard_concept <> 'S' - OR A.standard_concept IS NULL - ) - OR A.invalid_reason IS NOT NULL - ) - AND B.concept_id IS NULL -) c1 -inner join @TARGET_CDMV5_SCHEMA.concept_relationship cr1 on c1.concept_id = cr1.concept_id_1 -inner join @TARGET_CDMV5_SCHEMA.concept c2 on cr1.concept_id_2 = c2.concept_id -where c2.standard_concept = 'S' - and c2.invalid_reason is null - and cr1.relationship_id in ( - 'RxNorm replaced by', - 'SNOMED replaced by', - 'UCUM replaced by', - 'Concept replaced by', - 'ICD9P replaced by', - 'LOINC replaced by', - 'Concept same_as to', - 'Concept was_a to', - 'Concept alt_to to' -) -and cr1.invalid_reason is null - -union - ---concepts without 'map to' standard with 'is a' relation to standard -SELECT DISTINCT c1.concept_id AS source_concept_id - ,c2.concept_id AS target_concept_id - ,c2.domain_id -FROM ( - SELECT A.concept_id - FROM @TARGET_CDMV5_SCHEMA.concept A - LEFT JOIN - ( - SELECT DISTINCT c1.concept_id - FROM ( - SELECT concept_id - FROM @TARGET_CDMV5_SCHEMA.concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL - ) - ) c1 - INNER JOIN @TARGET_CDMV5_SCHEMA.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 - INNER JOIN @TARGET_CDMV5_SCHEMA.concept c2 ON cr1.concept_id_2 = c2.concept_id - WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ( - 'Maps to' - ,'RxNorm replaced by' - ,'SNOMED replaced by' - ,'UCUM replaced by' - ,'Concept replaced by' - ,'ICD9P replaced by' - ,'LOINC replaced by' - ,'Concept same_as to' - ,'Concept was_a to' - ,'Concept alt_to to' - ) - AND cr1.invalid_reason IS NULL - ) B ON A.concept_id = B.concept_id - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL - ) - AND B.concept_id IS NULL - ) c1 -INNER JOIN @TARGET_CDMV5_SCHEMA.concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 -INNER JOIN @TARGET_CDMV5_SCHEMA.concept c2 ON cr1.concept_id_2 = c2.concept_id -WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ('Is a') - AND cr1.invalid_reason IS NULL; - --- Update the source_concept_map_occurrence column --- to contain a count to indicate the number of target_concept_ids --- map to that source_concept_id. This will be used elsewhere in --- the script to ensure that we generate new primary keys --- for the target tables when applicable -/* - UPDATE #concept_map - SET #concept_map.source_concept_map_occurrence = A.targetConceptCount - FROM - #concept_map, - ( - select source_concept_id, domain_id, count(*) as "targetConceptCount" - from #concept_map - group by source_concept_id, domain_id - ) AS A -WHERE #concept_map.source_concept_id = A.source_concept_id AND #concept_map.domain_id = A.domain_id; - -UPDATE #concept_map -SET source_concept_map_occurrence = "targetConceptCount" -FROM - ( - select source_concept_id, domain_id, count(*) as "targetConceptCount" - from #concept_map - group by source_concept_id, domain_id - ) A -WHERE #concept_map.source_concept_id = A.source_concept_id AND #concept_map.domain_id = A.domain_id; - -UPDATE #concept_map -SET source_concept_map_occurrence = ( - select count(*) as "targetConceptCount" - from #concept_map A - WHERE A.source_concept_id = #concept_map.source_concept_id AND A.domain_id = #concept_map.domain_id - group by source_concept_id, domain_id - ) -*/ - -IF OBJECT_ID('tempdb..#concept_map_distinct', 'U') IS NOT NULL - DROP TABLE #concept_map_distinct; - -CREATE TABLE #concept_map_distinct -( - source_concept_id int, - domain_id varchar(20), - targetConceptCount int -); - - INSERT INTO #concept_map_distinct (source_concept_id, domain_id, targetConceptCount) - SELECT source_concept_id, domain_id, COUNT(*) - FROM #concept_map - GROUP BY source_concept_id, domain_id; - - -IF OBJECT_ID('@TARGET_CDMV5_SCHEMA.ETL_WARNINGS', 'U') IS NOT NULL - DROP TABLE @TARGET_CDMV5_SCHEMA.ETL_WARNINGS; - -CREATE TABLE @TARGET_CDMV5_SCHEMA.ETL_WARNINGS -( - WARNING_MESSAGE varchar(4000) -); - -/**** - -CDM_SOURCE - - ****/ - -INSERT INTO @TARGET_CDMV5_SCHEMA.cdm_source (cdm_source_name, cdm_version, vocabulary_version, cdm_release_date) -select '@TARGET_CDMV5', 'V5', v.vocabulary_version, getDate() -from @TARGET_CDMV5_SCHEMA.vocabulary v -where vocabulary_id = 'Vocabulary'; - -/**** - -LOCATION - - ****/ - -insert into @TARGET_CDMV5_SCHEMA.location -select location_id, address_1, address_2, city, state, zip, county, location_source_value -from @SOURCE_CDMV4_SCHEMA.LOCATION; - -/**** - -CARE_SITE - - ****/ - -insert into @TARGET_CDMV5_SCHEMA.care_site -select care_site_id, cast(null as varchar(255)) as care_site_name, place_of_service_concept_id, location_id, care_site_source_value, place_of_service_source_value -from @SOURCE_CDMV4_SCHEMA.CARE_SITE; - -/**** - -Provider - -****/ - -insert into @TARGET_CDMV5_SCHEMA.provider -select provider_id, cast(null as varchar(255)) as provider_name, NPI, DEA, specialty_concept_id, care_site_id, cast(null as integer) as year_of_birth, - cast(null as integer) as gender_concept_id, provider_source_value, specialty_source_value, 0 as specialty_source_concept_id, - cast(null as varchar(50)) as gender_source_value, cast(null as integer) as gender_source_concept_id -from @SOURCE_CDMV4_SCHEMA.provider -; - - - /**** - - PERSON - - ****/ - - INSERT into @TARGET_CDMV5_SCHEMA.person - SELECT - person_id, - coalesce(gender.target_concept_id, 0) as gender_concept_id, - year_of_birth, - month_of_birth, - day_of_birth, - CAST(null as varchar(50)) time_of_birth, - coalesce(race.target_concept_id, 0) as race_concept_id, - coalesce(ethnicity.target_concept_id, 0) as ethnicity_concept_id, - location_id, - provider_id, - care_site_id, - person_source_value, - gender_source_value, - CAST(null as integer) gender_source_concept_id, - CAST(null as integer) race_source_value, - CAST(null as integer) race_source_concept_id, - ethnicity_source_value, - CAST(null as integer) ethnicity_source_concept_id - FROM @SOURCE_CDMV4_SCHEMA.PERSON p - left JOIN #concept_map gender on LOWER(gender.DOMAIN_ID) IN ('gender') and p.gender_concept_id = gender.source_concept_id - left JOIN #concept_map race on LOWER(race.DOMAIN_ID) IN ('race') and p.race_concept_id = race.source_concept_id - LEFT JOIN #concept_map ethnicity on LOWER(ethnicity.DOMAIN_ID) IN ('ethnicity') and p.ETHNICITY_CONCEPT_ID = ethnicity.source_concept_id; - - - INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PERSON: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid GENDER_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM @SOURCE_CDMV4_SCHEMA.PERSON - WHERE GENDER_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM @TARGET_CDMV5_SCHEMA.CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('gender') - ) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PERSON: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid RACE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM @SOURCE_CDMV4_SCHEMA.PERSON - WHERE RACE_CONCEPT_ID IS NOT NULL - AND RACE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM @TARGET_CDMV5_SCHEMA.CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('race')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PERSON: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid ETHNICITY_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM @SOURCE_CDMV4_SCHEMA.PERSON - WHERE ETHNICITY_CONCEPT_ID IS NOT NULL - AND ETHNICITY_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM @TARGET_CDMV5_SCHEMA.CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('ethnicity')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - /**** - - OBSERVATION_PERIOD - - ****/ - - INSERT INTO @TARGET_CDMV5_SCHEMA.observation_period - SELECT observation_period_id, person_id, observation_period_start_date, observation_period_end_date, 44814722 as period_type_concept_id - FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION_PERIOD; - - /**** - - DEATH - - ****/ - - INSERT INTO @TARGET_CDMV5_SCHEMA.death - SELECT person_id, - death_date, - COALESCE(death_type_concept_id,0) AS death_type_concept_id, - cause_of_death_concept_id as cause_concept_id, - cause_of_death_source_value as cause_source_value, - CAST(null as integer) as cause_source_concept_id - FROM @SOURCE_CDMV4_SCHEMA.DEATH - LEFT JOIN #concept_map_distinct cm1 - ON DEATH.DEATH_TYPE_CONCEPT_ID = CM1.SOURCE_CONCEPT_ID - AND LOWER(DOMAIN_ID) IN ('death type'); - - - INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'DEATH: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid DEATH_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM @SOURCE_CDMV4_SCHEMA.DEATH - WHERE DEATH_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM @TARGET_CDMV5_SCHEMA.CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('death type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn ; - - - - /**** - - VISIT_OCCURRENCE - - ****/ - - INSERT INTO @TARGET_CDMV5_SCHEMA.visit_occurrence - SELECT visit_occurrence_id, person_id, - COALESCE(cm1.target_concept_id,0) as visit_concept_id, - visit_start_date, CAST(null as varchar(10)) visit_start_time, - visit_end_date, CAST(null as varchar(10)) visit_end_time, - 44818517 as visit_type_concept_id, - CAST(null as integer) provider_id, - care_site_id, place_of_service_source_value as visit_source_value, - CAST(null as integer) visit_source_concept_id - FROM @SOURCE_CDMV4_SCHEMA.VISIT_OCCURRENCE - LEFT JOIN #concept_map cm1 - ON VISIT_OCCURRENCE.PLACE_OF_SERVICE_CONCEPT_ID = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('visit'); - - INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'VISIT_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid VISIT_CONCEPT_ID (from the CDMv4 PLACE_OF_SERVICE_CONCEPT_ID field)' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM @SOURCE_CDMV4_SCHEMA.VISIT_OCCURRENCE - WHERE PLACE_OF_SERVICE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM @TARGET_CDMV5_SCHEMA.CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('visit')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - /**** - - PROCEDURE_OCCURRENCE - - ****/ - - -- *************************************************************************** - -- AGS: Modifying this section to insert this information into the temp - -- table #po_map but this may need to be revisited for - -- performance tuning on APS as a large temp table may cause processing - -- time issues. - -- *************************************************************************** - - IF OBJECT_ID('tempdb..#po_map', 'U') IS NOT NULL - DROP TABLE #po_map; - -CREATE TABLE #po_map -( - procedure_occurrence_id int, - person_id int, - procedure_concept_id int, - procedure_date date, - procedure_type_concept_id int, - modifier_concept_id int, - quantity int, - provider_id int, - visit_occurrence_id int, - procedure_source_value varchar(50), - procedure_source_concept_id int, - qualifier_source_value varchar(50), - origional_drug_id bigint -); - - --find valid procedures from procedure table -INSERT INTO #po_map -( - procedure_occurrence_id, - person_id, - procedure_concept_id, - procedure_date, - procedure_type_concept_id, - modifier_concept_id, - quantity, - provider_id, - visit_occurrence_id, - procedure_source_value, - procedure_source_concept_id, - qualifier_source_value, - origional_drug_id -) - SELECT - procedure_occurrence_id, - person_id, - COALESCE(cm1.target_concept_id,0) as procedure_concept_id, - procedure_date, - COALESCE(cm2.target_concept_id,0) as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id - FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - INNER JOIN #concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount = 1 - LEFT JOIN #concept_map cm2 - ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('procedure type') - LEFT JOIN #concept_map_distinct cmdis2 - ON cm2.source_concept_id = cmdis2.source_concept_id AND cm2.domain_id = cmdis2.domain_id AND cmdis2.targetConceptCount = 1 - -UNION ALL - - -- All procedures that did not map to a standard concept in V4 should also carry over to V5 - SELECT - procedure_occurrence_id, - person_id, - procedure_concept_id, - procedure_date, - procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id - FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE - WHERE procedure_concept_id = 0 - -UNION ALL - - -- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 - SELECT - procedure_occurrence_id, - person_id, - 0 as procedure_concept_id, - procedure_date, - COALESCE(cm2.target_concept_id,0) as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id - FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE - LEFT JOIN #concept_map cm1 - ON procedure_concept_id = cm1.source_concept_id - LEFT JOIN #concept_map cm2 - ON procedure_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('procedure type') - where procedure_concept_id <> 0 - and cm1.domain_id IS NULL - -UNION ALL - - select - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS procedure_occurrence_id, - person_id, - procedure_concept_id, - procedure_date, - procedure_type_concept_id, - modifier_concept_id, - quantity, - provider_id, - visit_occurrence_id, - procedure_source_value, - procedure_source_concept_id, - qualifier_source_value, - origional_drug_id - FROM - ( - --find valid procedures from procedure table that map to more than 1 - --target concept in V5 - SELECT - person_id, - COALESCE(cm1.target_concept_id,0) as procedure_concept_id, - procedure_date, - COALESCE(cm2.target_concept_id,0) as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id, - NULL as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - INNER JOIN #concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount > 1 - LEFT JOIN #concept_map cm2 - ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('procedure type') - - UNION ALL - - --find procedures that were previously classified as condition - SELECT - person_id, - cm1.target_concept_id as procedure_concept_id, - condition_start_date as procedure_date, - 0 as procedure_type_concept_id, - CAST(null as integer) modifier_concept_id, - CAST(null as integer) quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value as procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) origional_drug_id, - condition_occurrence_id as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - - UNION ALL - - --find procedures that were previously classified as drug - SELECT person_id, - cm1.target_concept_id as procedure_concept_id, - drug_exposure_start_date as procedure_date, - 0 as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) quantity, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value as procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - drug_exposure_id as origional_drug_id, - drug_exposure_id as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - - - --find procedures that were previously classified as observation - UNION ALL - SELECT person_id, - cm1.target_concept_id as procedure_concept_id, - observation_date as procedure_date, - 0 as procedure_type_concept_id, CAST(null as integer) modifier_concept_id, CAST(null as integer) quantity, - associated_provider_id as provider_id, visit_occurrence_id, observation_source_value as procedure_source_value, - CAST(null as integer) procedure_source_concept_id, CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id, - OBSERVATION_ID as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION - INNER JOIN #concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - - - ) OTHERS,(SELECT MAX(PROCEDURE_OCCURRENCE_ID) AS MAXROWID FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE) MAXROW -; - -INSERT INTO @TARGET_CDMV5_SCHEMA.procedure_occurrence - (procedure_occurrence_id - ,person_id - ,procedure_concept_id - ,procedure_date - ,procedure_type_concept_id - ,modifier_concept_id - ,quantity - ,provider_id - ,visit_occurrence_id - ,procedure_source_value - ,procedure_source_concept_id - ,qualifier_source_value) -SELECT - procedure_occurrence_id - ,person_id - ,procedure_concept_id - ,procedure_date - ,procedure_type_concept_id - ,modifier_concept_id - ,quantity - ,provider_id - ,visit_occurrence_id - ,procedure_source_value - ,procedure_source_concept_id - ,qualifier_source_value -FROM #po_map; - - --warnings of invalid records - - INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PROCEDURE_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid PROCOEDURE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE - WHERE PROCEDURE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM @TARGET_CDMV5_SCHEMA.CONCEPT - WHERE CONCEPT_ID = 0 - OR - STANDARD_CONCEPT = 'S' - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PROCEDURE_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid PROCOEDURE_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE - WHERE PROCEDURE_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM @TARGET_CDMV5_SCHEMA.CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('procedure type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - /**** - - DRUG_EXPOSURE - - ****/ - - --find valid drugs from drug_exposure table -IF OBJECT_ID('tempdb..#drgexp_map', 'U') IS NOT NULL - DROP TABLE #drgexp_map; - -CREATE TABLE #drgexp_map -( - drug_exposure_id int, - person_id int, - drug_concept_id int, - drug_exposure_start_date date, - drug_exposure_end_date date, - drug_type_concept_id int, - stop_reason varchar(20), - refills int, - quantity float, - days_supply int, - sig varchar(max), - route_concept_id int, - effective_drug_dose float, - dose_unit_concept_id int, - lot_number varchar(50), - provider_id int, - visit_occurrence_id int, - drug_source_value varchar(50), - drug_source_concept_id int, - route_source_value varchar(50), - dose_unit_source_value varchar(50), - origional_procedure_id int -); - -INSERT INTO #drgexp_map -( - drug_exposure_id, - person_id, - drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - route_concept_id, - effective_drug_dose, - dose_unit_concept_id, - lot_number, - provider_id, - visit_occurrence_id, - drug_source_value, - drug_source_concept_id, - route_source_value, - dose_unit_source_value, - origional_procedure_id -) - SELECT drug_exposure_id, - person_id, - COALESCE(cm1.target_concept_id,0) as drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - COALESCE(cm2.target_concept_id, 0) drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - CAST(null as varchar(50)) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - CAST(null as varchar(50)) route_source_value, - CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id - FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - INNER JOIN #concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount = 1 - LEFT JOIN #concept_map cm2 - ON drug_exposure.drug_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('drug type') - INNER JOIN #concept_map_distinct cmdis2 - ON cm2.source_concept_id = cmdis2.source_concept_id AND cm2.domain_id = cmdis2.domain_id AND cmdis2.targetConceptCount = 1 - WHERE drug_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 - -UNION ALL - - -- All drug exposures that did not map to a standard concept in V4 should also carry over to V5 - SELECT drug_exposure_id, - person_id, - drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - CAST(null as varchar(50)) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - CAST(null as varchar(50)) route_source_value, - CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id - FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE - WHERE drug_concept_id = 0 - -UNION ALL - - -- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 - SELECT drug_exposure_id, - person_id, - 0, - drug_exposure_start_date, - drug_exposure_end_date, - COALESCE(cm2.target_concept_id, 0) drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - CAST(null as varchar(50)) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - CAST(null as varchar(50)) route_source_value, - CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id - FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE - LEFT JOIN #concept_map cm1 - ON drug_concept_id = cm1.source_concept_id - LEFT JOIN #concept_map cm2 - ON drug_exposure.drug_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('drug type') - where drug_concept_id <> 0 - and cm1.domain_id IS NULL - -UNION ALL -select CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS drug_exposure_id, - person_id, drug_concept_id, drug_exposure_start_date, drug_exposure_end_date, - drug_type_concept_id, stop_reason, refills, quantity, days_supply, sig, route_concept_id, - effective_drug_dose, dose_unit_concept_id, lot_number, provider_id, visit_occurrence_id, drug_source_value, - drug_source_concept_id, route_source_value, dose_unit_source_value - , origional_procedure_id -FROM -( - --find valid drugs from drug_exposure table that map to > 1 target concept - SELECT - person_id, - COALESCE(cm1.target_concept_id,0) as drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - COALESCE(cm2.target_concept_id, 0) drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - CAST(null as varchar(50)) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - CAST(null as varchar(50)) route_source_value, - CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id, - NULL as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - INNER JOIN #concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount > 1 - LEFT JOIN #concept_map cm2 - ON drug_exposure.drug_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('drug type') - - UNION ALL - --find drugs that were previously classified as condition - select person_id, - cm1.target_concept_id as drug_concept_id, - condition_start_date as drug_exposure_start_date, null as drug_exposure_end_date, - 0 as drug_type_concept_id, null as stop_reason, null as refills, null as quantity, null as days_supply, null as sig, CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, CAST(null as integer) dose_unit_concept_id, CAST(null as varchar(50)) lot_number, - null as provider_id, visit_occurrence_id, condition_source_value as drug_source_value, - CAST(null as integer) drug_source_concept_id, CAST(null as varchar(50)) route_source_value, CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id, condition_occurrence_id as occurrence_id - FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - - --find drugs that were previously classified as procedure - UNION ALL - select person_id, - cm1.target_concept_id as drug_concept_id, - procedure_date as drug_exposure_start_date, null as drug_exposure_end_date, - 0 as drug_type_concept_id, null as stop_reason, null as refills, null as quantity, null as days_supply, null as sig, CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, CAST(null as integer) dose_unit_concept_id, CAST(null as varchar(50)) lot_number, - null as provider_id, visit_occurrence_id, procedure_source_value as drug_source_value, - CAST(null as integer) drug_source_concept_id, CAST(null as varchar(50)) route_source_value, CAST(null as varchar(50)) dose_unit_source_value, - procedure_occurrence_id as origional_procedure_id, procedure_occurrence_id as occurrence_id - FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - - --find drugs that were previously classified as observation - UNION ALL - select person_id, - cm1.target_concept_id as drug_concept_id, observation_date as drug_exposure_start_date, null as drug_exposure_end_date, - 0 as drug_type_concept_id, null as stop_reason, null as refills, null as quantity, null as days_supply, null as sig, CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, CAST(null as integer) dose_unit_concept_id, CAST(null as varchar(50)) lot_number, - null as provider_id, visit_occurrence_id, observation_source_value as drug_source_value, - CAST(null as integer) drug_source_concept_id, CAST(null as varchar(50)) route_source_value, CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id, observation_id as occurrence_id - FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION - INNER JOIN #concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') -) OTHERS,(SELECT MAX(DRUG_EXPOSURE_ID) AS MAXROWID FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE) MAXROW -; -INSERT INTO @TARGET_CDMV5_SCHEMA.drug_exposure - (drug_exposure_id - ,person_id - ,drug_concept_id - ,drug_exposure_start_date - ,drug_exposure_end_date - ,drug_type_concept_id - ,stop_reason - ,refills - ,quantity - ,days_supply - ,sig - ,route_concept_id - ,effective_drug_dose - ,dose_unit_concept_id - ,lot_number - ,provider_id - ,visit_occurrence_id - ,drug_source_value - ,drug_source_concept_id - ,route_source_value - ,dose_unit_source_value) -SELECT - drug_exposure_id - ,person_id - ,drug_concept_id - ,drug_exposure_start_date - ,drug_exposure_end_date - ,drug_type_concept_id - ,stop_reason - ,refills - ,quantity - ,days_supply - ,sig - ,route_concept_id - ,effective_drug_dose - ,dose_unit_concept_id - ,lot_number - ,provider_id - ,visit_occurrence_id - ,drug_source_value - ,drug_source_concept_id - ,route_source_value - ,dose_unit_source_value -FROM #drgexp_map; - - --warnings of invalid records - - INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'DRUG_EXPOSURE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid DRUG_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE - WHERE DRUG_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM @TARGET_CDMV5_SCHEMA.CONCEPT - WHERE CONCEPT_ID = 0 - OR - STANDARD_CONCEPT = 'S' - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'DRUG_EXPOSURE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid DRUG_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE - WHERE DRUG_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM @TARGET_CDMV5_SCHEMA.CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('drug type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - /**** - - CONDITION_OCCURRENCE - - ****/ - - --find valid conditions from condition_occurrence table - INSERT INTO @TARGET_CDMV5_SCHEMA.condition_occurrence - SELECT condition_occurrence_id, - person_id, - COALESCE(cm1.target_concept_id, 0) AS condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(cm2.target_concept_id,0) AS condition_type_concept_id, - stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - condition_source_value, CAST(null as integer) condition_source_concept_id - FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - INNER JOIN #concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount = 1 - LEFT JOIN #concept_map cm2 - ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('condition type') - WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 - -UNION ALL - - -- All conditions that did not map to a standard concept in V4 should also carry over to V5 - SELECT condition_occurrence_id, - person_id, - condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(condition_type_concept_id,0) AS condition_type_concept_id, - stop_reason, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value, - CAST(null as integer) condition_source_concept_id - FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE - WHERE condition_concept_id = 0 - -UNION ALL - - -- All conditions that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 - SELECT condition_occurrence_id, - person_id, - 0 AS condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(cm2.target_concept_id,0) AS condition_type_concept_id, - stop_reason, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value, - CAST(null as integer) condition_source_concept_id - FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE - LEFT JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - LEFT JOIN #concept_map cm2 - ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('condition type') - where condition_concept_id <> 0 - and cm1.domain_id IS NULL - -UNION ALL -select CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS drug_exposure_id, - person_id, condition_concept_id, condition_start_date, condition_end_date, - condition_type_concept_id, stop_reason, provider_id, visit_occurrence_id, - condition_source_value, condition_source_concept_id -FROM ( - - --find valid conditions from condition_occurrence table that map to > 1 target concept - SELECT - person_id, - COALESCE(cm1.target_concept_id, 0) AS condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(cm2.target_concept_id,0) AS condition_type_concept_id, - stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - condition_source_value, CAST(null as integer) condition_source_concept_id, - NULL as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - INNER JOIN #concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount > 1 - LEFT JOIN #concept_map cm2 - ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('condition type') - WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 - - UNION ALL - - --find conditions that were previously classified as procedure - select person_id, - cm1.target_concept_id as condition_concept_id, - procedure_date as condition_start_date, null as condition_end_date, - 0 as condition_type_concept_id, null as stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - procedure_source_value as condition_source_value, CAST(null as integer) condition_source_concept_id, - procedure_occurrence_id as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - - --find conditions that were previously classified as drug - UNION ALL - SELECT person_id, - cm1.target_concept_id as condition_concept_id, - drug_exposure_start_date as condition_start_date, null as condition_end_date, - 0 as condition_type_concept_id, null as stop_reason, prescribing_provider_id as provider_id, visit_occurrence_id, - drug_source_value as condition_source_value, CAST(null as integer) condition_source_concept_id, - drug_exposure_id as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - - --find conditions that were previously classified as observation - UNION ALL - SELECT person_id, - cm1.target_concept_id as condition_concept_id, - observation_date as condition_start_date, null as condition_end_date, - 0 as condition_type_concept_id, null as stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - observation_source_value as condition_source_value, CAST(null as integer) condition_source_concept_id, - observation_id as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION - INNER JOIN #concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') -) OTHERS,(SELECT MAX(condition_occurrence_id) AS MAXROWID FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE) MAXROW -; - - - --warnings of invalid records - - INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'CONDITION_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid CONDITION_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE - WHERE CONDITION_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM @TARGET_CDMV5_SCHEMA.CONCEPT - WHERE CONCEPT_ID = 0 - OR - STANDARD_CONCEPT = 'S' - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO @TARGET_CDMV5_SCHEMA.ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'CONDIITON_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid CONDITION_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE - WHERE CONDITION_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM @TARGET_CDMV5_SCHEMA.CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('condition type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - - - /**** - - DEVICE_EXPOSURE - - ****/ - -INSERT INTO @TARGET_CDMV5_SCHEMA.device_exposure -select row_number() over (order by OCCURRENCE_ID) AS device_exposure_id, - person_id, device_concept_id, device_exposure_start_date, device_exposure_end_date, device_type_concept_id, - unique_device_id, quantity, provider_id, visit_occurrence_id, device_source_value, device_source_concept_id -FROM -( - --find devices that were previously classified as procedures - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - PROCEDURE_DATE AS DEVICE_EXPOSURE_START_DATE, - CAST(NULL as date) AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, CAST(NULL as VARCHAR(50)) unique_device_id, - CAST(null as integer) quantity, ASSOCIATED_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, PROCEDURE_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - PROCEDURE_OCCURRENCE_ID as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') - - --find devices that were previously classified as drug exposure - UNION ALL - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - DRUG_EXPOSURE_START_DATE AS DEVICE_EXPOSURE_START_DATE, - CAST(NULL as DATE) AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, CAST(NULL as VARCHAR(50)) unique_device_id, - quantity, PRESCRIBING_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, DRUG_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - DRUG_EXPOSURE_ID as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') - - --find devices that were previously classified as conditions - UNION ALL - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - CONDITION_START_DATE AS DEVICE_EXPOSURE_START_DATE, - CAST(NULL as DATE) AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, CAST(NULL as VARCHAR(50)) unique_device_id, - CAST(NULL as integer) quantity, ASSOCIATED_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, CONDITION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - CONDITION_OCCURRENCE_ID as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') - - --find devices that were previously classified as observations - UNION ALL - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - OBSERVATION_DATE AS DEVICE_EXPOSURE_START_DATE, - CAST(NULL as DATE) AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, CAST(NULL as VARCHAR(50)) unique_device_id, - CAST(null as integer) quantity, ASSOCIATED_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, OBSERVATION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - OBSERVATION_ID as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION - INNER JOIN #concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') -) OTHERS -; - - - /**** - - MEASUREMENT - - ****/ - ---find valid measurements from observation table -INSERT INTO @TARGET_CDMV5_SCHEMA.measurement -SELECT row_number() over (order by occurrence_id) AS measurement_id, - person_id, measurement_concept_id, measurement_date, measurement_time, measurement_type_concept_id, operator_concept_id, value_as_number, value_as_concept_id, unit_concept_id, range_low, range_high, - provider_id, visit_occurrence_id, measurement_source_value, measurement_source_concept_id, unit_source_value, value_source_value -from -( - --find mesaurements that were previously classified as observations - select person_id, - cm1.target_concept_id AS measurement_concept_id, - OBSERVATION_DATE AS measurement_date, - CAST(OBSERVATION_TIME as varchar(50)) AS measurement_time, - 0 AS measurement_type_concept_id, - CAST(null as integer) operator_concept_id, - value_as_number, - value_as_concept_id, - COALESCE(cm2.target_concept_id,0) AS unit_concept_id, - range_low, - range_high, - ASSOCIATED_PROVIDER_ID AS provider_id, - visit_occurrence_id, - OBSERVATION_SOURCE_VALUE AS measurement_source_value, - CAST(null as integer) measurement_source_concept_id, - unit_source_value AS unit_source_value, - cast(null as varchar(50)) as value_source_value, - observation_id as occurrence_id - FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION - INNER JOIN #concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - LEFT JOIN #concept_map cm2 - ON observation.unit_concept_id = cm2.source_concept_id - AND LOWER(cm1.domain_id) IN ('unit') - - UNION ALL - - SELECT person_id, - cm1.target_concept_id as measurement_concept_id, - procedure_date as measurement_date, - CAST(NULL as varchar(50)) as measurement_time, - 0 as measurement_type_concept_id, - CAST(null as integer) as operator_concept_id, - CAST(null as integer) as value_as_number, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as range_low, - CAST(null as integer) as range_high, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value as measurement_source_value, - CAST(null as integer) as measurement_source_concept_id, - CAST(null as varchar(50)) as unit_source_value, - CAST(null as varchar(50)) as value_source_value, - procedure_occurrence_id as occurrence_id - FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - - UNION ALL - - SELECT person_id, - cm1.target_concept_id as measurement_concept_id, - condition_start_date as measurement_date, - CAST(NULL as varchar(50)) as measurement_time, - 0 as measurement_type_concept_id, - CAST(null as integer) as operator_concept_id, - CAST(null as integer) as value_as_number, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as range_low, - CAST(null as integer) as range_high, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value as measurement_source_value, - CAST(null as integer) as measurement_source_concept_id, - CAST(null as varchar(50)) as unit_source_value, - CAST(null as varchar(50)) as value_source_value, - condition_occurrence_id as occurrence_id - FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - - UNION ALL - - SELECT person_id, - cm1.target_concept_id as measurement_concept_id, - drug_exposure_start_date as measurement_date, - CAST(NULL as varchar(50)) as measurement_time, - 0 as measurement_type_concept_id, - CAST(null as integer) as operator_concept_id, - CAST(null as integer) as value_as_number, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as range_low, - CAST(null as integer) as range_high, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value as measurement_source_value, - CAST(null as integer) as measurement_source_concept_id, - CAST(null as varchar(50)) as unit_source_value, - CAST(null as varchar(50)) as value_source_value, - drug_exposure_id as occurrence_id - FROM @SOURCE_CDMV4_SCHEMA.drug_exposure - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - - -) OTHERS -; - - - - /**** - - OBSERVATION - - ****/ - - - --find valid observation from observation table - INSERT INTO @TARGET_CDMV5_SCHEMA.observation - SELECT - observation_id, - person_id, - observation_concept_id, - observation_date, - CAST(observation_time as varchar(50)) as observation_time, - observation_type_concept_id, - value_as_number, - value_as_string, - value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - unit_concept_id, - associated_provider_id as provider_id, - visit_occurrence_id, - observation_source_value, - CAST(null as integer) observation_source_concept_id, - unit_source_value, - cast(null as varchar(50)) qualifier_source_value - FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION - WHERE observation_concept_id NOT IN (SELECT source_concept_id FROM #concept_map_distinct WHERE LOWER(domain_id) IN ('condition','drug','procedure','device','measurement')) - - - --find observations that were previously classified as procedure -UNION ALL -select - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS observation_id, - person_id, - observation_concept_id, - observation_date, - observation_time, - observation_type_concept_id, - value_as_number, - 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 -( - select person_id, - cm1.target_concept_id as observation_concept_id, - procedure_date as observation_date, - CAST(null as varchar(50)) as observation_time, - 0 as observation_type_concept_id, - CAST(null as float) as value_as_number, - null as value_as_string, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - CAST(null as integer) as unit_concept_id, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value as observation_source_value, - CAST(null as integer) observation_source_concept_id, - null as unit_source_value, - cast(null as varchar(50)) qualifier_source_value, - procedure_occurrence_id as occurrence_id - FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('observation') - - --find observations that were previously classified as condition - UNION ALL - SELECT person_id, - cm1.target_concept_id as observation_concept_id, - condition_start_date as observation_date, - CAST(null as varchar(50)) as observation_time, - 0 as observation_type_concept_id, - CAST(null as float) as value_as_number, - null as value_as_string, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - CAST(null as integer) as unit_concept_id, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value as observation_source_value, - CAST(null as integer) observation_source_concept_id, - null as unit_source_value, - cast(null as varchar(50)) qualifier_source_value, - condition_occurrence_id as occurrence_id - FROM @SOURCE_CDMV4_SCHEMA.CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('observation') - - --find observations that were previously classified as drug exposure - UNION ALL - SELECT person_id, - cm1.target_concept_id as observation_concept_id, - drug_exposure_start_date as observation_date, - CAST(null as varchar(10)) as observation_time, - 0 as observation_type_concept_id, - CAST(null as float) as value_as_number, - null as value_as_string, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as provider_id, - visit_occurrence_id, - drug_source_value as observation_source_value, - CAST(null as integer) observation_source_concept_id, - null as unit_source_value, - cast(null as varchar(50)) qualifier_source_value, - drug_exposure_id as occurrence_id - FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('observation') - ) OTHERS,(SELECT MAX(OBSERVATION_ID) AS MAXROWID FROM @SOURCE_CDMV4_SCHEMA.OBSERVATION) MAXROW - ; - - - - /**** - - PAYER_PLAN_PERIOD - - ****/ - -INSERT INTO @TARGET_CDMV5_SCHEMA.payer_plan_period -SELECT payer_plan_period_id, person_id, payer_plan_period_start_date, payer_plan_period_end_date, - payer_source_value, plan_source_value, family_source_value -FROM @SOURCE_CDMV4_SCHEMA.PAYER_PLAN_PERIOD; - - /**** - - DRUG_COST - - note : if there were invalid drug concepts in DRUG_EXPOSURE, those records may not enter CDMv5 but costs will persist - - ****/ - -INSERT INTO @TARGET_CDMV5_SCHEMA.drug_cost -SELECT drug_cost_id, dc.drug_exposure_id, cast(null as integer) currency_concept_id, paid_copay, paid_coinsurance, paid_toward_deductible, paid_by_payer, - paid_by_coordination_benefits, total_out_of_pocket, total_paid, ingredient_cost, dispensing_fee, - average_wholesale_price, payer_plan_period_id -FROM @SOURCE_CDMV4_SCHEMA.DRUG_COST dc -; - --- insert procedure costs for procedures that were inserted into the drug_exposure table -INSERT INTO @TARGET_CDMV5_SCHEMA.drug_cost -select - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS drug_cost_id, - drug_exposure_id, - cast(null as integer) currency_concept_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - ingredient_cost, - dispensing_fee, - average_wholesale_price, - payer_plan_period_id -FROM ( - SELECT - drug_exposure_id, - po.person_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - CAST(null as float) as ingredient_cost, - CAST(null as float) as dispensing_fee, - CAST(null as float) as average_wholesale_price, - payer_plan_period_id, - procedure_cost_id as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_OCCURRENCE po - join @SOURCE_CDMV4_SCHEMA.PROCEDURE_COST pc on po.procedure_occurrence_id = pc.procedure_occurrence_id - --JOIN dbo.drug_exposure de on de.person_id = po.person_id and pc.procedure_occurrence_id = de.origional_procedure_id - JOIN #drgexp_map de on de.person_id = po.person_id and pc.procedure_occurrence_id = de.origional_procedure_id -) OTHERS ,(SELECT MAX(drug_cost_id) AS MAXROWID FROM @SOURCE_CDMV4_SCHEMA.DRUG_COST) MAXROW -; - - /**** - - PROCEDURE_COST - - note : if there were invalid procedure concepts in PROCEDURE_OCCURRENCE, those records may not enter CDMv5 but costs will persist - - - ****/ - -INSERT INTO @TARGET_CDMV5_SCHEMA.procedure_cost -SELECT procedure_cost_id, procedure_occurrence_id, cast(null as integer) currency_concept_id, paid_copay, paid_coinsurance, paid_toward_deductible, - paid_by_payer, paid_by_coordination_benefits, total_out_of_pocket, total_paid, - payer_plan_period_id, revenue_code_concept_id, revenue_code_source_value -FROM @SOURCE_CDMV4_SCHEMA.PROCEDURE_COST; - - --- insert drug costs for drugs that were inserted into the procedure_occurrence table -INSERT INTO @TARGET_CDMV5_SCHEMA.procedure_cost -SELECT - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS procedure_cost_id, - procedure_occurrence_id, - cast(null as integer) - currency_concept_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - payer_plan_period_id, - revenue_code_concept_id, - revenue_code_source_value - FROM ( - SELECT - po.procedure_occurrence_id, - po.person_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - CAST(null as float) as ingredient_cost, - CAST(null as float) as dispensing_fee, - CAST(null as float) as average_wholesale_price, - payer_plan_period_id, - CAST(null as integer) as revenue_code_concept_id, - CAST(null as integer) as revenue_code_source_value, - drug_cost_id as OCCURRENCE_ID - FROM @SOURCE_CDMV4_SCHEMA.DRUG_EXPOSURE de - join @SOURCE_CDMV4_SCHEMA.DRUG_COST dc on de.drug_exposure_id = dc.drug_exposure_id - --JOIN dbo.procedure_occurrence po on de.person_id = po.person_id and de.drug_exposure_id = po.origional_drug_id - JOIN #po_map po on de.person_id = po.person_id and de.drug_exposure_id = po.origional_drug_id - ) OTHERS,(SELECT MAX(drug_cost_id) AS MAXROWID FROM @SOURCE_CDMV4_SCHEMA.DRUG_COST) MAXROW -; - -/**** - -DRUG ERA -Note: Eras derived from DRUG_EXPOSURE table, using 30d gap - - ****/ - --- drop table dbo.drug_era -with cteDrugTarget (DRUG_EXPOSURE_ID, PERSON_ID, DRUG_CONCEPT_ID, DRUG_TYPE_CONCEPT_ID, DRUG_EXPOSURE_START_DATE, DRUG_EXPOSURE_END_DATE, INGREDIENT_CONCEPT_ID) as -( - -- 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 - FROM @TARGET_CDMV5_SCHEMA.DRUG_EXPOSURE d - join @TARGET_CDMV5_SCHEMA.CONCEPT_ANCESTOR ca on ca.DESCENDANT_CONCEPT_ID = d.DRUG_CONCEPT_ID - 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' -), -cteEndDates (PERSON_ID, INGREDIENT_CONCEPT_ID, END_DATE) as -- the magic -( - 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 - 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 -), -cteDrugExposureEnds (PERSON_ID, DRUG_CONCEPT_ID, DRUG_TYPE_CONCEPT_ID, DRUG_EXPOSURE_START_DATE, DRUG_ERA_END_DATE) 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 -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, drug_concept_id, min(DRUG_EXPOSURE_START_DATE) as drug_era_start_date, drug_era_end_date, COUNT(*) as DRUG_EXPOSURE_COUNT, 30 as gap_days -from cteDrugExposureEnds -GROUP BY person_id, drug_concept_id, drug_type_concept_id, DRUG_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; - -with cteConditionTarget (PERSON_ID, CONDITION_CONCEPT_ID, CONDITION_START_DATE, CONDITION_END_DATE) as -( - -- 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 - FROM @TARGET_CDMV5_SCHEMA.CONDITION_OCCURRENCE co -), -cteEndDates (PERSON_ID, CONDITION_CONCEPT_ID, END_DATE) as -- the magic -( - 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 - 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 -), -cteConditionEnds (PERSON_ID, CONDITION_CONCEPT_ID, CONDITION_START_DATE, ERA_END_DATE) as -( -select - c.PERSON_ID, - c.CONDITION_CONCEPT_ID, - c.CONDITION_START_DATE, - MIN(e.END_DATE) as ERA_END_DATE -FROM cteConditionTarget c -JOIN cteEndDates 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 -) -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 -INTO #condition_era_phase_1 -from cteConditionEnds -GROUP BY person_id, CONDITION_CONCEPT_ID, ERA_END_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 - condition_era_id, - PERSON_ID, - CONDITION_CONCEPT_ID, - CONDITION_ERA_START_DATE, - CONDITION_ERA_END_DATE, - CONDITIOn_OCCURRENCE_COUNT -FROM #condition_era_phase_1 - - diff --git a/Version4 To Version5 Conversion/Oracle/OMOP CDMv4 to CDMv5 - Oracle.sql b/Version4 To Version5 Conversion/Oracle/OMOP CDMv4 to CDMv5 - Oracle.sql index b485f41..5d3a13c 100644 --- a/Version4 To Version5 Conversion/Oracle/OMOP CDMv4 to CDMv5 - Oracle.sql +++ b/Version4 To Version5 Conversion/Oracle/OMOP CDMv4 to CDMv5 - Oracle.sql @@ -14,18 +14,16 @@ # See the License for the specific language governing permissions and # limitations under the License. ********************************************************************************/ - /******************************************************************************* PURPOSE: Use this script to convert your OMOP V4 common data model to CDM V5. -last revised: 09 July 2015 -author: Patrick Ryan, Chris Knoll -editor: Anthony Sena +last revised: 04 August 2015 +authors: Patrick Ryan, Chris Knoll, Anthony Sena !!!!!!!!!!!!!!!!!!!!! PLEASE READ THESE INSTRUCTIONS !!!!!!!!!!!!!!!!!!!!!!!!!!! -This script was authored using TemplateSQL which will require you to run this +This script was authored using OHDSI-SQL which will require you to run this script through SqlRender to creat a version that is compatible with your target RDBMS. We have pre-generated these scripts using SQL Render and have placed them in folders for each RDBMS. Depending on which script you are viewing, your @@ -35,19 +33,22 @@ General Assumptions ------------------- This script assumes that your V4 and V5 database are located on the same -RDBMS server. +RDBMS server. It also assumes that the V4 and V5 databases were created +using the standard data definition scripts for these databases. If you +altered your V4 database in any way, this script will likely require +some mo Getting Started --------------- Before you can use this script, there are some prerequisites: - 1. Create a target CDMv5 database on your server using the appropriate script - from https://github.com/OHDSI/CommonDataModel + 1. Create a target CDMv5 database on your database server using the + appropriate script from https://github.com/OHDSI/CommonDataModel 2. Load VocabV5 into the target database/schema that will contain CDMv5 using Athena: http://ohdsi.org/web/ATHENA -TemplateSQL File Instructions +OHDSI-SQL File Instructions ----------------------------- 1. Set parameter name of schema that contains CDMv4 instance @@ -75,13 +76,12 @@ TemplateSQL File Instructions 2. Run the resulting script on your target RDBDMS. *********************************************************************************/ - /* SCRIPT PARAMETERS */ - -- The CDMv4 database name - -- The CDMv4 database plus schema - -- The target CDMv5 database name - -- the target CDMv5 database plus schema - + -- The CDMv4 database name + -- The CDMv4 database plus schema + -- The target CDMv5 database name + -- the target CDMv5 database plus schema + ALTER SESSION SET current_schema = [TARGET_CDMV5]; /* @@ -109,8 +109,8 @@ ALTER SESSION SET current_schema = [TARGET_CDMV5]; * Also, as of the date which this script was authored, no source_concept_ids map to multiple domains */ BEGIN - EXECUTE IMMEDIATE 'TRUNCATE TABLE w3m16jd0concept_map'; - EXECUTE IMMEDIATE 'DROP TABLE w3m16jd0concept_map'; + EXECUTE IMMEDIATE 'TRUNCATE TABLE q7a3ac0oconcept_map'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0oconcept_map'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN @@ -118,79 +118,84 @@ EXCEPTION END IF; END; -CREATE GLOBAL TEMPORARY TABLE w3m16jd0concept_map - ( - source_concept_id int, - target_concept_id int, - domain_id varchar(20) -) ON COMMIT PRESERVE ROWS; +/ +CREATE GLOBAL TEMPORARY TABLE q7a3ac0oconcept_map + ON COMMIT PRESERVE ROWS +AS +SELECT + concept_id AS source_concept_id + ,concept_id AS target_concept_id + ,domain_id AS domain_id + +FROM + [TARGET_CDMV5].[SCHEMA].concept + WHERE 1 = 0; + +/ + +INSERT INTO q7a3ac0oconcept_map --standard concepts -INSERT INTO w3m16jd0concept_map (source_concept_id, target_concept_id, domain_id) -SELECT concept_id as source_concept_id, - concept_id as target_concept_id, - domain_id +SELECT concept_id AS source_concept_id + ,concept_id AS target_concept_id + ,domain_id FROM [TARGET_CDMV5].[SCHEMA].concept WHERE standard_concept = 'S' -and invalid_reason is null + AND invalid_reason IS NULL -union +UNION --concepts with 'map to' standard -SELECT distinct c1.concept_id as source_concept_id, - c2.concept_id as target_concept_id, - c2.domain_id - FROM -( -select concept_id -from [TARGET_CDMV5].[SCHEMA].concept -where ((standard_concept <> 'S' or standard_concept is null) -or invalid_reason is not null -) -) c1 -inner join -[TARGET_CDMV5].[SCHEMA].concept_relationship cr1 -on c1.concept_id = cr1.concept_id_1 -inner join -[TARGET_CDMV5].[SCHEMA].concept c2 -on cr1.concept_id_2 = c2.concept_id +SELECT DISTINCT c1.concept_id AS source_concept_id + ,c2.concept_id AS target_concept_id + ,c2.domain_id + FROM ( + SELECT concept_id + FROM [TARGET_CDMV5].[SCHEMA].concept + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL + ) + OR invalid_reason IS NOT NULL + ) + ) c1 +INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 +INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id WHERE c2.standard_concept = 'S' -and c2.invalid_reason is null -and cr1.relationship_id in ('Maps to') -and cr1.invalid_reason is null + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ('Maps to') + AND cr1.invalid_reason IS NULL - -union +UNION --concepts without 'map to' standard with another non 'is a' relation to standard -SELECT distinct c1.concept_id as source_concept_id, - c2.concept_id as target_concept_id, - c2.domain_id - FROM -( +SELECT DISTINCT c1.concept_id AS source_concept_id + ,c2.concept_id AS target_concept_id + ,c2.domain_id + FROM ( SELECT A.concept_id FROM [TARGET_CDMV5].[SCHEMA].concept A - LEFT JOIN - ( - SELECT DISTINCT c1.concept_id - FROM ( - SELECT concept_id - FROM [TARGET_CDMV5].[SCHEMA].concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL + LEFT JOIN ( + SELECT DISTINCT c1.concept_id + FROM ( + SELECT concept_id + FROM [TARGET_CDMV5].[SCHEMA].concept + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL ) - ) c1 - INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 - INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id - WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ('Maps to') - AND cr1.invalid_reason IS NULL - ) B ON A.concept_id = B.concept_id + OR invalid_reason IS NOT NULL + ) + ) c1 + INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 + INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id + WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ('Maps to') + AND cr1.invalid_reason IS NULL + ) B ON A.concept_id = B.concept_id WHERE ( ( A.standard_concept <> 'S' @@ -199,25 +204,25 @@ SELECT distinct c1.concept_id as source_concept_id, OR A.invalid_reason IS NOT NULL ) AND B.concept_id IS NULL -) c1 -inner join [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 on c1.concept_id = cr1.concept_id_1 -inner join [TARGET_CDMV5].[SCHEMA].concept c2 on cr1.concept_id_2 = c2.concept_id + ) c1 +INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 +INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id WHERE c2.standard_concept = 'S' - and c2.invalid_reason is null - and cr1.relationship_id in ( - 'RxNorm replaced by', - 'SNOMED replaced by', - 'UCUM replaced by', - 'Concept replaced by', - 'ICD9P replaced by', - 'LOINC replaced by', - 'Concept same_as to', - 'Concept was_a to', - 'Concept alt_to to' -) -and cr1.invalid_reason is null + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ( + 'RxNorm replaced by' + ,'SNOMED replaced by' + ,'UCUM replaced by' + ,'Concept replaced by' + ,'ICD9P replaced by' + ,'LOINC replaced by' + ,'Concept same_as to' + ,'Concept was_a to' + ,'Concept alt_to to' + ) + AND cr1.invalid_reason IS NULL -union +UNION --concepts without 'map to' standard with 'is a' relation to standard SELECT DISTINCT c1.concept_id AS source_concept_id @@ -226,38 +231,37 @@ SELECT DISTINCT c1.concept_id AS source_concept_id FROM ( SELECT A.concept_id FROM [TARGET_CDMV5].[SCHEMA].concept A - LEFT JOIN - ( - SELECT DISTINCT c1.concept_id - FROM ( - SELECT concept_id - FROM [TARGET_CDMV5].[SCHEMA].concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL + LEFT JOIN ( + SELECT DISTINCT c1.concept_id + FROM ( + SELECT concept_id + FROM [TARGET_CDMV5].[SCHEMA].concept + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL ) - ) c1 - INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 - INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id - WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ( - 'Maps to' - ,'RxNorm replaced by' - ,'SNOMED replaced by' - ,'UCUM replaced by' - ,'Concept replaced by' - ,'ICD9P replaced by' - ,'LOINC replaced by' - ,'Concept same_as to' - ,'Concept was_a to' - ,'Concept alt_to to' + OR invalid_reason IS NOT NULL ) - AND cr1.invalid_reason IS NULL - ) B ON A.concept_id = B.concept_id + ) c1 + INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 + INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id + WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ( + 'Maps to' + ,'RxNorm replaced by' + ,'SNOMED replaced by' + ,'UCUM replaced by' + ,'Concept replaced by' + ,'ICD9P replaced by' + ,'LOINC replaced by' + ,'Concept same_as to' + ,'Concept was_a to' + ,'Concept alt_to to' + ) + AND cr1.invalid_reason IS NULL + ) B ON A.concept_id = B.concept_id WHERE ( ( standard_concept <> 'S' @@ -274,45 +278,9 @@ INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_i AND cr1.relationship_id IN ('Is a') AND cr1.invalid_reason IS NULL; --- Update the source_concept_map_occurrence column --- to contain a count to indicate the number of target_concept_ids --- map to that source_concept_id. This will be used elsewhere in --- the script to ensure that we generate new primary keys --- for the target tables when applicable -/* - UPDATE #concept_map - SET #concept_map.source_concept_map_occurrence = A.targetConceptCount - FROM - #concept_map, - ( - select source_concept_id, domain_id, count(*) as "targetConceptCount" - from #concept_map - group by source_concept_id, domain_id - ) AS A -WHERE #concept_map.source_concept_id = A.source_concept_id AND #concept_map.domain_id = A.domain_id; - -UPDATE #concept_map -SET source_concept_map_occurrence = "targetConceptCount" -FROM - ( - select source_concept_id, domain_id, count(*) as "targetConceptCount" - from #concept_map - group by source_concept_id, domain_id - ) A -WHERE #concept_map.source_concept_id = A.source_concept_id AND #concept_map.domain_id = A.domain_id; - -UPDATE #concept_map -SET source_concept_map_occurrence = ( - select count(*) as "targetConceptCount" - from #concept_map A - WHERE A.source_concept_id = #concept_map.source_concept_id AND A.domain_id = #concept_map.domain_id - group by source_concept_id, domain_id - ) -*/ - BEGIN - EXECUTE IMMEDIATE 'TRUNCATE TABLE w3m16jd0concept_map_distinct'; - EXECUTE IMMEDIATE 'DROP TABLE w3m16jd0concept_map_distinct'; + EXECUTE IMMEDIATE 'TRUNCATE TABLE q7a3ac0oconcept_map_distinct'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0oconcept_map_distinct'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN @@ -320,19 +288,32 @@ EXCEPTION END IF; END; -CREATE GLOBAL TEMPORARY TABLE w3m16jd0concept_map_distinct - ( - source_concept_id int, - domain_id varchar(20), - targetConceptCount int -) ON COMMIT PRESERVE ROWS; +/ - INSERT INTO w3m16jd0concept_map_distinct (source_concept_id, domain_id, targetConceptCount) - SELECT source_concept_id, domain_id, COUNT(*) - FROM w3m16jd0concept_map - GROUP BY source_concept_id, domain_id; +CREATE GLOBAL TEMPORARY TABLE q7a3ac0oconcept_map_distinct + ON COMMIT PRESERVE ROWS +AS +SELECT + source_concept_id + ,domain_id + ,COUNT(*) AS targetConceptCount + +FROM + q7a3ac0oconcept_map + WHERE 1 = 0 +GROUP BY source_concept_id + ,domain_id; + +/ + +INSERT INTO q7a3ac0oconcept_map_distinct +SELECT source_concept_id + ,domain_id + ,COUNT(*) +FROM q7a3ac0oconcept_map +GROUP BY source_concept_id + ,domain_id; - BEGIN EXECUTE IMMEDIATE 'TRUNCATE TABLE [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS'; EXECUTE IMMEDIATE 'DROP TABLE [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS'; @@ -343,19 +324,26 @@ EXCEPTION END IF; END; -CREATE TABLE [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS -( - WARNING_MESSAGE varchar(4000) -); - +/ + +CREATE TABLE [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE VARCHAR(4000)); +/ + /**** CDM_SOURCE ****/ - -INSERT INTO [TARGET_CDMV5].[SCHEMA].cdm_source (cdm_source_name, cdm_version, vocabulary_version, cdm_release_date) -SELECT '[TARGET_CDMV5]', 'V5', v.vocabulary_version, SYSDATE +INSERT INTO [TARGET_CDMV5].[SCHEMA].cdm_source ( + cdm_source_name + ,cdm_version + ,vocabulary_version + ,cdm_release_date + ) +SELECT '[TARGET_CDMV5]' + ,'V5' + ,v.vocabulary_version + ,SYSDATE FROM [TARGET_CDMV5].[SCHEMA].vocabulary v WHERE vocabulary_id = 'Vocabulary'; @@ -364,228 +352,230 @@ SELECT '[TARGET_CDMV5]', 'V5', v.vocabulary_version, SYSDATE LOCATION ****/ - -insert into [TARGET_CDMV5].[SCHEMA].location -select location_id, address_1, address_2, city, state, zip, county, location_source_value -from [SOURCE_CDMV4].[SCHEMA].LOCATION; +INSERT INTO [TARGET_CDMV5].[SCHEMA].location +SELECT location_id + ,address_1 + ,address_2 + ,city + ,STATE + ,zip + ,county + ,location_source_value +FROM [SOURCE_CDMV4].[SCHEMA].LOCATION; /**** CARE_SITE ****/ - -insert into [TARGET_CDMV5].[SCHEMA].care_site -select care_site_id, TO_CHAR(null ) as care_site_name, place_of_service_concept_id, location_id, care_site_source_value, place_of_service_source_value -from [SOURCE_CDMV4].[SCHEMA].CARE_SITE; +INSERT INTO [TARGET_CDMV5].[SCHEMA].care_site +SELECT care_site_id + ,TO_CHAR(NULL ) AS care_site_name + ,place_of_service_concept_id + ,location_id + ,care_site_source_value + ,place_of_service_source_value +FROM [SOURCE_CDMV4].[SCHEMA].CARE_SITE; /**** Provider ****/ +INSERT INTO [TARGET_CDMV5].[SCHEMA].provider +SELECT provider_id + ,TO_CHAR(NULL ) AS provider_name + ,NPI + ,DEA + ,specialty_concept_id + ,care_site_id + ,cast(NULL AS INT) AS year_of_birth + ,cast(NULL AS INT) AS gender_concept_id + ,provider_source_value + ,specialty_source_value + ,0 AS specialty_source_concept_id + ,TO_CHAR(NULL ) AS gender_source_value + ,cast(NULL AS INT) AS gender_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].provider; -insert into [TARGET_CDMV5].[SCHEMA].provider -select provider_id, TO_CHAR(null ) as provider_name, NPI, DEA, specialty_concept_id, care_site_id, cast(null as integer) as year_of_birth, - cast(null as integer) as gender_concept_id, provider_source_value, specialty_source_value, 0 as specialty_source_concept_id, - TO_CHAR(null ) as gender_source_value, cast(null as integer) as gender_source_concept_id -from [SOURCE_CDMV4].[SCHEMA].provider -; - - - /**** +/**** PERSON ****/ - - INSERT into [TARGET_CDMV5].[SCHEMA].person - SELECT - person_id, - coalesce(gender.target_concept_id, 0) as gender_concept_id, - year_of_birth, - month_of_birth, - day_of_birth, - TO_CHAR(null ) time_of_birth, - coalesce(race.target_concept_id, 0) as race_concept_id, - coalesce(ethnicity.target_concept_id, 0) as ethnicity_concept_id, - location_id, - provider_id, - care_site_id, - person_source_value, - gender_source_value, - CAST(null as integer) gender_source_concept_id, - CAST(null as integer) race_source_value, - CAST(null as integer) race_source_concept_id, - ethnicity_source_value, - CAST(null as integer) ethnicity_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].PERSON p - left JOIN w3m16jd0concept_map gender on LOWER(gender.DOMAIN_ID) IN ('gender') and p.gender_concept_id = gender.source_concept_id - left JOIN w3m16jd0concept_map race on LOWER(race.DOMAIN_ID) IN ('race') and p.race_concept_id = race.source_concept_id - LEFT JOIN w3m16jd0concept_map ethnicity on LOWER(ethnicity.DOMAIN_ID) IN ('ethnicity') and p.ETHNICITY_CONCEPT_ID = ethnicity.source_concept_id; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PERSON: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid GENDER_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PERSON - WHERE GENDER_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('gender') - ) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PERSON: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid RACE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PERSON - WHERE RACE_CONCEPT_ID IS NOT NULL - AND RACE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('race')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PERSON: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid ETHNICITY_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PERSON - WHERE ETHNICITY_CONCEPT_ID IS NOT NULL - AND ETHNICITY_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('ethnicity')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - /**** +INSERT INTO [TARGET_CDMV5].[SCHEMA].person +SELECT person_id + ,coalesce(gender.target_concept_id, 0) AS gender_concept_id + ,year_of_birth + ,month_of_birth + ,day_of_birth + ,TO_CHAR(NULL ) time_of_birth + ,coalesce(race.target_concept_id, 0) AS race_concept_id + ,coalesce(ethnicity.target_concept_id, 0) AS ethnicity_concept_id + ,location_id + ,provider_id + ,care_site_id + ,person_source_value + ,gender_source_value + ,CAST(NULL AS INT) gender_source_concept_id + ,CAST(NULL AS INT) race_source_value + ,CAST(NULL AS INT) race_source_concept_id + ,ethnicity_source_value + ,CAST(NULL AS INT) ethnicity_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].PERSON p +LEFT JOIN q7a3ac0oconcept_map gender ON LOWER(gender.DOMAIN_ID) IN ('gender') + AND p.gender_concept_id = gender.source_concept_id +LEFT JOIN q7a3ac0oconcept_map race ON LOWER(race.DOMAIN_ID) IN ('race') + AND p.race_concept_id = race.source_concept_id +LEFT JOIN q7a3ac0oconcept_map ethnicity ON LOWER(ethnicity.DOMAIN_ID) IN ('ethnicity') + AND p.ETHNICITY_CONCEPT_ID = ethnicity.source_concept_id; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PERSON: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid GENDER_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PERSON + WHERE GENDER_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('gender') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PERSON: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid RACE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PERSON + WHERE RACE_CONCEPT_ID IS NOT NULL + AND RACE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('race') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PERSON: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid ETHNICITY_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PERSON + WHERE ETHNICITY_CONCEPT_ID IS NOT NULL + AND ETHNICITY_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('ethnicity') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** OBSERVATION_PERIOD ****/ +INSERT INTO [TARGET_CDMV5].[SCHEMA].observation_period +SELECT observation_period_id + ,person_id + ,observation_period_start_date + ,observation_period_end_date + ,44814722 AS period_type_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION_PERIOD; - INSERT INTO [TARGET_CDMV5].[SCHEMA].observation_period - SELECT observation_period_id, person_id, observation_period_start_date, observation_period_end_date, 44814722 as period_type_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION_PERIOD; - - /**** +/**** DEATH ****/ - - INSERT INTO [TARGET_CDMV5].[SCHEMA].death - SELECT person_id, - death_date, - COALESCE(death_type_concept_id,0) AS death_type_concept_id, - cause_of_death_concept_id as cause_concept_id, - cause_of_death_source_value as cause_source_value, - CAST(null as integer) as cause_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].DEATH - LEFT JOIN w3m16jd0concept_map_distinct cm1 - ON DEATH.DEATH_TYPE_CONCEPT_ID = CM1.SOURCE_CONCEPT_ID - AND LOWER(DOMAIN_ID) IN ('death type'); - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'DEATH: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid DEATH_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].DEATH - WHERE DEATH_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('death type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn ; - - - - /**** +INSERT INTO [TARGET_CDMV5].[SCHEMA].death +SELECT person_id + ,death_date + ,COALESCE(death_type_concept_id, 0) AS death_type_concept_id + ,cause_of_death_concept_id AS cause_concept_id + ,cause_of_death_source_value AS cause_source_value + ,CAST(NULL AS INT) AS cause_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].DEATH +LEFT JOIN q7a3ac0oconcept_map_distinct cm1 ON DEATH.DEATH_TYPE_CONCEPT_ID = CM1.SOURCE_CONCEPT_ID + AND LOWER(DOMAIN_ID) IN ('death type'); + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'DEATH: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid DEATH_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].DEATH + WHERE DEATH_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('death type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** VISIT_OCCURRENCE ****/ - - INSERT INTO [TARGET_CDMV5].[SCHEMA].visit_occurrence - SELECT visit_occurrence_id, person_id, - COALESCE(cm1.target_concept_id,0) as visit_concept_id, - visit_start_date, TO_CHAR(null ) visit_start_time, - visit_end_date, TO_CHAR(null ) visit_end_time, - 44818517 as visit_type_concept_id, - CAST(null as integer) provider_id, - care_site_id, place_of_service_source_value as visit_source_value, - CAST(null as integer) visit_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].VISIT_OCCURRENCE - LEFT JOIN w3m16jd0concept_map cm1 - ON VISIT_OCCURRENCE.PLACE_OF_SERVICE_CONCEPT_ID = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('visit'); - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'VISIT_OCCURRENCE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid VISIT_CONCEPT_ID (from the CDMv4 PLACE_OF_SERVICE_CONCEPT_ID field)' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].VISIT_OCCURRENCE - WHERE PLACE_OF_SERVICE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('visit')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - /**** +INSERT INTO [TARGET_CDMV5].[SCHEMA].visit_occurrence +SELECT visit_occurrence_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS visit_concept_id + ,visit_start_date + ,TO_CHAR(NULL ) visit_start_time + ,visit_end_date + ,TO_CHAR(NULL ) visit_end_time + ,44818517 AS visit_type_concept_id + ,CAST(NULL AS INT) provider_id + ,care_site_id + ,place_of_service_source_value AS visit_source_value + ,CAST(NULL AS INT) visit_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].VISIT_OCCURRENCE +LEFT JOIN q7a3ac0oconcept_map cm1 ON VISIT_OCCURRENCE.PLACE_OF_SERVICE_CONCEPT_ID = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('visit'); + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'VISIT_OCCURRENCE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid VISIT_CONCEPT_ID (from the CDMv4 PLACE_OF_SERVICE_CONCEPT_ID field)' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].VISIT_OCCURRENCE + WHERE PLACE_OF_SERVICE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('visit') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** PROCEDURE_OCCURRENCE ****/ - - -- *************************************************************************** - -- AGS: Modifying this section to insert this information into the temp - -- table #po_map but this may need to be revisited for - -- performance tuning on APS as a large temp table may cause processing - -- time issues. - -- *************************************************************************** - - BEGIN - EXECUTE IMMEDIATE 'TRUNCATE TABLE w3m16jd0po_map'; - EXECUTE IMMEDIATE 'DROP TABLE w3m16jd0po_map'; +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE q7a3ac0opo_map'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0opo_map'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN @@ -593,300 +583,282 @@ EXCEPTION END IF; END; -CREATE GLOBAL TEMPORARY TABLE w3m16jd0po_map - ( - procedure_occurrence_id int, - person_id int, - procedure_concept_id int, - procedure_date date, - procedure_type_concept_id int, - modifier_concept_id int, - quantity int, - provider_id int, - visit_occurrence_id int, - procedure_source_value varchar(50), - procedure_source_concept_id int, - qualifier_source_value varchar(50), - origional_drug_id NUMBER(19) -) ON COMMIT PRESERVE ROWS; +/ - --find valid procedures from procedure table -INSERT INTO w3m16jd0po_map -( - procedure_occurrence_id, - person_id, - procedure_concept_id, - procedure_date, - procedure_type_concept_id, - modifier_concept_id, - quantity, - provider_id, - visit_occurrence_id, - procedure_source_value, - procedure_source_concept_id, - qualifier_source_value, - origional_drug_id -) - SELECT - procedure_occurrence_id, - person_id, - COALESCE(cm1.target_concept_id,0) as procedure_concept_id, - procedure_date, - COALESCE(cm2.target_concept_id,0) as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - TO_CHAR(null ) qualifier_source_value, - CAST(null as NUMBER(19)) as origional_drug_id - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - INNER JOIN w3m16jd0concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount = 1 - LEFT JOIN w3m16jd0concept_map cm2 - ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('procedure type') - LEFT JOIN w3m16jd0concept_map_distinct cmdis2 - ON cm2.source_concept_id = cmdis2.source_concept_id AND cm2.domain_id = cmdis2.domain_id AND cmdis2.targetConceptCount = 1 +CREATE GLOBAL TEMPORARY TABLE q7a3ac0opo_map + ON COMMIT PRESERVE ROWS +AS +SELECT + po.procedure_occurrence_id + ,po.person_id + ,po.procedure_concept_id + ,po.procedure_date + ,po.procedure_type_concept_id + ,po.modifier_concept_id + ,po.quantity + ,po.provider_id + ,po.visit_occurrence_id + ,po.procedure_source_value + ,po.procedure_source_concept_id + ,po.qualifier_source_value + ,de.drug_exposure_id AS origional_drug_id + +FROM + [TARGET_CDMV5].[SCHEMA].procedure_occurrence po +LEFT JOIN [TARGET_CDMV5].[SCHEMA].drug_exposure de ON 1 = 0 + WHERE 0 = 1; + +/ + +--find valid procedures from procedure table +INSERT INTO q7a3ac0opo_map +SELECT procedure_occurrence_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS procedure_concept_id + ,procedure_date + ,COALESCE(cm2.target_concept_id, 0) AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id +FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE +INNER JOIN q7a3ac0oconcept_map cm1 ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') +INNER JOIN q7a3ac0oconcept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount = 1 +LEFT JOIN q7a3ac0oconcept_map cm2 ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('procedure type') +LEFT JOIN q7a3ac0oconcept_map_distinct cmdis2 ON cm2.source_concept_id = cmdis2.source_concept_id + AND cm2.domain_id = cmdis2.domain_id + AND cmdis2.targetConceptCount = 1 UNION ALL - -- All procedures that did not map to a standard concept in V4 should also carry over to V5 - SELECT - procedure_occurrence_id, - person_id, - procedure_concept_id, - procedure_date, - procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - TO_CHAR(null ) qualifier_source_value, - CAST(null as NUMBER(19)) as origional_drug_id - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - FROM - DUAL - FROM - DUAL -WHERE procedure_concept_id = 0 +-- All procedures that did not map to a standard concept in V4 should also carry over to V5 +SELECT procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) procedure_source_concept_id + ,NULL qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id +FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE +WHERE procedure_concept_id = 0 UNION ALL - -- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 - SELECT - procedure_occurrence_id, - person_id, - 0 as procedure_concept_id, - procedure_date, - COALESCE(cm2.target_concept_id,0) as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - TO_CHAR(null ) qualifier_source_value, - CAST(null as NUMBER(19)) as origional_drug_id - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - LEFT JOIN w3m16jd0concept_map cm1 - ON procedure_concept_id = cm1.source_concept_id - LEFT JOIN w3m16jd0concept_map cm2 - ON procedure_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('procedure type') - WHERE procedure_concept_id <> 0 - and cm1.domain_id IS NULL - +-- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 +SELECT procedure_occurrence_id + ,person_id + ,0 AS procedure_concept_id + ,procedure_date + ,COALESCE(cm2.target_concept_id, 0) AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) procedure_source_concept_id + ,NULL qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE +LEFT JOIN q7a3ac0oconcept_map cm1 ON procedure_concept_id = cm1.source_concept_id +LEFT JOIN q7a3ac0oconcept_map cm2 ON procedure_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('procedure type') + WHERE procedure_concept_id <> 0 + AND cm1.domain_id IS NULL + UNION ALL - select - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS procedure_occurrence_id, - person_id, - procedure_concept_id, - procedure_date, - procedure_type_concept_id, - modifier_concept_id, - quantity, - provider_id, - visit_occurrence_id, - procedure_source_value, - procedure_source_concept_id, - qualifier_source_value, - origional_drug_id - FROM - ( - --find valid procedures from procedure table that map to more than 1 - --target concept in V5 - SELECT - person_id, - COALESCE(cm1.target_concept_id,0) as procedure_concept_id, - procedure_date, - COALESCE(cm2.target_concept_id,0) as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - TO_CHAR(null ) qualifier_source_value, - CAST(null as NUMBER(19)) as origional_drug_id, - NULL as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - INNER JOIN w3m16jd0concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount > 1 - LEFT JOIN w3m16jd0concept_map cm2 - ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('procedure type') - - UNION ALL - - --find procedures that were previously classified as condition - SELECT - person_id, - cm1.target_concept_id as procedure_concept_id, - condition_start_date as procedure_date, - 0 as procedure_type_concept_id, - CAST(null as integer) modifier_concept_id, - CAST(null as integer) quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value as procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - TO_CHAR(null ) qualifier_source_value, - CAST(null as NUMBER(19)) origional_drug_id, - condition_occurrence_id as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,modifier_concept_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,procedure_source_value + ,procedure_source_concept_id + ,qualifier_source_value + ,origional_drug_id +FROM ( + --find valid procedures from procedure table that map to more than 1 + --target concept in V5 + SELECT person_id + ,COALESCE(cm1.target_concept_id, 0) AS procedure_concept_id + ,procedure_date + ,COALESCE(cm2.target_concept_id, 0) AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) procedure_source_concept_id + ,NULL qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + ,CAST(NULL AS INT) AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + INNER JOIN q7a3ac0oconcept_map cm1 ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + INNER JOIN q7a3ac0oconcept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount > 1 + LEFT JOIN q7a3ac0oconcept_map cm2 ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('procedure type') + UNION ALL - --find procedures that were previously classified as drug - SELECT person_id, - cm1.target_concept_id as procedure_concept_id, - drug_exposure_start_date as procedure_date, - 0 as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) quantity, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value as procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - TO_CHAR(null ) qualifier_source_value, - drug_exposure_id as origional_drug_id, - drug_exposure_id as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN w3m16jd0concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - - - --find procedures that were previously classified as observation + --find procedures that were previously classified as condition + SELECT person_id + ,cm1.target_concept_id AS procedure_concept_id + ,condition_start_date AS procedure_date + ,0 AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value AS procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + ,condition_occurrence_id AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + INNER JOIN q7a3ac0oconcept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + UNION ALL - SELECT person_id, - cm1.target_concept_id as procedure_concept_id, - observation_date as procedure_date, - 0 as procedure_type_concept_id, CAST(null as integer) modifier_concept_id, CAST(null as integer) quantity, - associated_provider_id as provider_id, visit_occurrence_id, observation_source_value as procedure_source_value, - CAST(null as integer) procedure_source_concept_id, TO_CHAR(null ) qualifier_source_value, - CAST(null as NUMBER(19)) as origional_drug_id, - OBSERVATION_ID as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN w3m16jd0concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - - - ) OTHERS,(SELECT MAX(PROCEDURE_OCCURRENCE_ID) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE) MAXROW -; - -INSERT INTO [TARGET_CDMV5].[SCHEMA].procedure_occurrence - (procedure_occurrence_id - ,person_id - ,procedure_concept_id - ,procedure_date - ,procedure_type_concept_id - ,modifier_concept_id - ,quantity - ,provider_id - ,visit_occurrence_id - ,procedure_source_value - ,procedure_source_concept_id - ,qualifier_source_value) -SELECT - procedure_occurrence_id - ,person_id - ,procedure_concept_id - ,procedure_date - ,procedure_type_concept_id - ,modifier_concept_id - ,quantity - ,provider_id - ,visit_occurrence_id - ,procedure_source_value - ,procedure_source_concept_id - ,qualifier_source_value -FROM w3m16jd0po_map; + + --find procedures that were previously classified as drug + SELECT person_id + ,cm1.target_concept_id AS procedure_concept_id + ,drug_exposure_start_date AS procedure_date + ,0 AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value AS procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,drug_exposure_id AS origional_drug_id + ,drug_exposure_id AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + INNER JOIN q7a3ac0oconcept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + --find procedures that were previously classified as observation + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS procedure_concept_id + ,observation_date AS procedure_date + ,0 AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,observation_source_value AS procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + ,OBSERVATION_ID AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION + INNER JOIN q7a3ac0oconcept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + ) OTHERS + ,( + SELECT MAX(PROCEDURE_OCCURRENCE_ID) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + ) MAXROW; - --warnings of invalid records - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PROCEDURE_OCCURRENCE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid PROCOEDURE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - WHERE PROCEDURE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - STANDARD_CONCEPT = 'S' - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PROCEDURE_OCCURRENCE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid PROCOEDURE_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - WHERE PROCEDURE_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('procedure type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - /**** +INSERT INTO [TARGET_CDMV5].[SCHEMA].procedure_occurrence ( + procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,modifier_concept_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,procedure_source_value + ,procedure_source_concept_id + ,qualifier_source_value + ) +SELECT procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,modifier_concept_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,procedure_source_value + ,procedure_source_concept_id + ,qualifier_source_value +FROM q7a3ac0opo_map; + +--warnings of invalid records +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PROCEDURE_OCCURRENCE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid PROCOEDURE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + WHERE PROCEDURE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR STANDARD_CONCEPT = 'S' + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PROCEDURE_OCCURRENCE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid PROCOEDURE_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + WHERE PROCEDURE_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('procedure type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** DRUG_EXPOSURE ****/ - - --find valid drugs from drug_exposure table +--find valid drugs from drug_exposure table BEGIN - EXECUTE IMMEDIATE 'TRUNCATE TABLE w3m16jd0drgexp_map'; - EXECUTE IMMEDIATE 'DROP TABLE w3m16jd0drgexp_map'; + EXECUTE IMMEDIATE 'TRUNCATE TABLE q7a3ac0odrgexp_map'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0odrgexp_map'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN @@ -894,891 +866,1043 @@ EXCEPTION END IF; END; -CREATE GLOBAL TEMPORARY TABLE w3m16jd0drgexp_map - ( - drug_exposure_id int, - person_id int, - drug_concept_id int, - drug_exposure_start_date date, - drug_exposure_end_date date, - drug_type_concept_id int, - stop_reason varchar(20), - refills int, - quantity float, - days_supply int, - sig CLOB, - route_concept_id int, - effective_drug_dose float, - dose_unit_concept_id int, - lot_number varchar(50), - provider_id int, - visit_occurrence_id int, - drug_source_value varchar(50), - drug_source_concept_id int, - route_source_value varchar(50), - dose_unit_source_value varchar(50), - origional_procedure_id int -) ON COMMIT PRESERVE ROWS; +/ -INSERT INTO w3m16jd0drgexp_map -( - drug_exposure_id, - person_id, - drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - route_concept_id, - effective_drug_dose, - dose_unit_concept_id, - lot_number, - provider_id, - visit_occurrence_id, - drug_source_value, - drug_source_concept_id, - route_source_value, - dose_unit_source_value, - origional_procedure_id -) - SELECT drug_exposure_id, - person_id, - COALESCE(cm1.target_concept_id,0) as drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - COALESCE(cm2.target_concept_id, 0) drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - TO_CHAR(null ) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - TO_CHAR(null ) route_source_value, - TO_CHAR(null ) dose_unit_source_value, - CAST(null as NUMBER(19)) origional_procedure_id - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN w3m16jd0concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - INNER JOIN w3m16jd0concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount = 1 - LEFT JOIN w3m16jd0concept_map cm2 - ON drug_exposure.drug_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('drug type') - INNER JOIN w3m16jd0concept_map_distinct cmdis2 - ON cm2.source_concept_id = cmdis2.source_concept_id AND cm2.domain_id = cmdis2.domain_id AND cmdis2.targetConceptCount = 1 - WHERE drug_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 - -UNION ALL - - -- All drug exposures that did not map to a standard concept in V4 should also carry over to V5 - SELECT drug_exposure_id, - person_id, - drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - TO_CHAR(null ) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - TO_CHAR(null ) route_source_value, - TO_CHAR(null ) dose_unit_source_value, - CAST(null as NUMBER(19)) origional_procedure_id - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - WHERE drug_concept_id = 0 - -UNION ALL - - -- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 - SELECT drug_exposure_id, - person_id, - 0, - drug_exposure_start_date, - drug_exposure_end_date, - COALESCE(cm2.target_concept_id, 0) drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - TO_CHAR(null ) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - TO_CHAR(null ) route_source_value, - TO_CHAR(null ) dose_unit_source_value, - CAST(null as NUMBER(19)) origional_procedure_id - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - LEFT JOIN w3m16jd0concept_map cm1 - ON drug_concept_id = cm1.source_concept_id - LEFT JOIN w3m16jd0concept_map cm2 - ON drug_exposure.drug_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('drug type') - WHERE drug_concept_id <> 0 - and cm1.domain_id IS NULL - -UNION ALL -select CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS drug_exposure_id, - person_id, drug_concept_id, drug_exposure_start_date, drug_exposure_end_date, - drug_type_concept_id, stop_reason, refills, quantity, days_supply, sig, route_concept_id, - effective_drug_dose, dose_unit_concept_id, lot_number, provider_id, visit_occurrence_id, drug_source_value, - drug_source_concept_id, route_source_value, dose_unit_source_value - , origional_procedure_id -FROM -( - --find valid drugs from drug_exposure table that map to > 1 target concept - SELECT - person_id, - COALESCE(cm1.target_concept_id,0) as drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - COALESCE(cm2.target_concept_id, 0) drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - TO_CHAR(null ) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - TO_CHAR(null ) route_source_value, - TO_CHAR(null ) dose_unit_source_value, - CAST(null as NUMBER(19)) origional_procedure_id, - NULL as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN w3m16jd0concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - INNER JOIN w3m16jd0concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount > 1 - LEFT JOIN w3m16jd0concept_map cm2 - ON drug_exposure.drug_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('drug type') - - UNION ALL - --find drugs that were previously classified as condition - select person_id, - cm1.target_concept_id as drug_concept_id, - condition_start_date as drug_exposure_start_date, null as drug_exposure_end_date, - 0 as drug_type_concept_id, null as stop_reason, null as refills, null as quantity, null as days_supply, null as sig, CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, CAST(null as integer) dose_unit_concept_id, TO_CHAR(null ) lot_number, - null as provider_id, visit_occurrence_id, condition_source_value as drug_source_value, - CAST(null as integer) drug_source_concept_id, TO_CHAR(null ) route_source_value, TO_CHAR(null ) dose_unit_source_value, - CAST(null as NUMBER(19)) origional_procedure_id, condition_occurrence_id as occurrence_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - - --find drugs that were previously classified as procedure - UNION ALL - select person_id, - cm1.target_concept_id as drug_concept_id, - procedure_date as drug_exposure_start_date, null as drug_exposure_end_date, - 0 as drug_type_concept_id, null as stop_reason, null as refills, null as quantity, null as days_supply, null as sig, CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, CAST(null as integer) dose_unit_concept_id, TO_CHAR(null ) lot_number, - null as provider_id, visit_occurrence_id, procedure_source_value as drug_source_value, - CAST(null as integer) drug_source_concept_id, TO_CHAR(null ) route_source_value, TO_CHAR(null ) dose_unit_source_value, - procedure_occurrence_id as origional_procedure_id, procedure_occurrence_id as occurrence_id - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - - --find drugs that were previously classified as observation - UNION ALL - select person_id, - cm1.target_concept_id as drug_concept_id, observation_date as drug_exposure_start_date, null as drug_exposure_end_date, - 0 as drug_type_concept_id, null as stop_reason, null as refills, null as quantity, null as days_supply, null as sig, CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, CAST(null as integer) dose_unit_concept_id, TO_CHAR(null ) lot_number, - null as provider_id, visit_occurrence_id, observation_source_value as drug_source_value, - CAST(null as integer) drug_source_concept_id, TO_CHAR(null ) route_source_value, TO_CHAR(null ) dose_unit_source_value, - CAST(null as NUMBER(19)) origional_procedure_id, observation_id as occurrence_id - FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN w3m16jd0concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') -) OTHERS,(SELECT MAX(DRUG_EXPOSURE_ID) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE) MAXROW -; -INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_exposure - (drug_exposure_id - ,person_id - ,drug_concept_id - ,drug_exposure_start_date - ,drug_exposure_end_date - ,drug_type_concept_id - ,stop_reason - ,refills - ,quantity - ,days_supply - ,sig - ,route_concept_id - ,effective_drug_dose - ,dose_unit_concept_id - ,lot_number - ,provider_id - ,visit_occurrence_id - ,drug_source_value - ,drug_source_concept_id - ,route_source_value - ,dose_unit_source_value) +CREATE GLOBAL TEMPORARY TABLE q7a3ac0odrgexp_map + ON COMMIT PRESERVE ROWS +AS SELECT + de.drug_exposure_id + ,de.person_id + ,de.drug_concept_id + ,de.drug_exposure_start_date + ,de.drug_exposure_end_date + ,de.drug_type_concept_id + ,de.stop_reason + ,de.refills + ,de.quantity + ,de.days_supply + ,de.sig + ,de.route_concept_id + ,de.effective_drug_dose + ,de.dose_unit_concept_id + ,de.lot_number + ,de.provider_id + ,de.visit_occurrence_id + ,de.drug_source_value + ,de.drug_source_concept_id + ,de.route_source_value + ,de.dose_unit_source_value + ,po.procedure_occurrence_id AS origional_procedure_id + +FROM + [TARGET_CDMV5].[SCHEMA].drug_exposure de +LEFT JOIN [TARGET_CDMV5].[SCHEMA].procedure_occurrence po ON 1 = 0 + WHERE 0 = 1; + +/ + +INSERT INTO q7a3ac0odrgexp_map +SELECT drug_exposure_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,COALESCE(cm2.target_concept_id, 0) drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE +INNER JOIN q7a3ac0oconcept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') +INNER JOIN q7a3ac0oconcept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount = 1 +LEFT JOIN q7a3ac0oconcept_map cm2 ON drug_exposure.drug_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('drug type') +INNER JOIN q7a3ac0oconcept_map_distinct cmdis2 ON cm2.source_concept_id = cmdis2.source_concept_id + AND cm2.domain_id = cmdis2.domain_id + AND cmdis2.targetConceptCount = 1 + WHERE drug_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 + +UNION ALL + +-- All drug exposures that did not map to a standard concept in V4 should also carry over to V5 +SELECT drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + WHERE drug_concept_id = 0 + +UNION ALL + +-- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 +SELECT drug_exposure_id + ,person_id + ,0 + ,drug_exposure_start_date + ,drug_exposure_end_date + ,COALESCE(cm2.target_concept_id, 0) drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE +LEFT JOIN q7a3ac0oconcept_map cm1 ON drug_concept_id = cm1.source_concept_id +LEFT JOIN q7a3ac0oconcept_map cm2 ON drug_exposure.drug_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('drug type') + WHERE drug_concept_id <> 0 + AND cm1.domain_id IS NULL + +UNION ALL + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,route_concept_id + ,effective_drug_dose + ,dose_unit_concept_id + ,lot_number + ,provider_id + ,visit_occurrence_id + ,drug_source_value + ,drug_source_concept_id + ,route_source_value + ,dose_unit_source_value + ,origional_procedure_id +FROM ( + --find valid drugs from drug_exposure table that map to > 1 target concept + SELECT person_id + ,COALESCE(cm1.target_concept_id, 0) AS drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,COALESCE(cm2.target_concept_id, 0) drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + ,CAST(NULL AS INT) AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + INNER JOIN q7a3ac0oconcept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + INNER JOIN q7a3ac0oconcept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount > 1 + LEFT JOIN q7a3ac0oconcept_map cm2 ON drug_exposure.drug_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('drug type') + + UNION ALL + + --find drugs that were previously classified as condition + SELECT person_id + ,cm1.target_concept_id AS drug_concept_id + ,condition_start_date AS drug_exposure_start_date + ,NULL AS drug_exposure_end_date + ,0 AS drug_type_concept_id + ,NULL AS stop_reason + ,CAST(NULL AS INT) AS refills + ,CAST(NULL AS FLOAT) AS quantity + ,CAST(NULL AS INT) AS days_supply + ,NULL AS sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,condition_source_value AS drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + ,condition_occurrence_id AS occurrence_id + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + INNER JOIN q7a3ac0oconcept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + --find drugs that were previously classified as procedure + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS drug_concept_id + ,procedure_date AS drug_exposure_start_date + ,TO_DATE(NULL , 'yyyymmdd') AS drug_exposure_end_date + ,0 AS drug_type_concept_id + ,NULL AS stop_reason + ,CAST(NULL AS INT) AS refills + ,CAST(NULL AS FLOAT) AS quantity + ,CAST(NULL AS INT) AS days_supply + ,NULL AS sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,procedure_occurrence_id AS origional_procedure_id + ,procedure_occurrence_id AS occurrence_id + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + INNER JOIN q7a3ac0oconcept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + --find drugs that were previously classified as observation + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS drug_concept_id + ,observation_date AS drug_exposure_start_date + ,TO_DATE(NULL , 'yyyymmdd') AS drug_exposure_end_date + ,0 AS drug_type_concept_id + ,NULL AS stop_reason + ,CAST(NULL AS INT) AS refills + ,CAST(NULL AS FLOAT) AS quantity + ,CAST(NULL AS INT) AS days_supply + ,NULL AS sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,observation_source_value AS drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + ,observation_id AS occurrence_id + FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION + INNER JOIN q7a3ac0oconcept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + ) OTHERS + ,( + SELECT MAX(DRUG_EXPOSURE_ID) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + ) MAXROW; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_exposure ( drug_exposure_id - ,person_id - ,drug_concept_id - ,drug_exposure_start_date - ,drug_exposure_end_date - ,drug_type_concept_id - ,stop_reason - ,refills - ,quantity - ,days_supply - ,sig - ,route_concept_id - ,effective_drug_dose - ,dose_unit_concept_id - ,lot_number - ,provider_id - ,visit_occurrence_id - ,drug_source_value - ,drug_source_concept_id - ,route_source_value - ,dose_unit_source_value -FROM w3m16jd0drgexp_map; - - --warnings of invalid records - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'DRUG_EXPOSURE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid DRUG_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - WHERE DRUG_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - STANDARD_CONCEPT = 'S' - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'DRUG_EXPOSURE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid DRUG_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - WHERE DRUG_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('drug type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - /**** + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,route_concept_id + ,effective_drug_dose + ,dose_unit_concept_id + ,lot_number + ,provider_id + ,visit_occurrence_id + ,drug_source_value + ,drug_source_concept_id + ,route_source_value + ,dose_unit_source_value + ) +SELECT drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,route_concept_id + ,effective_drug_dose + ,dose_unit_concept_id + ,lot_number + ,provider_id + ,visit_occurrence_id + ,drug_source_value + ,drug_source_concept_id + ,route_source_value + ,dose_unit_source_value +FROM q7a3ac0odrgexp_map; + +--warnings of invalid records +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'DRUG_EXPOSURE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid DRUG_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + WHERE DRUG_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR STANDARD_CONCEPT = 'S' + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'DRUG_EXPOSURE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid DRUG_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + WHERE DRUG_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('drug type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** CONDITION_OCCURRENCE ****/ - - --find valid conditions from condition_occurrence table - INSERT INTO [TARGET_CDMV5].[SCHEMA].condition_occurrence - SELECT condition_occurrence_id, - person_id, - COALESCE(cm1.target_concept_id, 0) AS condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(cm2.target_concept_id,0) AS condition_type_concept_id, - stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - condition_source_value, CAST(null as integer) condition_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - INNER JOIN w3m16jd0concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount = 1 - LEFT JOIN w3m16jd0concept_map cm2 - ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('condition type') - WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 +--find valid conditions from condition_occurrence table +INSERT INTO [TARGET_CDMV5].[SCHEMA].condition_occurrence +SELECT condition_occurrence_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(cm2.target_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE +INNER JOIN q7a3ac0oconcept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') +INNER JOIN q7a3ac0oconcept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount = 1 +LEFT JOIN q7a3ac0oconcept_map cm2 ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('condition type') + WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 UNION ALL - -- All conditions that did not map to a standard concept in V4 should also carry over to V5 - SELECT condition_occurrence_id, - person_id, - condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(condition_type_concept_id,0) AS condition_type_concept_id, - stop_reason, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value, - CAST(null as integer) condition_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - WHERE condition_concept_id = 0 +-- All conditions that did not map to a standard concept in V4 should also carry over to V5 +SELECT condition_occurrence_id + ,person_id + ,condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(condition_type_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + WHERE condition_concept_id = 0 UNION ALL - -- All conditions that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 - SELECT condition_occurrence_id, - person_id, - 0 AS condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(cm2.target_concept_id,0) AS condition_type_concept_id, - stop_reason, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value, - CAST(null as integer) condition_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - LEFT JOIN w3m16jd0concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - LEFT JOIN w3m16jd0concept_map cm2 - ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('condition type') - WHERE condition_concept_id <> 0 - and cm1.domain_id IS NULL +-- All conditions that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 +SELECT condition_occurrence_id + ,person_id + ,0 AS condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(cm2.target_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE +LEFT JOIN q7a3ac0oconcept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id +LEFT JOIN q7a3ac0oconcept_map cm2 ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('condition type') + WHERE condition_concept_id <> 0 + AND cm1.domain_id IS NULL UNION ALL -select CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS drug_exposure_id, - person_id, condition_concept_id, condition_start_date, condition_end_date, - condition_type_concept_id, stop_reason, provider_id, visit_occurrence_id, - condition_source_value, condition_source_concept_id + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS drug_exposure_id + ,person_id + ,condition_concept_id + ,condition_start_date + ,condition_end_date + ,condition_type_concept_id + ,stop_reason + ,provider_id + ,visit_occurrence_id + ,condition_source_value + ,condition_source_concept_id FROM ( - --find valid conditions from condition_occurrence table that map to > 1 target concept - SELECT - person_id, - COALESCE(cm1.target_concept_id, 0) AS condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(cm2.target_concept_id,0) AS condition_type_concept_id, - stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - condition_source_value, CAST(null as integer) condition_source_concept_id, - NULL as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - INNER JOIN w3m16jd0concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount > 1 - LEFT JOIN w3m16jd0concept_map cm2 - ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('condition type') - WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 - - UNION ALL - - --find conditions that were previously classified as procedure - select person_id, - cm1.target_concept_id as condition_concept_id, - procedure_date as condition_start_date, null as condition_end_date, - 0 as condition_type_concept_id, null as stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - procedure_source_value as condition_source_value, CAST(null as integer) condition_source_concept_id, - procedure_occurrence_id as OCCURRENCE_ID + SELECT person_id + ,COALESCE(cm1.target_concept_id, 0) AS condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(cm2.target_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,NULL AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + INNER JOIN q7a3ac0oconcept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + INNER JOIN q7a3ac0oconcept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount > 1 + LEFT JOIN q7a3ac0oconcept_map cm2 ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('condition type') + WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 + + UNION ALL + + --find conditions that were previously classified as procedure + SELECT person_id + ,cm1.target_concept_id AS condition_concept_id + ,procedure_date AS condition_start_date + ,NULL AS condition_end_date + ,0 AS condition_type_concept_id + ,NULL AS stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,procedure_occurrence_id AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - - --find conditions that were previously classified as drug + INNER JOIN q7a3ac0oconcept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + --find conditions that were previously classified as drug + UNION ALL - SELECT person_id, - cm1.target_concept_id as condition_concept_id, - drug_exposure_start_date as condition_start_date, null as condition_end_date, - 0 as condition_type_concept_id, null as stop_reason, prescribing_provider_id as provider_id, visit_occurrence_id, - drug_source_value as condition_source_value, CAST(null as integer) condition_source_concept_id, - drug_exposure_id as OCCURRENCE_ID + + SELECT person_id + ,cm1.target_concept_id AS condition_concept_id + ,drug_exposure_start_date AS condition_start_date + ,NULL AS condition_end_date + ,0 AS condition_type_concept_id + ,NULL AS stop_reason + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value AS condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,drug_exposure_id AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN w3m16jd0concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - - --find conditions that were previously classified as observation + INNER JOIN q7a3ac0oconcept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + --find conditions that were previously classified as observation + UNION ALL - SELECT person_id, - cm1.target_concept_id as condition_concept_id, - observation_date as condition_start_date, null as condition_end_date, - 0 as condition_type_concept_id, null as stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - observation_source_value as condition_source_value, CAST(null as integer) condition_source_concept_id, - observation_id as OCCURRENCE_ID + + SELECT person_id + ,cm1.target_concept_id AS condition_concept_id + ,observation_date AS condition_start_date + ,NULL AS condition_end_date + ,0 AS condition_type_concept_id + ,NULL AS stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,observation_source_value AS condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,observation_id AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN w3m16jd0concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') -) OTHERS,(SELECT MAX(condition_occurrence_id) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE) MAXROW -; - - - --warnings of invalid records - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'CONDITION_OCCURRENCE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid CONDITION_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - WHERE CONDITION_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - STANDARD_CONCEPT = 'S' - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'CONDIITON_OCCURRENCE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid CONDITION_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - WHERE CONDITION_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('condition type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - + INNER JOIN q7a3ac0oconcept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + ) OTHERS + ,( + SELECT MAX(condition_occurrence_id) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + ) MAXROW; - /**** +--warnings of invalid records +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'CONDITION_OCCURRENCE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid CONDITION_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + WHERE CONDITION_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR STANDARD_CONCEPT = 'S' + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'CONDIITON_OCCURRENCE: ' || TO_CHAR(NUM_INVALID_RECORDS ) || ' records in the source CDMv4 database have invalid CONDITION_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + WHERE CONDITION_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('condition type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** DEVICE_EXPOSURE ****/ - INSERT INTO [TARGET_CDMV5].[SCHEMA].device_exposure -select row_number() over (order by OCCURRENCE_ID) AS device_exposure_id, - person_id, device_concept_id, device_exposure_start_date, device_exposure_end_date, device_type_concept_id, - unique_device_id, quantity, provider_id, visit_occurrence_id, device_source_value, device_source_concept_id -FROM -( +SELECT row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS device_exposure_id + ,person_id + ,device_concept_id + ,device_exposure_start_date + ,device_exposure_end_date + ,device_type_concept_id + ,unique_device_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,device_source_value + ,device_source_concept_id +FROM ( --find devices that were previously classified as procedures - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - PROCEDURE_DATE AS DEVICE_EXPOSURE_START_DATE, - TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, TO_CHAR(NULL ) unique_device_id, - CAST(null as integer) quantity, ASSOCIATED_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, PROCEDURE_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - PROCEDURE_OCCURRENCE_ID as OCCURRENCE_ID + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,PROCEDURE_DATE AS DEVICE_EXPOSURE_START_DATE + ,TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,TO_CHAR(NULL ) unique_device_id + ,CAST(NULL AS INT) quantity + ,ASSOCIATED_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,PROCEDURE_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,PROCEDURE_OCCURRENCE_ID AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') - + INNER JOIN q7a3ac0oconcept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') --find devices that were previously classified as drug exposure - UNION ALL - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - DRUG_EXPOSURE_START_DATE AS DEVICE_EXPOSURE_START_DATE, - TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, TO_CHAR(NULL ) unique_device_id, - quantity, PRESCRIBING_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, DRUG_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - DRUG_EXPOSURE_ID as OCCURRENCE_ID + + UNION ALL + + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS DEVICE_EXPOSURE_START_DATE + ,TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,TO_CHAR(NULL ) unique_device_id + ,quantity + ,PRESCRIBING_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,DRUG_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,DRUG_EXPOSURE_ID AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN w3m16jd0concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') - + INNER JOIN q7a3ac0oconcept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') --find devices that were previously classified as conditions + UNION ALL - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - CONDITION_START_DATE AS DEVICE_EXPOSURE_START_DATE, - TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, TO_CHAR(NULL ) unique_device_id, - CAST(NULL as integer) quantity, ASSOCIATED_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, CONDITION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - CONDITION_OCCURRENCE_ID as OCCURRENCE_ID + + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,CONDITION_START_DATE AS DEVICE_EXPOSURE_START_DATE + ,TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,TO_CHAR(NULL ) unique_device_id + ,CAST(NULL AS INT) quantity + ,ASSOCIATED_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,CONDITION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,CONDITION_OCCURRENCE_ID AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') - + INNER JOIN q7a3ac0oconcept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') --find devices that were previously classified as observations + UNION ALL - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - OBSERVATION_DATE AS DEVICE_EXPOSURE_START_DATE, - TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, TO_CHAR(NULL ) unique_device_id, - CAST(null as integer) quantity, ASSOCIATED_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, OBSERVATION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - OBSERVATION_ID as OCCURRENCE_ID + + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,OBSERVATION_DATE AS DEVICE_EXPOSURE_START_DATE + ,TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,TO_CHAR(NULL ) unique_device_id + ,CAST(NULL AS INT) quantity + ,ASSOCIATED_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,OBSERVATION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,OBSERVATION_ID AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN w3m16jd0concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') -) OTHERS -; - - - /**** + INNER JOIN q7a3ac0oconcept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') + ) OTHERS; + +/**** MEASUREMENT ****/ - --find valid measurements from observation table INSERT INTO [TARGET_CDMV5].[SCHEMA].measurement -SELECT row_number() over (order by occurrence_id) AS measurement_id, - person_id, measurement_concept_id, measurement_date, measurement_time, measurement_type_concept_id, operator_concept_id, value_as_number, value_as_concept_id, unit_concept_id, range_low, range_high, - provider_id, visit_occurrence_id, measurement_source_value, measurement_source_concept_id, unit_source_value, value_source_value -from -( +SELECT row_number() OVER ( + ORDER BY occurrence_id + ) AS measurement_id + ,person_id + ,measurement_concept_id + ,measurement_date + ,measurement_time + ,measurement_type_concept_id + ,operator_concept_id + ,value_as_number + ,value_as_concept_id + ,unit_concept_id + ,range_low + ,range_high + ,provider_id + ,visit_occurrence_id + ,measurement_source_value + ,measurement_source_concept_id + ,unit_source_value + ,value_source_value +FROM ( --find mesaurements that were previously classified as observations - select person_id, - cm1.target_concept_id AS measurement_concept_id, - OBSERVATION_DATE AS measurement_date, - TO_CHAR(OBSERVATION_TIME ) AS measurement_time, - 0 AS measurement_type_concept_id, - CAST(null as integer) operator_concept_id, - value_as_number, - value_as_concept_id, - COALESCE(cm2.target_concept_id,0) AS unit_concept_id, - range_low, - range_high, - ASSOCIATED_PROVIDER_ID AS provider_id, - visit_occurrence_id, - OBSERVATION_SOURCE_VALUE AS measurement_source_value, - CAST(null as integer) measurement_source_concept_id, - unit_source_value AS unit_source_value, - TO_CHAR(null ) as value_source_value, - observation_id as occurrence_id + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,OBSERVATION_DATE AS measurement_date + ,TO_CHAR(OBSERVATION_TIME ) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) operator_concept_id + ,value_as_number + ,value_as_concept_id + ,COALESCE(cm2.target_concept_id, 0) AS unit_concept_id + ,range_low + ,range_high + ,ASSOCIATED_PROVIDER_ID AS provider_id + ,visit_occurrence_id + ,OBSERVATION_SOURCE_VALUE AS measurement_source_value + ,CAST(NULL AS INT) measurement_source_concept_id + ,unit_source_value AS unit_source_value + ,TO_CHAR(NULL ) AS value_source_value + ,observation_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN w3m16jd0concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - LEFT JOIN w3m16jd0concept_map cm2 - ON observation.unit_concept_id = cm2.source_concept_id - AND LOWER(cm1.domain_id) IN ('unit') - + INNER JOIN q7a3ac0oconcept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + LEFT JOIN q7a3ac0oconcept_map cm2 ON observation.unit_concept_id = cm2.source_concept_id + AND LOWER(cm1.domain_id) IN ('unit') + UNION ALL - - SELECT person_id, - cm1.target_concept_id as measurement_concept_id, - procedure_date as measurement_date, - TO_CHAR(NULL ) as measurement_time, - 0 as measurement_type_concept_id, - CAST(null as integer) as operator_concept_id, - CAST(null as integer) as value_as_number, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as range_low, - CAST(null as integer) as range_high, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value as measurement_source_value, - CAST(null as integer) as measurement_source_concept_id, - TO_CHAR(null ) as unit_source_value, - TO_CHAR(null ) as value_source_value, - procedure_occurrence_id as occurrence_id + + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,procedure_date AS measurement_date + ,TO_CHAR(NULL ) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) AS operator_concept_id + ,CAST(NULL AS INT) AS value_as_number + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS range_low + ,CAST(NULL AS INT) AS range_high + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS measurement_source_value + ,CAST(NULL AS INT) AS measurement_source_concept_id + ,TO_CHAR(NULL ) AS unit_source_value + ,TO_CHAR(NULL ) AS value_source_value + ,procedure_occurrence_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - + INNER JOIN q7a3ac0oconcept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + UNION ALL - - SELECT person_id, - cm1.target_concept_id as measurement_concept_id, - condition_start_date as measurement_date, - TO_CHAR(NULL ) as measurement_time, - 0 as measurement_type_concept_id, - CAST(null as integer) as operator_concept_id, - CAST(null as integer) as value_as_number, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as range_low, - CAST(null as integer) as range_high, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value as measurement_source_value, - CAST(null as integer) as measurement_source_concept_id, - TO_CHAR(null ) as unit_source_value, - TO_CHAR(null ) as value_source_value, - condition_occurrence_id as occurrence_id + + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,condition_start_date AS measurement_date + ,TO_CHAR(NULL ) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) AS operator_concept_id + ,CAST(NULL AS INT) AS value_as_number + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS range_low + ,CAST(NULL AS INT) AS range_high + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value AS measurement_source_value + ,CAST(NULL AS INT) AS measurement_source_concept_id + ,TO_CHAR(NULL ) AS unit_source_value + ,TO_CHAR(NULL ) AS value_source_value + ,condition_occurrence_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - + INNER JOIN q7a3ac0oconcept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + UNION ALL - - SELECT person_id, - cm1.target_concept_id as measurement_concept_id, - drug_exposure_start_date as measurement_date, - TO_CHAR(NULL ) as measurement_time, - 0 as measurement_type_concept_id, - CAST(null as integer) as operator_concept_id, - CAST(null as integer) as value_as_number, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as range_low, - CAST(null as integer) as range_high, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value as measurement_source_value, - CAST(null as integer) as measurement_source_concept_id, - TO_CHAR(null ) as unit_source_value, - TO_CHAR(null ) as value_source_value, - drug_exposure_id as occurrence_id + + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,drug_exposure_start_date AS measurement_date + ,TO_CHAR(NULL ) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) AS operator_concept_id + ,CAST(NULL AS INT) AS value_as_number + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS range_low + ,CAST(NULL AS INT) AS range_high + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value AS measurement_source_value + ,CAST(NULL AS INT) AS measurement_source_concept_id + ,TO_CHAR(NULL ) AS unit_source_value + ,TO_CHAR(NULL ) AS value_source_value + ,drug_exposure_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].drug_exposure - INNER JOIN w3m16jd0concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - - -) OTHERS -; - - - - /**** + INNER JOIN q7a3ac0oconcept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + ) OTHERS; + +/**** OBSERVATION ****/ - - - --find valid observation from observation table - INSERT INTO [TARGET_CDMV5].[SCHEMA].observation - SELECT - observation_id, - person_id, - observation_concept_id, - observation_date, - TO_CHAR(observation_time ) as observation_time, - observation_type_concept_id, - value_as_number, - value_as_string, - value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - unit_concept_id, - associated_provider_id as provider_id, - visit_occurrence_id, - observation_source_value, - CAST(null as integer) observation_source_concept_id, - unit_source_value, - TO_CHAR(null ) qualifier_source_value - FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - WHERE observation_concept_id NOT IN (SELECT source_concept_id FROM w3m16jd0concept_map_distinct WHERE LOWER(domain_id) IN ('condition','drug','procedure','device','measurement')) +--find valid observation from observation table +INSERT INTO [TARGET_CDMV5].[SCHEMA].observation +SELECT observation_id + ,person_id + ,observation_concept_id + ,observation_date + ,TO_CHAR(observation_time ) AS observation_time + ,observation_type_concept_id + ,value_as_number + ,value_as_string + ,value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,unit_concept_id + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,unit_source_value + ,TO_CHAR(NULL ) qualifier_source_value + FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION + WHERE observation_concept_id NOT IN ( + SELECT source_concept_id + FROM q7a3ac0oconcept_map_distinct + WHERE LOWER(domain_id) IN ( + 'condition' + ,'drug' + ,'procedure' + ,'device' + ,'measurement' + ) + ) +--find observations that were previously classified as procedure - - --find observations that were previously classified as procedure -UNION ALL -select - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS observation_id, - person_id, - observation_concept_id, - observation_date, - observation_time, - observation_type_concept_id, - value_as_number, - 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 -( - select person_id, - cm1.target_concept_id as observation_concept_id, - procedure_date as observation_date, - TO_CHAR(null ) as observation_time, - 0 as observation_type_concept_id, - CAST(null as float) as value_as_number, - null as value_as_string, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - CAST(null as integer) as unit_concept_id, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value as observation_source_value, - CAST(null as integer) observation_source_concept_id, - null as unit_source_value, - TO_CHAR(null ) qualifier_source_value, - procedure_occurrence_id as occurrence_id +UNION ALL + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS observation_id + ,person_id + ,observation_concept_id + ,observation_date + ,observation_time + ,observation_type_concept_id + ,value_as_number + ,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 ( + SELECT person_id + ,cm1.target_concept_id AS observation_concept_id + ,procedure_date AS observation_date + ,TO_CHAR(NULL ) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS FLOAT) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,NULL AS unit_source_value + ,TO_CHAR(NULL ) qualifier_source_value + ,procedure_occurrence_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('observation') - - --find observations that were previously classified as condition - UNION ALL - SELECT person_id, - cm1.target_concept_id as observation_concept_id, - condition_start_date as observation_date, - TO_CHAR(null ) as observation_time, - 0 as observation_type_concept_id, - CAST(null as float) as value_as_number, - null as value_as_string, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - CAST(null as integer) as unit_concept_id, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value as observation_source_value, - CAST(null as integer) observation_source_concept_id, - null as unit_source_value, - TO_CHAR(null ) qualifier_source_value, - condition_occurrence_id as occurrence_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN w3m16jd0concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('observation') - - --find observations that were previously classified as drug exposure + INNER JOIN q7a3ac0oconcept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + --find observations that were previously classified as condition + UNION ALL - SELECT person_id, - cm1.target_concept_id as observation_concept_id, - drug_exposure_start_date as observation_date, - TO_CHAR(null ) as observation_time, - 0 as observation_type_concept_id, - CAST(null as float) as value_as_number, - null as value_as_string, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as provider_id, - visit_occurrence_id, - drug_source_value as observation_source_value, - CAST(null as integer) observation_source_concept_id, - null as unit_source_value, - TO_CHAR(null ) qualifier_source_value, - drug_exposure_id as occurrence_id + + SELECT person_id + ,cm1.target_concept_id AS observation_concept_id + ,condition_start_date AS observation_date + ,TO_CHAR(NULL ) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS FLOAT) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value AS observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,NULL AS unit_source_value + ,TO_CHAR(NULL ) qualifier_source_value + ,condition_occurrence_id AS occurrence_id + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + INNER JOIN q7a3ac0oconcept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + + UNION ALL + + --find DRG observations that were previously classified as procedure_cost + SELECT po.person_id + ,cm1.target_concept_id AS observation_concept_id + ,po.procedure_date AS observation_date + ,TO_CHAR(NULL ) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS FLOAT) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,po.associated_provider_id AS provider_id + ,po.visit_occurrence_id + ,pc.DISEASE_CLASS_SOURCE_VALUE AS observation_source_value + ,cm1.source_concept_id as observation_source_concept_id + ,NULL AS unit_source_value + ,TO_CHAR(NULL ) qualifier_source_value + ,po.procedure_occurrence_id AS occurrence_id + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_COST pc + INNER JOIN [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE po ON pc.PROCEDURE_OCCURRENCE_ID = po.PROCEDURE_OCCURRENCE_ID + INNER JOIN q7a3ac0oconcept_map cm1 ON pc.disease_class_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + + UNION ALL + + --find observations that were previously classified as drug exposure + SELECT person_id + ,cm1.target_concept_id AS observation_concept_id + ,drug_exposure_start_date AS observation_date + ,TO_CHAR(NULL ) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS FLOAT) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,drug_source_value AS observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,NULL AS unit_source_value + ,TO_CHAR(NULL ) qualifier_source_value + ,drug_exposure_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN w3m16jd0concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('observation') - ) OTHERS,(SELECT MAX(OBSERVATION_ID) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION) MAXROW - ; - - - - /**** + INNER JOIN q7a3ac0oconcept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + ) OTHERS + ,( + SELECT MAX(OBSERVATION_ID) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION + ) MAXROW; + +/**** PAYER_PLAN_PERIOD ****/ - INSERT INTO [TARGET_CDMV5].[SCHEMA].payer_plan_period -SELECT payer_plan_period_id, person_id, payer_plan_period_start_date, payer_plan_period_end_date, - payer_source_value, plan_source_value, family_source_value +SELECT payer_plan_period_id + ,person_id + ,payer_plan_period_start_date + ,payer_plan_period_end_date + ,payer_source_value + ,plan_source_value + ,family_source_value FROM [SOURCE_CDMV4].[SCHEMA].PAYER_PLAN_PERIOD; - - /**** + +/**** DRUG_COST note : if there were invalid drug concepts in DRUG_EXPOSURE, those records may not enter CDMv5 but costs will persist ****/ - INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_cost -SELECT drug_cost_id, dc.drug_exposure_id, cast(null as integer) currency_concept_id, paid_copay, paid_coinsurance, paid_toward_deductible, paid_by_payer, - paid_by_coordination_benefits, total_out_of_pocket, total_paid, ingredient_cost, dispensing_fee, - average_wholesale_price, payer_plan_period_id -FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST dc -; +SELECT drug_cost_id + ,dc.drug_exposure_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,ingredient_cost + ,dispensing_fee + ,average_wholesale_price + ,payer_plan_period_id +FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST dc; -- insert procedure costs for procedures that were inserted into the drug_exposure table INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_cost -select - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS drug_cost_id, - drug_exposure_id, - cast(null as integer) currency_concept_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - ingredient_cost, - dispensing_fee, - average_wholesale_price, - payer_plan_period_id +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS drug_cost_id + ,drug_exposure_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,ingredient_cost + ,dispensing_fee + ,average_wholesale_price + ,payer_plan_period_id FROM ( - SELECT - drug_exposure_id, - po.person_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - CAST(null as float) as ingredient_cost, - CAST(null as float) as dispensing_fee, - CAST(null as float) as average_wholesale_price, - payer_plan_period_id, - procedure_cost_id as OCCURRENCE_ID + SELECT drug_exposure_id + ,po.person_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,CAST(NULL AS FLOAT) AS ingredient_cost + ,CAST(NULL AS FLOAT) AS dispensing_fee + ,CAST(NULL AS FLOAT) AS average_wholesale_price + ,payer_plan_period_id + ,procedure_cost_id AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE po - join [SOURCE_CDMV4].[SCHEMA].PROCEDURE_COST pc on po.procedure_occurrence_id = pc.procedure_occurrence_id + INNER JOIN [SOURCE_CDMV4].[SCHEMA].PROCEDURE_COST pc ON po.procedure_occurrence_id = pc.procedure_occurrence_id --JOIN dbo.drug_exposure de on de.person_id = po.person_id and pc.procedure_occurrence_id = de.origional_procedure_id - JOIN w3m16jd0drgexp_map de on de.person_id = po.person_id and pc.procedure_occurrence_id = de.origional_procedure_id -) OTHERS ,(SELECT MAX(drug_cost_id) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST) MAXROW -; - - /**** + INNER JOIN q7a3ac0odrgexp_map de ON de.person_id = po.person_id + AND pc.procedure_occurrence_id = de.origional_procedure_id + ) OTHERS + ,( + SELECT MAX(drug_cost_id) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST + ) MAXROW; + +/**** PROCEDURE_COST @@ -1786,138 +1910,80 @@ FROM ( ****/ - INSERT INTO [TARGET_CDMV5].[SCHEMA].procedure_cost -SELECT procedure_cost_id, procedure_occurrence_id, cast(null as integer) currency_concept_id, paid_copay, paid_coinsurance, paid_toward_deductible, - paid_by_payer, paid_by_coordination_benefits, total_out_of_pocket, total_paid, - payer_plan_period_id, revenue_code_concept_id, revenue_code_source_value +SELECT procedure_cost_id + ,procedure_occurrence_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,payer_plan_period_id + ,revenue_code_concept_id + ,revenue_code_source_value FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_COST; - -- insert drug costs for drugs that were inserted into the procedure_occurrence table INSERT INTO [TARGET_CDMV5].[SCHEMA].procedure_cost -SELECT - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS procedure_cost_id, - procedure_occurrence_id, - cast(null as integer) - currency_concept_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - payer_plan_period_id, - revenue_code_concept_id, - revenue_code_source_value - FROM ( - SELECT - po.procedure_occurrence_id, - po.person_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - CAST(null as float) as ingredient_cost, - CAST(null as float) as dispensing_fee, - CAST(null as float) as average_wholesale_price, - payer_plan_period_id, - CAST(null as integer) as revenue_code_concept_id, - CAST(null as integer) as revenue_code_source_value, - drug_cost_id as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE de - join [SOURCE_CDMV4].[SCHEMA].DRUG_COST dc on de.drug_exposure_id = dc.drug_exposure_id - --JOIN dbo.procedure_occurrence po on de.person_id = po.person_id and de.drug_exposure_id = po.origional_drug_id - JOIN w3m16jd0po_map po on de.person_id = po.person_id and de.drug_exposure_id = po.origional_drug_id - ) OTHERS,(SELECT MAX(drug_cost_id) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST) MAXROW -; - +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS procedure_cost_id + ,procedure_occurrence_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,payer_plan_period_id + ,revenue_code_concept_id + ,revenue_code_source_value +FROM ( + SELECT po.procedure_occurrence_id + ,po.person_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,CAST(NULL AS FLOAT) AS ingredient_cost + ,CAST(NULL AS FLOAT) AS dispensing_fee + ,CAST(NULL AS FLOAT) AS average_wholesale_price + ,payer_plan_period_id + ,CAST(NULL AS INT) AS revenue_code_concept_id + ,CAST(NULL AS INT) AS revenue_code_source_value + ,drug_cost_id AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE de + INNER JOIN [SOURCE_CDMV4].[SCHEMA].DRUG_COST dc ON de.drug_exposure_id = dc.drug_exposure_id + --JOIN dbo.procedure_occurrence po on de.person_id = po.person_id and de.drug_exposure_id = po.origional_drug_id + INNER JOIN q7a3ac0opo_map po ON de.person_id = po.person_id + AND de.drug_exposure_id = po.origional_drug_id + ) OTHERS + ,( + SELECT MAX(drug_cost_id) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST + ) MAXROW; + /**** DRUG ERA Note: Eras derived from DRUG_EXPOSURE table, using 30d gap ****/ - --- drop table dbo.drug_era -INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_era - WITH cteDrugTarget (DRUG_EXPOSURE_ID, PERSON_ID, DRUG_CONCEPT_ID, DRUG_TYPE_CONCEPT_ID, DRUG_EXPOSURE_START_DATE, DRUG_EXPOSURE_END_DATE, INGREDIENT_CONCEPT_ID) AS -( - -- 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, (DRUG_EXPOSURE_START_DATE + DAYS_SUPPLY), (DRUG_EXPOSURE_START_DATE + 1)) as DRUG_EXPOSURE_END_DATE, - c.CONCEPT_ID as INGREDIENT_CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].DRUG_EXPOSURE d - join [TARGET_CDMV5].[SCHEMA].CONCEPT_ANCESTOR ca on ca.DESCENDANT_CONCEPT_ID = d.DRUG_CONCEPT_ID - 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' -), -cteEndDates (PERSON_ID, INGREDIENT_CONCEPT_ID, END_DATE) as -- the magic -( - 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 - 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 -), -cteDrugExposureEnds (PERSON_ID, DRUG_CONCEPT_ID, DRUG_TYPE_CONCEPT_ID, DRUG_EXPOSURE_START_DATE, DRUG_ERA_END_DATE) 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 -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 -) - SELECT row_number() over (order by person_id) as drug_era_id, person_id, drug_concept_id, min(DRUG_EXPOSURE_START_DATE) as drug_era_start_date, drug_era_end_date, COUNT(*) as DRUG_EXPOSURE_COUNT, 30 as gap_days -from cteDrugExposureEnds -GROUP BY person_id, drug_concept_id, drug_type_concept_id, DRUG_ERA_END_DATE -; - -/**** - -CONDITION ERA -Note: Eras derived from CONDITION_OCCURRENCE table, using 30d gap - - ****/ - BEGIN - EXECUTE IMMEDIATE 'TRUNCATE TABLE w3m16jd0condition_era_phase_1'; - EXECUTE IMMEDIATE 'DROP TABLE w3m16jd0condition_era_phase_1'; + EXECUTE IMMEDIATE 'TRUNCATE TABLE q7a3ac0octeDrugTarget'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0octeDrugTarget'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN @@ -1925,83 +1991,538 @@ EXCEPTION END IF; END; -CREATE GLOBAL TEMPORARY TABLE w3m16jd0condition_era_phase_1 - ON COMMIT PRESERVE ROWS +/ + +-- 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 GLOBAL TEMPORARY TABLE q7a3ac0octeDrugTarget + ON COMMIT PRESERVE ROWS AS -WITH cteConditionTarget (PERSON_ID, CONDITION_CONCEPT_ID, CONDITION_START_DATE, CONDITION_END_DATE) AS -( - -- 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, (CONDITION_START_DATE + 1)) as CONDITION_END_DATE - FROM [TARGET_CDMV5].[SCHEMA].CONDITION_OCCURRENCE co -), -cteEndDates (PERSON_ID, CONDITION_CONCEPT_ID, END_DATE) as -- the magic -( - 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 - 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 -), -cteConditionEnds (PERSON_ID, CONDITION_CONCEPT_ID, CONDITION_START_DATE, ERA_END_DATE) as -( -select - c.PERSON_ID, - c.CONDITION_CONCEPT_ID, - c.CONDITION_START_DATE, - MIN(e.END_DATE) as ERA_END_DATE -FROM cteConditionTarget c -JOIN cteEndDates 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 -) - 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 +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 - cteConditionEnds -GROUP BY person_id, CONDITION_CONCEPT_ID, ERA_END_DATE -; + [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'; -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) +/ + +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE q7a3ac0octeEndDates'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0octeEndDates'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/ + +CREATE GLOBAL TEMPORARY TABLE q7a3ac0octeEndDates + ON COMMIT PRESERVE ROWS +AS SELECT - condition_era_id, - PERSON_ID, - CONDITION_CONCEPT_ID, - CONDITION_ERA_START_DATE, - CONDITION_ERA_END_DATE, - CONDITIOn_OCCURRENCE_COUNT -FROM w3m16jd0condition_era_phase_1 + 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 q7a3ac0octeDrugTarget + + 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 q7a3ac0octeDrugTarget + ) 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 q7a3ac0octeDrugTarget + ) 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 q7a3ac0octeDrugExpEnds'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0octeDrugExpEnds'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/ + +CREATE GLOBAL TEMPORARY TABLE q7a3ac0octeDrugExpEnds + ON COMMIT PRESERVE ROWS +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 + q7a3ac0octeDrugTarget d +INNER JOIN q7a3ac0octeEndDates 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 q7a3ac0octeDrugExpEnds +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 q7a3ac0ocondition_era_phase_1'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0ocondition_era_phase_1'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/ + +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE q7a3ac0octeConditionTarget'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0octeConditionTarget'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/ + +-- create base eras from the concepts found in condition_occurrence +CREATE GLOBAL TEMPORARY TABLE q7a3ac0octeConditionTarget + ON COMMIT PRESERVE ROWS +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 + [TARGET_CDMV5].[SCHEMA].CONDITION_OCCURRENCE co; + +/ + +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE q7a3ac0octeCondEndDates'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0octeCondEndDates'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/ + +CREATE GLOBAL TEMPORARY TABLE q7a3ac0octeCondEndDates + ON COMMIT PRESERVE ROWS +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 q7a3ac0octeConditionTarget + + 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 q7a3ac0octeConditionTarget + ) 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 q7a3ac0octeConditionTarget + ) 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 q7a3ac0octeConditionEnds'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0octeConditionEnds'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/ + +CREATE GLOBAL TEMPORARY TABLE q7a3ac0octeConditionEnds + ON COMMIT PRESERVE ROWS +AS +SELECT + c.PERSON_ID + ,c.CONDITION_CONCEPT_ID + ,c.CONDITION_START_DATE + ,MIN(e.END_DATE) AS ERA_END_DATE + +FROM + q7a3ac0octeConditionTarget c +INNER JOIN q7a3ac0octeCondEndDates 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 q7a3ac0octeConditionEnds +GROUP BY person_id + ,CONDITION_CONCEPT_ID + ,ERA_END_DATE; + +/**** + +QUALITY ASSURANCE OUTPUT + +Note: These queries are used to provide some basic stats around row counts between your V4 and V5 database + to ensure that all of the data has migrated as expected. + + ****/ + +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE q7a3ac0ov5_stats'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0ov5_stats'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/ + +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE q7a3ac0ov4_stats'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0ov4_stats'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/ + +-- Get the row counts for each table that is in scope for the migration +CREATE GLOBAL TEMPORARY TABLE q7a3ac0ov4_stats + ON COMMIT PRESERVE ROWS +AS +SELECT + * + +FROM + +( + SELECT '[SOURCE_CDMV4]' AS DBName, 'care_site' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].care_site + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'condition_era' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].condition_era + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'condition_occurrence' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].condition_occurrence + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'death' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].death + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'drug_cost' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].drug_cost + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'drug_era' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].drug_era + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'drug_exposure' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].drug_exposure + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'location' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].location + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'observation' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].observation + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'observation_period' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].observation_period + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'payer_plan_period' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].payer_plan_period + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'person' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].person + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'procedure_cost' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].procedure_cost + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'procedure_occurrence' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].procedure_occurrence + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'provider' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].provider + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'visit_occurrence' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].visit_occurrence +) v4_stats; + +/ + +CREATE GLOBAL TEMPORARY TABLE q7a3ac0ov5_stats + ON COMMIT PRESERVE ROWS +AS +SELECT + * + +FROM + +( + SELECT '[TARGET_CDMV5]' AS DBName, 'care_site' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].care_site + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'condition_era' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].condition_era + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'condition_occurrence' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].condition_occurrence + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'death' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].death + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'device_exposure' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].device_exposure + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'drug_cost' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].drug_cost + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'drug_era' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].drug_era + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'drug_exposure' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].drug_exposure + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'location' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].location + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'measurement' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].measurement + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'observation' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].observation + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'observation_period' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].observation_period + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'payer_plan_period' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].payer_plan_period + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'person' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].person + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'procedure_cost' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].procedure_cost + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'procedure_occurrence' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].procedure_occurrence + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'provider' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].provider + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'visit_occurrence' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].visit_occurrence +) v5_stats; + +/ + +-- Show the results +select + 'Rowcounts for each database and table', + NVL(V4.DBName, 'None') v4_database_name, + v4.TableName v4_table_name, + v4.row_count v4_row_count, + NVL(v5.DBName, 'None') v5_database_name, + v5.TableName v5_table_name, + v5.row_count v5_row_count, + NVL(v5.row_count, 0) - NVL(v4.row_count, 0) row_count_change +from q7a3ac0ov4_stats v4 +full outer join q7a3ac0ov5_stats v5 ON v4.TableName = v5.TableName +order by v5.TableName; + +/* + * Determine how the vocabulary/domains helped to map from the V4 source + * tables to the V5 destinations + */ +BEGIN + EXECUTE IMMEDIATE 'TRUNCATE TABLE q7a3ac0oclassification_map'; + EXECUTE IMMEDIATE 'DROP TABLE q7a3ac0oclassification_map'; +EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE; + END IF; +END; + +/ + +CREATE GLOBAL TEMPORARY TABLE q7a3ac0oclassification_map + ON COMMIT PRESERVE ROWS +AS +SELECT + * + +FROM + +( + SELECT 'Condition_Occurrence' TableName, NVL(LOWER(cm.domain_id), 'condition') domain_id, COUNT(*) row_count + FROM [SOURCE_CDMV4].[SCHEMA].Condition_Occurrence CO + LEFT JOIN q7a3ac0oconcept_map CM ON co.condition_concept_id = cm.source_concept_id + GROUP BY NVL(LOWER(cm.domain_id), 'condition') + UNION + SELECT 'Drug_Exposure' TableName, NVL(LOWER(cm.domain_id), 'drug') domain_id, COUNT(*) row_count + FROM [SOURCE_CDMV4].[SCHEMA].Drug_Exposure de + LEFT JOIN q7a3ac0oconcept_map CM ON de.drug_concept_id = cm.source_concept_id + GROUP BY NVL(LOWER(cm.domain_id), 'drug') + UNION + SELECT 'Observation' TableName, NVL(LOWER(cm.domain_id), 'observation') domain_id, COUNT(*) row_count + FROM [SOURCE_CDMV4].[SCHEMA].Observation o + LEFT JOIN q7a3ac0oconcept_map CM ON o.observation_concept_id = cm.source_concept_id + GROUP BY NVL(LOWER(cm.domain_id), 'observation') + UNION + SELECT 'Procedure_Occurrence' TableName, NVL(LOWER(cm.domain_id), 'procedure') domain_id, COUNT(*) row_count + FROM [SOURCE_CDMV4].[SCHEMA].Procedure_Occurrence po + LEFT JOIN q7a3ac0oconcept_map CM ON po.PROCEDURE_CONCEPT_ID = cm.source_concept_id + GROUP BY NVL(LOWER(cm.domain_id), 'procedure') +) A +ORDER by A.TableName, A.domain_id; + +/ + +select * +from q7a3ac0oclassification_map +order by tablename, domain_id; + +select domain_id, SUM(row_count) +from q7a3ac0oclassification_map +group by domain_id +order by domain_id; \ No newline at end of file diff --git a/Version4 To Version5 Conversion/PostgreSQL/OMOP CDMv4 to CDMv5 - PostgreSQL.sql b/Version4 To Version5 Conversion/PostgreSQL/OMOP CDMv4 to CDMv5 - PostgreSQL.sql index 156123f..dba70f3 100644 --- a/Version4 To Version5 Conversion/PostgreSQL/OMOP CDMv4 to CDMv5 - PostgreSQL.sql +++ b/Version4 To Version5 Conversion/PostgreSQL/OMOP CDMv4 to CDMv5 - PostgreSQL.sql @@ -14,18 +14,16 @@ # See the License for the specific language governing permissions and # limitations under the License. ********************************************************************************/ - /******************************************************************************* PURPOSE: Use this script to convert your OMOP V4 common data model to CDM V5. -last revised: 09 July 2015 -author: Patrick Ryan, Chris Knoll -editor: Anthony Sena +last revised: 04 August 2015 +authors: Patrick Ryan, Chris Knoll, Anthony Sena !!!!!!!!!!!!!!!!!!!!! PLEASE READ THESE INSTRUCTIONS !!!!!!!!!!!!!!!!!!!!!!!!!!! -This script was authored using TemplateSQL which will require you to run this +This script was authored using OHDSI-SQL which will require you to run this script through SqlRender to creat a version that is compatible with your target RDBMS. We have pre-generated these scripts using SQL Render and have placed them in folders for each RDBMS. Depending on which script you are viewing, your @@ -35,19 +33,22 @@ General Assumptions ------------------- This script assumes that your V4 and V5 database are located on the same -RDBMS server. +RDBMS server. It also assumes that the V4 and V5 databases were created +using the standard data definition scripts for these databases. If you +altered your V4 database in any way, this script will likely require +some mo Getting Started --------------- Before you can use this script, there are some prerequisites: - 1. Create a target CDMv5 database on your server using the appropriate script - from https://github.com/OHDSI/CommonDataModel + 1. Create a target CDMv5 database on your database server using the + appropriate script from https://github.com/OHDSI/CommonDataModel 2. Load VocabV5 into the target database/schema that will contain CDMv5 using Athena: http://ohdsi.org/web/ATHENA -TemplateSQL File Instructions +OHDSI-SQL File Instructions ----------------------------- 1. Set parameter name of schema that contains CDMv4 instance @@ -75,13 +76,12 @@ TemplateSQL File Instructions 2. Run the resulting script on your target RDBDMS. *********************************************************************************/ - /* SCRIPT PARAMETERS */ - -- The CDMv4 database name - -- The CDMv4 database plus schema - -- The target CDMv5 database name - -- the target CDMv5 database plus schema - + -- The CDMv4 database name + -- The CDMv4 database plus schema + -- The target CDMv5 database name + -- the target CDMv5 database plus schema + SET search_path TO [TARGET_CDMV5]; /* @@ -110,79 +110,84 @@ SET search_path TO [TARGET_CDMV5]; */ DROP TABLE IF EXISTS concept_map; -CREATE TEMP TABLE concept_map - ( - source_concept_id int, - target_concept_id int, - domain_id varchar(20) -); +/* / */ +CREATE TEMP TABLE concept_map + +AS +SELECT + concept_id AS source_concept_id + ,concept_id AS target_concept_id + ,domain_id AS domain_id + +FROM + [TARGET_CDMV5].[SCHEMA].concept +WHERE 1 = 0; + +/* / */ + +INSERT INTO concept_map --standard concepts -INSERT INTO concept_map (source_concept_id, target_concept_id, domain_id) -select concept_id as source_concept_id, - concept_id as target_concept_id, - domain_id -from [TARGET_CDMV5].[SCHEMA].concept -where standard_concept = 'S' -and invalid_reason is null +SELECT concept_id AS source_concept_id + ,concept_id AS target_concept_id + ,domain_id +FROM [TARGET_CDMV5].[SCHEMA].concept +WHERE standard_concept = 'S' + AND invalid_reason IS NULL -union +UNION --concepts with 'map to' standard -select distinct c1.concept_id as source_concept_id, - c2.concept_id as target_concept_id, - c2.domain_id -from -( -select concept_id -from [TARGET_CDMV5].[SCHEMA].concept -where ((standard_concept <> 'S' or standard_concept is null) -or invalid_reason is not null -) -) c1 -inner join -[TARGET_CDMV5].[SCHEMA].concept_relationship cr1 -on c1.concept_id = cr1.concept_id_1 -inner join -[TARGET_CDMV5].[SCHEMA].concept c2 -on cr1.concept_id_2 = c2.concept_id -where c2.standard_concept = 'S' -and c2.invalid_reason is null -and cr1.relationship_id in ('Maps to') -and cr1.invalid_reason is null +SELECT DISTINCT c1.concept_id AS source_concept_id + ,c2.concept_id AS target_concept_id + ,c2.domain_id +FROM ( + SELECT concept_id + FROM [TARGET_CDMV5].[SCHEMA].concept + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL + ) + OR invalid_reason IS NOT NULL + ) + ) c1 +INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 +INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id +WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ('Maps to') + AND cr1.invalid_reason IS NULL - -union +UNION --concepts without 'map to' standard with another non 'is a' relation to standard -select distinct c1.concept_id as source_concept_id, - c2.concept_id as target_concept_id, - c2.domain_id -from -( +SELECT DISTINCT c1.concept_id AS source_concept_id + ,c2.concept_id AS target_concept_id + ,c2.domain_id +FROM ( SELECT A.concept_id FROM [TARGET_CDMV5].[SCHEMA].concept A - LEFT JOIN - ( - SELECT DISTINCT c1.concept_id - FROM ( - SELECT concept_id - FROM [TARGET_CDMV5].[SCHEMA].concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL + LEFT JOIN ( + SELECT DISTINCT c1.concept_id + FROM ( + SELECT concept_id + FROM [TARGET_CDMV5].[SCHEMA].concept + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL ) - ) c1 - INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 - INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id - WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ('Maps to') - AND cr1.invalid_reason IS NULL - ) B ON A.concept_id = B.concept_id + OR invalid_reason IS NOT NULL + ) + ) c1 + INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 + INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id + WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ('Maps to') + AND cr1.invalid_reason IS NULL + ) B ON A.concept_id = B.concept_id WHERE ( ( A.standard_concept <> 'S' @@ -191,25 +196,25 @@ from OR A.invalid_reason IS NOT NULL ) AND B.concept_id IS NULL -) c1 -inner join [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 on c1.concept_id = cr1.concept_id_1 -inner join [TARGET_CDMV5].[SCHEMA].concept c2 on cr1.concept_id_2 = c2.concept_id -where c2.standard_concept = 'S' - and c2.invalid_reason is null - and cr1.relationship_id in ( - 'RxNorm replaced by', - 'SNOMED replaced by', - 'UCUM replaced by', - 'Concept replaced by', - 'ICD9P replaced by', - 'LOINC replaced by', - 'Concept same_as to', - 'Concept was_a to', - 'Concept alt_to to' -) -and cr1.invalid_reason is null + ) c1 +INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 +INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id +WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ( + 'RxNorm replaced by' + ,'SNOMED replaced by' + ,'UCUM replaced by' + ,'Concept replaced by' + ,'ICD9P replaced by' + ,'LOINC replaced by' + ,'Concept same_as to' + ,'Concept was_a to' + ,'Concept alt_to to' + ) + AND cr1.invalid_reason IS NULL -union +UNION --concepts without 'map to' standard with 'is a' relation to standard SELECT DISTINCT c1.concept_id AS source_concept_id @@ -218,38 +223,37 @@ SELECT DISTINCT c1.concept_id AS source_concept_id FROM ( SELECT A.concept_id FROM [TARGET_CDMV5].[SCHEMA].concept A - LEFT JOIN - ( - SELECT DISTINCT c1.concept_id - FROM ( - SELECT concept_id - FROM [TARGET_CDMV5].[SCHEMA].concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL + LEFT JOIN ( + SELECT DISTINCT c1.concept_id + FROM ( + SELECT concept_id + FROM [TARGET_CDMV5].[SCHEMA].concept + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL ) - ) c1 - INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 - INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id - WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ( - 'Maps to' - ,'RxNorm replaced by' - ,'SNOMED replaced by' - ,'UCUM replaced by' - ,'Concept replaced by' - ,'ICD9P replaced by' - ,'LOINC replaced by' - ,'Concept same_as to' - ,'Concept was_a to' - ,'Concept alt_to to' + OR invalid_reason IS NOT NULL ) - AND cr1.invalid_reason IS NULL - ) B ON A.concept_id = B.concept_id + ) c1 + INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 + INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id + WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ( + 'Maps to' + ,'RxNorm replaced by' + ,'SNOMED replaced by' + ,'UCUM replaced by' + ,'Concept replaced by' + ,'ICD9P replaced by' + ,'LOINC replaced by' + ,'Concept same_as to' + ,'Concept was_a to' + ,'Concept alt_to to' + ) + AND cr1.invalid_reason IS NULL + ) B ON A.concept_id = B.concept_id WHERE ( ( standard_concept <> 'S' @@ -266,1475 +270,1599 @@ WHERE c2.standard_concept = 'S' AND cr1.relationship_id IN ('Is a') AND cr1.invalid_reason IS NULL; --- Update the source_concept_map_occurrence column --- to contain a count to indicate the number of target_concept_ids --- map to that source_concept_id. This will be used elsewhere in --- the script to ensure that we generate new primary keys --- for the target tables when applicable -/* - UPDATE #concept_map - SET #concept_map.source_concept_map_occurrence = A.targetConceptCount - FROM - #concept_map, - ( - select source_concept_id, domain_id, count(*) as "targetConceptCount" - from #concept_map - group by source_concept_id, domain_id - ) AS A -WHERE #concept_map.source_concept_id = A.source_concept_id AND #concept_map.domain_id = A.domain_id; - -UPDATE #concept_map -SET source_concept_map_occurrence = "targetConceptCount" -FROM - ( - select source_concept_id, domain_id, count(*) as "targetConceptCount" - from #concept_map - group by source_concept_id, domain_id - ) A -WHERE #concept_map.source_concept_id = A.source_concept_id AND #concept_map.domain_id = A.domain_id; - -UPDATE #concept_map -SET source_concept_map_occurrence = ( - select count(*) as "targetConceptCount" - from #concept_map A - WHERE A.source_concept_id = #concept_map.source_concept_id AND A.domain_id = #concept_map.domain_id - group by source_concept_id, domain_id - ) -*/ - DROP TABLE IF EXISTS concept_map_distinct; -CREATE TEMP TABLE concept_map_distinct - ( - source_concept_id int, - domain_id varchar(20), - targetConceptCount int -); +/* / */ - INSERT INTO concept_map_distinct (source_concept_id, domain_id, targetConceptCount) - SELECT source_concept_id, domain_id, COUNT(*) - FROM concept_map - GROUP BY source_concept_id, domain_id; +CREATE TEMP TABLE concept_map_distinct + +AS +SELECT + source_concept_id + ,domain_id + ,COUNT(*) AS targetConceptCount + +FROM + concept_map +WHERE 1 = 0 +GROUP BY source_concept_id + ,domain_id; + +/* / */ + +INSERT INTO concept_map_distinct +SELECT source_concept_id + ,domain_id + ,COUNT(*) +FROM concept_map +GROUP BY source_concept_id + ,domain_id; - DROP TABLE IF EXISTS [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS; -CREATE TABLE [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS -( - WARNING_MESSAGE varchar(4000) -); - +/* / */ + +CREATE TABLE [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE VARCHAR(4000)); +/* / */ + /**** CDM_SOURCE ****/ - -INSERT INTO [TARGET_CDMV5].[SCHEMA].cdm_source (cdm_source_name, cdm_version, vocabulary_version, cdm_release_date) -select '[TARGET_CDMV5]', 'V5', v.vocabulary_version, CURRENT_DATE -from [TARGET_CDMV5].[SCHEMA].vocabulary v -where vocabulary_id = 'Vocabulary'; +INSERT INTO [TARGET_CDMV5].[SCHEMA].cdm_source ( + cdm_source_name + ,cdm_version + ,vocabulary_version + ,cdm_release_date + ) +SELECT '[TARGET_CDMV5]' + ,'V5' + ,v.vocabulary_version + ,CURRENT_DATE +FROM [TARGET_CDMV5].[SCHEMA].vocabulary v +WHERE vocabulary_id = 'Vocabulary'; /**** LOCATION ****/ - -insert into [TARGET_CDMV5].[SCHEMA].location -select location_id, address_1, address_2, city, state, zip, county, location_source_value -from [SOURCE_CDMV4].[SCHEMA].LOCATION; +INSERT INTO [TARGET_CDMV5].[SCHEMA].location +SELECT location_id + ,address_1 + ,address_2 + ,city + ,STATE + ,zip + ,county + ,location_source_value +FROM [SOURCE_CDMV4].[SCHEMA].LOCATION; /**** CARE_SITE ****/ - -insert into [TARGET_CDMV5].[SCHEMA].care_site -select care_site_id, cast(null as varchar(255)) as care_site_name, place_of_service_concept_id, location_id, care_site_source_value, place_of_service_source_value -from [SOURCE_CDMV4].[SCHEMA].CARE_SITE; +INSERT INTO [TARGET_CDMV5].[SCHEMA].care_site +SELECT care_site_id + ,cast(NULL AS VARCHAR(255)) AS care_site_name + ,place_of_service_concept_id + ,location_id + ,care_site_source_value + ,place_of_service_source_value +FROM [SOURCE_CDMV4].[SCHEMA].CARE_SITE; /**** Provider ****/ +INSERT INTO [TARGET_CDMV5].[SCHEMA].provider +SELECT provider_id + ,cast(NULL AS VARCHAR(255)) AS provider_name + ,NPI + ,DEA + ,specialty_concept_id + ,care_site_id + ,cast(NULL AS INT) AS year_of_birth + ,cast(NULL AS INT) AS gender_concept_id + ,provider_source_value + ,specialty_source_value + ,0 AS specialty_source_concept_id + ,cast(NULL AS VARCHAR(50)) AS gender_source_value + ,cast(NULL AS INT) AS gender_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].provider; -insert into [TARGET_CDMV5].[SCHEMA].provider -select provider_id, cast(null as varchar(255)) as provider_name, NPI, DEA, specialty_concept_id, care_site_id, cast(null as integer) as year_of_birth, - cast(null as integer) as gender_concept_id, provider_source_value, specialty_source_value, 0 as specialty_source_concept_id, - cast(null as varchar(50)) as gender_source_value, cast(null as integer) as gender_source_concept_id -from [SOURCE_CDMV4].[SCHEMA].provider -; - - - /**** +/**** PERSON ****/ - - INSERT into [TARGET_CDMV5].[SCHEMA].person - SELECT - person_id, - coalesce(gender.target_concept_id, 0) as gender_concept_id, - year_of_birth, - month_of_birth, - day_of_birth, - CAST(null as varchar(50)) time_of_birth, - coalesce(race.target_concept_id, 0) as race_concept_id, - coalesce(ethnicity.target_concept_id, 0) as ethnicity_concept_id, - location_id, - provider_id, - care_site_id, - person_source_value, - gender_source_value, - CAST(null as integer) gender_source_concept_id, - CAST(null as integer) race_source_value, - CAST(null as integer) race_source_concept_id, - ethnicity_source_value, - CAST(null as integer) ethnicity_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].PERSON p - left JOIN concept_map gender on LOWER(gender.DOMAIN_ID) IN ('gender') and p.gender_concept_id = gender.source_concept_id - left JOIN concept_map race on LOWER(race.DOMAIN_ID) IN ('race') and p.race_concept_id = race.source_concept_id - LEFT JOIN concept_map ethnicity on LOWER(ethnicity.DOMAIN_ID) IN ('ethnicity') and p.ETHNICITY_CONCEPT_ID = ethnicity.source_concept_id; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PERSON: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid GENDER_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PERSON - WHERE GENDER_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('gender') - ) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PERSON: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid RACE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PERSON - WHERE RACE_CONCEPT_ID IS NOT NULL - AND RACE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('race')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PERSON: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid ETHNICITY_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PERSON - WHERE ETHNICITY_CONCEPT_ID IS NOT NULL - AND ETHNICITY_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('ethnicity')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - /**** +INSERT INTO [TARGET_CDMV5].[SCHEMA].person +SELECT person_id + ,coalesce(gender.target_concept_id, 0) AS gender_concept_id + ,year_of_birth + ,month_of_birth + ,day_of_birth + ,CAST(NULL AS VARCHAR(10)) time_of_birth + ,coalesce(race.target_concept_id, 0) AS race_concept_id + ,coalesce(ethnicity.target_concept_id, 0) AS ethnicity_concept_id + ,location_id + ,provider_id + ,care_site_id + ,person_source_value + ,gender_source_value + ,CAST(NULL AS INT) gender_source_concept_id + ,CAST(NULL AS INT) race_source_value + ,CAST(NULL AS INT) race_source_concept_id + ,ethnicity_source_value + ,CAST(NULL AS INT) ethnicity_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].PERSON p +LEFT JOIN concept_map gender ON LOWER(gender.DOMAIN_ID) IN ('gender') + AND p.gender_concept_id = gender.source_concept_id +LEFT JOIN concept_map race ON LOWER(race.DOMAIN_ID) IN ('race') + AND p.race_concept_id = race.source_concept_id +LEFT JOIN concept_map ethnicity ON LOWER(ethnicity.DOMAIN_ID) IN ('ethnicity') + AND p.ETHNICITY_CONCEPT_ID = ethnicity.source_concept_id; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PERSON: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid GENDER_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PERSON + WHERE GENDER_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('gender') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PERSON: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid RACE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PERSON + WHERE RACE_CONCEPT_ID IS NOT NULL + AND RACE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('race') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PERSON: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid ETHNICITY_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PERSON + WHERE ETHNICITY_CONCEPT_ID IS NOT NULL + AND ETHNICITY_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('ethnicity') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** OBSERVATION_PERIOD ****/ +INSERT INTO [TARGET_CDMV5].[SCHEMA].observation_period +SELECT observation_period_id + ,person_id + ,observation_period_start_date + ,observation_period_end_date + ,44814722 AS period_type_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION_PERIOD; - INSERT INTO [TARGET_CDMV5].[SCHEMA].observation_period - SELECT observation_period_id, person_id, observation_period_start_date, observation_period_end_date, 44814722 as period_type_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION_PERIOD; - - /**** +/**** DEATH ****/ - - INSERT INTO [TARGET_CDMV5].[SCHEMA].death - SELECT person_id, - death_date, - COALESCE(death_type_concept_id,0) AS death_type_concept_id, - cause_of_death_concept_id as cause_concept_id, - cause_of_death_source_value as cause_source_value, - CAST(null as integer) as cause_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].DEATH - LEFT JOIN concept_map_distinct cm1 - ON DEATH.DEATH_TYPE_CONCEPT_ID = CM1.SOURCE_CONCEPT_ID - AND LOWER(DOMAIN_ID) IN ('death type'); - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'DEATH: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid DEATH_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].DEATH - WHERE DEATH_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('death type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn ; - - - - /**** +INSERT INTO [TARGET_CDMV5].[SCHEMA].death +SELECT person_id + ,death_date + ,COALESCE(death_type_concept_id, 0) AS death_type_concept_id + ,cause_of_death_concept_id AS cause_concept_id + ,cause_of_death_source_value AS cause_source_value + ,CAST(NULL AS INT) AS cause_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].DEATH +LEFT JOIN concept_map_distinct cm1 ON DEATH.DEATH_TYPE_CONCEPT_ID = CM1.SOURCE_CONCEPT_ID + AND LOWER(DOMAIN_ID) IN ('death type'); + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'DEATH: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid DEATH_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].DEATH + WHERE DEATH_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('death type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** VISIT_OCCURRENCE ****/ - - INSERT INTO [TARGET_CDMV5].[SCHEMA].visit_occurrence - SELECT visit_occurrence_id, person_id, - COALESCE(cm1.target_concept_id,0) as visit_concept_id, - visit_start_date, CAST(null as varchar(10)) visit_start_time, - visit_end_date, CAST(null as varchar(10)) visit_end_time, - 44818517 as visit_type_concept_id, - CAST(null as integer) provider_id, - care_site_id, place_of_service_source_value as visit_source_value, - CAST(null as integer) visit_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].VISIT_OCCURRENCE - LEFT JOIN concept_map cm1 - ON VISIT_OCCURRENCE.PLACE_OF_SERVICE_CONCEPT_ID = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('visit'); - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'VISIT_OCCURRENCE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid VISIT_CONCEPT_ID (from the CDMv4 PLACE_OF_SERVICE_CONCEPT_ID field)' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].VISIT_OCCURRENCE - WHERE PLACE_OF_SERVICE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('visit')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - /**** +INSERT INTO [TARGET_CDMV5].[SCHEMA].visit_occurrence +SELECT visit_occurrence_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS visit_concept_id + ,visit_start_date + ,CAST(NULL AS VARCHAR(10)) visit_start_time + ,visit_end_date + ,CAST(NULL AS VARCHAR(10)) visit_end_time + ,44818517 AS visit_type_concept_id + ,CAST(NULL AS INT) provider_id + ,care_site_id + ,place_of_service_source_value AS visit_source_value + ,CAST(NULL AS INT) visit_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].VISIT_OCCURRENCE +LEFT JOIN concept_map cm1 ON VISIT_OCCURRENCE.PLACE_OF_SERVICE_CONCEPT_ID = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('visit'); + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'VISIT_OCCURRENCE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid VISIT_CONCEPT_ID (from the CDMv4 PLACE_OF_SERVICE_CONCEPT_ID field)' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].VISIT_OCCURRENCE + WHERE PLACE_OF_SERVICE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('visit') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** PROCEDURE_OCCURRENCE ****/ +DROP TABLE IF EXISTS po_map; - -- *************************************************************************** - -- AGS: Modifying this section to insert this information into the temp - -- table #po_map but this may need to be revisited for - -- performance tuning on APS as a large temp table may cause processing - -- time issues. - -- *************************************************************************** - - DROP TABLE IF EXISTS po_map; +/* / */ -CREATE TEMP TABLE po_map - ( - procedure_occurrence_id int, - person_id int, - procedure_concept_id int, - procedure_date date, - procedure_type_concept_id int, - modifier_concept_id int, - quantity int, - provider_id int, - visit_occurrence_id int, - procedure_source_value varchar(50), - procedure_source_concept_id int, - qualifier_source_value varchar(50), - origional_drug_id bigint -); +CREATE TEMP TABLE po_map - --find valid procedures from procedure table +AS +SELECT + po.procedure_occurrence_id + ,po.person_id + ,po.procedure_concept_id + ,po.procedure_date + ,po.procedure_type_concept_id + ,po.modifier_concept_id + ,po.quantity + ,po.provider_id + ,po.visit_occurrence_id + ,po.procedure_source_value + ,po.procedure_source_concept_id + ,po.qualifier_source_value + ,de.drug_exposure_id AS origional_drug_id + +FROM + [TARGET_CDMV5].[SCHEMA].procedure_occurrence po +LEFT JOIN [TARGET_CDMV5].[SCHEMA].drug_exposure de ON 1 = 0 +WHERE 0 = 1; + +/* / */ + +--find valid procedures from procedure table INSERT INTO po_map -( - procedure_occurrence_id, - person_id, - procedure_concept_id, - procedure_date, - procedure_type_concept_id, - modifier_concept_id, - quantity, - provider_id, - visit_occurrence_id, - procedure_source_value, - procedure_source_concept_id, - qualifier_source_value, - origional_drug_id -) - SELECT - procedure_occurrence_id, - person_id, - COALESCE(cm1.target_concept_id,0) as procedure_concept_id, - procedure_date, - COALESCE(cm2.target_concept_id,0) as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN concept_map cm1 - ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - INNER JOIN concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount = 1 - LEFT JOIN concept_map cm2 - ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('procedure type') - LEFT JOIN concept_map_distinct cmdis2 - ON cm2.source_concept_id = cmdis2.source_concept_id AND cm2.domain_id = cmdis2.domain_id AND cmdis2.targetConceptCount = 1 +SELECT procedure_occurrence_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS procedure_concept_id + ,procedure_date + ,COALESCE(cm2.target_concept_id, 0) AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id +FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE +INNER JOIN concept_map cm1 ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') +INNER JOIN concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount = 1 +LEFT JOIN concept_map cm2 ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('procedure type') +LEFT JOIN concept_map_distinct cmdis2 ON cm2.source_concept_id = cmdis2.source_concept_id + AND cm2.domain_id = cmdis2.domain_id + AND cmdis2.targetConceptCount = 1 UNION ALL - -- All procedures that did not map to a standard concept in V4 should also carry over to V5 - SELECT - procedure_occurrence_id, - person_id, - procedure_concept_id, - procedure_date, - procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - WHERE procedure_concept_id = 0 +-- All procedures that did not map to a standard concept in V4 should also carry over to V5 +SELECT procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) procedure_source_concept_id + ,NULL qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id +FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE +WHERE procedure_concept_id = 0 UNION ALL - -- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 - SELECT - procedure_occurrence_id, - person_id, - 0 as procedure_concept_id, - procedure_date, - COALESCE(cm2.target_concept_id,0) as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - LEFT JOIN concept_map cm1 - ON procedure_concept_id = cm1.source_concept_id - LEFT JOIN concept_map cm2 - ON procedure_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('procedure type') - where procedure_concept_id <> 0 - and cm1.domain_id IS NULL - +-- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 +SELECT procedure_occurrence_id + ,person_id + ,0 AS procedure_concept_id + ,procedure_date + ,COALESCE(cm2.target_concept_id, 0) AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) procedure_source_concept_id + ,NULL qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id +FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE +LEFT JOIN concept_map cm1 ON procedure_concept_id = cm1.source_concept_id +LEFT JOIN concept_map cm2 ON procedure_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('procedure type') +WHERE procedure_concept_id <> 0 + AND cm1.domain_id IS NULL + UNION ALL - select - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS procedure_occurrence_id, - person_id, - procedure_concept_id, - procedure_date, - procedure_type_concept_id, - modifier_concept_id, - quantity, - provider_id, - visit_occurrence_id, - procedure_source_value, - procedure_source_concept_id, - qualifier_source_value, - origional_drug_id - FROM - ( - --find valid procedures from procedure table that map to more than 1 - --target concept in V5 - SELECT - person_id, - COALESCE(cm1.target_concept_id,0) as procedure_concept_id, - procedure_date, - COALESCE(cm2.target_concept_id,0) as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id, - NULL as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN concept_map cm1 - ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - INNER JOIN concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount > 1 - LEFT JOIN concept_map cm2 - ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('procedure type') - - UNION ALL - - --find procedures that were previously classified as condition - SELECT - person_id, - cm1.target_concept_id as procedure_concept_id, - condition_start_date as procedure_date, - 0 as procedure_type_concept_id, - CAST(null as integer) modifier_concept_id, - CAST(null as integer) quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value as procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) origional_drug_id, - condition_occurrence_id as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,modifier_concept_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,procedure_source_value + ,procedure_source_concept_id + ,qualifier_source_value + ,origional_drug_id +FROM ( + --find valid procedures from procedure table that map to more than 1 + --target concept in V5 + SELECT person_id + ,COALESCE(cm1.target_concept_id, 0) AS procedure_concept_id + ,procedure_date + ,COALESCE(cm2.target_concept_id, 0) AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) procedure_source_concept_id + ,NULL qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + ,CAST(NULL AS INT) AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + INNER JOIN concept_map cm1 ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + INNER JOIN concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount > 1 + LEFT JOIN concept_map cm2 ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('procedure type') + UNION ALL - --find procedures that were previously classified as drug - SELECT person_id, - cm1.target_concept_id as procedure_concept_id, - drug_exposure_start_date as procedure_date, - 0 as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) quantity, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value as procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - drug_exposure_id as origional_drug_id, - drug_exposure_id as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - - - --find procedures that were previously classified as observation + --find procedures that were previously classified as condition + SELECT person_id + ,cm1.target_concept_id AS procedure_concept_id + ,condition_start_date AS procedure_date + ,0 AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value AS procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + ,condition_occurrence_id AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + INNER JOIN concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + UNION ALL - SELECT person_id, - cm1.target_concept_id as procedure_concept_id, - observation_date as procedure_date, - 0 as procedure_type_concept_id, CAST(null as integer) modifier_concept_id, CAST(null as integer) quantity, - associated_provider_id as provider_id, visit_occurrence_id, observation_source_value as procedure_source_value, - CAST(null as integer) procedure_source_concept_id, CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id, - OBSERVATION_ID as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - - - ) OTHERS,(SELECT MAX(PROCEDURE_OCCURRENCE_ID) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE) MAXROW -; - -INSERT INTO [TARGET_CDMV5].[SCHEMA].procedure_occurrence - (procedure_occurrence_id - ,person_id - ,procedure_concept_id - ,procedure_date - ,procedure_type_concept_id - ,modifier_concept_id - ,quantity - ,provider_id - ,visit_occurrence_id - ,procedure_source_value - ,procedure_source_concept_id - ,qualifier_source_value) -SELECT - procedure_occurrence_id - ,person_id - ,procedure_concept_id - ,procedure_date - ,procedure_type_concept_id - ,modifier_concept_id - ,quantity - ,provider_id - ,visit_occurrence_id - ,procedure_source_value - ,procedure_source_concept_id - ,qualifier_source_value + + --find procedures that were previously classified as drug + SELECT person_id + ,cm1.target_concept_id AS procedure_concept_id + ,drug_exposure_start_date AS procedure_date + ,0 AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value AS procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,drug_exposure_id AS origional_drug_id + ,drug_exposure_id AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + INNER JOIN concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + --find procedures that were previously classified as observation + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS procedure_concept_id + ,observation_date AS procedure_date + ,0 AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,observation_source_value AS procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + ,OBSERVATION_ID AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION + INNER JOIN concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + ) OTHERS + ,( + SELECT MAX(PROCEDURE_OCCURRENCE_ID) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + ) MAXROW; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].procedure_occurrence ( + procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,modifier_concept_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,procedure_source_value + ,procedure_source_concept_id + ,qualifier_source_value + ) +SELECT procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,modifier_concept_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,procedure_source_value + ,procedure_source_concept_id + ,qualifier_source_value FROM po_map; - --warnings of invalid records - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PROCEDURE_OCCURRENCE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid PROCOEDURE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - WHERE PROCEDURE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - STANDARD_CONCEPT = 'S' - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PROCEDURE_OCCURRENCE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid PROCOEDURE_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - WHERE PROCEDURE_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('procedure type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - /**** +--warnings of invalid records +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PROCEDURE_OCCURRENCE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid PROCOEDURE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + WHERE PROCEDURE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR STANDARD_CONCEPT = 'S' + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PROCEDURE_OCCURRENCE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid PROCOEDURE_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + WHERE PROCEDURE_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('procedure type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** DRUG_EXPOSURE ****/ - - --find valid drugs from drug_exposure table +--find valid drugs from drug_exposure table DROP TABLE IF EXISTS drgexp_map; -CREATE TEMP TABLE drgexp_map - ( - drug_exposure_id int, - person_id int, - drug_concept_id int, - drug_exposure_start_date date, - drug_exposure_end_date date, - drug_type_concept_id int, - stop_reason varchar(20), - refills int, - quantity NUMERIC, - days_supply int, - sig TEXT, - route_concept_id int, - effective_drug_dose NUMERIC, - dose_unit_concept_id int, - lot_number varchar(50), - provider_id int, - visit_occurrence_id int, - drug_source_value varchar(50), - drug_source_concept_id int, - route_source_value varchar(50), - dose_unit_source_value varchar(50), - origional_procedure_id int -); +/* / */ + +CREATE TEMP TABLE drgexp_map + +AS +SELECT + de.drug_exposure_id + ,de.person_id + ,de.drug_concept_id + ,de.drug_exposure_start_date + ,de.drug_exposure_end_date + ,de.drug_type_concept_id + ,de.stop_reason + ,de.refills + ,de.quantity + ,de.days_supply + ,de.sig + ,de.route_concept_id + ,de.effective_drug_dose + ,de.dose_unit_concept_id + ,de.lot_number + ,de.provider_id + ,de.visit_occurrence_id + ,de.drug_source_value + ,de.drug_source_concept_id + ,de.route_source_value + ,de.dose_unit_source_value + ,po.procedure_occurrence_id AS origional_procedure_id + +FROM + [TARGET_CDMV5].[SCHEMA].drug_exposure de +LEFT JOIN [TARGET_CDMV5].[SCHEMA].procedure_occurrence po ON 1 = 0 +WHERE 0 = 1; + +/* / */ INSERT INTO drgexp_map -( - drug_exposure_id, - person_id, - drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - route_concept_id, - effective_drug_dose, - dose_unit_concept_id, - lot_number, - provider_id, - visit_occurrence_id, - drug_source_value, - drug_source_concept_id, - route_source_value, - dose_unit_source_value, - origional_procedure_id -) - SELECT drug_exposure_id, - person_id, - COALESCE(cm1.target_concept_id,0) as drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - COALESCE(cm2.target_concept_id, 0) drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as NUMERIC) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - CAST(null as varchar(50)) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - CAST(null as varchar(50)) route_source_value, - CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - INNER JOIN concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount = 1 - LEFT JOIN concept_map cm2 - ON drug_exposure.drug_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('drug type') - INNER JOIN concept_map_distinct cmdis2 - ON cm2.source_concept_id = cmdis2.source_concept_id AND cm2.domain_id = cmdis2.domain_id AND cmdis2.targetConceptCount = 1 - WHERE drug_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 +SELECT drug_exposure_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,COALESCE(cm2.target_concept_id, 0) drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS NUMERIC) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id +FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE +INNER JOIN concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') +INNER JOIN concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount = 1 +LEFT JOIN concept_map cm2 ON drug_exposure.drug_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('drug type') +INNER JOIN concept_map_distinct cmdis2 ON cm2.source_concept_id = cmdis2.source_concept_id + AND cm2.domain_id = cmdis2.domain_id + AND cmdis2.targetConceptCount = 1 +WHERE drug_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 UNION ALL - -- All drug exposures that did not map to a standard concept in V4 should also carry over to V5 - SELECT drug_exposure_id, - person_id, - drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as NUMERIC) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - CAST(null as varchar(50)) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - CAST(null as varchar(50)) route_source_value, - CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - WHERE drug_concept_id = 0 +-- All drug exposures that did not map to a standard concept in V4 should also carry over to V5 +SELECT drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS NUMERIC) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id +FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE +WHERE drug_concept_id = 0 UNION ALL - -- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 - SELECT drug_exposure_id, - person_id, - 0, - drug_exposure_start_date, - drug_exposure_end_date, - COALESCE(cm2.target_concept_id, 0) drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as NUMERIC) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - CAST(null as varchar(50)) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - CAST(null as varchar(50)) route_source_value, - CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - LEFT JOIN concept_map cm1 - ON drug_concept_id = cm1.source_concept_id - LEFT JOIN concept_map cm2 - ON drug_exposure.drug_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('drug type') - where drug_concept_id <> 0 - and cm1.domain_id IS NULL - -UNION ALL -select CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS drug_exposure_id, - person_id, drug_concept_id, drug_exposure_start_date, drug_exposure_end_date, - drug_type_concept_id, stop_reason, refills, quantity, days_supply, sig, route_concept_id, - effective_drug_dose, dose_unit_concept_id, lot_number, provider_id, visit_occurrence_id, drug_source_value, - drug_source_concept_id, route_source_value, dose_unit_source_value - , origional_procedure_id -FROM -( +-- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 +SELECT drug_exposure_id + ,person_id + ,0 + ,drug_exposure_start_date + ,drug_exposure_end_date + ,COALESCE(cm2.target_concept_id, 0) drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS NUMERIC) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id +FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE +LEFT JOIN concept_map cm1 ON drug_concept_id = cm1.source_concept_id +LEFT JOIN concept_map cm2 ON drug_exposure.drug_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('drug type') +WHERE drug_concept_id <> 0 + AND cm1.domain_id IS NULL + +UNION ALL + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,route_concept_id + ,effective_drug_dose + ,dose_unit_concept_id + ,lot_number + ,provider_id + ,visit_occurrence_id + ,drug_source_value + ,drug_source_concept_id + ,route_source_value + ,dose_unit_source_value + ,origional_procedure_id +FROM ( --find valid drugs from drug_exposure table that map to > 1 target concept - SELECT - person_id, - COALESCE(cm1.target_concept_id,0) as drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - COALESCE(cm2.target_concept_id, 0) drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as NUMERIC) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - CAST(null as varchar(50)) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - CAST(null as varchar(50)) route_source_value, - CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id, - NULL as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - INNER JOIN concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount > 1 - LEFT JOIN concept_map cm2 - ON drug_exposure.drug_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('drug type') - - UNION ALL - --find drugs that were previously classified as condition - select person_id, - cm1.target_concept_id as drug_concept_id, - condition_start_date as drug_exposure_start_date, null as drug_exposure_end_date, - 0 as drug_type_concept_id, null as stop_reason, null as refills, null as quantity, null as days_supply, null as sig, CAST(null as integer) route_concept_id, - CAST(null as NUMERIC) effective_drug_dose, CAST(null as integer) dose_unit_concept_id, CAST(null as varchar(50)) lot_number, - null as provider_id, visit_occurrence_id, condition_source_value as drug_source_value, - CAST(null as integer) drug_source_concept_id, CAST(null as varchar(50)) route_source_value, CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id, condition_occurrence_id as occurrence_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - - --find drugs that were previously classified as procedure + SELECT person_id + ,COALESCE(cm1.target_concept_id, 0) AS drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,COALESCE(cm2.target_concept_id, 0) drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS NUMERIC) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + ,CAST(NULL AS INT) AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + INNER JOIN concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + INNER JOIN concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount > 1 + LEFT JOIN concept_map cm2 ON drug_exposure.drug_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('drug type') + UNION ALL - select person_id, - cm1.target_concept_id as drug_concept_id, - procedure_date as drug_exposure_start_date, null as drug_exposure_end_date, - 0 as drug_type_concept_id, null as stop_reason, null as refills, null as quantity, null as days_supply, null as sig, CAST(null as integer) route_concept_id, - CAST(null as NUMERIC) effective_drug_dose, CAST(null as integer) dose_unit_concept_id, CAST(null as varchar(50)) lot_number, - null as provider_id, visit_occurrence_id, procedure_source_value as drug_source_value, - CAST(null as integer) drug_source_concept_id, CAST(null as varchar(50)) route_source_value, CAST(null as varchar(50)) dose_unit_source_value, - procedure_occurrence_id as origional_procedure_id, procedure_occurrence_id as occurrence_id + + --find drugs that were previously classified as condition + SELECT person_id + ,cm1.target_concept_id AS drug_concept_id + ,condition_start_date AS drug_exposure_start_date + ,NULL AS drug_exposure_end_date + ,0 AS drug_type_concept_id + ,NULL AS stop_reason + ,CAST(NULL AS INT) AS refills + ,CAST(NULL AS NUMERIC) AS quantity + ,CAST(NULL AS INT) AS days_supply + ,NULL AS sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS NUMERIC) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,condition_source_value AS drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + ,condition_occurrence_id AS occurrence_id + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + INNER JOIN concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + --find drugs that were previously classified as procedure + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS drug_concept_id + ,procedure_date AS drug_exposure_start_date + ,TO_DATE(NULL , 'yyyymmdd') AS drug_exposure_end_date + ,0 AS drug_type_concept_id + ,NULL AS stop_reason + ,CAST(NULL AS INT) AS refills + ,CAST(NULL AS NUMERIC) AS quantity + ,CAST(NULL AS INT) AS days_supply + ,NULL AS sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS NUMERIC) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,procedure_occurrence_id AS origional_procedure_id + ,procedure_occurrence_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - - --find drugs that were previously classified as observation - UNION ALL - select person_id, - cm1.target_concept_id as drug_concept_id, observation_date as drug_exposure_start_date, null as drug_exposure_end_date, - 0 as drug_type_concept_id, null as stop_reason, null as refills, null as quantity, null as days_supply, null as sig, CAST(null as integer) route_concept_id, - CAST(null as NUMERIC) effective_drug_dose, CAST(null as integer) dose_unit_concept_id, CAST(null as varchar(50)) lot_number, - null as provider_id, visit_occurrence_id, observation_source_value as drug_source_value, - CAST(null as integer) drug_source_concept_id, CAST(null as varchar(50)) route_source_value, CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id, observation_id as occurrence_id + INNER JOIN concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + --find drugs that were previously classified as observation + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS drug_concept_id + ,observation_date AS drug_exposure_start_date + ,TO_DATE(NULL , 'yyyymmdd') AS drug_exposure_end_date + ,0 AS drug_type_concept_id + ,NULL AS stop_reason + ,CAST(NULL AS INT) AS refills + ,CAST(NULL AS NUMERIC) AS quantity + ,CAST(NULL AS INT) AS days_supply + ,NULL AS sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS NUMERIC) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,observation_source_value AS drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + ,observation_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') -) OTHERS,(SELECT MAX(DRUG_EXPOSURE_ID) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE) MAXROW -; -INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_exposure - (drug_exposure_id - ,person_id - ,drug_concept_id - ,drug_exposure_start_date - ,drug_exposure_end_date - ,drug_type_concept_id - ,stop_reason - ,refills - ,quantity - ,days_supply - ,sig - ,route_concept_id - ,effective_drug_dose - ,dose_unit_concept_id - ,lot_number - ,provider_id - ,visit_occurrence_id - ,drug_source_value - ,drug_source_concept_id - ,route_source_value - ,dose_unit_source_value) -SELECT + INNER JOIN concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + ) OTHERS + ,( + SELECT MAX(DRUG_EXPOSURE_ID) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + ) MAXROW; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_exposure ( drug_exposure_id - ,person_id - ,drug_concept_id - ,drug_exposure_start_date - ,drug_exposure_end_date - ,drug_type_concept_id - ,stop_reason - ,refills - ,quantity - ,days_supply - ,sig - ,route_concept_id - ,effective_drug_dose - ,dose_unit_concept_id - ,lot_number - ,provider_id - ,visit_occurrence_id - ,drug_source_value - ,drug_source_concept_id - ,route_source_value - ,dose_unit_source_value + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,route_concept_id + ,effective_drug_dose + ,dose_unit_concept_id + ,lot_number + ,provider_id + ,visit_occurrence_id + ,drug_source_value + ,drug_source_concept_id + ,route_source_value + ,dose_unit_source_value + ) +SELECT drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,route_concept_id + ,effective_drug_dose + ,dose_unit_concept_id + ,lot_number + ,provider_id + ,visit_occurrence_id + ,drug_source_value + ,drug_source_concept_id + ,route_source_value + ,dose_unit_source_value FROM drgexp_map; - - --warnings of invalid records - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'DRUG_EXPOSURE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid DRUG_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - WHERE DRUG_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - STANDARD_CONCEPT = 'S' - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'DRUG_EXPOSURE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid DRUG_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - WHERE DRUG_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('drug type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - /**** + +--warnings of invalid records +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'DRUG_EXPOSURE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid DRUG_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + WHERE DRUG_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR STANDARD_CONCEPT = 'S' + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'DRUG_EXPOSURE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid DRUG_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + WHERE DRUG_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('drug type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** CONDITION_OCCURRENCE ****/ - - --find valid conditions from condition_occurrence table - INSERT INTO [TARGET_CDMV5].[SCHEMA].condition_occurrence - SELECT condition_occurrence_id, - person_id, - COALESCE(cm1.target_concept_id, 0) AS condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(cm2.target_concept_id,0) AS condition_type_concept_id, - stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - condition_source_value, CAST(null as integer) condition_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - INNER JOIN concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount = 1 - LEFT JOIN concept_map cm2 - ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('condition type') - WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 +--find valid conditions from condition_occurrence table +INSERT INTO [TARGET_CDMV5].[SCHEMA].condition_occurrence +SELECT condition_occurrence_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(cm2.target_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE +INNER JOIN concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') +INNER JOIN concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount = 1 +LEFT JOIN concept_map cm2 ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('condition type') +WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 UNION ALL - -- All conditions that did not map to a standard concept in V4 should also carry over to V5 - SELECT condition_occurrence_id, - person_id, - condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(condition_type_concept_id,0) AS condition_type_concept_id, - stop_reason, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value, - CAST(null as integer) condition_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - WHERE condition_concept_id = 0 +-- All conditions that did not map to a standard concept in V4 should also carry over to V5 +SELECT condition_occurrence_id + ,person_id + ,condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(condition_type_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE +WHERE condition_concept_id = 0 UNION ALL - -- All conditions that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 - SELECT condition_occurrence_id, - person_id, - 0 AS condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(cm2.target_concept_id,0) AS condition_type_concept_id, - stop_reason, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value, - CAST(null as integer) condition_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - LEFT JOIN concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - LEFT JOIN concept_map cm2 - ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('condition type') - where condition_concept_id <> 0 - and cm1.domain_id IS NULL +-- All conditions that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 +SELECT condition_occurrence_id + ,person_id + ,0 AS condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(cm2.target_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE +LEFT JOIN concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id +LEFT JOIN concept_map cm2 ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('condition type') +WHERE condition_concept_id <> 0 + AND cm1.domain_id IS NULL UNION ALL -select CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS drug_exposure_id, - person_id, condition_concept_id, condition_start_date, condition_end_date, - condition_type_concept_id, stop_reason, provider_id, visit_occurrence_id, - condition_source_value, condition_source_concept_id + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS drug_exposure_id + ,person_id + ,condition_concept_id + ,condition_start_date + ,condition_end_date + ,condition_type_concept_id + ,stop_reason + ,provider_id + ,visit_occurrence_id + ,condition_source_value + ,condition_source_concept_id FROM ( - --find valid conditions from condition_occurrence table that map to > 1 target concept - SELECT - person_id, - COALESCE(cm1.target_concept_id, 0) AS condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(cm2.target_concept_id,0) AS condition_type_concept_id, - stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - condition_source_value, CAST(null as integer) condition_source_concept_id, - NULL as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - INNER JOIN concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount > 1 - LEFT JOIN concept_map cm2 - ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('condition type') - WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 - - UNION ALL - - --find conditions that were previously classified as procedure - select person_id, - cm1.target_concept_id as condition_concept_id, - procedure_date as condition_start_date, null as condition_end_date, - 0 as condition_type_concept_id, null as stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - procedure_source_value as condition_source_value, CAST(null as integer) condition_source_concept_id, - procedure_occurrence_id as OCCURRENCE_ID + SELECT person_id + ,COALESCE(cm1.target_concept_id, 0) AS condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(cm2.target_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,NULL AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + INNER JOIN concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + INNER JOIN concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount > 1 + LEFT JOIN concept_map cm2 ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('condition type') + WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 + + UNION ALL + + --find conditions that were previously classified as procedure + SELECT person_id + ,cm1.target_concept_id AS condition_concept_id + ,procedure_date AS condition_start_date + ,NULL AS condition_end_date + ,0 AS condition_type_concept_id + ,NULL AS stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,procedure_occurrence_id AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - - --find conditions that were previously classified as drug + INNER JOIN concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + --find conditions that were previously classified as drug + UNION ALL - SELECT person_id, - cm1.target_concept_id as condition_concept_id, - drug_exposure_start_date as condition_start_date, null as condition_end_date, - 0 as condition_type_concept_id, null as stop_reason, prescribing_provider_id as provider_id, visit_occurrence_id, - drug_source_value as condition_source_value, CAST(null as integer) condition_source_concept_id, - drug_exposure_id as OCCURRENCE_ID + + SELECT person_id + ,cm1.target_concept_id AS condition_concept_id + ,drug_exposure_start_date AS condition_start_date + ,NULL AS condition_end_date + ,0 AS condition_type_concept_id + ,NULL AS stop_reason + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value AS condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,drug_exposure_id AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - - --find conditions that were previously classified as observation + INNER JOIN concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + --find conditions that were previously classified as observation + UNION ALL - SELECT person_id, - cm1.target_concept_id as condition_concept_id, - observation_date as condition_start_date, null as condition_end_date, - 0 as condition_type_concept_id, null as stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - observation_source_value as condition_source_value, CAST(null as integer) condition_source_concept_id, - observation_id as OCCURRENCE_ID + + SELECT person_id + ,cm1.target_concept_id AS condition_concept_id + ,observation_date AS condition_start_date + ,NULL AS condition_end_date + ,0 AS condition_type_concept_id + ,NULL AS stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,observation_source_value AS condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,observation_id AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') -) OTHERS,(SELECT MAX(condition_occurrence_id) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE) MAXROW -; - - - --warnings of invalid records - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'CONDITION_OCCURRENCE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid CONDITION_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - WHERE CONDITION_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - STANDARD_CONCEPT = 'S' - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'CONDIITON_OCCURRENCE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid CONDITION_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - WHERE CONDITION_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('condition type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - + INNER JOIN concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + ) OTHERS + ,( + SELECT MAX(condition_occurrence_id) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + ) MAXROW; - /**** +--warnings of invalid records +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'CONDITION_OCCURRENCE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid CONDITION_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + WHERE CONDITION_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR STANDARD_CONCEPT = 'S' + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'CONDIITON_OCCURRENCE: ' || CAST(NUM_INVALID_RECORDS AS VARCHAR) || ' records in the source CDMv4 database have invalid CONDITION_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + WHERE CONDITION_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('condition type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** DEVICE_EXPOSURE ****/ - INSERT INTO [TARGET_CDMV5].[SCHEMA].device_exposure -select row_number() over (order by OCCURRENCE_ID) AS device_exposure_id, - person_id, device_concept_id, device_exposure_start_date, device_exposure_end_date, device_type_concept_id, - unique_device_id, quantity, provider_id, visit_occurrence_id, device_source_value, device_source_concept_id -FROM -( +SELECT row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS device_exposure_id + ,person_id + ,device_concept_id + ,device_exposure_start_date + ,device_exposure_end_date + ,device_type_concept_id + ,unique_device_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,device_source_value + ,device_source_concept_id +FROM ( --find devices that were previously classified as procedures - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - PROCEDURE_DATE AS DEVICE_EXPOSURE_START_DATE, - TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, CAST(NULL as VARCHAR(50)) unique_device_id, - CAST(null as integer) quantity, ASSOCIATED_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, PROCEDURE_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - PROCEDURE_OCCURRENCE_ID as OCCURRENCE_ID + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,PROCEDURE_DATE AS DEVICE_EXPOSURE_START_DATE + ,TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,CAST(NULL AS VARCHAR(50)) unique_device_id + ,CAST(NULL AS INT) quantity + ,ASSOCIATED_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,PROCEDURE_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,PROCEDURE_OCCURRENCE_ID AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') - + INNER JOIN concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') --find devices that were previously classified as drug exposure - UNION ALL - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - DRUG_EXPOSURE_START_DATE AS DEVICE_EXPOSURE_START_DATE, - TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, CAST(NULL as VARCHAR(50)) unique_device_id, - quantity, PRESCRIBING_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, DRUG_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - DRUG_EXPOSURE_ID as OCCURRENCE_ID + + UNION ALL + + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS DEVICE_EXPOSURE_START_DATE + ,TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,CAST(NULL AS VARCHAR(50)) unique_device_id + ,quantity + ,PRESCRIBING_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,DRUG_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,DRUG_EXPOSURE_ID AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') - + INNER JOIN concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') --find devices that were previously classified as conditions + UNION ALL - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - CONDITION_START_DATE AS DEVICE_EXPOSURE_START_DATE, - TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, CAST(NULL as VARCHAR(50)) unique_device_id, - CAST(NULL as integer) quantity, ASSOCIATED_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, CONDITION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - CONDITION_OCCURRENCE_ID as OCCURRENCE_ID + + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,CONDITION_START_DATE AS DEVICE_EXPOSURE_START_DATE + ,TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,CAST(NULL AS VARCHAR(50)) unique_device_id + ,CAST(NULL AS INT) quantity + ,ASSOCIATED_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,CONDITION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,CONDITION_OCCURRENCE_ID AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') - + INNER JOIN concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') --find devices that were previously classified as observations + UNION ALL - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - OBSERVATION_DATE AS DEVICE_EXPOSURE_START_DATE, - TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, CAST(NULL as VARCHAR(50)) unique_device_id, - CAST(null as integer) quantity, ASSOCIATED_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, OBSERVATION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - OBSERVATION_ID as OCCURRENCE_ID + + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,OBSERVATION_DATE AS DEVICE_EXPOSURE_START_DATE + ,TO_DATE(NULL , 'yyyymmdd') AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,CAST(NULL AS VARCHAR(50)) unique_device_id + ,CAST(NULL AS INT) quantity + ,ASSOCIATED_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,OBSERVATION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,OBSERVATION_ID AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') -) OTHERS -; - - - /**** + INNER JOIN concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') + ) OTHERS; + +/**** MEASUREMENT ****/ - --find valid measurements from observation table INSERT INTO [TARGET_CDMV5].[SCHEMA].measurement -SELECT row_number() over (order by occurrence_id) AS measurement_id, - person_id, measurement_concept_id, measurement_date, measurement_time, measurement_type_concept_id, operator_concept_id, value_as_number, value_as_concept_id, unit_concept_id, range_low, range_high, - provider_id, visit_occurrence_id, measurement_source_value, measurement_source_concept_id, unit_source_value, value_source_value -from -( +SELECT row_number() OVER ( + ORDER BY occurrence_id + ) AS measurement_id + ,person_id + ,measurement_concept_id + ,measurement_date + ,measurement_time + ,measurement_type_concept_id + ,operator_concept_id + ,value_as_number + ,value_as_concept_id + ,unit_concept_id + ,range_low + ,range_high + ,provider_id + ,visit_occurrence_id + ,measurement_source_value + ,measurement_source_concept_id + ,unit_source_value + ,value_source_value +FROM ( --find mesaurements that were previously classified as observations - select person_id, - cm1.target_concept_id AS measurement_concept_id, - OBSERVATION_DATE AS measurement_date, - CAST(OBSERVATION_TIME as varchar(50)) AS measurement_time, - 0 AS measurement_type_concept_id, - CAST(null as integer) operator_concept_id, - value_as_number, - value_as_concept_id, - COALESCE(cm2.target_concept_id,0) AS unit_concept_id, - range_low, - range_high, - ASSOCIATED_PROVIDER_ID AS provider_id, - visit_occurrence_id, - OBSERVATION_SOURCE_VALUE AS measurement_source_value, - CAST(null as integer) measurement_source_concept_id, - unit_source_value AS unit_source_value, - cast(null as varchar(50)) as value_source_value, - observation_id as occurrence_id + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,OBSERVATION_DATE AS measurement_date + ,CAST(OBSERVATION_TIME AS VARCHAR(50)) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) operator_concept_id + ,value_as_number + ,value_as_concept_id + ,COALESCE(cm2.target_concept_id, 0) AS unit_concept_id + ,range_low + ,range_high + ,ASSOCIATED_PROVIDER_ID AS provider_id + ,visit_occurrence_id + ,OBSERVATION_SOURCE_VALUE AS measurement_source_value + ,CAST(NULL AS INT) measurement_source_concept_id + ,unit_source_value AS unit_source_value + ,cast(NULL AS VARCHAR(50)) AS value_source_value + ,observation_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - LEFT JOIN concept_map cm2 - ON observation.unit_concept_id = cm2.source_concept_id - AND LOWER(cm1.domain_id) IN ('unit') - + INNER JOIN concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + LEFT JOIN concept_map cm2 ON observation.unit_concept_id = cm2.source_concept_id + AND LOWER(cm1.domain_id) IN ('unit') + UNION ALL - - SELECT person_id, - cm1.target_concept_id as measurement_concept_id, - procedure_date as measurement_date, - CAST(NULL as varchar(50)) as measurement_time, - 0 as measurement_type_concept_id, - CAST(null as integer) as operator_concept_id, - CAST(null as integer) as value_as_number, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as range_low, - CAST(null as integer) as range_high, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value as measurement_source_value, - CAST(null as integer) as measurement_source_concept_id, - CAST(null as varchar(50)) as unit_source_value, - CAST(null as varchar(50)) as value_source_value, - procedure_occurrence_id as occurrence_id + + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,procedure_date AS measurement_date + ,CAST(NULL AS VARCHAR(50)) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) AS operator_concept_id + ,CAST(NULL AS INT) AS value_as_number + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS range_low + ,CAST(NULL AS INT) AS range_high + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS measurement_source_value + ,CAST(NULL AS INT) AS measurement_source_concept_id + ,CAST(NULL AS VARCHAR(50)) AS unit_source_value + ,CAST(NULL AS VARCHAR(50)) AS value_source_value + ,procedure_occurrence_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - + INNER JOIN concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + UNION ALL - - SELECT person_id, - cm1.target_concept_id as measurement_concept_id, - condition_start_date as measurement_date, - CAST(NULL as varchar(50)) as measurement_time, - 0 as measurement_type_concept_id, - CAST(null as integer) as operator_concept_id, - CAST(null as integer) as value_as_number, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as range_low, - CAST(null as integer) as range_high, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value as measurement_source_value, - CAST(null as integer) as measurement_source_concept_id, - CAST(null as varchar(50)) as unit_source_value, - CAST(null as varchar(50)) as value_source_value, - condition_occurrence_id as occurrence_id + + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,condition_start_date AS measurement_date + ,CAST(NULL AS VARCHAR(50)) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) AS operator_concept_id + ,CAST(NULL AS INT) AS value_as_number + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS range_low + ,CAST(NULL AS INT) AS range_high + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value AS measurement_source_value + ,CAST(NULL AS INT) AS measurement_source_concept_id + ,CAST(NULL AS VARCHAR(50)) AS unit_source_value + ,CAST(NULL AS VARCHAR(50)) AS value_source_value + ,condition_occurrence_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - + INNER JOIN concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + UNION ALL - - SELECT person_id, - cm1.target_concept_id as measurement_concept_id, - drug_exposure_start_date as measurement_date, - CAST(NULL as varchar(50)) as measurement_time, - 0 as measurement_type_concept_id, - CAST(null as integer) as operator_concept_id, - CAST(null as integer) as value_as_number, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as range_low, - CAST(null as integer) as range_high, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value as measurement_source_value, - CAST(null as integer) as measurement_source_concept_id, - CAST(null as varchar(50)) as unit_source_value, - CAST(null as varchar(50)) as value_source_value, - drug_exposure_id as occurrence_id + + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,drug_exposure_start_date AS measurement_date + ,CAST(NULL AS VARCHAR(50)) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) AS operator_concept_id + ,CAST(NULL AS INT) AS value_as_number + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS range_low + ,CAST(NULL AS INT) AS range_high + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value AS measurement_source_value + ,CAST(NULL AS INT) AS measurement_source_concept_id + ,CAST(NULL AS VARCHAR(50)) AS unit_source_value + ,CAST(NULL AS VARCHAR(50)) AS value_source_value + ,drug_exposure_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].drug_exposure - INNER JOIN concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - - -) OTHERS -; - - - - /**** + INNER JOIN concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + ) OTHERS; + +/**** OBSERVATION ****/ - - - --find valid observation from observation table - INSERT INTO [TARGET_CDMV5].[SCHEMA].observation - SELECT - observation_id, - person_id, - observation_concept_id, - observation_date, - CAST(observation_time as varchar(50)) as observation_time, - observation_type_concept_id, - value_as_number, - value_as_string, - value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - unit_concept_id, - associated_provider_id as provider_id, - visit_occurrence_id, - observation_source_value, - CAST(null as integer) observation_source_concept_id, - unit_source_value, - cast(null as varchar(50)) qualifier_source_value - FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - WHERE observation_concept_id NOT IN (SELECT source_concept_id FROM concept_map_distinct WHERE LOWER(domain_id) IN ('condition','drug','procedure','device','measurement')) +--find valid observation from observation table +INSERT INTO [TARGET_CDMV5].[SCHEMA].observation +SELECT observation_id + ,person_id + ,observation_concept_id + ,observation_date + ,CAST(observation_time AS VARCHAR(50)) AS observation_time + ,observation_type_concept_id + ,value_as_number + ,value_as_string + ,value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,unit_concept_id + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value +FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION +WHERE observation_concept_id NOT IN ( + SELECT source_concept_id + FROM concept_map_distinct + WHERE LOWER(domain_id) IN ( + 'condition' + ,'drug' + ,'procedure' + ,'device' + ,'measurement' + ) + ) +--find observations that were previously classified as procedure - - --find observations that were previously classified as procedure -UNION ALL -select - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS observation_id, - person_id, - observation_concept_id, - observation_date, - observation_time, - observation_type_concept_id, - value_as_number, - 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 -( - select person_id, - cm1.target_concept_id as observation_concept_id, - procedure_date as observation_date, - CAST(null as varchar(50)) as observation_time, - 0 as observation_type_concept_id, - CAST(null as NUMERIC) as value_as_number, - null as value_as_string, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - CAST(null as integer) as unit_concept_id, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value as observation_source_value, - CAST(null as integer) observation_source_concept_id, - null as unit_source_value, - cast(null as varchar(50)) qualifier_source_value, - procedure_occurrence_id as occurrence_id +UNION ALL + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS observation_id + ,person_id + ,observation_concept_id + ,observation_date + ,observation_time + ,observation_type_concept_id + ,value_as_number + ,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 ( + SELECT person_id + ,cm1.target_concept_id AS observation_concept_id + ,procedure_date AS observation_date + ,CAST(NULL AS VARCHAR(50)) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS NUMERIC) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,NULL AS unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value + ,procedure_occurrence_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('observation') - - --find observations that were previously classified as condition - UNION ALL - SELECT person_id, - cm1.target_concept_id as observation_concept_id, - condition_start_date as observation_date, - CAST(null as varchar(50)) as observation_time, - 0 as observation_type_concept_id, - CAST(null as NUMERIC) as value_as_number, - null as value_as_string, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - CAST(null as integer) as unit_concept_id, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value as observation_source_value, - CAST(null as integer) observation_source_concept_id, - null as unit_source_value, - cast(null as varchar(50)) qualifier_source_value, - condition_occurrence_id as occurrence_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('observation') - - --find observations that were previously classified as drug exposure + INNER JOIN concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + --find observations that were previously classified as condition + UNION ALL - SELECT person_id, - cm1.target_concept_id as observation_concept_id, - drug_exposure_start_date as observation_date, - CAST(null as varchar(10)) as observation_time, - 0 as observation_type_concept_id, - CAST(null as NUMERIC) as value_as_number, - null as value_as_string, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as provider_id, - visit_occurrence_id, - drug_source_value as observation_source_value, - CAST(null as integer) observation_source_concept_id, - null as unit_source_value, - cast(null as varchar(50)) qualifier_source_value, - drug_exposure_id as occurrence_id + + SELECT person_id + ,cm1.target_concept_id AS observation_concept_id + ,condition_start_date AS observation_date + ,CAST(NULL AS VARCHAR(50)) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS NUMERIC) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value AS observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,NULL AS unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value + ,condition_occurrence_id AS occurrence_id + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + INNER JOIN concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + + UNION ALL + + --find DRG observations that were previously classified as procedure_cost + SELECT po.person_id + ,cm1.target_concept_id AS observation_concept_id + ,po.procedure_date AS observation_date + ,CAST(NULL AS VARCHAR(50)) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS NUMERIC) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,po.associated_provider_id AS provider_id + ,po.visit_occurrence_id + ,pc.DISEASE_CLASS_SOURCE_VALUE AS observation_source_value + ,cm1.source_concept_id as observation_source_concept_id + ,NULL AS unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value + ,po.procedure_occurrence_id AS occurrence_id + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_COST pc + INNER JOIN [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE po ON pc.PROCEDURE_OCCURRENCE_ID = po.PROCEDURE_OCCURRENCE_ID + INNER JOIN concept_map cm1 ON pc.disease_class_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + + UNION ALL + + --find observations that were previously classified as drug exposure + SELECT person_id + ,cm1.target_concept_id AS observation_concept_id + ,drug_exposure_start_date AS observation_date + ,CAST(NULL AS VARCHAR(10)) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS NUMERIC) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,drug_source_value AS observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,NULL AS unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value + ,drug_exposure_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('observation') - ) OTHERS,(SELECT MAX(OBSERVATION_ID) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION) MAXROW - ; - - - - /**** + INNER JOIN concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + ) OTHERS + ,( + SELECT MAX(OBSERVATION_ID) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION + ) MAXROW; + +/**** PAYER_PLAN_PERIOD ****/ - INSERT INTO [TARGET_CDMV5].[SCHEMA].payer_plan_period -SELECT payer_plan_period_id, person_id, payer_plan_period_start_date, payer_plan_period_end_date, - payer_source_value, plan_source_value, family_source_value +SELECT payer_plan_period_id + ,person_id + ,payer_plan_period_start_date + ,payer_plan_period_end_date + ,payer_source_value + ,plan_source_value + ,family_source_value FROM [SOURCE_CDMV4].[SCHEMA].PAYER_PLAN_PERIOD; - - /**** + +/**** DRUG_COST note : if there were invalid drug concepts in DRUG_EXPOSURE, those records may not enter CDMv5 but costs will persist ****/ - INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_cost -SELECT drug_cost_id, dc.drug_exposure_id, cast(null as integer) currency_concept_id, paid_copay, paid_coinsurance, paid_toward_deductible, paid_by_payer, - paid_by_coordination_benefits, total_out_of_pocket, total_paid, ingredient_cost, dispensing_fee, - average_wholesale_price, payer_plan_period_id -FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST dc -; +SELECT drug_cost_id + ,dc.drug_exposure_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,ingredient_cost + ,dispensing_fee + ,average_wholesale_price + ,payer_plan_period_id +FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST dc; -- insert procedure costs for procedures that were inserted into the drug_exposure table INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_cost -select - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS drug_cost_id, - drug_exposure_id, - cast(null as integer) currency_concept_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - ingredient_cost, - dispensing_fee, - average_wholesale_price, - payer_plan_period_id +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS drug_cost_id + ,drug_exposure_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,ingredient_cost + ,dispensing_fee + ,average_wholesale_price + ,payer_plan_period_id FROM ( - SELECT - drug_exposure_id, - po.person_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - CAST(null as NUMERIC) as ingredient_cost, - CAST(null as NUMERIC) as dispensing_fee, - CAST(null as NUMERIC) as average_wholesale_price, - payer_plan_period_id, - procedure_cost_id as OCCURRENCE_ID + SELECT drug_exposure_id + ,po.person_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,CAST(NULL AS NUMERIC) AS ingredient_cost + ,CAST(NULL AS NUMERIC) AS dispensing_fee + ,CAST(NULL AS NUMERIC) AS average_wholesale_price + ,payer_plan_period_id + ,procedure_cost_id AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE po - join [SOURCE_CDMV4].[SCHEMA].PROCEDURE_COST pc on po.procedure_occurrence_id = pc.procedure_occurrence_id + INNER JOIN [SOURCE_CDMV4].[SCHEMA].PROCEDURE_COST pc ON po.procedure_occurrence_id = pc.procedure_occurrence_id --JOIN dbo.drug_exposure de on de.person_id = po.person_id and pc.procedure_occurrence_id = de.origional_procedure_id - JOIN drgexp_map de on de.person_id = po.person_id and pc.procedure_occurrence_id = de.origional_procedure_id -) OTHERS ,(SELECT MAX(drug_cost_id) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST) MAXROW -; - - /**** + INNER JOIN drgexp_map de ON de.person_id = po.person_id + AND pc.procedure_occurrence_id = de.origional_procedure_id + ) OTHERS + ,( + SELECT MAX(drug_cost_id) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST + ) MAXROW; + +/**** PROCEDURE_COST @@ -1742,127 +1870,219 @@ FROM ( ****/ - INSERT INTO [TARGET_CDMV5].[SCHEMA].procedure_cost -SELECT procedure_cost_id, procedure_occurrence_id, cast(null as integer) currency_concept_id, paid_copay, paid_coinsurance, paid_toward_deductible, - paid_by_payer, paid_by_coordination_benefits, total_out_of_pocket, total_paid, - payer_plan_period_id, revenue_code_concept_id, revenue_code_source_value +SELECT procedure_cost_id + ,procedure_occurrence_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,payer_plan_period_id + ,revenue_code_concept_id + ,revenue_code_source_value FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_COST; - -- insert drug costs for drugs that were inserted into the procedure_occurrence table INSERT INTO [TARGET_CDMV5].[SCHEMA].procedure_cost -SELECT - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS procedure_cost_id, - procedure_occurrence_id, - cast(null as integer) - currency_concept_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - payer_plan_period_id, - revenue_code_concept_id, - revenue_code_source_value - FROM ( - SELECT - po.procedure_occurrence_id, - po.person_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - CAST(null as NUMERIC) as ingredient_cost, - CAST(null as NUMERIC) as dispensing_fee, - CAST(null as NUMERIC) as average_wholesale_price, - payer_plan_period_id, - CAST(null as integer) as revenue_code_concept_id, - CAST(null as integer) as revenue_code_source_value, - drug_cost_id as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE de - join [SOURCE_CDMV4].[SCHEMA].DRUG_COST dc on de.drug_exposure_id = dc.drug_exposure_id - --JOIN dbo.procedure_occurrence po on de.person_id = po.person_id and de.drug_exposure_id = po.origional_drug_id - JOIN po_map po on de.person_id = po.person_id and de.drug_exposure_id = po.origional_drug_id - ) OTHERS,(SELECT MAX(drug_cost_id) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST) MAXROW -; - +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS procedure_cost_id + ,procedure_occurrence_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,payer_plan_period_id + ,revenue_code_concept_id + ,revenue_code_source_value +FROM ( + SELECT po.procedure_occurrence_id + ,po.person_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,CAST(NULL AS NUMERIC) AS ingredient_cost + ,CAST(NULL AS NUMERIC) AS dispensing_fee + ,CAST(NULL AS NUMERIC) AS average_wholesale_price + ,payer_plan_period_id + ,CAST(NULL AS INT) AS revenue_code_concept_id + ,CAST(NULL AS INT) AS revenue_code_source_value + ,drug_cost_id AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE de + INNER JOIN [SOURCE_CDMV4].[SCHEMA].DRUG_COST dc ON de.drug_exposure_id = dc.drug_exposure_id + --JOIN dbo.procedure_occurrence po on de.person_id = po.person_id and de.drug_exposure_id = po.origional_drug_id + INNER JOIN po_map po ON de.person_id = po.person_id + AND de.drug_exposure_id = po.origional_drug_id + ) OTHERS + ,( + SELECT MAX(drug_cost_id) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST + ) MAXROW; + /**** DRUG ERA Note: Eras derived from DRUG_EXPOSURE table, using 30d gap ****/ +DROP TABLE IF EXISTS cteDrugTarget; --- drop table dbo.drug_era -with cteDrugTarget (DRUG_EXPOSURE_ID, PERSON_ID, DRUG_CONCEPT_ID, DRUG_TYPE_CONCEPT_ID, DRUG_EXPOSURE_START_DATE, DRUG_EXPOSURE_END_DATE, INGREDIENT_CONCEPT_ID) as -( - -- 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, (DRUG_EXPOSURE_START_DATE + DAYS_SUPPLY), (DRUG_EXPOSURE_START_DATE + 1)) as DRUG_EXPOSURE_END_DATE, - c.CONCEPT_ID as INGREDIENT_CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].DRUG_EXPOSURE d - join [TARGET_CDMV5].[SCHEMA].CONCEPT_ANCESTOR ca on ca.DESCENDANT_CONCEPT_ID = d.DRUG_CONCEPT_ID - 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' -), -cteEndDates (PERSON_ID, INGREDIENT_CONCEPT_ID, END_DATE) as -- the magic -( - 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 +/* / */ + +-- 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 + [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'; + +/* / */ + +DROP TABLE IF EXISTS cteEndDates; + +/* / */ + +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 - 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 + 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 -), -cteDrugExposureEnds (PERSON_ID, DRUG_CONCEPT_ID, DRUG_TYPE_CONCEPT_ID, DRUG_EXPOSURE_START_DATE, DRUG_ERA_END_DATE) 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 -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, drug_concept_id, min(DRUG_EXPOSURE_START_DATE) as drug_era_start_date, drug_era_end_date, COUNT(*) as DRUG_EXPOSURE_COUNT, 30 as gap_days -from cteDrugExposureEnds -GROUP BY person_id, drug_concept_id, drug_type_concept_id, DRUG_ERA_END_DATE -; +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 [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; /**** @@ -1870,86 +2090,319 @@ CONDITION ERA Note: Eras derived from CONDITION_OCCURRENCE table, using 30d gap ****/ - DROP TABLE IF EXISTS condition_era_phase_1; -CREATE TEMP TABLE condition_era_phase_1 +/* / */ + +DROP TABLE IF EXISTS cteConditionTarget; + +/* / */ + +-- create base eras from the concepts found in condition_occurrence +CREATE TEMP TABLE cteConditionTarget AS -WITH cteConditionTarget (PERSON_ID, CONDITION_CONCEPT_ID, CONDITION_START_DATE, CONDITION_END_DATE) AS -( - -- 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, (CONDITION_START_DATE + 1)) as CONDITION_END_DATE - FROM [TARGET_CDMV5].[SCHEMA].CONDITION_OCCURRENCE co -), -cteEndDates (PERSON_ID, CONDITION_CONCEPT_ID, END_DATE) as -- the magic -( - 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 - 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 -), -cteConditionEnds (PERSON_ID, CONDITION_CONCEPT_ID, CONDITION_START_DATE, ERA_END_DATE) as -( -select - c.PERSON_ID, - c.CONDITION_CONCEPT_ID, - c.CONDITION_START_DATE, - MIN(e.END_DATE) as ERA_END_DATE -FROM cteConditionTarget c -JOIN cteEndDates 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 -) - 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 +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 - cteConditionEnds -GROUP BY person_id, CONDITION_CONCEPT_ID, ERA_END_DATE -; + [TARGET_CDMV5].[SCHEMA].CONDITION_OCCURRENCE co; -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) +/* / */ + +DROP TABLE IF EXISTS cteCondEndDates; + +/* / */ + +CREATE TEMP TABLE cteCondEndDates + +AS SELECT - condition_era_id, - PERSON_ID, - CONDITION_CONCEPT_ID, - CONDITION_ERA_START_DATE, - CONDITION_ERA_END_DATE, - CONDITIOn_OCCURRENCE_COUNT -FROM condition_era_phase_1 + 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 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 [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; + +/**** + +QUALITY ASSURANCE OUTPUT + +Note: These queries are used to provide some basic stats around row counts between your V4 and V5 database + to ensure that all of the data has migrated as expected. + + ****/ + +DROP TABLE IF EXISTS v5_stats; + +/* / */ + +DROP TABLE IF EXISTS v4_stats; + +/* / */ + +-- Get the row counts for each table that is in scope for the migration +CREATE TEMP TABLE v4_stats + +AS +SELECT + * + +FROM + +( + SELECT '[SOURCE_CDMV4]' AS DBName, 'care_site' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].care_site + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'condition_era' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].condition_era + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'condition_occurrence' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].condition_occurrence + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'death' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].death + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'drug_cost' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].drug_cost + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'drug_era' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].drug_era + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'drug_exposure' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].drug_exposure + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'location' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].location + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'observation' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].observation + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'observation_period' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].observation_period + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'payer_plan_period' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].payer_plan_period + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'person' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].person + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'procedure_cost' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].procedure_cost + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'procedure_occurrence' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].procedure_occurrence + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'provider' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].provider + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'visit_occurrence' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].visit_occurrence +) v4_stats; + +/* / */ + +CREATE TEMP TABLE v5_stats + +AS +SELECT + * + +FROM + +( + SELECT '[TARGET_CDMV5]' AS DBName, 'care_site' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].care_site + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'condition_era' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].condition_era + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'condition_occurrence' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].condition_occurrence + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'death' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].death + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'device_exposure' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].device_exposure + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'drug_cost' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].drug_cost + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'drug_era' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].drug_era + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'drug_exposure' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].drug_exposure + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'location' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].location + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'measurement' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].measurement + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'observation' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].observation + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'observation_period' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].observation_period + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'payer_plan_period' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].payer_plan_period + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'person' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].person + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'procedure_cost' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].procedure_cost + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'procedure_occurrence' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].procedure_occurrence + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'provider' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].provider + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'visit_occurrence' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].visit_occurrence +) v5_stats; + +/* / */ + +-- Show the results +select + 'Rowcounts for each database and table', + COALESCE(V4.DBName, 'None') v4_database_name, + v4.TableName v4_table_name, + v4.row_count v4_row_count, + COALESCE(v5.DBName, 'None') v5_database_name, + v5.TableName v5_table_name, + v5.row_count v5_row_count, + COALESCE(v5.row_count, 0) - COALESCE(v4.row_count, 0) row_count_change +from v4_stats v4 +full outer join v5_stats v5 ON v4.TableName = v5.TableName +order by v5.TableName; + +/* + * Determine how the vocabulary/domains helped to map from the V4 source + * tables to the V5 destinations + */ +DROP TABLE IF EXISTS classification_map; + +/* / */ + +CREATE TEMP TABLE classification_map + +AS +SELECT + * + +FROM + +( + SELECT 'Condition_Occurrence' TableName, COALESCE(LOWER(cm.domain_id), 'condition') domain_id, COUNT(*) row_count + FROM [SOURCE_CDMV4].[SCHEMA].Condition_Occurrence CO + LEFT JOIN concept_map CM ON co.condition_concept_id = cm.source_concept_id + GROUP BY COALESCE(LOWER(cm.domain_id), 'condition') + UNION + SELECT 'Drug_Exposure' TableName, COALESCE(LOWER(cm.domain_id), 'drug') domain_id, COUNT(*) row_count + FROM [SOURCE_CDMV4].[SCHEMA].Drug_Exposure de + LEFT JOIN concept_map CM ON de.drug_concept_id = cm.source_concept_id + GROUP BY COALESCE(LOWER(cm.domain_id), 'drug') + UNION + SELECT 'Observation' TableName, COALESCE(LOWER(cm.domain_id), 'observation') domain_id, COUNT(*) row_count + FROM [SOURCE_CDMV4].[SCHEMA].Observation o + LEFT JOIN concept_map CM ON o.observation_concept_id = cm.source_concept_id + GROUP BY COALESCE(LOWER(cm.domain_id), 'observation') + UNION + SELECT 'Procedure_Occurrence' TableName, COALESCE(LOWER(cm.domain_id), 'procedure') domain_id, COUNT(*) row_count + FROM [SOURCE_CDMV4].[SCHEMA].Procedure_Occurrence po + LEFT JOIN concept_map CM ON po.PROCEDURE_CONCEPT_ID = cm.source_concept_id + GROUP BY COALESCE(LOWER(cm.domain_id), 'procedure') +) A +ORDER by A.TableName, A.domain_id; + +/* / */ + +select * +from classification_map +order by tablename, domain_id; + +select domain_id, SUM(row_count) +from classification_map +group by domain_id +order by domain_id; \ No newline at end of file diff --git a/Version4 To Version5 Conversion/QA-Results.xlsx b/Version4 To Version5 Conversion/QA-Results.xlsx new file mode 100644 index 0000000000000000000000000000000000000000..6c17c3f15d103463e6de6a521656c9c8fc5e48c5 GIT binary patch literal 17494 zcmeHuV|bq1)^60;Xl&a?W81cEG&URCYS@@f8r!y=Hnx-VcI~}S_v%{vy1w)CT;G0v zyvj4~%xBJ_Ip(`k0>=-h3r3G%@}C~|>70Qdj*`d>T)qbftPJq(C##1{y0RV5B1WI^eU6!u_+$p{R$ z^)){hlg<2Y&(aDb5veMOsHUXy7qgqBzp%fwdhFFAh?@t}3)7!PzhbuDn$bi>FwZ3~vdNG{7TrUr!5Crre%jNmBTpmL9-! z=34a`KD$#X)Do8QaHB`Kje8hx|Jyg^OVhT&kP#zWgqvez(N!?Gmy{|akWavO6wp43*zjW8$FC4SsOYPKe8X( zNUR7v6~eQX`_}hXhbCf8?FdIN*9dI1X6h-b5^t>5xbHK1C^FQ}It49#;q0Yw55)3! zw#A*b@xr6aeWwL71qd<@Hmb})>kb5oXmK|E*XRW97*nYHF_DT_t~Wv2jn1a>l4g41 ziFZ3?7B^3~4+ecD2#Ms9z)s$MA^ui*DhwVV{GN@lofeioiYI;<wgXSf3em6+oMOtPXG)U zw*O50o6zpl4_k4_yw9!D;;n?rc%3At_zj;5Ncit=gFpi$jaH^^4<w|=BIFtpnOUF?U`68?sI9GA>$w*uW*9C!mDEN?Vzneb6C1MN z%Avws96NrFV^A12FrP}mEHPP4+~W=Dz>}xtnd`EIgz$tY<9p?E)Lp~F}^qG>O)Z013dU&twdymr>RBO?d+_62E2b64KN_;0q*_ZeSJ$Du?=KE6uC=!L>PQBB#7Zd9n4qxY`t;~O2e#= zS{*mweSU|VH_M{9Yc0!l~rMV~=8F(yN%Kfh0Q|4CdFdm4k z=QI-YtFL$Zec@*H)J~>uqfzkXj_`d}ONs>n*j=p3v9EK#Ta;q?n=iOV6yZc^*cS;S=)gnrN zG)ZLvtII~|pDG4ZqTU%CFpD){B@fi=>)rai0O%1w-TqzCq7r26RtXS8&XO+iDVD7k@SmoR zEl)~p(#b+qRnlXOgh$;!1$2RE+r4^2thz|heTPB-JsahrU(dqTl<*0x5iAcdy-Gxu zPudqef%)j^bg`9)e3ZH^ZTaqzqe2tGDFp+oS23Z5hLTNfHE)>VPekA(PK)g}!e$m< z%Y%bj9f-PHP9dyn&H@XCnU2~WxBSqZgY)n<`$E3APPE0QuF*`tlNq)c%n7kC(V$<0 zi*{2M(|ur?Sa>ZIb0F8RexrMc#W@Y${&+5ibaKTw%p4UG+k(Eznz~U~JhM(3=Dh>` z=uoHbaYGW108}Hb9u7UDbCfsT=J(yPioBnr6>?cSi$eP3i7MlUuPZICIJctb<1 zvTNI`rkhA{a6>iB@?dLSCg<%S&ApidBj&Jsg!vFh0EDJ&=EelySnbL2 z3eC!Kd^A8#x_y-rkomnFbEhnxkr1zxl{ELW^x#U~0-9vLw7H@5Cjgj-m@ThUo*%88F< zI{eHIC6VL%;@HBMmi!WMg=N!!pfHN59{jn{rN5)2u?~IQE4DF_R&($klSl91&h0zW z+B!RsKT_9Y6g#1FIHE4Aeql^Cs8kYkR-C`08q5Y~>>h)$W=+@*xj|v07YWJfdvMhx z)oKA32K^pLhsk07NACje4^vSs@5~BU@LSRZXOQwIE8q`+htm{>DjN@tr>5779}1LF zJjE-|MX5va$`O%dqXetmbiY;LD;q#=j2EbYrxP(*GzI+PP2EHg4Fed9()^^0e)Lp9Mb$E_#x1hssBg>PZqVki7tj=&t17 zN}4y3K0F;R1_?&@7_Bqt_-dfvL>TvT#NwmyZ+T=#jC{6lyYeml7Ri=)8uL^WEO9>Yo zW{;shS9U==C8u?Uqu=k0^7)JS*YZK~TN4ph|9=$exo z!2SGn3b<{Uq`LkmQ^5G|QxMV3fGTna`YPn^nJ^y=E2P9u)U0v~dG4W=eof#e0F$ESCxCK{?VmT!MaBHV*v=phn&@=KYe&7~ehJ-uwh8O^S@S|As% zqQ>iSv^PGFZ9&KQ&l!;5jMeAM7v~%lIl1%$%z)c%wv{(LSdq=>$ki>>-_1ZO)nZa7 zAQLc0|Bt5m$MR>YYbE4!p!#f-y&%xYwIU3QD6A+JYgV@@%goJ>kDfArQYZ!A2D#na zn2;bKgqlkBuwZz&cN}+fl$ABR-Q$&sQcFZ<9N#aRX_5goL0TVJak!jANd(>aeKG-JzcV}>lB}TI`Id!-@!!NQm3=Gc zmz7b8^V>@V%VrH{K9puEk=Ps(KW=BP7sG|coX0sg#@QJU@!Ocic6W@=IE^_%*c{?Z zyb8bvyYxWL@f_$#h4_(ygF0_(8d$orCi)GBz33iZ4 zbL!sxm>(B#YY9ha;SUa_TG0lLCnNb5p1!FOH?Jasm;GQJDRDfgkyS7V1HJdLvQ;pi zrfq`J!mNf%qOkbJVH+Xt&{C5jQQB!Hb0O|Vn6>l#WK6~d{uKMR)R0qA+`Nj%YZeRv ztnYjMAOaGx7!jM^k(*Or%f3+6k5uwfzU;&0%#3_{{>8Ezl9|OmFn|sFwo3G(F zue#lB=&H{DIqIC0I`Tty2=h^{{~1;psLna+zPX($n(u+ETkLlc>Bxuq6Pr$@U=d_& zXibP3s7I8V6+|(#3;~w$ch=F774Tn{{0JJ0k2S!jXsT`YNovGs)6BoPfoP+)B4b3M zUTGn}FY|&h0LU4vAes?8oiK-4zjqIUq0t1DJ>gs~&>%ca3A2Bs8cnCT}X; z(C4<@g1pH=Do5AIYP9}E*02P9hd*M1z^+5eoZGC;8M4bb2Fy{R?nxHDvDQ|KfpO0| zFENCfhTAZcho5q&DWjjSDdT(RKYAAv8vrj^KuCbrd=VoUb0^>#6meL1U^Nwo*=@qt zd%IpMJ$w1=#uz&(!+BGcID^&{o~Y+L3sadG-~xwAqk>}JL(n46>f~6m{H{e35qN`E zx$rge;DDYKl28FfIDAAg@FFo{%PC4U-cRll%;M9RBP0PARw#DB92>5T4wVVT~$L^-{-e*L5UUJ;A4)B4af2vZ#L zqNm}0Se>v_7>Crpe)h{EI$cF|yU`s81eW_d>LUTHj}9GH(OUN#saZ|Cg`^j#(~Byv zGwPNM+0#o8I0Z1|IlEh^V#ZezC~I9_^G@u=$}7)oMJjMxyXD4{=@VqwSHVb2Uen30 z3^|=2lsZ0HkS6pnXkIND8?`eKWyqy>!0*@TUL-%-M1ACXg6}aOGfVjN&>d#Y_dQ?u z%J+K^DY}7WxRo6hoH*~>bBM$dMzJ{$N~rOI_=3Yo1NVsb+Be8gc&kE+ZU%DNXV)0w z6i(61?;xt?ThbdI`M`PP0H=>@_I)qm2_@=s{sH@EHpwF3rpN{Gw((>v+j7OE}?i2@TA8*a}NTw=bnx}q_= ztSP>iBX)^d`?%7vSpG$)}>ed(7t09UWZpu)3>>9Mc?GqTGmU~m{Z z!kJA^u+A+{n3J|GtouksLjP)$Z$C0u9YhPG&7B;KA9@u^+8#)1sj<0SySdb(h818c zv|LV3G~}vu6$xPi6(J&`9Jj;DU}^N8?^q&R|R%*53;i$Q~7QwHK3Ma!M_Y@;tZZ_coTORY9TX@CuYyE)yt|<(J*0NDX2F@AS@(9!$KDa(eie+K;gvbP zd3B2@N5@VlvRSK{8gxG(JF1+I%!22N-^ty-ve{cS=b7@p$bBipU%|kdMWG6f;=yc2RHPcByA7Wrk_gT{1T&X>~lc9A5lhQG~TD={TuC z3iz$J1@PPG;%SwUo3-;SLYCW3IB_r^xYn44iXvFsexzjWkv`3cXsF9P&Nql8mN_u+ zlgEChrq;9Sr(=DuW>p1C5w+EBuMQca49+~xCurS~4wAU~EIGkcxn#>jzqd1wG)7)` zmO80spJVV(rxhnfMC6a$rE*_Tb!B5VUq?f~%#Ru8oqguw>cK^Q@|VJZYAI%hjX;ea zX2$>6ALq2hTVhaz&)WnjtNu-h&P{X@k11Z|9Yw%vq`P z+s2|xy2jalq>El& z!qq~{%~HbmeQtVpvWNHM31^hA*o4`M=SZ(su*ojO^2rutSLk?``9KFyncZ*BgTn8? z4uWpYGTyVB9Zw9eTS<3=M;o3^bKchhFa7;7uTAp<&_FCmBU2w( zF>bJCZLJ>sLuPh9`+B~*smxDyRr@^?u#=XiAOrK#+J64J=wtDbifNT8N$xkBnxQCq zIf@NV)$dXdZ&($HV?%j79|>hYh3MKW3YoND(q zmqRvyRJKJz9Z3?=`ZM1sjJB2YGuB{2X4cd}MM%^OBXLZC%Nz(u=_Bcqpr-&$W{``r4l8*@Mz$a619R4|aKPZ#hx1L@9$q)0qqniU-t z)|`Wav_E%p-(JkTDCMQ*t67k!Py&+(hu1d=q;yWAxt~LlkX+DKw6DSgYzG-B>$z8v z(lbs;1c~zmkUHF4odB@g?NPm`67ntk0RgIp06=hgpcltRMhZcvNPbKxxM9>STr19_yl(d9Js@@$8My7^&S&NMbXmwP$EUNnAb}<& zPw*9CnNr5(Svd8|XMdJpQ2KOYZ(1aBI@)I-8irxnE2ORur~Y#;ehwPc(eOxkpQKTe zdFB<2d2R>Z%(P{1TpPzUC@e3VM>!^H&XD8)dC8J|z<`Z_yiwLz*07v~`9zLEY3vk$ zYV!|NvU_@=&BrJoU$1yVvDbsp!^Ov;;CK^mkaF$n z!?a}%zE#yG_hN59v3hNikH@rE@{dwBFOX<#!mWzX7gs-aBb;pW7%}^qbtvH5$HNgT9jn7|$f<)SN9_DtESrOPLs`lsqK8M^tAn_RjWS2XDc<~>K zdaQrskO_Kr84Rd>8{{Y4>OS<~g46GTRq9JL@yTSAn%oAoJ0sp0RwUBxI;`aLEysi& z{hHPKKWsR`S7xu*6G7PPYAVgpNKgV3TT{#E&1_UnxFICocgl<;vC7Y&xIfN%y(r>V ztULe{Ad+C{%@79F7>`B*v)qN_c5O-t8c`s0WEM2O(otBI4dr}5j(*jV$zRj5 za&y@FTwxIbh5#*$D$CIhe-4)@C?6gEl9lEGRtt0C?OpUi4*12nFgW^5<=!M_L*Q1Z zv%?@fpy0HY*QOJO1qVU)a?fNG4&hsACNDB9eUFnEo^SA%-p9xBBIJt|myj#`bi=Qj zG*=P0_Duc=@pR1;JEq!vTbFY#v)jxieL=%`l?4$Kxe*$>zJ;7IOD%DC=Yg%dSaPV& z2_1Kd&76KLU0jQdEj}>@);5r;Ijz9-D7h&X0gqf(JzvAq^eWA+07c!umd>6GKiedN z0|6BS5(1QeR1claO>9i)|9Jf)7dY0Cvs+<9?Lb&`BXG8}A#cQnaEVx~$*7RQ?zIiY zvq(!;SIXy~mhi@2-thzOX)#CvZarbJrk(_8b3Sng++7p9>Wx z^7VS#*dcbgSq==#6Cxtnb66?Ysr(q$%ZES1VeaV`@*;(e7Y{vPH0mzByq+n3wmkoI zrqh=}MS>(y&6k|fd=e~4nvoQ7ZGbT{!b8Y7D$^WR9iWD!+z)~eycVW1Up8k-+Rbt+ zA4N>y>B*GGCmbC|{oD4&rJ3kgDE zC`K|g*|P53^S9yoIp}q1bjAil8v~t<=V_Pk0T<3==crv2W|~I}T57J2kKmoNOqB~q zE}jjU*}(c65Hb}sBI!4;q7?~KG=9fBOeeMt3KgyQATKwhX9nVuyCL9z-RxckuqMP~WqmaW^YCO--8N9X`3K@n2AY>gKGu z8RG^S7MVjGU>ocL-Eo-V(n-SE3tdsEyK_VaI_?{)_TuV$srR==8VxkGX@ICO!$=O? zuElZ~o-*T51qMyla}%w zw$jzQ&JEp#gL>v;C{ByGIOM2g5I*vL>IGLeB~DTt&UP3YoDWKQwe(<@_PvO<9M!oq zKZaNvV_dEEm<{mb`%E8Dp*AX)C%goQs!#BDzWf&M$z$IIh zN{O-Fbe2p}e>Co$S6Vl<*(~-B$D7>=*XRa6AtWE-@X=@6CGhYoAXdB1jlJG&45_F$UgN4P> zCaBg31XIITK!X>|7PnWGZXuUrAbmSWmgi23rlBJvkDO9iv0|Oa!n<^sz9q9) z4jG^Tu98}lHhkadolq47_oS4tWc<*bQ6bI94rOWoWN^}6SgizsOgIOhoCgQToD>2S z$x2TBrU^RwQ2{zpxu8y>rX9HJyh;Mt)mcZ13}w4KzYd0Y+4Yu{_On+}7)H+TRCm!oO)R^ z1uEL&vcbuizG?S<<5fQ{b8XYeK4}vXx$ey$D>Kso9);Etpq6=BK;6pJs;E$x!m46r z+UkrP!RpapM3itoU!SO4nT9ig;TC&-`^3}2xek(4F zGUwqmhhE@l+=U74lEXLvWkV-n^o0emnN=v7kK&ntQh+bnOgkG-(uC!ukK8ALtD~+V zz-gBVk`{Uw0%e>@5Sy(FlpbLuEznPkWDnV|eZS3sF%Fo*P#7hfLp`#9 zLz7Qsl>wSPWDcV%KHFEk-?jeHDqz1cAXlMi!wqIfWenS}o?OjspP7aggCT*6s5ZTX z^G03c*P)b$irRlcQM4s}9@{lphkW}%vKte4!2hg_Gto)wlpIjp_-8I7l?9WpMzBx#B-hC!P1K{M@EiKajkUbJT+Qv$Vck>7ln{IH z{^OCfiKk%Pb)vIrsOt?syCTZK&WhVFzl|Fm5n>qI@1;{V~O-p4L%9AKQk_t81!y#(FIfAtz z2s2O!K~y#=0KJ`v0&lQNE`TFeUw)6T@dHxFd7*;09|2}#32#?3soQc5p4ah;EF*?g z^!iYhrQ(>l=`zjlMQvkU=QF$Z5jVNT*&hhYrdpp^DBW@;*C!7S+{|Jnm$8IxQUBb> zW>c=*ruB<5r1$JmGT=Cm+~WjD0*+}7Z9$|OUc&$#wmyaGi>PZibt|RAxEm&&?jSU> zBE*6g>CI|IkESrj^cN55ANBsoRu53iKX@FB8Z_ishG9Fa*`+R~NhTBnPoly=^Y6a% zAy0jcy@p6s|JF8T)?yor(08*I*60Kg7?-mXi{)9dR;r$n4SQW`uSlljUX1cBDr;VW z{Ef?fOk6&NpP@tIVOi0U>w=&?8Ao1dST>J>q7|&!S)B?om*B*|+S4)%M!*ejl3Y1` z>yv7;ITg;g;j6VLiU2ZHAgs3@{gy&$g=iZ=H@~PAdc|ghEX@dQy@g1>6H|0&L6Ke8 zoIzvRd^Ix=+_t3d*RsSPr)!7UjcdVRlVwDCoP`ptj%g@&wpV8>kxE|qQWyh;9 zSE0Ln%_vLHUSA%zT+i=04;xRH5!@=)S-&@dzl08`cCdT6d%=RA*m_b}2cZ7bNtzotniwlNJ6hP9{oyO?)i&&w84!JP>fgGC@t_lu>q}0GpcPdnB{L|b zaZM0rP`^g|i<697hc>*ujOUS5p45LyWWOJ8&)ImOTf2I44p&W#3^L(88~kvMI0hM+ zV7-22ORkpF?k+B#+2=mQw0wnEaz5U3ch({(4(7%@b@g6x-%NmDFrY~No~9U6+%&3K zy<3kDL3o@px-UR6jV^F}Ys(^bo8$`7K!mL8)QmyNcqk{}c46>)DY~l&va1P4mzxw< zH{}U9(=j--HjM3}o`E4K%?0jz)UR}iqZTB{78XP_ktk4d=M} zd)?nKW>f^th0mPGplvs{`gn+>#gDR)IdHDHO5VfdYEx?^9(ny$5!VauRT8MVkt(6W5A+Bv`^ol1M&BEwXfDZ z1)A5=yQ%y~R3CEJXJK*>hv?schoHtx5_?NR#Xs)CsM-@$h3G|rn{&K+c+4nXrk28o zT-jW^1ZhI3e1~5i9L!&VntWb#av6KZnuTTO4AMPO;8>4%Y+nc0;;3)fIl1Z)Y+Yl}>~6rP#Pf=&(piC*cLvlJ{$#B$?gqrL*mqw6xOrqB}FV?y9xyW3pCH zBY}jjqkUYHJIM|P(t7<0^l2Hslm3-}2QEC}aG+xa&du}Msp`jOjc3@Z9cT0%{+iW3 zd+A63J_7vV^^;Dz+Z`6zX$OAibIb>XjvM5hY0^Uz+C7q#X}-&(=(ilNsJ$om^et0Q z_w*XjENTR7dntATP1S>OS z_?V3tHF||8W@++uDN9i(!779gA~LeqCBs?b-BPsFN6NfbO?86uYEnZq#dry%^975L zCJ{kO-79qdo2j8F^Sn6fTs$q za8wi2x`eTN$dd(a(_;OR>Nu_YN}FQslY&9Yvxa}5aj9-+X2cK0rWh7s#q6-4x{i;T zE1b`T@YfEd-C6Fx1c||83i>0QTh_6sUIxh43qB`!IjBZ_6O`4C*PfI}G>=4m7g=y{ zf`y6Im4us(J%Qj(wwUx{VB#R|FCS(*Ol1L8+GTNlV_fQDK@~yGnzrCtke!^SwuPQm z5RV3b{r;nMcX>V={Fp`^ZI^$?KxhqJ@Lk75vAET4Ve-7CzOnFnNf>Ix_}o%6Kd0dG z_tsKEN0mvx9sLG3+*5M6Rgq6EAeEr+R;+QqgCwOKFw}*BFKcGK4S+yrvfIm1D2!u^ zP_KP-Df+}3GmF{m*w6~kUfII4yV{vFt~uI}&#sj6n(pxlnt_wq?1u0gUetZCh*(MK zpgc@~MDI1-nT5&s)Db7!zMyw_S6|&9M<=)~L-?K_Gh!!r&gu(Yfk)kD!M(0ddxIhF zqx%)MUu7T+U?pciqc`6KvGiI?gMO6gc<_{mSo9;}%FFTR@t58haps@VG!3$|i*B7M z-H78~_D;*0Rztndazj!&Iw7|^>mHx)-#6QoIoVEO)#(uXGQmz6U;acf)uUx^t+ewk zc(ReI5p&U0Kf~V!{O5;FP^NSGzYVwl??%t~U!(u8(f`-z|9>`m)lLXab--bYC!j+b z2|&s)wlk7k=CwUx0}V)&X_b^4#hH~@!0nPS-b+0LO%;ZeHBeBo1G2LT(16#||%m*xrRXaiTy z^QARU@~;~lt*m7}*@0gQa5Fqx|M7)=-sNPjfGuQ9?)>UyEgyGo%(#vko+2EqSR0u6 zv*de%r8Fnfv7$uogPU82M(uAR?wjU~Y0NgKC);Y6VMl9vA_Jl;rMO?LAi8T5EZ7$X zJh0YAr#U4-a)K&9xCUM&YRh|yZb>EVhcW{i%)C@ng0<1c*UrNssX6XHc%wMGD55 zpt7GGZSjE&khQi4Ku|y1=_xl9>fQ}jGkbxu3}mqGmI>js8Oc{s6D(71#GH0-?!34( zKp-bLx3R2Sfah>^*LZuGC$dB!I69M%HxKHITX4x^&E-}^S$(ibaU17TPrGE&HqQ)5 z_Qt7~ou8CZIVl+fo@9#v1Gl5+7X{ZMAWHyxNpkz(h?HG(9u%B;k)=$7P2$Wdd-6lu z+w_Oy%~wC(ZC}Hh)Sg}t6c}k521fect0T^}n`g*7tDQ(boV%^mD`lR;sJ_h{3QZru zCqTE$UsLiegSO>XfT1=3(sIOqH&g?A`~TW0Kvn*EWde9TD?h0mptty7_^wvF#wQHM zwGo7C^03tJSuEW4jk(@aNd=U+5BYfSxl0^-1NGRF=xz52DIzbl_E*0LwJ?jc<{DxS zQT?j8A`{2^<%90GF$|GvQVg@2!CUdA2CoM}n!qcJd{M)pZpFAc#z)SBLQ88uGKofs zQf+gBA{OiBa;l2+{!*Jjwo8rdj;-cMb1547=OKn8+yk3uy_xCK=oq{O&m6zc?q_XN z(1z)X>lSD@U#V&lxPwK{^C*zlpy${Qn^V4S_9%Zr#n2`(((orlebz>7f?S(U&IOg2 z>i3AGYUvbz6SvARImSkG@tGR~xP#~T`RQt$0wq02Y@&ch(O=ufbXkuk&we@V+<^{PV ziFbPb+3CstJmIKpW$5~B+M41M_?yXWuocf@+w-oa)OfAhve25NL zcEk(!O9zE7mXPX2YL2rL?;J8Jaiz^_OS){Ud2XNSoDr^T-hv%Jat`Sod_RG+49I!Q z@B*CX{zKt`L1+P$p1^`0d;*+g{CQaa2KbA}@;l(~OpsrIFMuxLKLh@v1^tflduQ=4lq*0H<8M&@ z=rjHu<@avGUnr!2lbXLl`Qx#ENBO-&#HB= 2.1 Billion Rows, you will need to make the corresponding changes in your V5 Database and potentially to this conversion script** - * [SOURCE_CDMV4] - * [SOURCE_CDMV4].[SCHEMA] - * [TARGET_CDMV5] - * [TARGET_CDMV5].[SCHEMA] +2. **Download the conversion script:** The **[CDM V4 to V5 Conversion](https://github.com/OHDSI/CommonDataModel/tree/master/Version4%20To%20Version5%20Conversion "CDM V4 to V5 Conversion Directory")** folder has subfolders with scripts that will work on each RDBMS. In order to make this file work in your environment, you will need to perform a global "FIND AND REPLACE" on the conversion script 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: + + * [SOURCE_CDMV4] - Your V4 database name + * [SOURCE_CDMV4].[SCHEMA] - Your V4 database name + schema + * [TARGET_CDMV5] - Your V5 database name + * [TARGET_CDMV5].[SCHEMA] - Your V5 database name + schema -2. Run the resulting script on your target RDBDMS. +3. Run the resulting script on your target RDBDMS. ** **NOTE** ** If you are running the Oracle script via Sql Developer or similar, you may need to alter the script to include the appropriate "/" symbols to mark the end of the anonymous code blocks. This has been done in the Oracle script that has been provided in this repository. +4. At the end of the conversion process, several tables will be produced that will help you to understand how your data has changed as a result of the conversion process. This is described in the Quality Assurance section below. -** **NOTE** ** If you are running the Oracle script via Sql Developer or similar, you may need to alter the script to include the appropriate "/" symbols to mark the end of the anonymous code blocks. Quality Assurance =================== -We have included 2 scripts in the root of this directory that were used while doing quality assurance on the conversion scripts: +At the end of the conversion script, there are 3 queries which will provide information on the conversion process. For reference, this section of the conversion script has a header comment: -* Conversion-QA - Sql Server.sql -* Conversion-QA-Part-2 - Sql Server.sql - -As noted in the file names, these scripts were written specifically for Sql Server but should be a fairly easy port to your RDBMS target. The goals of these scripts were to measure the following: +/**** QUALITY ASSURANCE OUTPUT ****/ -* **Conversion-QA - Sql Server.sql**: provides row counts from each table in the V4 and V5 databases. It also includes a column called "Migration Target" which notes if that table was a target of the migration. The full list will help you to see if there were any tables in V4 that were either missed or are not targeted as part of the migration. Of particular note: **Cohort** and **Source\_To\_Concept\_Map** are not targeted for this migration. +The first query provides a means for comparing the table row counts between the V4 and V5 databases. As mentioned in the overview section above, table row counts will differ between V4 and V5 based on the way that the standard vocabulary maps the data. The next set of queries will help to tie out the row count changes in these tables. -* **Conversion-QA-Part-2 - Sql Server.sql**: provides 2 summary tables to help verify the output from the first script. The first summary table provides row counts for specific V4 tables and how the rows in the tables map to the V5 domains. This summary is useful to understand why the row counts for these tables will vary between the V4 and V5. The second summary table provides a row count sum by domain which should then match the V5 row counts for the corresponding V5 tables. The tables that are summarized in this script are: condition\_occurrence, drug\_exposure, observation, procedure\_occurrence. +The second query shows the source V4 table (i.e condition\_occurrence) and how the row counts maps to the V5 domain. This table is useful to understand how the data from the V4 source was distributed into the V5 tables. As a note, 1 record in the V4 table could map to multiple records in V5 as some concepts will map to multiple standard domains. -Contributions +The third query uses the information from the second query and provides a summary for each V5 domain. This is useful for tying out the rowcounts we'd expect from the script with the actual results observed in the first query. + +We have included a spreadsheet called "QA-Results.xlsx" which provides an example of how to utilize these 3 result queries to understand the results of the conversion process. The results of the first query go into the "Rowcounts" worksheet. The results of the second and third queries go into the "Classification Map Results" worksheet. If the conversion process worked as expected, all of the "Difference" columns should equal 0 in the "Classification Map Results" worksheet. + +Getting Involved ============================================================== +Each script found in the RDBMS directory was generated from the OHDSI-SQL file: *OMOP CDMv4 to CDMv5 - OHDSI-SQL.sql* found in the root of this directory. If you would like to contribute to this script, we'd suggest you modify this script and use **[SqlRender](https://github.com/OHDSI/SqlRender "SqlRender")** to re-generate the specific RDBMS scripts. We have also supplied a basic R script in this directory to help re-generate the scripts using SqlRender. -Each script found in the RDBMS directory was generated from the template SQL file: *OMOP CDMv4 to CDMv5 - templateSQL.sql* found in the root of this directory. If you would like to contribute to this script, we'd suggest you modify this script and use **[SqlRender](https://github.com/OHDSI/SqlRender "SqlRender")** to re-generate the specific RDBMS scripts. +Developer questions/comments/feedback: OHDSI Forum +We use the GitHub issue tracker for all bugs/issues/enhancements \ No newline at end of file diff --git a/Version4 To Version5 Conversion/Sql Server/OMOP CDMv4 to CDMv5 - SQL Server.sql b/Version4 To Version5 Conversion/Sql Server/OMOP CDMv4 to CDMv5 - SQL Server.sql index ca655a0..1fc6366 100644 --- a/Version4 To Version5 Conversion/Sql Server/OMOP CDMv4 to CDMv5 - SQL Server.sql +++ b/Version4 To Version5 Conversion/Sql Server/OMOP CDMv4 to CDMv5 - SQL Server.sql @@ -14,18 +14,16 @@ # See the License for the specific language governing permissions and # limitations under the License. ********************************************************************************/ - /******************************************************************************* PURPOSE: Use this script to convert your OMOP V4 common data model to CDM V5. -last revised: 09 July 2015 -author: Patrick Ryan, Chris Knoll -editor: Anthony Sena +last revised: 04 August 2015 +authors: Patrick Ryan, Chris Knoll, Anthony Sena !!!!!!!!!!!!!!!!!!!!! PLEASE READ THESE INSTRUCTIONS !!!!!!!!!!!!!!!!!!!!!!!!!!! -This script was authored using TemplateSQL which will require you to run this +This script was authored using OHDSI-SQL which will require you to run this script through SqlRender to creat a version that is compatible with your target RDBMS. We have pre-generated these scripts using SQL Render and have placed them in folders for each RDBMS. Depending on which script you are viewing, your @@ -35,19 +33,22 @@ General Assumptions ------------------- This script assumes that your V4 and V5 database are located on the same -RDBMS server. +RDBMS server. It also assumes that the V4 and V5 databases were created +using the standard data definition scripts for these databases. If you +altered your V4 database in any way, this script will likely require +some mo Getting Started --------------- Before you can use this script, there are some prerequisites: - 1. Create a target CDMv5 database on your server using the appropriate script - from https://github.com/OHDSI/CommonDataModel + 1. Create a target CDMv5 database on your database server using the + appropriate script from https://github.com/OHDSI/CommonDataModel 2. Load VocabV5 into the target database/schema that will contain CDMv5 using Athena: http://ohdsi.org/web/ATHENA -TemplateSQL File Instructions +OHDSI-SQL File Instructions ----------------------------- 1. Set parameter name of schema that contains CDMv4 instance @@ -75,13 +76,12 @@ TemplateSQL File Instructions 2. Run the resulting script on your target RDBDMS. *********************************************************************************/ - /* SCRIPT PARAMETERS */ - -- The CDMv4 database name - -- The CDMv4 database plus schema - -- The target CDMv5 database name - -- the target CDMv5 database plus schema - + -- The CDMv4 database name + -- The CDMv4 database plus schema + -- The target CDMv5 database name + -- the target CDMv5 database plus schema + USE [TARGET_CDMV5]; /* @@ -111,79 +111,79 @@ USE [TARGET_CDMV5]; IF OBJECT_ID('tempdb..#concept_map', 'U') IS NOT NULL DROP TABLE #concept_map; -CREATE TABLE #concept_map -( - source_concept_id int, - target_concept_id int, - domain_id varchar(20) -); +/* / */ +SELECT concept_id AS source_concept_id + ,concept_id AS target_concept_id + ,domain_id AS domain_id +INTO #concept_map +FROM [TARGET_CDMV5].[SCHEMA].concept +WHERE 1 = 0; + +/* / */ + +INSERT INTO #concept_map --standard concepts -INSERT INTO #concept_map (source_concept_id, target_concept_id, domain_id) -select concept_id as source_concept_id, - concept_id as target_concept_id, - domain_id -from [TARGET_CDMV5].[SCHEMA].concept -where standard_concept = 'S' -and invalid_reason is null +SELECT concept_id AS source_concept_id + ,concept_id AS target_concept_id + ,domain_id +FROM [TARGET_CDMV5].[SCHEMA].concept +WHERE standard_concept = 'S' + AND invalid_reason IS NULL -union +UNION --concepts with 'map to' standard -select distinct c1.concept_id as source_concept_id, - c2.concept_id as target_concept_id, - c2.domain_id -from -( -select concept_id -from [TARGET_CDMV5].[SCHEMA].concept -where ((standard_concept <> 'S' or standard_concept is null) -or invalid_reason is not null -) -) c1 -inner join -[TARGET_CDMV5].[SCHEMA].concept_relationship cr1 -on c1.concept_id = cr1.concept_id_1 -inner join -[TARGET_CDMV5].[SCHEMA].concept c2 -on cr1.concept_id_2 = c2.concept_id -where c2.standard_concept = 'S' -and c2.invalid_reason is null -and cr1.relationship_id in ('Maps to') -and cr1.invalid_reason is null +SELECT DISTINCT c1.concept_id AS source_concept_id + ,c2.concept_id AS target_concept_id + ,c2.domain_id +FROM ( + SELECT concept_id + FROM [TARGET_CDMV5].[SCHEMA].concept + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL + ) + OR invalid_reason IS NOT NULL + ) + ) c1 +INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 +INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id +WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ('Maps to') + AND cr1.invalid_reason IS NULL - -union +UNION --concepts without 'map to' standard with another non 'is a' relation to standard -select distinct c1.concept_id as source_concept_id, - c2.concept_id as target_concept_id, - c2.domain_id -from -( +SELECT DISTINCT c1.concept_id AS source_concept_id + ,c2.concept_id AS target_concept_id + ,c2.domain_id +FROM ( SELECT A.concept_id FROM [TARGET_CDMV5].[SCHEMA].concept A - LEFT JOIN - ( - SELECT DISTINCT c1.concept_id - FROM ( - SELECT concept_id - FROM [TARGET_CDMV5].[SCHEMA].concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL + LEFT JOIN ( + SELECT DISTINCT c1.concept_id + FROM ( + SELECT concept_id + FROM [TARGET_CDMV5].[SCHEMA].concept + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL ) - ) c1 - INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 - INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id - WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ('Maps to') - AND cr1.invalid_reason IS NULL - ) B ON A.concept_id = B.concept_id + OR invalid_reason IS NOT NULL + ) + ) c1 + INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 + INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id + WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ('Maps to') + AND cr1.invalid_reason IS NULL + ) B ON A.concept_id = B.concept_id WHERE ( ( A.standard_concept <> 'S' @@ -192,25 +192,25 @@ from OR A.invalid_reason IS NOT NULL ) AND B.concept_id IS NULL -) c1 -inner join [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 on c1.concept_id = cr1.concept_id_1 -inner join [TARGET_CDMV5].[SCHEMA].concept c2 on cr1.concept_id_2 = c2.concept_id -where c2.standard_concept = 'S' - and c2.invalid_reason is null - and cr1.relationship_id in ( - 'RxNorm replaced by', - 'SNOMED replaced by', - 'UCUM replaced by', - 'Concept replaced by', - 'ICD9P replaced by', - 'LOINC replaced by', - 'Concept same_as to', - 'Concept was_a to', - 'Concept alt_to to' -) -and cr1.invalid_reason is null + ) c1 +INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 +INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id +WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ( + 'RxNorm replaced by' + ,'SNOMED replaced by' + ,'UCUM replaced by' + ,'Concept replaced by' + ,'ICD9P replaced by' + ,'LOINC replaced by' + ,'Concept same_as to' + ,'Concept was_a to' + ,'Concept alt_to to' + ) + AND cr1.invalid_reason IS NULL -union +UNION --concepts without 'map to' standard with 'is a' relation to standard SELECT DISTINCT c1.concept_id AS source_concept_id @@ -219,38 +219,37 @@ SELECT DISTINCT c1.concept_id AS source_concept_id FROM ( SELECT A.concept_id FROM [TARGET_CDMV5].[SCHEMA].concept A - LEFT JOIN - ( - SELECT DISTINCT c1.concept_id - FROM ( - SELECT concept_id - FROM [TARGET_CDMV5].[SCHEMA].concept - WHERE ( - ( - standard_concept <> 'S' - OR standard_concept IS NULL - ) - OR invalid_reason IS NOT NULL + LEFT JOIN ( + SELECT DISTINCT c1.concept_id + FROM ( + SELECT concept_id + FROM [TARGET_CDMV5].[SCHEMA].concept + WHERE ( + ( + standard_concept <> 'S' + OR standard_concept IS NULL ) - ) c1 - INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 - INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id - WHERE c2.standard_concept = 'S' - AND c2.invalid_reason IS NULL - AND cr1.relationship_id IN ( - 'Maps to' - ,'RxNorm replaced by' - ,'SNOMED replaced by' - ,'UCUM replaced by' - ,'Concept replaced by' - ,'ICD9P replaced by' - ,'LOINC replaced by' - ,'Concept same_as to' - ,'Concept was_a to' - ,'Concept alt_to to' + OR invalid_reason IS NOT NULL ) - AND cr1.invalid_reason IS NULL - ) B ON A.concept_id = B.concept_id + ) c1 + INNER JOIN [TARGET_CDMV5].[SCHEMA].concept_relationship cr1 ON c1.concept_id = cr1.concept_id_1 + INNER JOIN [TARGET_CDMV5].[SCHEMA].concept c2 ON cr1.concept_id_2 = c2.concept_id + WHERE c2.standard_concept = 'S' + AND c2.invalid_reason IS NULL + AND cr1.relationship_id IN ( + 'Maps to' + ,'RxNorm replaced by' + ,'SNOMED replaced by' + ,'UCUM replaced by' + ,'Concept replaced by' + ,'ICD9P replaced by' + ,'LOINC replaced by' + ,'Concept same_as to' + ,'Concept was_a to' + ,'Concept alt_to to' + ) + AND cr1.invalid_reason IS NULL + ) B ON A.concept_id = B.concept_id WHERE ( ( standard_concept <> 'S' @@ -267,1479 +266,1588 @@ WHERE c2.standard_concept = 'S' AND cr1.relationship_id IN ('Is a') AND cr1.invalid_reason IS NULL; --- Update the source_concept_map_occurrence column --- to contain a count to indicate the number of target_concept_ids --- map to that source_concept_id. This will be used elsewhere in --- the script to ensure that we generate new primary keys --- for the target tables when applicable -/* - UPDATE #concept_map - SET #concept_map.source_concept_map_occurrence = A.targetConceptCount - FROM - #concept_map, - ( - select source_concept_id, domain_id, count(*) as "targetConceptCount" - from #concept_map - group by source_concept_id, domain_id - ) AS A -WHERE #concept_map.source_concept_id = A.source_concept_id AND #concept_map.domain_id = A.domain_id; - -UPDATE #concept_map -SET source_concept_map_occurrence = "targetConceptCount" -FROM - ( - select source_concept_id, domain_id, count(*) as "targetConceptCount" - from #concept_map - group by source_concept_id, domain_id - ) A -WHERE #concept_map.source_concept_id = A.source_concept_id AND #concept_map.domain_id = A.domain_id; - -UPDATE #concept_map -SET source_concept_map_occurrence = ( - select count(*) as "targetConceptCount" - from #concept_map A - WHERE A.source_concept_id = #concept_map.source_concept_id AND A.domain_id = #concept_map.domain_id - group by source_concept_id, domain_id - ) -*/ - IF OBJECT_ID('tempdb..#concept_map_distinct', 'U') IS NOT NULL DROP TABLE #concept_map_distinct; -CREATE TABLE #concept_map_distinct -( - source_concept_id int, - domain_id varchar(20), - targetConceptCount int -); +/* / */ - INSERT INTO #concept_map_distinct (source_concept_id, domain_id, targetConceptCount) - SELECT source_concept_id, domain_id, COUNT(*) - FROM #concept_map - GROUP BY source_concept_id, domain_id; +SELECT source_concept_id + ,domain_id + ,COUNT(*) AS targetConceptCount +INTO #concept_map_distinct +FROM #concept_map +WHERE 1 = 0 +GROUP BY source_concept_id + ,domain_id; + +/* / */ + +INSERT INTO #concept_map_distinct +SELECT source_concept_id + ,domain_id + ,COUNT(*) +FROM #concept_map +GROUP BY source_concept_id + ,domain_id; - IF OBJECT_ID('[TARGET_CDMV5].[SCHEMA].ETL_WARNINGS', 'U') IS NOT NULL DROP TABLE [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS; -CREATE TABLE [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS -( - WARNING_MESSAGE varchar(4000) -); - +/* / */ + +CREATE TABLE [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE VARCHAR(4000)); +/* / */ + /**** CDM_SOURCE ****/ - -INSERT INTO [TARGET_CDMV5].[SCHEMA].cdm_source (cdm_source_name, cdm_version, vocabulary_version, cdm_release_date) -select '[TARGET_CDMV5]', 'V5', v.vocabulary_version, getDate() -from [TARGET_CDMV5].[SCHEMA].vocabulary v -where vocabulary_id = 'Vocabulary'; +INSERT INTO [TARGET_CDMV5].[SCHEMA].cdm_source ( + cdm_source_name + ,cdm_version + ,vocabulary_version + ,cdm_release_date + ) +SELECT '[TARGET_CDMV5]' + ,'V5' + ,v.vocabulary_version + ,getDate() +FROM [TARGET_CDMV5].[SCHEMA].vocabulary v +WHERE vocabulary_id = 'Vocabulary'; /**** LOCATION ****/ - -insert into [TARGET_CDMV5].[SCHEMA].location -select location_id, address_1, address_2, city, state, zip, county, location_source_value -from [SOURCE_CDMV4].[SCHEMA].LOCATION; +INSERT INTO [TARGET_CDMV5].[SCHEMA].location +SELECT location_id + ,address_1 + ,address_2 + ,city + ,STATE + ,zip + ,county + ,location_source_value +FROM [SOURCE_CDMV4].[SCHEMA].LOCATION; /**** CARE_SITE ****/ - -insert into [TARGET_CDMV5].[SCHEMA].care_site -select care_site_id, cast(null as varchar(255)) as care_site_name, place_of_service_concept_id, location_id, care_site_source_value, place_of_service_source_value -from [SOURCE_CDMV4].[SCHEMA].CARE_SITE; +INSERT INTO [TARGET_CDMV5].[SCHEMA].care_site +SELECT care_site_id + ,cast(NULL AS VARCHAR(255)) AS care_site_name + ,place_of_service_concept_id + ,location_id + ,care_site_source_value + ,place_of_service_source_value +FROM [SOURCE_CDMV4].[SCHEMA].CARE_SITE; /**** Provider ****/ +INSERT INTO [TARGET_CDMV5].[SCHEMA].provider +SELECT provider_id + ,cast(NULL AS VARCHAR(255)) AS provider_name + ,NPI + ,DEA + ,specialty_concept_id + ,care_site_id + ,cast(NULL AS INT) AS year_of_birth + ,cast(NULL AS INT) AS gender_concept_id + ,provider_source_value + ,specialty_source_value + ,0 AS specialty_source_concept_id + ,cast(NULL AS VARCHAR(50)) AS gender_source_value + ,cast(NULL AS INT) AS gender_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].provider; -insert into [TARGET_CDMV5].[SCHEMA].provider -select provider_id, cast(null as varchar(255)) as provider_name, NPI, DEA, specialty_concept_id, care_site_id, cast(null as integer) as year_of_birth, - cast(null as integer) as gender_concept_id, provider_source_value, specialty_source_value, 0 as specialty_source_concept_id, - cast(null as varchar(50)) as gender_source_value, cast(null as integer) as gender_source_concept_id -from [SOURCE_CDMV4].[SCHEMA].provider -; - - - /**** +/**** PERSON ****/ - - INSERT into [TARGET_CDMV5].[SCHEMA].person - SELECT - person_id, - coalesce(gender.target_concept_id, 0) as gender_concept_id, - year_of_birth, - month_of_birth, - day_of_birth, - CAST(null as varchar(50)) time_of_birth, - coalesce(race.target_concept_id, 0) as race_concept_id, - coalesce(ethnicity.target_concept_id, 0) as ethnicity_concept_id, - location_id, - provider_id, - care_site_id, - person_source_value, - gender_source_value, - CAST(null as integer) gender_source_concept_id, - CAST(null as integer) race_source_value, - CAST(null as integer) race_source_concept_id, - ethnicity_source_value, - CAST(null as integer) ethnicity_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].PERSON p - left JOIN #concept_map gender on LOWER(gender.DOMAIN_ID) IN ('gender') and p.gender_concept_id = gender.source_concept_id - left JOIN #concept_map race on LOWER(race.DOMAIN_ID) IN ('race') and p.race_concept_id = race.source_concept_id - LEFT JOIN #concept_map ethnicity on LOWER(ethnicity.DOMAIN_ID) IN ('ethnicity') and p.ETHNICITY_CONCEPT_ID = ethnicity.source_concept_id; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PERSON: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid GENDER_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PERSON - WHERE GENDER_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('gender') - ) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PERSON: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid RACE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PERSON - WHERE RACE_CONCEPT_ID IS NOT NULL - AND RACE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('race')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PERSON: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid ETHNICITY_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PERSON - WHERE ETHNICITY_CONCEPT_ID IS NOT NULL - AND ETHNICITY_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('ethnicity')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - /**** +INSERT INTO [TARGET_CDMV5].[SCHEMA].person +SELECT person_id + ,coalesce(gender.target_concept_id, 0) AS gender_concept_id + ,year_of_birth + ,month_of_birth + ,day_of_birth + ,CAST(NULL AS VARCHAR(10)) time_of_birth + ,coalesce(race.target_concept_id, 0) AS race_concept_id + ,coalesce(ethnicity.target_concept_id, 0) AS ethnicity_concept_id + ,location_id + ,provider_id + ,care_site_id + ,person_source_value + ,gender_source_value + ,CAST(NULL AS INT) gender_source_concept_id + ,CAST(NULL AS INT) race_source_value + ,CAST(NULL AS INT) race_source_concept_id + ,ethnicity_source_value + ,CAST(NULL AS INT) ethnicity_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].PERSON p +LEFT JOIN #concept_map gender ON LOWER(gender.DOMAIN_ID) IN ('gender') + AND p.gender_concept_id = gender.source_concept_id +LEFT JOIN #concept_map race ON LOWER(race.DOMAIN_ID) IN ('race') + AND p.race_concept_id = race.source_concept_id +LEFT JOIN #concept_map ethnicity ON LOWER(ethnicity.DOMAIN_ID) IN ('ethnicity') + AND p.ETHNICITY_CONCEPT_ID = ethnicity.source_concept_id; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PERSON: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid GENDER_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PERSON + WHERE GENDER_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('gender') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PERSON: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid RACE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PERSON + WHERE RACE_CONCEPT_ID IS NOT NULL + AND RACE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('race') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PERSON: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid ETHNICITY_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PERSON + WHERE ETHNICITY_CONCEPT_ID IS NOT NULL + AND ETHNICITY_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('ethnicity') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** OBSERVATION_PERIOD ****/ +INSERT INTO [TARGET_CDMV5].[SCHEMA].observation_period +SELECT observation_period_id + ,person_id + ,observation_period_start_date + ,observation_period_end_date + ,44814722 AS period_type_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION_PERIOD; - INSERT INTO [TARGET_CDMV5].[SCHEMA].observation_period - SELECT observation_period_id, person_id, observation_period_start_date, observation_period_end_date, 44814722 as period_type_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION_PERIOD; - - /**** +/**** DEATH ****/ - - INSERT INTO [TARGET_CDMV5].[SCHEMA].death - SELECT person_id, - death_date, - COALESCE(death_type_concept_id,0) AS death_type_concept_id, - cause_of_death_concept_id as cause_concept_id, - cause_of_death_source_value as cause_source_value, - CAST(null as integer) as cause_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].DEATH - LEFT JOIN #concept_map_distinct cm1 - ON DEATH.DEATH_TYPE_CONCEPT_ID = CM1.SOURCE_CONCEPT_ID - AND LOWER(DOMAIN_ID) IN ('death type'); - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'DEATH: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid DEATH_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].DEATH - WHERE DEATH_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('death type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn ; - - - - /**** +INSERT INTO [TARGET_CDMV5].[SCHEMA].death +SELECT person_id + ,death_date + ,COALESCE(death_type_concept_id, 0) AS death_type_concept_id + ,cause_of_death_concept_id AS cause_concept_id + ,cause_of_death_source_value AS cause_source_value + ,CAST(NULL AS INT) AS cause_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].DEATH +LEFT JOIN #concept_map_distinct cm1 ON DEATH.DEATH_TYPE_CONCEPT_ID = CM1.SOURCE_CONCEPT_ID + AND LOWER(DOMAIN_ID) IN ('death type'); + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'DEATH: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid DEATH_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].DEATH + WHERE DEATH_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('death type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** VISIT_OCCURRENCE ****/ - - INSERT INTO [TARGET_CDMV5].[SCHEMA].visit_occurrence - SELECT visit_occurrence_id, person_id, - COALESCE(cm1.target_concept_id,0) as visit_concept_id, - visit_start_date, CAST(null as varchar(10)) visit_start_time, - visit_end_date, CAST(null as varchar(10)) visit_end_time, - 44818517 as visit_type_concept_id, - CAST(null as integer) provider_id, - care_site_id, place_of_service_source_value as visit_source_value, - CAST(null as integer) visit_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].VISIT_OCCURRENCE - LEFT JOIN #concept_map cm1 - ON VISIT_OCCURRENCE.PLACE_OF_SERVICE_CONCEPT_ID = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('visit'); - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'VISIT_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid VISIT_CONCEPT_ID (from the CDMv4 PLACE_OF_SERVICE_CONCEPT_ID field)' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].VISIT_OCCURRENCE - WHERE PLACE_OF_SERVICE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('visit')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - /**** +INSERT INTO [TARGET_CDMV5].[SCHEMA].visit_occurrence +SELECT visit_occurrence_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS visit_concept_id + ,visit_start_date + ,CAST(NULL AS VARCHAR(10)) visit_start_time + ,visit_end_date + ,CAST(NULL AS VARCHAR(10)) visit_end_time + ,44818517 AS visit_type_concept_id + ,CAST(NULL AS INT) provider_id + ,care_site_id + ,place_of_service_source_value AS visit_source_value + ,CAST(NULL AS INT) visit_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].VISIT_OCCURRENCE +LEFT JOIN #concept_map cm1 ON VISIT_OCCURRENCE.PLACE_OF_SERVICE_CONCEPT_ID = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('visit'); + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'VISIT_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid VISIT_CONCEPT_ID (from the CDMv4 PLACE_OF_SERVICE_CONCEPT_ID field)' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].VISIT_OCCURRENCE + WHERE PLACE_OF_SERVICE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('visit') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** PROCEDURE_OCCURRENCE ****/ - - -- *************************************************************************** - -- AGS: Modifying this section to insert this information into the temp - -- table #po_map but this may need to be revisited for - -- performance tuning on APS as a large temp table may cause processing - -- time issues. - -- *************************************************************************** - - IF OBJECT_ID('tempdb..#po_map', 'U') IS NOT NULL +IF OBJECT_ID('tempdb..#po_map', 'U') IS NOT NULL DROP TABLE #po_map; -CREATE TABLE #po_map -( - procedure_occurrence_id int, - person_id int, - procedure_concept_id int, - procedure_date date, - procedure_type_concept_id int, - modifier_concept_id int, - quantity int, - provider_id int, - visit_occurrence_id int, - procedure_source_value varchar(50), - procedure_source_concept_id int, - qualifier_source_value varchar(50), - origional_drug_id bigint -); +/* / */ - --find valid procedures from procedure table +SELECT po.procedure_occurrence_id + ,po.person_id + ,po.procedure_concept_id + ,po.procedure_date + ,po.procedure_type_concept_id + ,po.modifier_concept_id + ,po.quantity + ,po.provider_id + ,po.visit_occurrence_id + ,po.procedure_source_value + ,po.procedure_source_concept_id + ,po.qualifier_source_value + ,de.drug_exposure_id AS origional_drug_id +INTO #po_map +FROM [TARGET_CDMV5].[SCHEMA].procedure_occurrence po +LEFT JOIN [TARGET_CDMV5].[SCHEMA].drug_exposure de ON 1 = 0 +WHERE 0 = 1; + +/* / */ + +--find valid procedures from procedure table INSERT INTO #po_map -( - procedure_occurrence_id, - person_id, - procedure_concept_id, - procedure_date, - procedure_type_concept_id, - modifier_concept_id, - quantity, - provider_id, - visit_occurrence_id, - procedure_source_value, - procedure_source_concept_id, - qualifier_source_value, - origional_drug_id -) - SELECT - procedure_occurrence_id, - person_id, - COALESCE(cm1.target_concept_id,0) as procedure_concept_id, - procedure_date, - COALESCE(cm2.target_concept_id,0) as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - INNER JOIN #concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount = 1 - LEFT JOIN #concept_map cm2 - ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('procedure type') - LEFT JOIN #concept_map_distinct cmdis2 - ON cm2.source_concept_id = cmdis2.source_concept_id AND cm2.domain_id = cmdis2.domain_id AND cmdis2.targetConceptCount = 1 +SELECT procedure_occurrence_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS procedure_concept_id + ,procedure_date + ,COALESCE(cm2.target_concept_id, 0) AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id +FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE +INNER JOIN #concept_map cm1 ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') +INNER JOIN #concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount = 1 +LEFT JOIN #concept_map cm2 ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('procedure type') +LEFT JOIN #concept_map_distinct cmdis2 ON cm2.source_concept_id = cmdis2.source_concept_id + AND cm2.domain_id = cmdis2.domain_id + AND cmdis2.targetConceptCount = 1 UNION ALL - -- All procedures that did not map to a standard concept in V4 should also carry over to V5 - SELECT - procedure_occurrence_id, - person_id, - procedure_concept_id, - procedure_date, - procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - WHERE procedure_concept_id = 0 +-- All procedures that did not map to a standard concept in V4 should also carry over to V5 +SELECT procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) procedure_source_concept_id + ,NULL qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id +FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE +WHERE procedure_concept_id = 0 UNION ALL - -- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 - SELECT - procedure_occurrence_id, - person_id, - 0 as procedure_concept_id, - procedure_date, - COALESCE(cm2.target_concept_id,0) as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - LEFT JOIN #concept_map cm1 - ON procedure_concept_id = cm1.source_concept_id - LEFT JOIN #concept_map cm2 - ON procedure_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('procedure type') - where procedure_concept_id <> 0 - and cm1.domain_id IS NULL - +-- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 +SELECT procedure_occurrence_id + ,person_id + ,0 AS procedure_concept_id + ,procedure_date + ,COALESCE(cm2.target_concept_id, 0) AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) procedure_source_concept_id + ,NULL qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id +FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE +LEFT JOIN #concept_map cm1 ON procedure_concept_id = cm1.source_concept_id +LEFT JOIN #concept_map cm2 ON procedure_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('procedure type') +WHERE procedure_concept_id <> 0 + AND cm1.domain_id IS NULL + UNION ALL - select - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS procedure_occurrence_id, - person_id, - procedure_concept_id, - procedure_date, - procedure_type_concept_id, - modifier_concept_id, - quantity, - provider_id, - visit_occurrence_id, - procedure_source_value, - procedure_source_concept_id, - qualifier_source_value, - origional_drug_id - FROM - ( - --find valid procedures from procedure table that map to more than 1 - --target concept in V5 - SELECT - person_id, - COALESCE(cm1.target_concept_id,0) as procedure_concept_id, - procedure_date, - COALESCE(cm2.target_concept_id,0) as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) as quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id, - NULL as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - INNER JOIN #concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount > 1 - LEFT JOIN #concept_map cm2 - ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('procedure type') - - UNION ALL - - --find procedures that were previously classified as condition - SELECT - person_id, - cm1.target_concept_id as procedure_concept_id, - condition_start_date as procedure_date, - 0 as procedure_type_concept_id, - CAST(null as integer) modifier_concept_id, - CAST(null as integer) quantity, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value as procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) origional_drug_id, - condition_occurrence_id as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,modifier_concept_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,procedure_source_value + ,procedure_source_concept_id + ,qualifier_source_value + ,origional_drug_id +FROM ( + --find valid procedures from procedure table that map to more than 1 + --target concept in V5 + SELECT person_id + ,COALESCE(cm1.target_concept_id, 0) AS procedure_concept_id + ,procedure_date + ,COALESCE(cm2.target_concept_id, 0) AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value + ,CAST(NULL AS INT) procedure_source_concept_id + ,NULL qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + ,CAST(NULL AS INT) AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + INNER JOIN #concept_map cm1 ON PROCEDURE_OCCURRENCE.PROCEDURE_CONCEPT_ID = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + INNER JOIN #concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount > 1 + LEFT JOIN #concept_map cm2 ON PROCEDURE_OCCURRENCE.PROCEDURE_TYPE_CONCEPT_ID = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('procedure type') + UNION ALL - --find procedures that were previously classified as drug - SELECT person_id, - cm1.target_concept_id as procedure_concept_id, - drug_exposure_start_date as procedure_date, - 0 as procedure_type_concept_id, - CAST(null as integer) as modifier_concept_id, - CAST(null as integer) quantity, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value as procedure_source_value, - CAST(null as integer) procedure_source_concept_id, - CAST(null as varchar(50)) qualifier_source_value, - drug_exposure_id as origional_drug_id, - drug_exposure_id as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - - - --find procedures that were previously classified as observation + --find procedures that were previously classified as condition + SELECT person_id + ,cm1.target_concept_id AS procedure_concept_id + ,condition_start_date AS procedure_date + ,0 AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value AS procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + ,condition_occurrence_id AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + UNION ALL - SELECT person_id, - cm1.target_concept_id as procedure_concept_id, - observation_date as procedure_date, - 0 as procedure_type_concept_id, CAST(null as integer) modifier_concept_id, CAST(null as integer) quantity, - associated_provider_id as provider_id, visit_occurrence_id, observation_source_value as procedure_source_value, - CAST(null as integer) procedure_source_concept_id, CAST(null as varchar(50)) qualifier_source_value, - CAST(null as bigint) as origional_drug_id, - OBSERVATION_ID as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN #concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('procedure') - - - ) OTHERS,(SELECT MAX(PROCEDURE_OCCURRENCE_ID) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE) MAXROW -; - -INSERT INTO [TARGET_CDMV5].[SCHEMA].procedure_occurrence - (procedure_occurrence_id - ,person_id - ,procedure_concept_id - ,procedure_date - ,procedure_type_concept_id - ,modifier_concept_id - ,quantity - ,provider_id - ,visit_occurrence_id - ,procedure_source_value - ,procedure_source_concept_id - ,qualifier_source_value) -SELECT - procedure_occurrence_id - ,person_id - ,procedure_concept_id - ,procedure_date - ,procedure_type_concept_id - ,modifier_concept_id - ,quantity - ,provider_id - ,visit_occurrence_id - ,procedure_source_value - ,procedure_source_concept_id - ,qualifier_source_value + + --find procedures that were previously classified as drug + SELECT person_id + ,cm1.target_concept_id AS procedure_concept_id + ,drug_exposure_start_date AS procedure_date + ,0 AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value AS procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,drug_exposure_id AS origional_drug_id + ,drug_exposure_id AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + --find procedures that were previously classified as observation + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS procedure_concept_id + ,observation_date AS procedure_date + ,0 AS procedure_type_concept_id + ,CAST(NULL AS INT) AS modifier_concept_id + ,CAST(NULL AS INT) AS quantity + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,observation_source_value AS procedure_source_value + ,CAST(NULL AS INT) AS procedure_source_concept_id + ,NULL AS qualifier_source_value + ,CAST(NULL AS INT) AS origional_drug_id + ,OBSERVATION_ID AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION + INNER JOIN #concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('procedure') + ) OTHERS + ,( + SELECT MAX(PROCEDURE_OCCURRENCE_ID) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + ) MAXROW; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].procedure_occurrence ( + procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,modifier_concept_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,procedure_source_value + ,procedure_source_concept_id + ,qualifier_source_value + ) +SELECT procedure_occurrence_id + ,person_id + ,procedure_concept_id + ,procedure_date + ,procedure_type_concept_id + ,modifier_concept_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,procedure_source_value + ,procedure_source_concept_id + ,qualifier_source_value FROM #po_map; - --warnings of invalid records - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PROCEDURE_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid PROCOEDURE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - WHERE PROCEDURE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - STANDARD_CONCEPT = 'S' - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'PROCEDURE_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid PROCOEDURE_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - WHERE PROCEDURE_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('procedure type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - /**** +--warnings of invalid records +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PROCEDURE_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid PROCOEDURE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + WHERE PROCEDURE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR STANDARD_CONCEPT = 'S' + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'PROCEDURE_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid PROCOEDURE_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE + WHERE PROCEDURE_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('procedure type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** DRUG_EXPOSURE ****/ - - --find valid drugs from drug_exposure table +--find valid drugs from drug_exposure table IF OBJECT_ID('tempdb..#drgexp_map', 'U') IS NOT NULL DROP TABLE #drgexp_map; -CREATE TABLE #drgexp_map -( - drug_exposure_id int, - person_id int, - drug_concept_id int, - drug_exposure_start_date date, - drug_exposure_end_date date, - drug_type_concept_id int, - stop_reason varchar(20), - refills int, - quantity float, - days_supply int, - sig varchar(max), - route_concept_id int, - effective_drug_dose float, - dose_unit_concept_id int, - lot_number varchar(50), - provider_id int, - visit_occurrence_id int, - drug_source_value varchar(50), - drug_source_concept_id int, - route_source_value varchar(50), - dose_unit_source_value varchar(50), - origional_procedure_id int -); +/* / */ + +SELECT de.drug_exposure_id + ,de.person_id + ,de.drug_concept_id + ,de.drug_exposure_start_date + ,de.drug_exposure_end_date + ,de.drug_type_concept_id + ,de.stop_reason + ,de.refills + ,de.quantity + ,de.days_supply + ,de.sig + ,de.route_concept_id + ,de.effective_drug_dose + ,de.dose_unit_concept_id + ,de.lot_number + ,de.provider_id + ,de.visit_occurrence_id + ,de.drug_source_value + ,de.drug_source_concept_id + ,de.route_source_value + ,de.dose_unit_source_value + ,po.procedure_occurrence_id AS origional_procedure_id +INTO #drgexp_map +FROM [TARGET_CDMV5].[SCHEMA].drug_exposure de +LEFT JOIN [TARGET_CDMV5].[SCHEMA].procedure_occurrence po ON 1 = 0 +WHERE 0 = 1; + +/* / */ INSERT INTO #drgexp_map -( - drug_exposure_id, - person_id, - drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - route_concept_id, - effective_drug_dose, - dose_unit_concept_id, - lot_number, - provider_id, - visit_occurrence_id, - drug_source_value, - drug_source_concept_id, - route_source_value, - dose_unit_source_value, - origional_procedure_id -) - SELECT drug_exposure_id, - person_id, - COALESCE(cm1.target_concept_id,0) as drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - COALESCE(cm2.target_concept_id, 0) drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - CAST(null as varchar(50)) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - CAST(null as varchar(50)) route_source_value, - CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - INNER JOIN #concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount = 1 - LEFT JOIN #concept_map cm2 - ON drug_exposure.drug_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('drug type') - INNER JOIN #concept_map_distinct cmdis2 - ON cm2.source_concept_id = cmdis2.source_concept_id AND cm2.domain_id = cmdis2.domain_id AND cmdis2.targetConceptCount = 1 - WHERE drug_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 +SELECT drug_exposure_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,COALESCE(cm2.target_concept_id, 0) drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id +FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE +INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') +INNER JOIN #concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount = 1 +LEFT JOIN #concept_map cm2 ON drug_exposure.drug_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('drug type') +INNER JOIN #concept_map_distinct cmdis2 ON cm2.source_concept_id = cmdis2.source_concept_id + AND cm2.domain_id = cmdis2.domain_id + AND cmdis2.targetConceptCount = 1 +WHERE drug_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 UNION ALL - -- All drug exposures that did not map to a standard concept in V4 should also carry over to V5 - SELECT drug_exposure_id, - person_id, - drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - CAST(null as varchar(50)) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - CAST(null as varchar(50)) route_source_value, - CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - WHERE drug_concept_id = 0 +-- All drug exposures that did not map to a standard concept in V4 should also carry over to V5 +SELECT drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id +FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE +WHERE drug_concept_id = 0 UNION ALL - -- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 - SELECT drug_exposure_id, - person_id, - 0, - drug_exposure_start_date, - drug_exposure_end_date, - COALESCE(cm2.target_concept_id, 0) drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - CAST(null as varchar(50)) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - CAST(null as varchar(50)) route_source_value, - CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - LEFT JOIN #concept_map cm1 - ON drug_concept_id = cm1.source_concept_id - LEFT JOIN #concept_map cm2 - ON drug_exposure.drug_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('drug type') - where drug_concept_id <> 0 - and cm1.domain_id IS NULL - -UNION ALL -select CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS drug_exposure_id, - person_id, drug_concept_id, drug_exposure_start_date, drug_exposure_end_date, - drug_type_concept_id, stop_reason, refills, quantity, days_supply, sig, route_concept_id, - effective_drug_dose, dose_unit_concept_id, lot_number, provider_id, visit_occurrence_id, drug_source_value, - drug_source_concept_id, route_source_value, dose_unit_source_value - , origional_procedure_id -FROM -( +-- All drug exposures that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 +SELECT drug_exposure_id + ,person_id + ,0 + ,drug_exposure_start_date + ,drug_exposure_end_date + ,COALESCE(cm2.target_concept_id, 0) drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id +FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE +LEFT JOIN #concept_map cm1 ON drug_concept_id = cm1.source_concept_id +LEFT JOIN #concept_map cm2 ON drug_exposure.drug_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('drug type') +WHERE drug_concept_id <> 0 + AND cm1.domain_id IS NULL + +UNION ALL + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,route_concept_id + ,effective_drug_dose + ,dose_unit_concept_id + ,lot_number + ,provider_id + ,visit_occurrence_id + ,drug_source_value + ,drug_source_concept_id + ,route_source_value + ,dose_unit_source_value + ,origional_procedure_id +FROM ( --find valid drugs from drug_exposure table that map to > 1 target concept - SELECT - person_id, - COALESCE(cm1.target_concept_id,0) as drug_concept_id, - drug_exposure_start_date, - drug_exposure_end_date, - COALESCE(cm2.target_concept_id, 0) drug_type_concept_id, - stop_reason, - refills, - quantity, - days_supply, - sig, - CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, - CAST(null as integer) dose_unit_concept_id, - CAST(null as varchar(50)) lot_number, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value, - CAST(null as integer) drug_source_concept_id, - CAST(null as varchar(50)) route_source_value, - CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id, - NULL as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - INNER JOIN #concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount > 1 - LEFT JOIN #concept_map cm2 - ON drug_exposure.drug_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('drug type') - - UNION ALL - --find drugs that were previously classified as condition - select person_id, - cm1.target_concept_id as drug_concept_id, - condition_start_date as drug_exposure_start_date, null as drug_exposure_end_date, - 0 as drug_type_concept_id, null as stop_reason, null as refills, null as quantity, null as days_supply, null as sig, CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, CAST(null as integer) dose_unit_concept_id, CAST(null as varchar(50)) lot_number, - null as provider_id, visit_occurrence_id, condition_source_value as drug_source_value, - CAST(null as integer) drug_source_concept_id, CAST(null as varchar(50)) route_source_value, CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id, condition_occurrence_id as occurrence_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - - --find drugs that were previously classified as procedure + SELECT person_id + ,COALESCE(cm1.target_concept_id, 0) AS drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,COALESCE(cm2.target_concept_id, 0) drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + ,CAST(NULL AS INT) AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + INNER JOIN #concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount > 1 + LEFT JOIN #concept_map cm2 ON drug_exposure.drug_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('drug type') + UNION ALL - select person_id, - cm1.target_concept_id as drug_concept_id, - procedure_date as drug_exposure_start_date, null as drug_exposure_end_date, - 0 as drug_type_concept_id, null as stop_reason, null as refills, null as quantity, null as days_supply, null as sig, CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, CAST(null as integer) dose_unit_concept_id, CAST(null as varchar(50)) lot_number, - null as provider_id, visit_occurrence_id, procedure_source_value as drug_source_value, - CAST(null as integer) drug_source_concept_id, CAST(null as varchar(50)) route_source_value, CAST(null as varchar(50)) dose_unit_source_value, - procedure_occurrence_id as origional_procedure_id, procedure_occurrence_id as occurrence_id + + --find drugs that were previously classified as condition + SELECT person_id + ,cm1.target_concept_id AS drug_concept_id + ,condition_start_date AS drug_exposure_start_date + ,NULL AS drug_exposure_end_date + ,0 AS drug_type_concept_id + ,NULL AS stop_reason + ,CAST(NULL AS INT) AS refills + ,CAST(NULL AS FLOAT) AS quantity + ,CAST(NULL AS INT) AS days_supply + ,NULL AS sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,condition_source_value AS drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + ,condition_occurrence_id AS occurrence_id + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + --find drugs that were previously classified as procedure + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS drug_concept_id + ,procedure_date AS drug_exposure_start_date + ,CAST(NULL AS DATE) AS drug_exposure_end_date + ,0 AS drug_type_concept_id + ,NULL AS stop_reason + ,CAST(NULL AS INT) AS refills + ,CAST(NULL AS FLOAT) AS quantity + ,CAST(NULL AS INT) AS days_supply + ,NULL AS sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,procedure_occurrence_id AS origional_procedure_id + ,procedure_occurrence_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') - - --find drugs that were previously classified as observation - UNION ALL - select person_id, - cm1.target_concept_id as drug_concept_id, observation_date as drug_exposure_start_date, null as drug_exposure_end_date, - 0 as drug_type_concept_id, null as stop_reason, null as refills, null as quantity, null as days_supply, null as sig, CAST(null as integer) route_concept_id, - CAST(null as float) effective_drug_dose, CAST(null as integer) dose_unit_concept_id, CAST(null as varchar(50)) lot_number, - null as provider_id, visit_occurrence_id, observation_source_value as drug_source_value, - CAST(null as integer) drug_source_concept_id, CAST(null as varchar(50)) route_source_value, CAST(null as varchar(50)) dose_unit_source_value, - CAST(null as bigint) origional_procedure_id, observation_id as occurrence_id + INNER JOIN #concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + --find drugs that were previously classified as observation + + UNION ALL + + SELECT person_id + ,cm1.target_concept_id AS drug_concept_id + ,observation_date AS drug_exposure_start_date + ,CAST(NULL AS DATE) AS drug_exposure_end_date + ,0 AS drug_type_concept_id + ,NULL AS stop_reason + ,CAST(NULL AS INT) AS refills + ,CAST(NULL AS FLOAT) AS quantity + ,CAST(NULL AS INT) AS days_supply + ,NULL AS sig + ,CAST(NULL AS INT) AS route_concept_id + ,CAST(NULL AS FLOAT) AS effective_drug_dose + ,CAST(NULL AS INT) AS dose_unit_concept_id + ,NULL AS lot_number + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,observation_source_value AS drug_source_value + ,CAST(NULL AS INT) AS drug_source_concept_id + ,NULL AS route_source_value + ,NULL AS dose_unit_source_value + ,CAST(NULL AS INT) AS origional_procedure_id + ,observation_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN #concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('drug') -) OTHERS,(SELECT MAX(DRUG_EXPOSURE_ID) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE) MAXROW -; -INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_exposure - (drug_exposure_id - ,person_id - ,drug_concept_id - ,drug_exposure_start_date - ,drug_exposure_end_date - ,drug_type_concept_id - ,stop_reason - ,refills - ,quantity - ,days_supply - ,sig - ,route_concept_id - ,effective_drug_dose - ,dose_unit_concept_id - ,lot_number - ,provider_id - ,visit_occurrence_id - ,drug_source_value - ,drug_source_concept_id - ,route_source_value - ,dose_unit_source_value) -SELECT + INNER JOIN #concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('drug') + ) OTHERS + ,( + SELECT MAX(DRUG_EXPOSURE_ID) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + ) MAXROW; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_exposure ( drug_exposure_id - ,person_id - ,drug_concept_id - ,drug_exposure_start_date - ,drug_exposure_end_date - ,drug_type_concept_id - ,stop_reason - ,refills - ,quantity - ,days_supply - ,sig - ,route_concept_id - ,effective_drug_dose - ,dose_unit_concept_id - ,lot_number - ,provider_id - ,visit_occurrence_id - ,drug_source_value - ,drug_source_concept_id - ,route_source_value - ,dose_unit_source_value + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,route_concept_id + ,effective_drug_dose + ,dose_unit_concept_id + ,lot_number + ,provider_id + ,visit_occurrence_id + ,drug_source_value + ,drug_source_concept_id + ,route_source_value + ,dose_unit_source_value + ) +SELECT drug_exposure_id + ,person_id + ,drug_concept_id + ,drug_exposure_start_date + ,drug_exposure_end_date + ,drug_type_concept_id + ,stop_reason + ,refills + ,quantity + ,days_supply + ,sig + ,route_concept_id + ,effective_drug_dose + ,dose_unit_concept_id + ,lot_number + ,provider_id + ,visit_occurrence_id + ,drug_source_value + ,drug_source_concept_id + ,route_source_value + ,dose_unit_source_value FROM #drgexp_map; - - --warnings of invalid records - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'DRUG_EXPOSURE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid DRUG_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - WHERE DRUG_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - STANDARD_CONCEPT = 'S' - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'DRUG_EXPOSURE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid DRUG_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - WHERE DRUG_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('drug type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - /**** + +--warnings of invalid records +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'DRUG_EXPOSURE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid DRUG_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + WHERE DRUG_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR STANDARD_CONCEPT = 'S' + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'DRUG_EXPOSURE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid DRUG_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE + WHERE DRUG_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('drug type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** CONDITION_OCCURRENCE ****/ - - --find valid conditions from condition_occurrence table - INSERT INTO [TARGET_CDMV5].[SCHEMA].condition_occurrence - SELECT condition_occurrence_id, - person_id, - COALESCE(cm1.target_concept_id, 0) AS condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(cm2.target_concept_id,0) AS condition_type_concept_id, - stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - condition_source_value, CAST(null as integer) condition_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - INNER JOIN #concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount = 1 - LEFT JOIN #concept_map cm2 - ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('condition type') - WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 +--find valid conditions from condition_occurrence table +INSERT INTO [TARGET_CDMV5].[SCHEMA].condition_occurrence +SELECT condition_occurrence_id + ,person_id + ,COALESCE(cm1.target_concept_id, 0) AS condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(cm2.target_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE +INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') +INNER JOIN #concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount = 1 +LEFT JOIN #concept_map cm2 ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('condition type') +WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 UNION ALL - -- All conditions that did not map to a standard concept in V4 should also carry over to V5 - SELECT condition_occurrence_id, - person_id, - condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(condition_type_concept_id,0) AS condition_type_concept_id, - stop_reason, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value, - CAST(null as integer) condition_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - WHERE condition_concept_id = 0 +-- All conditions that did not map to a standard concept in V4 should also carry over to V5 +SELECT condition_occurrence_id + ,person_id + ,condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(condition_type_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE +WHERE condition_concept_id = 0 UNION ALL - -- All conditions that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 - SELECT condition_occurrence_id, - person_id, - 0 AS condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(cm2.target_concept_id,0) AS condition_type_concept_id, - stop_reason, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value, - CAST(null as integer) condition_source_concept_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - LEFT JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - LEFT JOIN #concept_map cm2 - ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('condition type') - where condition_concept_id <> 0 - and cm1.domain_id IS NULL +-- All conditions that do not map to a standard concept in V5 should also carry over with condition_concept_id = 0 +SELECT condition_occurrence_id + ,person_id + ,0 AS condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(cm2.target_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id +FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE +LEFT JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id +LEFT JOIN #concept_map cm2 ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('condition type') +WHERE condition_concept_id <> 0 + AND cm1.domain_id IS NULL UNION ALL -select CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS drug_exposure_id, - person_id, condition_concept_id, condition_start_date, condition_end_date, - condition_type_concept_id, stop_reason, provider_id, visit_occurrence_id, - condition_source_value, condition_source_concept_id + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS drug_exposure_id + ,person_id + ,condition_concept_id + ,condition_start_date + ,condition_end_date + ,condition_type_concept_id + ,stop_reason + ,provider_id + ,visit_occurrence_id + ,condition_source_value + ,condition_source_concept_id FROM ( - --find valid conditions from condition_occurrence table that map to > 1 target concept - SELECT - person_id, - COALESCE(cm1.target_concept_id, 0) AS condition_concept_id, - condition_start_date, - condition_end_date, - COALESCE(cm2.target_concept_id,0) AS condition_type_concept_id, - stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - condition_source_value, CAST(null as integer) condition_source_concept_id, - NULL as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - INNER JOIN #concept_map_distinct cmdis - ON cm1.source_concept_id = cmdis.source_concept_id AND cm1.domain_id = cmdis.domain_id AND cmdis.targetConceptCount > 1 - LEFT JOIN #concept_map cm2 - ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id - AND LOWER(cm2.domain_id) IN ('condition type') - WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 - - UNION ALL - - --find conditions that were previously classified as procedure - select person_id, - cm1.target_concept_id as condition_concept_id, - procedure_date as condition_start_date, null as condition_end_date, - 0 as condition_type_concept_id, null as stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - procedure_source_value as condition_source_value, CAST(null as integer) condition_source_concept_id, - procedure_occurrence_id as OCCURRENCE_ID + SELECT person_id + ,COALESCE(cm1.target_concept_id, 0) AS condition_concept_id + ,condition_start_date + ,condition_end_date + ,COALESCE(cm2.target_concept_id, 0) AS condition_type_concept_id + ,stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,NULL AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + INNER JOIN #concept_map_distinct cmdis ON cm1.source_concept_id = cmdis.source_concept_id + AND cm1.domain_id = cmdis.domain_id + AND cmdis.targetConceptCount > 1 + LEFT JOIN #concept_map cm2 ON condition_occurrence.condition_type_concept_id = cm2.source_concept_id + AND LOWER(cm2.domain_id) IN ('condition type') + WHERE condition_concept_id > 0 -- This condition will map those concepts that were mapped to valid concepts in V4 + + UNION ALL + + --find conditions that were previously classified as procedure + SELECT person_id + ,cm1.target_concept_id AS condition_concept_id + ,procedure_date AS condition_start_date + ,NULL AS condition_end_date + ,0 AS condition_type_concept_id + ,NULL AS stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,procedure_occurrence_id AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - - --find conditions that were previously classified as drug + INNER JOIN #concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + --find conditions that were previously classified as drug + UNION ALL - SELECT person_id, - cm1.target_concept_id as condition_concept_id, - drug_exposure_start_date as condition_start_date, null as condition_end_date, - 0 as condition_type_concept_id, null as stop_reason, prescribing_provider_id as provider_id, visit_occurrence_id, - drug_source_value as condition_source_value, CAST(null as integer) condition_source_concept_id, - drug_exposure_id as OCCURRENCE_ID + + SELECT person_id + ,cm1.target_concept_id AS condition_concept_id + ,drug_exposure_start_date AS condition_start_date + ,NULL AS condition_end_date + ,0 AS condition_type_concept_id + ,NULL AS stop_reason + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value AS condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,drug_exposure_id AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') - - --find conditions that were previously classified as observation + INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + --find conditions that were previously classified as observation + UNION ALL - SELECT person_id, - cm1.target_concept_id as condition_concept_id, - observation_date as condition_start_date, null as condition_end_date, - 0 as condition_type_concept_id, null as stop_reason, associated_provider_id as provider_id, visit_occurrence_id, - observation_source_value as condition_source_value, CAST(null as integer) condition_source_concept_id, - observation_id as OCCURRENCE_ID + + SELECT person_id + ,cm1.target_concept_id AS condition_concept_id + ,observation_date AS condition_start_date + ,NULL AS condition_end_date + ,0 AS condition_type_concept_id + ,NULL AS stop_reason + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,observation_source_value AS condition_source_value + ,CAST(NULL AS INT) condition_source_concept_id + ,observation_id AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN #concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('condition') -) OTHERS,(SELECT MAX(condition_occurrence_id) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE) MAXROW -; - - - --warnings of invalid records - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'CONDITION_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid CONDITION_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - WHERE CONDITION_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - STANDARD_CONCEPT = 'S' - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) - SELECT 'CONDIITON_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid CONDITION_TYPE_CONCEPT_ID' - FROM - ( - SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - WHERE CONDITION_TYPE_CONCEPT_ID NOT IN ( - SELECT CONCEPT_ID - FROM [TARGET_CDMV5].[SCHEMA].CONCEPT - WHERE CONCEPT_ID = 0 - OR - (STANDARD_CONCEPT = 'S' - AND LOWER(DOMAIN_ID) IN ('condition type')) - ) - HAVING COUNT(PERSON_ID) > 0 - ) warn - ; - - - + INNER JOIN #concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('condition') + ) OTHERS + ,( + SELECT MAX(condition_occurrence_id) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + ) MAXROW; - /**** +--warnings of invalid records +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'CONDITION_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid CONDITION_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + WHERE CONDITION_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR STANDARD_CONCEPT = 'S' + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +INSERT INTO [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE) +SELECT 'CONDIITON_OCCURRENCE: ' + CAST(NUM_INVALID_RECORDS AS VARCHAR) + ' records in the source CDMv4 database have invalid CONDITION_TYPE_CONCEPT_ID' +FROM ( + SELECT COUNT(PERSON_ID) AS NUM_INVALID_RECORDS + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + WHERE CONDITION_TYPE_CONCEPT_ID NOT IN ( + SELECT CONCEPT_ID + FROM [TARGET_CDMV5].[SCHEMA].CONCEPT + WHERE CONCEPT_ID = 0 + OR ( + STANDARD_CONCEPT = 'S' + AND LOWER(DOMAIN_ID) IN ('condition type') + ) + ) + HAVING COUNT(PERSON_ID) > 0 + ) warn; + +/**** DEVICE_EXPOSURE ****/ - INSERT INTO [TARGET_CDMV5].[SCHEMA].device_exposure -select row_number() over (order by OCCURRENCE_ID) AS device_exposure_id, - person_id, device_concept_id, device_exposure_start_date, device_exposure_end_date, device_type_concept_id, - unique_device_id, quantity, provider_id, visit_occurrence_id, device_source_value, device_source_concept_id -FROM -( +SELECT row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS device_exposure_id + ,person_id + ,device_concept_id + ,device_exposure_start_date + ,device_exposure_end_date + ,device_type_concept_id + ,unique_device_id + ,quantity + ,provider_id + ,visit_occurrence_id + ,device_source_value + ,device_source_concept_id +FROM ( --find devices that were previously classified as procedures - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - PROCEDURE_DATE AS DEVICE_EXPOSURE_START_DATE, - CAST(NULL as date) AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, CAST(NULL as VARCHAR(50)) unique_device_id, - CAST(null as integer) quantity, ASSOCIATED_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, PROCEDURE_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - PROCEDURE_OCCURRENCE_ID as OCCURRENCE_ID + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,PROCEDURE_DATE AS DEVICE_EXPOSURE_START_DATE + ,CAST(NULL AS DATE) AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,CAST(NULL AS VARCHAR(50)) unique_device_id + ,CAST(NULL AS INT) quantity + ,ASSOCIATED_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,PROCEDURE_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,PROCEDURE_OCCURRENCE_ID AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') - + INNER JOIN #concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') --find devices that were previously classified as drug exposure - UNION ALL - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - DRUG_EXPOSURE_START_DATE AS DEVICE_EXPOSURE_START_DATE, - CAST(NULL as DATE) AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, CAST(NULL as VARCHAR(50)) unique_device_id, - quantity, PRESCRIBING_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, DRUG_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - DRUG_EXPOSURE_ID as OCCURRENCE_ID + + UNION ALL + + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,DRUG_EXPOSURE_START_DATE AS DEVICE_EXPOSURE_START_DATE + ,CAST(NULL AS DATE) AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,CAST(NULL AS VARCHAR(50)) unique_device_id + ,quantity + ,PRESCRIBING_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,DRUG_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,DRUG_EXPOSURE_ID AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') - + INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') --find devices that were previously classified as conditions + UNION ALL - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - CONDITION_START_DATE AS DEVICE_EXPOSURE_START_DATE, - CAST(NULL as DATE) AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, CAST(NULL as VARCHAR(50)) unique_device_id, - CAST(NULL as integer) quantity, ASSOCIATED_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, CONDITION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - CONDITION_OCCURRENCE_ID as OCCURRENCE_ID + + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,CONDITION_START_DATE AS DEVICE_EXPOSURE_START_DATE + ,CAST(NULL AS DATE) AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,CAST(NULL AS VARCHAR(50)) unique_device_id + ,CAST(NULL AS INT) quantity + ,ASSOCIATED_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,CONDITION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,CONDITION_OCCURRENCE_ID AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') - + INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') --find devices that were previously classified as observations + UNION ALL - SELECT PERSON_ID, - cm1.target_concept_id AS DEVICE_CONCEPT_ID, - OBSERVATION_DATE AS DEVICE_EXPOSURE_START_DATE, - CAST(NULL as DATE) AS DEVICE_EXPOSURE_END_DATE, 0 AS DEVICE_TYPE_CONCEPT_ID, CAST(NULL as VARCHAR(50)) unique_device_id, - CAST(null as integer) quantity, ASSOCIATED_PROVIDER_ID AS PROVIDER_ID, - VISIT_OCCURRENCE_ID, OBSERVATION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE, 0 as device_source_concept_id, - OBSERVATION_ID as OCCURRENCE_ID + + SELECT PERSON_ID + ,cm1.target_concept_id AS DEVICE_CONCEPT_ID + ,OBSERVATION_DATE AS DEVICE_EXPOSURE_START_DATE + ,CAST(NULL AS DATE) AS DEVICE_EXPOSURE_END_DATE + ,0 AS DEVICE_TYPE_CONCEPT_ID + ,CAST(NULL AS VARCHAR(50)) unique_device_id + ,CAST(NULL AS INT) quantity + ,ASSOCIATED_PROVIDER_ID AS PROVIDER_ID + ,VISIT_OCCURRENCE_ID + ,OBSERVATION_SOURCE_VALUE AS DEVICE_SOURCE_VALUE + ,0 AS device_source_concept_id + ,OBSERVATION_ID AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN #concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('device') -) OTHERS -; - - - /**** + INNER JOIN #concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('device') + ) OTHERS; + +/**** MEASUREMENT ****/ - --find valid measurements from observation table INSERT INTO [TARGET_CDMV5].[SCHEMA].measurement -SELECT row_number() over (order by occurrence_id) AS measurement_id, - person_id, measurement_concept_id, measurement_date, measurement_time, measurement_type_concept_id, operator_concept_id, value_as_number, value_as_concept_id, unit_concept_id, range_low, range_high, - provider_id, visit_occurrence_id, measurement_source_value, measurement_source_concept_id, unit_source_value, value_source_value -from -( +SELECT row_number() OVER ( + ORDER BY occurrence_id + ) AS measurement_id + ,person_id + ,measurement_concept_id + ,measurement_date + ,measurement_time + ,measurement_type_concept_id + ,operator_concept_id + ,value_as_number + ,value_as_concept_id + ,unit_concept_id + ,range_low + ,range_high + ,provider_id + ,visit_occurrence_id + ,measurement_source_value + ,measurement_source_concept_id + ,unit_source_value + ,value_source_value +FROM ( --find mesaurements that were previously classified as observations - select person_id, - cm1.target_concept_id AS measurement_concept_id, - OBSERVATION_DATE AS measurement_date, - CAST(OBSERVATION_TIME as varchar(50)) AS measurement_time, - 0 AS measurement_type_concept_id, - CAST(null as integer) operator_concept_id, - value_as_number, - value_as_concept_id, - COALESCE(cm2.target_concept_id,0) AS unit_concept_id, - range_low, - range_high, - ASSOCIATED_PROVIDER_ID AS provider_id, - visit_occurrence_id, - OBSERVATION_SOURCE_VALUE AS measurement_source_value, - CAST(null as integer) measurement_source_concept_id, - unit_source_value AS unit_source_value, - cast(null as varchar(50)) as value_source_value, - observation_id as occurrence_id + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,OBSERVATION_DATE AS measurement_date + ,CAST(OBSERVATION_TIME AS VARCHAR(50)) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) operator_concept_id + ,value_as_number + ,value_as_concept_id + ,COALESCE(cm2.target_concept_id, 0) AS unit_concept_id + ,range_low + ,range_high + ,ASSOCIATED_PROVIDER_ID AS provider_id + ,visit_occurrence_id + ,OBSERVATION_SOURCE_VALUE AS measurement_source_value + ,CAST(NULL AS INT) measurement_source_concept_id + ,unit_source_value AS unit_source_value + ,cast(NULL AS VARCHAR(50)) AS value_source_value + ,observation_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - INNER JOIN #concept_map cm1 - ON observation.observation_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - LEFT JOIN #concept_map cm2 - ON observation.unit_concept_id = cm2.source_concept_id - AND LOWER(cm1.domain_id) IN ('unit') - + INNER JOIN #concept_map cm1 ON observation.observation_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + LEFT JOIN #concept_map cm2 ON observation.unit_concept_id = cm2.source_concept_id + AND LOWER(cm1.domain_id) IN ('unit') + UNION ALL - - SELECT person_id, - cm1.target_concept_id as measurement_concept_id, - procedure_date as measurement_date, - CAST(NULL as varchar(50)) as measurement_time, - 0 as measurement_type_concept_id, - CAST(null as integer) as operator_concept_id, - CAST(null as integer) as value_as_number, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as range_low, - CAST(null as integer) as range_high, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value as measurement_source_value, - CAST(null as integer) as measurement_source_concept_id, - CAST(null as varchar(50)) as unit_source_value, - CAST(null as varchar(50)) as value_source_value, - procedure_occurrence_id as occurrence_id + + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,procedure_date AS measurement_date + ,CAST(NULL AS VARCHAR(50)) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) AS operator_concept_id + ,CAST(NULL AS INT) AS value_as_number + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS range_low + ,CAST(NULL AS INT) AS range_high + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS measurement_source_value + ,CAST(NULL AS INT) AS measurement_source_concept_id + ,CAST(NULL AS VARCHAR(50)) AS unit_source_value + ,CAST(NULL AS VARCHAR(50)) AS value_source_value + ,procedure_occurrence_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - + INNER JOIN #concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + UNION ALL - - SELECT person_id, - cm1.target_concept_id as measurement_concept_id, - condition_start_date as measurement_date, - CAST(NULL as varchar(50)) as measurement_time, - 0 as measurement_type_concept_id, - CAST(null as integer) as operator_concept_id, - CAST(null as integer) as value_as_number, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as range_low, - CAST(null as integer) as range_high, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value as measurement_source_value, - CAST(null as integer) as measurement_source_concept_id, - CAST(null as varchar(50)) as unit_source_value, - CAST(null as varchar(50)) as value_source_value, - condition_occurrence_id as occurrence_id + + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,condition_start_date AS measurement_date + ,CAST(NULL AS VARCHAR(50)) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) AS operator_concept_id + ,CAST(NULL AS INT) AS value_as_number + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS range_low + ,CAST(NULL AS INT) AS range_high + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value AS measurement_source_value + ,CAST(NULL AS INT) AS measurement_source_concept_id + ,CAST(NULL AS VARCHAR(50)) AS unit_source_value + ,CAST(NULL AS VARCHAR(50)) AS value_source_value + ,condition_occurrence_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - + INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + UNION ALL - - SELECT person_id, - cm1.target_concept_id as measurement_concept_id, - drug_exposure_start_date as measurement_date, - CAST(NULL as varchar(50)) as measurement_time, - 0 as measurement_type_concept_id, - CAST(null as integer) as operator_concept_id, - CAST(null as integer) as value_as_number, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as range_low, - CAST(null as integer) as range_high, - prescribing_provider_id as provider_id, - visit_occurrence_id, - drug_source_value as measurement_source_value, - CAST(null as integer) as measurement_source_concept_id, - CAST(null as varchar(50)) as unit_source_value, - CAST(null as varchar(50)) as value_source_value, - drug_exposure_id as occurrence_id + + SELECT person_id + ,cm1.target_concept_id AS measurement_concept_id + ,drug_exposure_start_date AS measurement_date + ,CAST(NULL AS VARCHAR(50)) AS measurement_time + ,0 AS measurement_type_concept_id + ,CAST(NULL AS INT) AS operator_concept_id + ,CAST(NULL AS INT) AS value_as_number + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS range_low + ,CAST(NULL AS INT) AS range_high + ,prescribing_provider_id AS provider_id + ,visit_occurrence_id + ,drug_source_value AS measurement_source_value + ,CAST(NULL AS INT) AS measurement_source_concept_id + ,CAST(NULL AS VARCHAR(50)) AS unit_source_value + ,CAST(NULL AS VARCHAR(50)) AS value_source_value + ,drug_exposure_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].drug_exposure - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('measurement') - - -) OTHERS -; - - - - /**** + INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('measurement') + ) OTHERS; + +/**** OBSERVATION ****/ - - - --find valid observation from observation table - INSERT INTO [TARGET_CDMV5].[SCHEMA].observation - SELECT - observation_id, - person_id, - observation_concept_id, - observation_date, - CAST(observation_time as varchar(50)) as observation_time, - observation_type_concept_id, - value_as_number, - value_as_string, - value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - unit_concept_id, - associated_provider_id as provider_id, - visit_occurrence_id, - observation_source_value, - CAST(null as integer) observation_source_concept_id, - unit_source_value, - cast(null as varchar(50)) qualifier_source_value - FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION - WHERE observation_concept_id NOT IN (SELECT source_concept_id FROM #concept_map_distinct WHERE LOWER(domain_id) IN ('condition','drug','procedure','device','measurement')) +--find valid observation from observation table +INSERT INTO [TARGET_CDMV5].[SCHEMA].observation +SELECT observation_id + ,person_id + ,observation_concept_id + ,observation_date + ,CAST(observation_time AS VARCHAR(50)) AS observation_time + ,observation_type_concept_id + ,value_as_number + ,value_as_string + ,value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,unit_concept_id + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value +FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION +WHERE observation_concept_id NOT IN ( + SELECT source_concept_id + FROM #concept_map_distinct + WHERE LOWER(domain_id) IN ( + 'condition' + ,'drug' + ,'procedure' + ,'device' + ,'measurement' + ) + ) +--find observations that were previously classified as procedure - - --find observations that were previously classified as procedure -UNION ALL -select - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS observation_id, - person_id, - observation_concept_id, - observation_date, - observation_time, - observation_type_concept_id, - value_as_number, - 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 -( - select person_id, - cm1.target_concept_id as observation_concept_id, - procedure_date as observation_date, - CAST(null as varchar(50)) as observation_time, - 0 as observation_type_concept_id, - CAST(null as float) as value_as_number, - null as value_as_string, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - CAST(null as integer) as unit_concept_id, - associated_provider_id as provider_id, - visit_occurrence_id, - procedure_source_value as observation_source_value, - CAST(null as integer) observation_source_concept_id, - null as unit_source_value, - cast(null as varchar(50)) qualifier_source_value, - procedure_occurrence_id as occurrence_id +UNION ALL + +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS observation_id + ,person_id + ,observation_concept_id + ,observation_date + ,observation_time + ,observation_type_concept_id + ,value_as_number + ,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 ( + SELECT person_id + ,cm1.target_concept_id AS observation_concept_id + ,procedure_date AS observation_date + ,CAST(NULL AS VARCHAR(50)) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS FLOAT) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,procedure_source_value AS observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,NULL AS unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value + ,procedure_occurrence_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE - INNER JOIN #concept_map cm1 - ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('observation') - - --find observations that were previously classified as condition - UNION ALL - SELECT person_id, - cm1.target_concept_id as observation_concept_id, - condition_start_date as observation_date, - CAST(null as varchar(50)) as observation_time, - 0 as observation_type_concept_id, - CAST(null as float) as value_as_number, - null as value_as_string, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - CAST(null as integer) as unit_concept_id, - associated_provider_id as provider_id, - visit_occurrence_id, - condition_source_value as observation_source_value, - CAST(null as integer) observation_source_concept_id, - null as unit_source_value, - cast(null as varchar(50)) qualifier_source_value, - condition_occurrence_id as occurrence_id - FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE - INNER JOIN #concept_map cm1 - ON condition_occurrence.condition_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('observation') - - --find observations that were previously classified as drug exposure + INNER JOIN #concept_map cm1 ON procedure_occurrence.procedure_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + --find observations that were previously classified as condition + UNION ALL - SELECT person_id, - cm1.target_concept_id as observation_concept_id, - drug_exposure_start_date as observation_date, - CAST(null as varchar(10)) as observation_time, - 0 as observation_type_concept_id, - CAST(null as float) as value_as_number, - null as value_as_string, - CAST(null as integer) as value_as_concept_id, - CAST(null as integer) qualifier_concept_id, - CAST(null as integer) as unit_concept_id, - CAST(null as integer) as provider_id, - visit_occurrence_id, - drug_source_value as observation_source_value, - CAST(null as integer) observation_source_concept_id, - null as unit_source_value, - cast(null as varchar(50)) qualifier_source_value, - drug_exposure_id as occurrence_id + + SELECT person_id + ,cm1.target_concept_id AS observation_concept_id + ,condition_start_date AS observation_date + ,CAST(NULL AS VARCHAR(50)) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS FLOAT) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,associated_provider_id AS provider_id + ,visit_occurrence_id + ,condition_source_value AS observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,NULL AS unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value + ,condition_occurrence_id AS occurrence_id + FROM [SOURCE_CDMV4].[SCHEMA].CONDITION_OCCURRENCE + INNER JOIN #concept_map cm1 ON condition_occurrence.condition_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + + UNION ALL + + --find DRG observations that were previously classified as procedure_cost + SELECT po.person_id + ,cm1.target_concept_id AS observation_concept_id + ,po.procedure_date AS observation_date + ,CAST(NULL AS VARCHAR(50)) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS FLOAT) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,po.associated_provider_id AS provider_id + ,po.visit_occurrence_id + ,pc.DISEASE_CLASS_SOURCE_VALUE AS observation_source_value + ,cm1.source_concept_id as observation_source_concept_id + ,NULL AS unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value + ,po.procedure_occurrence_id AS occurrence_id + FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_COST pc + INNER JOIN [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE po ON pc.PROCEDURE_OCCURRENCE_ID = po.PROCEDURE_OCCURRENCE_ID + INNER JOIN #concept_map cm1 ON pc.disease_class_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + + UNION ALL + + --find observations that were previously classified as drug exposure + SELECT person_id + ,cm1.target_concept_id AS observation_concept_id + ,drug_exposure_start_date AS observation_date + ,CAST(NULL AS VARCHAR(10)) AS observation_time + ,0 AS observation_type_concept_id + ,CAST(NULL AS FLOAT) AS value_as_number + ,NULL AS value_as_string + ,CAST(NULL AS INT) AS value_as_concept_id + ,CAST(NULL AS INT) qualifier_concept_id + ,CAST(NULL AS INT) AS unit_concept_id + ,CAST(NULL AS INT) AS provider_id + ,visit_occurrence_id + ,drug_source_value AS observation_source_value + ,CAST(NULL AS INT) observation_source_concept_id + ,NULL AS unit_source_value + ,cast(NULL AS VARCHAR(50)) qualifier_source_value + ,drug_exposure_id AS occurrence_id FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE - INNER JOIN #concept_map cm1 - ON drug_exposure.drug_concept_id = cm1.source_concept_id - AND LOWER(cm1.domain_id) IN ('observation') - ) OTHERS,(SELECT MAX(OBSERVATION_ID) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION) MAXROW - ; - - - - /**** + INNER JOIN #concept_map cm1 ON drug_exposure.drug_concept_id = cm1.source_concept_id + AND LOWER(cm1.domain_id) IN ('observation') + ) OTHERS + ,( + SELECT MAX(OBSERVATION_ID) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].OBSERVATION + ) MAXROW; + +/**** PAYER_PLAN_PERIOD ****/ - INSERT INTO [TARGET_CDMV5].[SCHEMA].payer_plan_period -SELECT payer_plan_period_id, person_id, payer_plan_period_start_date, payer_plan_period_end_date, - payer_source_value, plan_source_value, family_source_value +SELECT payer_plan_period_id + ,person_id + ,payer_plan_period_start_date + ,payer_plan_period_end_date + ,payer_source_value + ,plan_source_value + ,family_source_value FROM [SOURCE_CDMV4].[SCHEMA].PAYER_PLAN_PERIOD; - - /**** + +/**** DRUG_COST note : if there were invalid drug concepts in DRUG_EXPOSURE, those records may not enter CDMv5 but costs will persist ****/ - INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_cost -SELECT drug_cost_id, dc.drug_exposure_id, cast(null as integer) currency_concept_id, paid_copay, paid_coinsurance, paid_toward_deductible, paid_by_payer, - paid_by_coordination_benefits, total_out_of_pocket, total_paid, ingredient_cost, dispensing_fee, - average_wholesale_price, payer_plan_period_id -FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST dc -; +SELECT drug_cost_id + ,dc.drug_exposure_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,ingredient_cost + ,dispensing_fee + ,average_wholesale_price + ,payer_plan_period_id +FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST dc; -- insert procedure costs for procedures that were inserted into the drug_exposure table INSERT INTO [TARGET_CDMV5].[SCHEMA].drug_cost -select - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS drug_cost_id, - drug_exposure_id, - cast(null as integer) currency_concept_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - ingredient_cost, - dispensing_fee, - average_wholesale_price, - payer_plan_period_id +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS drug_cost_id + ,drug_exposure_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,ingredient_cost + ,dispensing_fee + ,average_wholesale_price + ,payer_plan_period_id FROM ( - SELECT - drug_exposure_id, - po.person_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - CAST(null as float) as ingredient_cost, - CAST(null as float) as dispensing_fee, - CAST(null as float) as average_wholesale_price, - payer_plan_period_id, - procedure_cost_id as OCCURRENCE_ID + SELECT drug_exposure_id + ,po.person_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,CAST(NULL AS FLOAT) AS ingredient_cost + ,CAST(NULL AS FLOAT) AS dispensing_fee + ,CAST(NULL AS FLOAT) AS average_wholesale_price + ,payer_plan_period_id + ,procedure_cost_id AS OCCURRENCE_ID FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_OCCURRENCE po - join [SOURCE_CDMV4].[SCHEMA].PROCEDURE_COST pc on po.procedure_occurrence_id = pc.procedure_occurrence_id + INNER JOIN [SOURCE_CDMV4].[SCHEMA].PROCEDURE_COST pc ON po.procedure_occurrence_id = pc.procedure_occurrence_id --JOIN dbo.drug_exposure de on de.person_id = po.person_id and pc.procedure_occurrence_id = de.origional_procedure_id - JOIN #drgexp_map de on de.person_id = po.person_id and pc.procedure_occurrence_id = de.origional_procedure_id -) OTHERS ,(SELECT MAX(drug_cost_id) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST) MAXROW -; - - /**** + INNER JOIN #drgexp_map de ON de.person_id = po.person_id + AND pc.procedure_occurrence_id = de.origional_procedure_id + ) OTHERS + ,( + SELECT MAX(drug_cost_id) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST + ) MAXROW; + +/**** PROCEDURE_COST @@ -1747,127 +1855,207 @@ FROM ( ****/ - INSERT INTO [TARGET_CDMV5].[SCHEMA].procedure_cost -SELECT procedure_cost_id, procedure_occurrence_id, cast(null as integer) currency_concept_id, paid_copay, paid_coinsurance, paid_toward_deductible, - paid_by_payer, paid_by_coordination_benefits, total_out_of_pocket, total_paid, - payer_plan_period_id, revenue_code_concept_id, revenue_code_source_value +SELECT procedure_cost_id + ,procedure_occurrence_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,payer_plan_period_id + ,revenue_code_concept_id + ,revenue_code_source_value FROM [SOURCE_CDMV4].[SCHEMA].PROCEDURE_COST; - -- insert drug costs for drugs that were inserted into the procedure_occurrence table INSERT INTO [TARGET_CDMV5].[SCHEMA].procedure_cost -SELECT - CASE WHEN MAXROW.MAXROWID IS NULL THEN 0 ELSE MAXROW.MAXROWID END + row_number() over (order by OCCURRENCE_ID) AS procedure_cost_id, - procedure_occurrence_id, - cast(null as integer) - currency_concept_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - payer_plan_period_id, - revenue_code_concept_id, - revenue_code_source_value - FROM ( - SELECT - po.procedure_occurrence_id, - po.person_id, - paid_copay, - paid_coinsurance, - paid_toward_deductible, - paid_by_payer, - paid_by_coordination_benefits, - total_out_of_pocket, - total_paid, - CAST(null as float) as ingredient_cost, - CAST(null as float) as dispensing_fee, - CAST(null as float) as average_wholesale_price, - payer_plan_period_id, - CAST(null as integer) as revenue_code_concept_id, - CAST(null as integer) as revenue_code_source_value, - drug_cost_id as OCCURRENCE_ID - FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE de - join [SOURCE_CDMV4].[SCHEMA].DRUG_COST dc on de.drug_exposure_id = dc.drug_exposure_id - --JOIN dbo.procedure_occurrence po on de.person_id = po.person_id and de.drug_exposure_id = po.origional_drug_id - JOIN #po_map po on de.person_id = po.person_id and de.drug_exposure_id = po.origional_drug_id - ) OTHERS,(SELECT MAX(drug_cost_id) AS MAXROWID FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST) MAXROW -; - +SELECT CASE + WHEN MAXROW.MAXROWID IS NULL + THEN 0 + ELSE MAXROW.MAXROWID + END + row_number() OVER ( + ORDER BY OCCURRENCE_ID + ) AS procedure_cost_id + ,procedure_occurrence_id + ,cast(NULL AS INT) currency_concept_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,payer_plan_period_id + ,revenue_code_concept_id + ,revenue_code_source_value +FROM ( + SELECT po.procedure_occurrence_id + ,po.person_id + ,paid_copay + ,paid_coinsurance + ,paid_toward_deductible + ,paid_by_payer + ,paid_by_coordination_benefits + ,total_out_of_pocket + ,total_paid + ,CAST(NULL AS FLOAT) AS ingredient_cost + ,CAST(NULL AS FLOAT) AS dispensing_fee + ,CAST(NULL AS FLOAT) AS average_wholesale_price + ,payer_plan_period_id + ,CAST(NULL AS INT) AS revenue_code_concept_id + ,CAST(NULL AS INT) AS revenue_code_source_value + ,drug_cost_id AS OCCURRENCE_ID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_EXPOSURE de + INNER JOIN [SOURCE_CDMV4].[SCHEMA].DRUG_COST dc ON de.drug_exposure_id = dc.drug_exposure_id + --JOIN dbo.procedure_occurrence po on de.person_id = po.person_id and de.drug_exposure_id = po.origional_drug_id + INNER JOIN #po_map po ON de.person_id = po.person_id + AND de.drug_exposure_id = po.origional_drug_id + ) OTHERS + ,( + SELECT MAX(drug_cost_id) AS MAXROWID + FROM [SOURCE_CDMV4].[SCHEMA].DRUG_COST + ) MAXROW; + /**** DRUG ERA Note: Eras derived from DRUG_EXPOSURE table, using 30d gap ****/ +IF OBJECT_ID('tempdb..#cteDrugTarget', 'U') IS NOT NULL + DROP TABLE #cteDrugTarget; --- drop table dbo.drug_era -with cteDrugTarget (DRUG_EXPOSURE_ID, PERSON_ID, DRUG_CONCEPT_ID, DRUG_TYPE_CONCEPT_ID, DRUG_EXPOSURE_START_DATE, DRUG_EXPOSURE_END_DATE, INGREDIENT_CONCEPT_ID) as -( - -- 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 - FROM [TARGET_CDMV5].[SCHEMA].DRUG_EXPOSURE d - join [TARGET_CDMV5].[SCHEMA].CONCEPT_ANCESTOR ca on ca.DESCENDANT_CONCEPT_ID = d.DRUG_CONCEPT_ID - 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' -), -cteEndDates (PERSON_ID, INGREDIENT_CONCEPT_ID, END_DATE) as -- the magic -( - 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 +/* / */ + +-- 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 - 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 + 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 -), -cteDrugExposureEnds (PERSON_ID, DRUG_CONCEPT_ID, DRUG_TYPE_CONCEPT_ID, DRUG_EXPOSURE_START_DATE, DRUG_ERA_END_DATE) 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 -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, drug_concept_id, min(DRUG_EXPOSURE_START_DATE) as drug_era_start_date, drug_era_end_date, COUNT(*) as DRUG_EXPOSURE_COUNT, 30 as gap_days -from cteDrugExposureEnds -GROUP BY person_id, drug_concept_id, drug_type_concept_id, DRUG_ERA_END_DATE -; +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; /**** @@ -1875,82 +2063,296 @@ 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; -with cteConditionTarget (PERSON_ID, CONDITION_CONCEPT_ID, CONDITION_START_DATE, CONDITION_END_DATE) as -( - -- 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 - FROM [TARGET_CDMV5].[SCHEMA].CONDITION_OCCURRENCE co -), -cteEndDates (PERSON_ID, CONDITION_CONCEPT_ID, END_DATE) as -- the magic -( - 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 +/* / */ + +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 - 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 + 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 -), -cteConditionEnds (PERSON_ID, CONDITION_CONCEPT_ID, CONDITION_START_DATE, ERA_END_DATE) as +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; + +/**** + +QUALITY ASSURANCE OUTPUT + +Note: These queries are used to provide some basic stats around row counts between your V4 and V5 database + to ensure that all of the data has migrated as expected. + + ****/ + +IF OBJECT_ID('tempdb..#v5_stats', 'U') IS NOT NULL + DROP TABLE #v5_stats; + +/* / */ + +IF OBJECT_ID('tempdb..#v4_stats', 'U') IS NOT NULL + DROP TABLE #v4_stats; + +/* / */ + +-- Get the row counts for each table that is in scope for the migration +SELECT * +INTO #v4_stats +FROM ( -select - c.PERSON_ID, - c.CONDITION_CONCEPT_ID, - c.CONDITION_START_DATE, - MIN(e.END_DATE) as ERA_END_DATE -FROM cteConditionTarget c -JOIN cteEndDates 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 -) -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 -INTO #condition_era_phase_1 -from cteConditionEnds -GROUP BY person_id, CONDITION_CONCEPT_ID, ERA_END_DATE -; + SELECT '[SOURCE_CDMV4]' AS DBName, 'care_site' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].care_site + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'condition_era' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].condition_era + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'condition_occurrence' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].condition_occurrence + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'death' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].death + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'drug_cost' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].drug_cost + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'drug_era' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].drug_era + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'drug_exposure' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].drug_exposure + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'location' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].location + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'observation' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].observation + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'observation_period' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].observation_period + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'payer_plan_period' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].payer_plan_period + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'person' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].person + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'procedure_cost' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].procedure_cost + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'procedure_occurrence' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].procedure_occurrence + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'provider' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].provider + UNION + SELECT '[SOURCE_CDMV4]' AS DBName, 'visit_occurrence' AS TableName, COUNT(*) as row_count FROM [SOURCE_CDMV4].[SCHEMA].visit_occurrence +) v4_stats; -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 - condition_era_id, - PERSON_ID, - CONDITION_CONCEPT_ID, - CONDITION_ERA_START_DATE, - CONDITION_ERA_END_DATE, - CONDITIOn_OCCURRENCE_COUNT -FROM #condition_era_phase_1 +/* / */ +SELECT * +INTO #v5_stats +FROM +( + SELECT '[TARGET_CDMV5]' AS DBName, 'care_site' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].care_site + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'condition_era' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].condition_era + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'condition_occurrence' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].condition_occurrence + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'death' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].death + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'device_exposure' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].device_exposure + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'drug_cost' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].drug_cost + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'drug_era' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].drug_era + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'drug_exposure' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].drug_exposure + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'location' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].location + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'measurement' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].measurement + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'observation' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].observation + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'observation_period' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].observation_period + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'payer_plan_period' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].payer_plan_period + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'person' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].person + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'procedure_cost' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].procedure_cost + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'procedure_occurrence' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].procedure_occurrence + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'provider' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].provider + UNION + SELECT '[TARGET_CDMV5]' AS DBName, 'visit_occurrence' AS TableName, COUNT(*) as row_count FROM [TARGET_CDMV5].[SCHEMA].visit_occurrence +) v5_stats; +/* / */ + +-- Show the results +select + 'Rowcounts for each database and table', + ISNULL(V4.DBName, 'None') v4_database_name, + v4.TableName v4_table_name, + v4.row_count v4_row_count, + ISNULL(v5.DBName, 'None') v5_database_name, + v5.TableName v5_table_name, + v5.row_count v5_row_count, + ISNULL(v5.row_count, 0) - ISNULL(v4.row_count, 0) row_count_change +from #v4_stats v4 +full outer join #v5_stats v5 ON v4.TableName = v5.TableName +order by v5.TableName; + +/* + * Determine how the vocabulary/domains helped to map from the V4 source + * tables to the V5 destinations + */ +IF OBJECT_ID('tempdb..#classification_map', 'U') IS NOT NULL + DROP TABLE #classification_map; + +/* / */ + +SELECT * +INTO #classification_map +FROM +( + SELECT 'Condition_Occurrence' TableName, ISNULL(LOWER(cm.domain_id), 'condition') domain_id, COUNT(*) row_count + FROM [SOURCE_CDMV4].[SCHEMA].Condition_Occurrence CO + LEFT JOIN #concept_map CM ON co.condition_concept_id = cm.source_concept_id + GROUP BY ISNULL(LOWER(cm.domain_id), 'condition') + UNION + SELECT 'Drug_Exposure' TableName, ISNULL(LOWER(cm.domain_id), 'drug') domain_id, COUNT(*) row_count + FROM [SOURCE_CDMV4].[SCHEMA].Drug_Exposure de + LEFT JOIN #concept_map CM ON de.drug_concept_id = cm.source_concept_id + GROUP BY ISNULL(LOWER(cm.domain_id), 'drug') + UNION + SELECT 'Observation' TableName, ISNULL(LOWER(cm.domain_id), 'observation') domain_id, COUNT(*) row_count + FROM [SOURCE_CDMV4].[SCHEMA].Observation o + LEFT JOIN #concept_map CM ON o.observation_concept_id = cm.source_concept_id + GROUP BY ISNULL(LOWER(cm.domain_id), 'observation') + UNION + SELECT 'Procedure_Occurrence' TableName, ISNULL(LOWER(cm.domain_id), 'procedure') domain_id, COUNT(*) row_count + FROM [SOURCE_CDMV4].[SCHEMA].Procedure_Occurrence po + LEFT JOIN #concept_map CM ON po.PROCEDURE_CONCEPT_ID = cm.source_concept_id + GROUP BY ISNULL(LOWER(cm.domain_id), 'procedure') +) A +ORDER by A.TableName, A.domain_id; + +/* / */ + +select * +from #classification_map +order by tablename, domain_id; + +select domain_id, SUM(row_count) +from #classification_map +group by domain_id +order by domain_id; \ No newline at end of file