* 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 XACT_STATE() = 1 COMMIT; IF OBJECT_ID('tempdb..#concept_map', 'U') IS NOT NULL DROP TABLE #concept_map;
/* / */
IF XACT_STATE() = 1 COMMIT; CREATE TABLE #concept_map
WITH (LOCATION = USER_DB, DISTRIBUTION = REPLICATE) 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
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 XACT_STATE() = 1 COMMIT; IF OBJECT_ID('tempdb..#concept_map_distinct', 'U') IS NOT NULL DROP TABLE #concept_map_distinct;
/* / */
IF XACT_STATE() = 1 COMMIT; CREATE TABLE #concept_map_distinct
WITH (LOCATION = USER_DB, DISTRIBUTION = REPLICATE) 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;
IF XACT_STATE() = 1 COMMIT; IF OBJECT_ID('[TARGET_CDMV5].[SCHEMA].ETL_WARNINGS', 'U') IS NOT NULL DROP TABLE [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS;
/* / */
IF XACT_STATE() = 1 COMMIT; CREATE TABLE [TARGET_CDMV5].[SCHEMA].ETL_WARNINGS (WARNING_MESSAGE VARCHAR(4000))
WITH (DISTRIBUTION = REPLICATE);
/* / */
/****
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 XACT_STATE() = 1 COMMIT; IF OBJECT_ID('tempdb..#po_map', 'U') IS NOT NULL DROP TABLE #po_map;
/* / */
IF XACT_STATE() = 1 COMMIT; CREATE TABLE #po_map
WITH (LOCATION = USER_DB, DISTRIBUTION = HASH(person_id)) 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
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 XACT_STATE() = 1 COMMIT; IF OBJECT_ID('tempdb..#drgexp_map', 'U') IS NOT NULL DROP TABLE #drgexp_map;
/* / */
IF XACT_STATE() = 1 COMMIT; CREATE TABLE #drgexp_map
WITH (LOCATION = USER_DB, DISTRIBUTION = HASH(person_id)) 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
SELECT drug_exposure_id
,person_id
,COALESCE(cm1.target_concept_id, 0) AS drug_concept_id
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