├── CureID Cohort Creation Guide.pdf
├── Cohort curation scripts
├── OMOP Deidentification Steps.pdf
├── 07_D_review_unmapped_drugs.sql
├── SEPSIS
│ ├── 03B_SEPSIS_Review_UNMAPPED_DRUG_Profile.sql
│ ├── 03C_SEPSIS_MEASUREMENT_Profile.sql
│ ├── 03E_DEVICE_ancestor_and_unmapped_occurrence_profile.sql
│ ├── 03D_CONDITION_ancestor_and_unmapped_occurrence_profile.sql
│ ├── 02_SEPSIS_INGREDIENT_Profile.sql
│ ├── 01A_SEPSIS_Cohort_V4.sql
│ ├── 03A_SEPSIS_MAPPED_DRUG_Profile.sql
│ ├── 04_SEPSIS_COHORT_SUMMARY.v2sql
│ └── 04_SEPSIS_COHORT_SUMMARY.v2_standard_SQLsql
├── 07_A_condition_profile.sql
├── 07_E_device_profile.sql
├── 07_C_drug_exposure_profile.sql
├── 06_DE_ID_Quality_Checks.sql
├── 07_B_measurement_profile.sql
├── old
│ ├── measurement_count_profile.sql
│ └── 01_CURE_ID_Cohort_20220421.sql
├── 03_CURE_ID_replace_rare_conditions_with_parents.sql
├── 04_DE_ID_CDM_Table_ddl.sql
├── 01_CURE_ID_Cohort.sql
├── 02_CURE_ID_All_Tables.sql
└── 05_DE_ID_script.sql
├── CURE ID Concepts
├── READ_BEFORE_USING_JSON.md
├── custom_concepts.csv
├── old
│ ├── cure_id_device_exposure.json
│ ├── cure_id_observations.json
│ ├── cure_id_conditions.json
│ ├── cure_id_person.json
│ ├── OMOP_concept_list_parent_only.csv
│ ├── cure_id_concepts.csv
│ ├── conceptcountcheck.sql
│ └── cure_id_procedures.json
└── CureID_concepts_parents_Version1.csv
├── EdgeToolSuite.md
├── README.md
└── CureID Cohort Creation Guide.md
/CureID Cohort Creation Guide.pdf:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/OHDSI/CureIdRegistry/HEAD/CureID Cohort Creation Guide.pdf
--------------------------------------------------------------------------------
/Cohort curation scripts/OMOP Deidentification Steps.pdf:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/OHDSI/CureIdRegistry/HEAD/Cohort curation scripts/OMOP Deidentification Steps.pdf
--------------------------------------------------------------------------------
/CURE ID Concepts/READ_BEFORE_USING_JSON.md:
--------------------------------------------------------------------------------
1 | *Please note that the .json file maintained in ATLAS does not contain 5 custom concepts assigned to oxygen devices that are not covered by the OMOP Vocabularies.
2 |
3 | If you are generating a cohort using ATLAS or the json file, you will need to add these concepts manually. These are listed in the "custom_concepts.csv" file.
4 |
--------------------------------------------------------------------------------
/CURE ID Concepts/custom_concepts.csv:
--------------------------------------------------------------------------------
1 | concept_id ,concept_code ,concept_name ,domain ,vocabulary ,is_standard ,include_descendants
2 | 2004208004,NA,Other oxygen device,Device,Custom,C,FALSE
3 | 2004208005,NA,Room air (in the context of a device),Device,Custom,C,FALSE
4 | 2004208006,NA,CPAP (continuous positive airway pressure),Device,Custom,C,FALSE
5 | 2004208007,NA,BiPAP (bilevel positive airway pressure),Device,Custom,C,FALSE
6 | 2004208008,NA,NIPPV (non-invasive positive pressure ventilation or nasal intermittent positive pressure ventilation),Device,Custom,C,FALSE
7 |
--------------------------------------------------------------------------------
/Cohort curation scripts/07_D_review_unmapped_drugs.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 07_D_review_unmapped_drugs.sql
4 |
5 | Purpose:
6 | Generate a profile of drugs that are not mapped to drug_concept_ids in the final cohort
7 |
8 | Description:
9 | This file filters drugs that were unsuccessfully mapped to a drug_concept_id when
10 | running the 02_CURE_ID_All_Tables.sql script. Drug source values for which the
11 | drug_concept_id is “0” and have at least 20 instances in the final cohort are
12 | aggregated for manual review.
13 | Drug source values can contain PHI. Please review the output for PHI before sharing.
14 |
15 | Dependencies:
16 | */
17 |
18 | SELECT *
19 | FROM (
20 | SELECT
21 | de.drug_source_value,
22 | COUNT(de.drug_source_value) AS unmapped_drug_count
23 | FROM
24 | DRUG_EXPOSURE AS de
25 | LEFT JOIN
26 | [Results].[CURE_ID_Visit_Occurrence] AS coh
27 | ON
28 | de.person_id = coh.person_id
29 | AND de.drug_exposure_start_date >= coh.visit_start_date
30 | AND de.drug_exposure_start_date <= coh.visit_end_date
31 | WHERE
32 | de.drug_concept_id = 0
33 | GROUP BY de.drug_source_value
34 | ) AS x1
35 | WHERE unmapped_drug_count > 20
36 | ORDER BY unmapped_drug_count DESC;
37 |
--------------------------------------------------------------------------------
/Cohort curation scripts/SEPSIS/03B_SEPSIS_Review_UNMAPPED_DRUG_Profile.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 03B_SEPSIS_Review_UNMAPPED_DRUG_Profile.sql
4 |
5 | Purpose:
6 | Generate a profile of drugs that are not mapped to drug_concept_ids in the final cohort
7 |
8 | Description:
9 | This file filters drugs that were unsuccessfully mapped to a drug_concept_id in the sepsis cohort. Drug source values for which the
10 | drug_concept_id is “0” and have at least 20 instances in the final cohort are
11 | aggregated for manual review.
12 | Drug source values can contain PHI. Please review the output for PHI before sharing.
13 |
14 | Dependencies:
15 | */
16 |
17 | SELECT *
18 | FROM (
19 | SELECT
20 | de.drug_source_value,
21 | COUNT(de.drug_source_value) AS unmapped_drug_count
22 | FROM
23 | DRUG_EXPOSURE AS de
24 | LEFT JOIN
25 | [Results].[YOUR_SEPSIS_CDM_Visit_Occurrence] AS coh
26 | ON
27 | de.person_id = coh.person_id
28 | AND de.drug_exposure_start_date >= coh.visit_start_date
29 | AND de.drug_exposure_start_date <= coh.visit_end_date
30 | WHERE
31 | de.drug_concept_id = 0
32 | GROUP BY de.drug_source_value
33 | ) AS x1
34 | WHERE unmapped_drug_count > 20
35 | ORDER BY unmapped_drug_count DESC;
36 |
--------------------------------------------------------------------------------
/Cohort curation scripts/SEPSIS/03C_SEPSIS_MEASUREMENT_Profile.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 03C_SEPSIS_measurement_profile.sql
4 |
5 | Purpose:
6 | Generate a profile of measurement prevalence in the final Sepsis cohort
7 |
8 | Description:
9 | Measurement counts are calculated per patient and are aggregated by parent concepts
10 | for each measurement concept present in the final Sepsis OMOP Measurement table.
11 |
12 | Dependencies:
13 |
14 | */
15 |
16 | WITH measurement_counts AS (
17 | SELECT
18 | measurement_concept_id,
19 | measurement_source_value,
20 | COUNT(DISTINCT person_id) AS unique_person_count,
21 | COUNT(*) / COUNT(DISTINCT person_id) AS mean_measurements_per_patient
22 | FROM
23 | YOUR SCHEMA NAME measurement
24 | GROUP BY
25 | measurement_concept_id,
26 | measurement_source_value
27 | ),
28 | total_person_count AS (
29 | SELECT
30 | COUNT(DISTINCT person_id) AS total_persons
31 | FROM
32 | measurement
33 | )
34 | SELECT
35 | mc.measurement_concept_id,
36 | mc.measurement_source_value,
37 | mc.unique_person_count,
38 | ROUND((mc.unique_person_count / tpc.total_persons) * 100, 2) AS percent_of_persons,
39 | mc.mean_measurements_per_patient
40 | FROM
41 | measurement_counts mc,
42 | total_person_count tpc
43 | ORDER BY
44 | percent_of_persons DESC;
45 |
--------------------------------------------------------------------------------
/Cohort curation scripts/SEPSIS/03E_DEVICE_ancestor_and_unmapped_occurrence_profile.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 03E_DEVICE_ancestor_and_unmapped_occurrence_profile.sql
4 |
5 | Purpose:
6 | Generate a profile of device occurrence prevalence, including both ancestor concepts and unmapped devices, in the final cohort.
7 |
8 | Description:
9 | Device occurrence counts are calculated per patient and are aggregated by ancestor concepts
10 | for each device concept present in the final OMOP Device Exposure table. Unmapped devices
11 | (those without ancestors) are also included. The `device_source_value` is also included in the output.
12 |
13 | Dependencies:
14 | Requires a device exposure table, concept table, and concept_ancestor table in the specified schema.
15 | */
16 |
17 | WITH device_counts AS (
18 | SELECT
19 | COALESCE(ca.ancestor_concept_id, de.device_concept_id) AS concept_id,
20 | COALESCE(ac.concept_name, sc.concept_name, de.device_source_value) AS concept_name,
21 | de.device_source_value,
22 | COUNT(DISTINCT de.person_id) AS unique_person_count,
23 | COUNT(*) / COUNT(DISTINCT de.person_id) AS mean_devices_per_patient
24 | FROM
25 | YOUR_SCHEMA_NAME.device_exposure de
26 | LEFT JOIN
27 | YOUR_SCHEMA_NAME.concept_ancestor ca
28 | ON de.device_concept_id = ca.descendant_concept_id
29 | LEFT JOIN
30 | YOUR_SCHEMA_NAME.concept ac
31 | ON ca.ancestor_concept_id = ac.concept_id
32 | LEFT JOIN
33 | YOUR_SCHEMA_NAME.concept sc
34 | ON de.device_concept_id = sc.concept_id
35 | GROUP BY
36 | COALESCE(ca.ancestor_concept_id, de.device_concept_id),
37 | COALESCE(ac.concept_name, sc.concept_name, de.device_source_value),
38 | de.device_source_value
39 | ),
40 | total_person_count AS (
41 | SELECT
42 | COUNT(DISTINCT person_id) AS total_persons
43 | FROM
44 | YOUR_SCHEMA_NAME.device_exposure
45 | )
46 | SELECT
47 | dc.concept_id,
48 | dc.concept_name,
49 | dc.device_source_value,
50 | dc.unique_person_count,
51 | ROUND((dc.unique_person_count / tpc.total_persons) * 100, 2) AS percent_of_persons,
52 | dc.mean_devices_per_patient
53 | FROM
54 | device_counts dc,
55 | total_person_count tpc
56 | ORDER BY
57 | percent_of_persons DESC;
58 |
--------------------------------------------------------------------------------
/Cohort curation scripts/SEPSIS/03D_CONDITION_ancestor_and_unmapped_occurrence_profile.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 03D_CONDITION_ancestor_and_unmapped_occurrence_profile.sql
4 |
5 | Purpose:
6 | Generate a profile of condition occurrence prevalence, including both ancestor concepts and unmapped conditions, in the final cohort.
7 |
8 | Description:
9 | Condition occurrence counts are calculated per patient and are aggregated by ancestor concepts
10 | for each condition concept present in the final OMOP Condition Occurrence table. Unmapped conditions
11 | (those without ancestors) are also included. The `condition_source_value` is also included in the output.
12 |
13 | Dependencies:
14 | Requires a condition occurrence table, concept table, and concept_ancestor table in the specified schema.
15 | */
16 |
17 | WITH condition_counts AS (
18 | SELECT
19 | COALESCE(ca.ancestor_concept_id, co.condition_concept_id) AS concept_id,
20 | COALESCE(ac.concept_name, sc.concept_name, co.condition_source_value) AS concept_name,
21 | co.condition_source_value,
22 | COUNT(DISTINCT co.person_id) AS unique_person_count,
23 | COUNT(*) / COUNT(DISTINCT co.person_id) AS mean_conditions_per_patient
24 | FROM
25 | YOUR_SCHEMA_NAME.condition_occurrence co
26 | LEFT JOIN
27 | YOUR_SCHEMA_NAME.concept_ancestor ca
28 | ON co.condition_concept_id = ca.descendant_concept_id
29 | LEFT JOIN
30 | YOUR_SCHEMA_NAME.concept ac
31 | ON ca.ancestor_concept_id = ac.concept_id
32 | LEFT JOIN
33 | YOUR_SCHEMA_NAME.concept sc
34 | ON co.condition_concept_id = sc.concept_id
35 | GROUP BY
36 | COALESCE(ca.ancestor_concept_id, co.condition_concept_id),
37 | COALESCE(ac.concept_name, sc.concept_name, co.condition_source_value),
38 | co.condition_source_value
39 | ),
40 | total_person_count AS (
41 | SELECT
42 | COUNT(DISTINCT person_id) AS total_persons
43 | FROM
44 | YOUR_SCHEMA_NAME.condition_occurrence
45 | )
46 | SELECT
47 | cc.concept_id,
48 | cc.concept_name,
49 | cc.condition_source_value,
50 | cc.unique_person_count,
51 | ROUND((cc.unique_person_count / tpc.total_persons) * 100, 2) AS percent_of_persons,
52 | cc.mean_conditions_per_patient
53 | FROM
54 | condition_counts cc,
55 | total_person_count tpc
56 | ORDER BY
57 | percent_of_persons DESC;
58 |
59 |
--------------------------------------------------------------------------------
/CURE ID Concepts/old/cure_id_device_exposure.json:
--------------------------------------------------------------------------------
1 | {
2 | "items": [
3 | {
4 | "concept": {
5 | "CONCEPT_CLASS_ID": "Physical Object",
6 | "CONCEPT_CODE": "336623009",
7 | "CONCEPT_ID": 4224038,
8 | "CONCEPT_NAME": "Oxygen nasal cannula",
9 | "DOMAIN_ID": "Device",
10 | "INVALID_REASON": "V",
11 | "INVALID_REASON_CAPTION": "Valid",
12 | "STANDARD_CONCEPT": "S",
13 | "STANDARD_CONCEPT_CAPTION": "Standard",
14 | "VOCABULARY_ID": "SNOMED"
15 | },
16 | "isExcluded": false,
17 | "includeDescendants": true,
18 | "includeMapped": false
19 | },
20 | {
21 | "concept": {
22 | "CONCEPT_CLASS_ID": "Physical Object",
23 | "CONCEPT_CODE": "706172005",
24 | "CONCEPT_ID": 45768197,
25 | "CONCEPT_NAME": "Ventilator",
26 | "DOMAIN_ID": "Device",
27 | "INVALID_REASON": "V",
28 | "INVALID_REASON_CAPTION": "Valid",
29 | "STANDARD_CONCEPT": "S",
30 | "STANDARD_CONCEPT_CAPTION": "Standard",
31 | "VOCABULARY_ID": "SNOMED"
32 | },
33 | "isExcluded": false,
34 | "includeDescendants": true,
35 | "includeMapped": false
36 | },
37 | {
38 | "concept": {
39 | "CONCEPT_CLASS_ID": "Physical Object",
40 | "CONCEPT_CODE": "336602003",
41 | "CONCEPT_ID": 4222966,
42 | "CONCEPT_NAME": "Oxygen mask",
43 | "DOMAIN_ID": "Device",
44 | "INVALID_REASON": "V",
45 | "INVALID_REASON_CAPTION": "Valid",
46 | "STANDARD_CONCEPT": "S",
47 | "STANDARD_CONCEPT_CAPTION": "Standard",
48 | "VOCABULARY_ID": "SNOMED"
49 | },
50 | "isExcluded": false,
51 | "includeDescendants": true,
52 | "includeMapped": false
53 | },
54 | {
55 | "concept": {
56 | "CONCEPT_CLASS_ID": "Physical Object",
57 | "CONCEPT_CODE": "426294006",
58 | "CONCEPT_ID": 4138487,
59 | "CONCEPT_NAME": "Face tent oxygen delivery device",
60 | "DOMAIN_ID": "Device",
61 | "INVALID_REASON": "V",
62 | "INVALID_REASON_CAPTION": "Valid",
63 | "STANDARD_CONCEPT": "S",
64 | "STANDARD_CONCEPT_CAPTION": "Standard",
65 | "VOCABULARY_ID": "SNOMED"
66 | },
67 | "isExcluded": false,
68 | "includeDescendants": false,
69 | "includeMapped": false
70 | }
71 | ]
72 | }
--------------------------------------------------------------------------------
/Cohort curation scripts/07_A_condition_profile.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 07_A_condition_profile.sql
4 |
5 | Purpose:
6 | Generate a profile of condition prevalence in the final cohort
7 |
8 | Description:
9 | Condition counts are calculated per patient and are aggregated by parent concepts
10 | for each condition concept present in the final OMOP Condition Occurrence table.
11 |
12 | Dependencies:
13 |
14 | */
15 |
16 | USE YOUR_DATABASE;
17 |
18 | --Profile condition prevalence in cohort by individual condition concept
19 | --Condition counts include descendants
20 | SELECT
21 | CONCEPT.concept_name AS condition_name,
22 | CONCEPT_ANCESTOR.ancestor_concept_id,
23 | COUNT(DISTINCT c.person_id) AS persons_with_condition_or_descendant,
24 | 100 * COUNT(DISTINCT c.person_id) / (SELECT COUNT(DISTINCT c.person_id) FROM [Results].[deident_CURE_ID_Person]) AS percent_persons_with_condition
25 | FROM
26 | [Results].[deident_CURE_ID_Condition_Occurrence] AS c
27 | INNER JOIN CONCEPT_ANCESTOR
28 | ON
29 | CONCEPT_ANCESTOR.descendant_concept_id = c.condition_concept_id
30 | AND CONCEPT_ANCESTOR.ancestor_concept_id IN
31 | (SELECT condition_concept_id FROM [Results].[deident_CURE_ID_Condition_Occurrence])
32 | LEFT JOIN CONCEPT
33 | ON CONCEPT.concept_id = CONCEPT_ANCESTOR.ancestor_concept_id
34 | GROUP BY CONCEPT_ANCESTOR.ancestor_concept_id, CONCEPT.concept_name
35 | ORDER BY persons_with_condition_or_descendant DESC
36 |
37 | --Profile condition prevalence in cohort by parent condition concepts
38 | SELECT
39 | [Results].[cure_id_concepts].concept_name AS condition_name,
40 | CONCEPT_ANCESTOR.ancestor_concept_id,
41 | COUNT(DISTINCT c.person_id) AS persons_with_condition,
42 | 100 * COUNT(DISTINCT c.person_id) / (SELECT COUNT(DISTINCT c.person_id) FROM [Results].[deident_CURE_ID_Person]) AS percent_persons_with_condition
43 | FROM
44 | [Results].[deident_CURE_ID_Condition_Occurrence] AS c
45 | LEFT JOIN CONCEPT_ANCESTOR
46 | ON CONCEPT_ANCESTOR.descendant_concept_id = c.condition_concept_id
47 | INNER JOIN [Results].[cure_id_concepts]
48 | ON CONCEPT_ANCESTOR.ancestor_concept_id = [Results].[cure_id_concepts].concept_id
49 | WHERE
50 | [Results].[cure_id_concepts].domain = 'Condition'
51 | AND (
52 | [Results].[cure_id_concepts].include_descendants = 'TRUE'
53 | OR CONCEPT_ANCESTOR.ancestor_concept_id = CONCEPT_ANCESTOR.descendant_concept_id
54 | )
55 | GROUP BY
56 | CONCEPT_ANCESTOR.ancestor_concept_id, [Results].[cure_id_concepts].concept_name
57 | ORDER BY persons_with_condition DESC
58 |
--------------------------------------------------------------------------------
/Cohort curation scripts/SEPSIS/02_SEPSIS_INGREDIENT_Profile.sql:
--------------------------------------------------------------------------------
1 | -- This query retrieves the count of patients exposed to specific drug ingredients,
2 | -- aggregated by ingredient concept ID, ingredient name, drug source value, and route of administration.
3 |
4 | SELECT
5 | i.concept_id AS ingredient_concept_id, -- Concept ID representing the drug ingredient
6 | i.concept_name AS ingredient_name, -- Name of the drug ingredient
7 | de.route_source_value AS route_source_value, -- Source value representing the route of administration (e.g., oral, intravenous)
8 | de.drug_source_value AS drug_source_value, -- Source value representing the specific drug as recorded in the database
9 | COUNT(DISTINCT de.person_id) AS patient_count -- Count of unique patients exposed to this drug ingredient
10 | FROM YOUR_CDM.drug_exposure de -- Table containing drug exposure records
11 | JOIN vocab.concept_ancestor ca -- Table linking drug concepts to their ancestors (i.e., higher-level concepts like ingredients)
12 | ON ca.descendant_concept_id = de.drug_concept_id -- Join on drug concept ID from drug_exposure to find the ancestor concept
13 | JOIN vocab.concept i -- Table containing details of each concept (e.g., drugs, ingredients)
14 | ON i.concept_id = ca.ancestor_concept_id -- Join to get the ingredient concept details
15 | AND i.concept_class_id = 'Ingredient' -- Filter to only include concepts classified as 'Ingredient'
16 | WHERE i.concept_id IN ( -- Filter for specific ingredient concept IDs of interest
17 | 40171288, 44818461, 37002573, 1594587, 36860404,
18 | 1758974, 1510627, 36851220, 36855247, 1525713,
19 | 1361614, 36849476, 779180, 36858062, 745970,
20 | 40244464, 42904205, 1361580, 1555120, 1114375,
21 | 40161669, 19023450, 43012762, 905518, 45775965,
22 | 42629079, 35200783, 45892628, 1302024, 747052,
23 | 1319998, 1314002, 1322081, 1338005, 1346823,
24 | 19063575, 1386957, 1307046, 1313200, 1314577,
25 | 1327978, 1345858, 1353766, 1370109, 902427,
26 | 963889, 19137312
27 | )
28 | GROUP BY
29 | i.concept_id, -- Group by ingredient concept ID
30 | i.concept_name, -- Group by ingredient name
31 | de.drug_source_value, -- Group by drug source value
32 | de.route_source_value -- Group by route of administration
33 | ORDER BY
34 | patient_count DESC; -- Order results by patient count in descending order
35 |
--------------------------------------------------------------------------------
/CURE ID Concepts/old/cure_id_observations.json:
--------------------------------------------------------------------------------
1 | {
2 | "items": [
3 | {
4 | "concept": {
5 | "CONCEPT_CLASS_ID": "Clinical Finding",
6 | "CONCEPT_CODE": "77176002",
7 | "CONCEPT_ID": 4298794,
8 | "CONCEPT_NAME": "Smoker",
9 | "DOMAIN_ID": "Observation",
10 | "INVALID_REASON": "V",
11 | "INVALID_REASON_CAPTION": "Valid",
12 | "STANDARD_CONCEPT": "S",
13 | "STANDARD_CONCEPT_CAPTION": "Standard",
14 | "VOCABULARY_ID": "SNOMED"
15 | },
16 | "isExcluded": false,
17 | "includeDescendants": true,
18 | "includeMapped": false
19 | },
20 | {
21 | "concept": {
22 | "CONCEPT_CLASS_ID": "Clinical Observation",
23 | "CONCEPT_CODE": "32624-9",
24 | "CONCEPT_ID": 3046853,
25 | "CONCEPT_NAME": "Race",
26 | "DOMAIN_ID": "Observation",
27 | "INVALID_REASON": "V",
28 | "INVALID_REASON_CAPTION": "Valid",
29 | "STANDARD_CONCEPT": "S",
30 | "STANDARD_CONCEPT_CAPTION": "Standard",
31 | "VOCABULARY_ID": "LOINC"
32 | },
33 | "isExcluded": false,
34 | "includeDescendants": true,
35 | "includeMapped": false
36 | },
37 | {
38 | "concept": {
39 | "CONCEPT_CLASS_ID": "Clinical Observation",
40 | "CONCEPT_CODE": "76691-5",
41 | "CONCEPT_ID": 46235215,
42 | "CONCEPT_NAME": "Gender identity",
43 | "DOMAIN_ID": "Observation",
44 | "INVALID_REASON": "V",
45 | "INVALID_REASON_CAPTION": "Valid",
46 | "STANDARD_CONCEPT": "S",
47 | "STANDARD_CONCEPT_CAPTION": "Standard",
48 | "VOCABULARY_ID": "LOINC"
49 | },
50 | "isExcluded": false,
51 | "includeDescendants": true,
52 | "includeMapped": false
53 | },
54 | {
55 | "concept": {
56 | "CONCEPT_CLASS_ID": "Event",
57 | "CONCEPT_CODE": "419620001",
58 | "CONCEPT_ID": 4306655,
59 | "CONCEPT_NAME": "Death",
60 | "DOMAIN_ID": "Observation",
61 | "INVALID_REASON": "V",
62 | "INVALID_REASON_CAPTION": "Valid",
63 | "STANDARD_CONCEPT": "S",
64 | "STANDARD_CONCEPT_CAPTION": "Standard",
65 | "VOCABULARY_ID": "SNOMED"
66 | },
67 | "isExcluded": false,
68 | "includeDescendants": true,
69 | "includeMapped": false
70 | },
71 | {
72 | "concept": {
73 | "CONCEPT_CLASS_ID": "Procedure",
74 | "CONCEPT_CODE": "229306004",
75 | "CONCEPT_ID": 4039922,
76 | "CONCEPT_NAME": "Positive pressure therapy",
77 | "DOMAIN_ID": "Observation",
78 | "INVALID_REASON": "V",
79 | "INVALID_REASON_CAPTION": "Valid",
80 | "STANDARD_CONCEPT": "S",
81 | "STANDARD_CONCEPT_CAPTION": "Standard",
82 | "VOCABULARY_ID": "SNOMED"
83 | },
84 | "isExcluded": false,
85 | "includeDescendants": true,
86 | "includeMapped": false
87 | }
88 | ]
89 | }
--------------------------------------------------------------------------------
/Cohort curation scripts/07_E_device_profile.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 07_E_device_profile.sql
4 |
5 | Purpose:
6 | Generate a profile of device prevalence in the final cohort
7 |
8 | Description:
9 | Device counts are calculated per patient and are aggregated by parent concepts for
10 | each device concept present in the final OMOP Device Exposure table
11 |
12 | Dependencies:
13 | */
14 |
15 | --Create table which includes the device concepts included in the cohort and their names
16 | DROP TABLE IF EXISTS #device_concepts_of_interest;
17 | SELECT
18 | CONCEPT_ANCESTOR.descendant_concept_id AS concept_id,
19 | CONCEPT_ANCESTOR.ancestor_concept_id,
20 | [Results].[cure_id_concepts].concept_name
21 | INTO #device_concepts_of_interest
22 | FROM [Results].[cure_id_concepts]
23 | INNER JOIN CONCEPT_ANCESTOR
24 | ON CONCEPT_ANCESTOR.ancestor_concept_id = [Results].[cure_id_concepts].concept_id
25 | WHERE
26 | [Results].[cure_id_concepts].domain = 'Device'
27 | AND ([Results].[cure_id_concepts].include_descendants = 'TRUE' OR CONCEPT_ANCESTOR.ancestor_concept_id = CONCEPT_ANCESTOR.descendant_concept_id)
28 | ORDER BY [Results].[cure_id_concepts].concept_name
29 |
30 | --The #device_count_temp table counts the number of times that each concept is present for each patient in the cohort.
31 | DROP TABLE IF EXISTS #device_count_temp;
32 | SELECT
33 | p.person_id,
34 | dci.concept_id AS concept_id,
35 | dci.concept_name,
36 | COUNT(
37 | CASE
38 | WHEN d.device_concept_id IS NOT NULL THEN 1
39 | END
40 | ) AS concept_count
41 | INTO #device_count_temp
42 | FROM [Results].[deident_CURE_ID_person] AS p
43 | CROSS JOIN #device_concepts_of_interest AS dci
44 | LEFT JOIN [Results].[deident_CURE_ID_device_exposure] AS d
45 | ON
46 | dci.concept_id = d.device_concept_id
47 | AND d.person_id = p.person_id
48 | GROUP BY
49 | p.person_id,
50 | dci.concept_id,
51 | dci.concept_name
52 |
53 | --Device use by person
54 | DROP TABLE IF EXISTS #device_use_by_person
55 | SELECT
56 | dci.concept_name,
57 | dci.concept_id,
58 | COUNT(DISTINCT d.person_id) AS person_count,
59 | (
60 | 100 * COUNT(DISTINCT d.person_id)
61 | / (SELECT COUNT(DISTINCT person_id) FROM [Results].[deident_CURE_ID_person])
62 | ) AS person_perc
63 | INTO #device_use_by_person
64 | FROM #device_concepts_of_interest AS dci
65 | LEFT JOIN [Results].[deident_CURE_ID_device_exposure] AS d
66 | ON d.device_concept_id = dci.concept_id
67 | GROUP BY
68 | dci.concept_id,
69 | dci.concept_name
70 | ORDER BY person_count DESC
71 |
72 |
73 | DROP TABLE IF EXISTS #device_count_by_person
74 | SELECT
75 | concept_name,
76 | concept_id,
77 | AVG(concept_count) AS average_entries_per_person,
78 | MAX(concept_count) AS max_entries_per_person
79 | INTO #device_count_by_person
80 | FROM #device_count_temp
81 | WHERE concept_count > 0
82 | GROUP BY
83 | concept_id,
84 | concept_name
85 |
86 | -- Display summary table for each device:
87 | -- the number of persons who used the device
88 | -- percent of persons who used the device
89 | -- average entries of the device per person who used the device
90 | -- maximum entries of the device per person who used the device
91 |
92 | SELECT
93 | du.concept_name,
94 | du.concept_id,
95 | du.person_count,
96 | du.person_perc,
97 | dc.average_entries_per_person,
98 | dc.max_entries_per_person
99 | FROM #device_use_by_person AS du
100 | LEFT JOIN #device_count_by_person AS dc
101 | ON du.concept_id = dc.concept_id
102 | ORDER BY du.person_count DESC;
103 |
--------------------------------------------------------------------------------
/Cohort curation scripts/SEPSIS/01A_SEPSIS_Cohort_V4.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 01A_SEPSIS_Cohort_V4.sql
4 |
5 | Purpose:
6 | This script creates a cohort of patients for the SEPSIS registry.
7 | The patient list is saved in the cohort table, along with other useful data elements.
8 |
9 | Description:
10 | This SQL script creates a cohort of hospitalized patients with sepsis
11 | based on specific criteria. The script performs several steps to identify and filter
12 | the patients before finally creating the cohort table. The script sets the context to
13 | use a specific database, but the schema name is meant to be provided
14 | by the user.
15 |
16 | Dependencies:
17 | None
18 | */
19 |
20 | USE YOUR_DATABASE;
21 |
22 | -- Drop all tables
23 | DROP TABLE IF EXISTS [Results].[Sepsis_Cohort]; -- Change schema as appropriate
24 | DROP TABLE IF EXISTS #sepsis_diagnosis;
25 | DROP TABLE IF EXISTS #inpat;
26 | DROP TABLE IF EXISTS #Vis_Occ;
27 |
28 |
29 | -- Create cohort table (again specify schema as appropriate)
30 | CREATE TABLE [Results].[Sepsis_Cohort] (
31 | [person_id] [int] NOT NULL,
32 | [visit_occurrence_id] [int] NOT NULL,
33 | [visit_start_date] [date] NOT NULL,
34 | [visit_end_date] [date] NOT NULL,
35 | [birth_date] [date] NULL,
36 | [death_date] [date] NULL
37 | ) ON [PRIMARY];
38 |
39 | -- First identify patients (inpatient and outpatient) with sepsis diagnosis
40 | SELECT DISTINCT
41 | person_id,
42 | condition_start_date AS diagnosis_date
43 | INTO #sepsis_diagnosis
44 | FROM dbo.CONDITION_OCCURRENCE
45 | WHERE condition_concept_id IN (
46 | SELECT c.concept_id
47 | FROM dbo.CONCEPT AS c
48 | INNER JOIN dbo.CONCEPT_ANCESTOR AS ca ON c.concept_id = ca.descendant_concept_id
49 | WHERE ca.ancestor_concept_id IN (132797, 43021283)
50 | AND c.invalid_reason IS NULL
51 | )
52 | AND condition_start_date >= DATEFROMPARTS(2020, 01, 01);
53 |
54 | -- Show counts of unique sepsis diagnoses (not unique patients)
55 | SELECT COUNT(*) AS "sepsis_diagnosis_count" FROM #sepsis_diagnosis;
56 |
57 | -- Show count of unique patients so far
58 | SELECT COUNT(DISTINCT person_id) AS "sepsis_positive_person_count" FROM #sepsis_diagnosis;
59 |
60 | -- Sepsis patients with inpatient encounters
61 | SELECT
62 | v.person_id,
63 | v.visit_occurrence_id,
64 | v.visit_start_date,
65 | v.visit_end_date
66 | INTO #inpat
67 | FROM visit_occurrence AS v
68 | INNER JOIN #sepsis_diagnosis AS sd ON v.person_id = sd.person_id
69 | WHERE v.visit_concept_id IN (9201, 262) -- Inpatient visit/ED and inpatient visit
70 | AND v.visit_start_date >= '2020-01-01'
71 | AND (
72 | DATEDIFF(DAY, sd.diagnosis_date, v.visit_start_date) > -7
73 | AND DATEDIFF(DAY, sd.diagnosis_date, v.visit_start_date) < 21
74 | );
75 |
76 | -- Count of patients and encounters that meet the criteria
77 | SELECT
78 | COUNT(DISTINCT person_id) AS "sepsis_inpatients",
79 | COUNT(DISTINCT visit_occurrence_id) AS "sepsis_inpatient_visits"
80 | FROM #inpat;
81 |
82 | -- Create cohort table with birth and death dates
83 | SELECT
84 | i.person_id,
85 | i.visit_occurrence_id,
86 | i.visit_start_date,
87 | i.visit_end_date,
88 | p.birth_datetime,
89 | d.death_datetime
90 | INTO #Vis_Occ
91 | FROM #inpat AS i
92 | INNER JOIN person AS p ON i.person_id = p.person_id
93 | LEFT JOIN death AS d ON i.person_id = d.person_id;
94 |
95 | -- Inserts the cohort into the final table
96 | INSERT INTO [Results].[Sepsis_Cohort] -- Change schema if not using Results
97 | (
98 | [person_id], [visit_occurrence_id], [visit_start_date], [visit_end_date],
99 | [birth_date], [death_date]
100 | )
101 | SELECT
102 | v.[person_id],
103 | v.[visit_occurrence_id],
104 | v.[visit_start_date],
105 | v.[visit_end_date],
106 | v.[birth_datetime],
107 | v.[death_datetime]
108 | FROM #Vis_Occ AS v;
109 |
110 | -- Final count of patients
111 | SELECT COUNT(DISTINCT person_id) AS "Final_patient_count" FROM #Vis_Occ;
112 |
113 | -- View data
114 | SELECT TOP 100 *
115 | FROM [Results].[Sepsis_Cohort];
116 |
--------------------------------------------------------------------------------
/Cohort curation scripts/07_C_drug_exposure_profile.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 07_C_drug_exposure_profile.sql
4 |
5 | Purpose:
6 | Generate a profile of drug prevalence in the final cohort
7 |
8 | Description:
9 | Drug counts are calculated per patient and are aggregated by ingredient for each
10 | drug concept present in the final OMOP Drug Exposure table
11 |
12 | Dependencies:
13 | */
14 |
15 | -- Create table of all drugs given in the cohort
16 | DROP TABLE IF EXISTS #drug_concepts_of_interest;
17 | SELECT DISTINCT
18 | CONCEPT.concept_id,
19 | CONCEPT.concept_name
20 | INTO #drug_concepts_of_interest
21 | FROM [Results].[deident_CURE_ID_drug_exposure]
22 | LEFT JOIN CONCEPT
23 | ON CONCEPT.concept_id = [Results].[deident_CURE_ID_drug_exposure].drug_concept_id;
24 |
25 | --Roll up drugs into ingredients
26 | DROP TABLE IF EXISTS #ingredients_of_interest;
27 | SELECT
28 | dci.concept_id AS drug_concept_id,
29 | dci.concept_name AS drug_concept_name,
30 | CONCEPT.concept_id AS ingredient_concept_id,
31 | CONCEPT.concept_name AS ingredient_name
32 | INTO #ingredients_of_interest
33 | FROM #drug_concepts_of_interest AS dci
34 | LEFT JOIN
35 | CONCEPT_ANCESTOR
36 | ON
37 | CONCEPT_ANCESTOR.descendant_concept_id = dci.concept_id
38 | LEFT JOIN CONCEPT
39 | ON CONCEPT.concept_id = CONCEPT_ANCESTOR.ancestor_concept_id
40 | WHERE
41 | CONCEPT.concept_class_id = 'Ingredient'
42 |
43 | --Create table of drug exposures by ingredient
44 | DROP TABLE IF EXISTS #drug_exposure_by_ingredient
45 | SELECT
46 | i.ingredient_name,
47 | i.ingredient_concept_id,
48 | d.drug_concept_id,
49 | d.person_id
50 | INTO #drug_exposure_by_ingredient
51 | FROM [Results].[deident_CURE_ID_drug_exposure] AS d
52 | LEFT JOIN #ingredients_of_interest AS i
53 | ON i.drug_concept_id = d.drug_concept_id
54 |
55 | --Ingredient use by person
56 | DROP TABLE IF EXISTS #ingredient_use_by_person;
57 | SELECT
58 | ingredient_name,
59 | ingredient_concept_id,
60 | COUNT(person_id) AS person_count,
61 | (
62 | 100 * COUNT(person_id)
63 | / (SELECT COUNT(DISTINCT person_id) FROM #drug_exposure_by_ingredient)
64 | ) AS person_perc
65 | INTO #ingredient_use_by_person
66 | FROM
67 | (
68 | SELECT DISTINCT
69 | person_id,
70 | ingredient_concept_id,
71 | ingredient_name
72 | FROM
73 | #drug_exposure_by_ingredient
74 | ) AS x1
75 | GROUP BY
76 | ingredient_concept_id,
77 | ingredient_name
78 | ORDER BY
79 | person_count DESC
80 |
81 | DROP TABLE IF EXISTS #ingredient_count_by_person
82 | SELECT
83 | ingredient_name,
84 | ingredient_concept_id,
85 | AVG(ingredient_admin_count_per_person) AS average_admin_per_person,
86 | MAX(ingredient_admin_count_per_person) AS max_admin_per_person
87 | INTO #ingredient_count_by_person
88 | FROM
89 | (
90 | SELECT
91 | ingredient_name,
92 | ingredient_concept_id,
93 | person_id,
94 | COUNT(ingredient_concept_id) AS ingredient_admin_count_per_person
95 | FROM #drug_exposure_by_ingredient
96 | GROUP BY person_id, ingredient_concept_id, ingredient_name
97 | ) AS x1
98 | GROUP BY
99 | ingredient_concept_id,
100 | ingredient_name
101 |
102 | --Display summary table for each drug ingredient:
103 | ----the number of persons who took the drug ingredient
104 | ----percent of persons who took the drug ingredient
105 | ----average administrations of the drug ingredient per person who took the drug
106 | ----maximum administrations of the drug ingredient per person
107 | SELECT
108 | #ingredient_use_by_person.ingredient_name,
109 | #ingredient_use_by_person.ingredient_concept_id,
110 | #ingredient_use_by_person.person_count,
111 | #ingredient_use_by_person.person_perc,
112 | #ingredient_count_by_person.average_admin_per_person,
113 | #ingredient_count_by_person.max_admin_per_person
114 | FROM
115 | #ingredient_use_by_person
116 | LEFT JOIN
117 | #ingredient_count_by_person
118 | ON
119 | #ingredient_use_by_person.ingredient_concept_id = #ingredient_count_by_person.ingredient_concept_id
120 | ORDER BY #ingredient_use_by_person.person_count DESC
121 |
--------------------------------------------------------------------------------
/EdgeToolSuite.md:
--------------------------------------------------------------------------------
1 | # Edge Tool Suite
2 |
3 | The Edge Tool Suite are a set of OHDSI tools that should be deployed by the site that provide value around the OMOP CDM. This work was funded by the Cure ID initiative https://cure.ncats.io
4 |
5 | The OHDSI open source software configured for deployment include:
6 | - The Atlas data science platform
7 | - The WebAPI backed for Atlas
8 | - The HADES statistical analysis packages
9 | - The Data Quality Dashboard
10 | - The Perseus ETL management system
11 |
12 | ## Simplifying the ETL process
13 |
14 | The OHDSI community has created a series of individual software packages to facilitate the
15 | ETL from proprietary EHRs to OMOP, evaluate data quality, define cohorts, and perform
16 | analyses. The “Edge Tool” packages these individual tools to facilitate the performance of an
17 | OMOP ETL and subsequent use of the data for defining cohorts for observational research. In
18 | contrast to registry approaches which ingest data represented in various data models and
19 | perform data harmonization centrally, software components of the “Edge Tool” facilitate ETL
20 | performance locally at the “edge.” This suite of software aims to drastically reduce the labor and
21 | effort required to go from “zero to OMOP.” We anticipate that institutions that use the full suite
22 | of offered software will be able to reduce the person-hours required for an OMOP ETL to as little
23 | as 50 hours.
24 |
25 | ## Software components
26 | The Edge Tool encompasses the Perseus ETL management solution, the HADES R analysis
27 | package within an RStudio Server R integrated development environment, and the ATLAS
28 | cohort discovery tool with WebAPI web services integration (Figure).
29 | The Perseus graphic-user interface (GUI) approach provides source-to-concept mapping for the
30 | ETL, with assisted extraction of data from EHR such as flowsheets (vital signs, nursing
31 | assessments), test measurements, and diagnoses. Rather than performing a series of SQL
32 | queries with wildcards to identify data elements of interest from primary source EHR tables,
33 | users may enter desired data element terms into a browser text field which are then matched
34 | using term similarity to source table entries.
35 |
36 | Users may then evaluate the completeness and quality of the ETL using the Data Quality
37 | Dashboard which performs >3,000 individual data quality checks on the OMOP-formatted data
38 | and is reported through a web-based reporting system.
39 | In tandem with Perseus, OHDSI HADES and OHDSI ATLAS are the two projects within the
40 | Edge Tool that allow for advanced analysis once data has been harmonized with the OMOP
41 | CDM, such as generating cohorts for research, patient level prediction, treatment pathways,
42 | large scale population analytics, automated reporting and, optionally, participation in OHDSI
43 | network studies.
44 |
45 | The OHDSI applications within the Edge Tool have been containerized using OHDSI Broadsea,
46 | allowing for even easier deployment. Current use of the Edge Tool has proven promising and
47 | while limitations still exist - e.g., not currently capable of extracting data from unstructured fields
48 | such as notes or loose text - further process optimization and tool development will reduce this
49 | implementation time and effort further.
50 |
51 | ## Ways to deploy the software
52 |
53 | ### 1. Cloud vendor software configured for use.
54 |
55 | - https://github.com/microsoft/OHDSIonAzure
56 | - - Includes Perseus, Atlas, and Hades
57 | - https://github.com/OHDSI/OHDSIonAWS
58 | - - Includes Atlas and Hades
59 |
60 | ### 2. Broadsea provides a set of docker containers that ease the cost of implementation
61 |
62 | - https://github.com/OHDSI/Broadsea
63 | - - Includes Atlas and Hades
64 |
65 | ### 3. Sites can compile the tools from the source repositories
66 | #### OHDSI Specific
67 | - https://github.com/OHDSI/CommonDataModel
68 | - https://github.com/OHDSI/Broadsea
69 | - https://github.com/OHDSI/Athena
70 | #### Perseus and the ETL Process
71 | - https://github.com/OHDSI/Perseus
72 | - https://github.com/OHDSI/WhiteRabbit
73 | - https://github.com/OHDSI/Usagi
74 | #### ATLAS and Cohort Discovery
75 | - https://github.com/OHDSI/Atlas
76 | - https://github.com/OHDSI/WebAPI
77 | #### Data Analysis
78 | - https://github.com/OHDSI/Achilles
79 | - https://github.com/OHDSI/Hades
80 | - https://github.com/OHDSI/DataQualityDashboard
81 |
--------------------------------------------------------------------------------
/Cohort curation scripts/06_DE_ID_Quality_Checks.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 06_DE_ID_Quality_Checks.sql
4 |
5 | Purpose:
6 | This script checks basic metrics for each table in the deidentified dataset to ensure
7 | the previous scripts were successful. This does
8 |
9 | Description:
10 | This script runs a number of summary level quality checks for each table to audit
11 | basic data counts and date ranges.
12 |
13 | Dependencies:
14 | 01_CURE_ID_Cohort.sql
15 | 02_CURE_ID_All_Tables.sql
16 | 03_CURE_ID_replace_rare_conditions_with_parents.sql
17 | 04_DE_ID_CDM_Table_ddl.sql
18 | 05_DE_ID_script.sql
19 | */
20 |
21 |
22 | /******* VARIABLES *******/
23 | --SOURCE_SCHEMA: [deident]
24 |
25 |
26 | USE YOUR_DATABASE;
27 |
28 | /******* PERSON *******/
29 | SELECT
30 | COUNT(DISTINCT person_id) AS [Num People],
31 | MAX([birth_datetime]) AS [Max Birthday],
32 | MIN([birth_datetime]) AS [Min Birthday] -- should not be older than 99
33 | FROM [Results].[deident_CURE_ID_person];
34 |
35 | /******* DEATH *******/
36 | SELECT COUNT(DISTINCT person_id) AS [Num People]
37 | FROM [Results].[deident_CURE_ID_death];
38 |
39 | /******* OBSERVATION *******/
40 | SELECT
41 | observation_concept_id,
42 | COUNT(DISTINCT person_id) AS [Num People],
43 | COUNT(*) AS [Num Records]
44 | FROM [Results].[deident_CURE_ID_observation]
45 | GROUP BY observation_concept_id;
46 |
47 | SELECT
48 | MAX([observation_date]) AS [Max Observation Date], -- Should fall within target range
49 | MIN([observation_date]) AS [Min Observation Date] -- Should fall within target range
50 | FROM [Results].[deident_CURE_ID_observation];
51 |
52 | /******* PROCEDURE OCCURENCE *******/
53 | SELECT
54 | procedure_concept_id,
55 | COUNT(DISTINCT person_id) AS [Num People],
56 | COUNT(*) AS [Num Records]
57 | FROM [Results].[deident_CURE_ID_procedure_occurrence]
58 | GROUP BY procedure_concept_id;
59 |
60 | SELECT
61 | MAX([procedure_date]) AS [Max Procedure Date], -- Should fall within target range
62 | MIN([procedure_date]) AS [Min Procedure Date] -- Should fall within target range
63 | FROM [Results].[deident_CURE_ID_procedure_occurrence];
64 |
65 | /******* CONDITION OCCURENCE *******/
66 | SELECT
67 | condition_concept_id,
68 | COUNT(DISTINCT person_id) AS [Num People],
69 | COUNT(*) AS [Num Records]
70 | FROM [Results].[deident_CURE_ID_condition_occurrence]
71 | GROUP BY condition_concept_id;
72 |
73 | SELECT
74 | MAX(COALESCE([condition_end_date], [condition_start_date])) AS [Max Condition Date], -- Should fall within target range
75 | MIN([condition_start_date]) AS [Min Condition Date] -- Should fall within target range
76 | FROM [Results].[deident_CURE_ID_condition_occurrence];
77 |
78 | /******* MEASUREMENT *******/
79 | SELECT
80 | measurement_concept_id,
81 | COUNT(DISTINCT person_id) AS [Num People],
82 | COUNT(*) AS [Num Records]
83 | FROM [Results].[deident_CURE_ID_measurement]
84 | GROUP BY measurement_concept_id;
85 |
86 | SELECT
87 | MAX([measurement_date]) AS [Max Measurement Date], -- Should fall within target range
88 | MIN([measurement_date]) AS [Min Measurement Date] -- Should fall within target range
89 | FROM [Results].[deident_CURE_ID_measurement];
90 |
91 | /******* DEVICE EXPOSURE *******/
92 | SELECT
93 | device_concept_id,
94 | COUNT(DISTINCT person_id) AS [Num People],
95 | COUNT(*) AS [Num Records]
96 | FROM [Results].[deident_CURE_ID_device_exposure]
97 | GROUP BY device_concept_id;
98 |
99 | SELECT
100 | MAX(COALESCE([device_exposure_end_date], [device_exposure_start_date])) AS [Max Device Date], -- Should fall within target range
101 | MIN([device_exposure_start_date]) AS [Min DECICE Date] -- Should fall within target range
102 | FROM [Results].[deident_CURE_ID_device_exposure];
103 |
104 | /******* DRUG EXPOSURE *******/
105 | SELECT
106 | drug_concept_id,
107 | COUNT(DISTINCT person_id) AS [Num People],
108 | COUNT(*) AS [Num Records]
109 | FROM [Results].[deident_CURE_ID_drug_exposure]
110 | GROUP BY drug_concept_id;
111 |
112 | SELECT
113 | MAX([drug_exposure_end_date]) AS [Max Condition Date], -- Should fall within target range
114 | MIN([drug_exposure_start_date]) AS [Min Condition Date] -- Should fall within target range
115 | FROM [Results].[deident_CURE_ID_drug_exposure];
116 |
--------------------------------------------------------------------------------
/Cohort curation scripts/SEPSIS/03A_SEPSIS_MAPPED_DRUG_Profile.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 03A_SEPSIS_drug_exposure_profile.sql
4 |
5 | Purpose:
6 | Generate a profile of drug prevalence in the final cohort
7 |
8 | Description:
9 | Drug counts are calculated per patient and are aggregated by ingredient for each
10 | drug concept present in the final OMOP Drug Exposure table
11 |
12 | Dependencies:
13 | */
14 |
15 | -- Create table of all drugs given in the cohort
16 | --Replace "YOUR_CDM" with your schema name for the Sepsis cohort
17 |
18 | DROP TABLE IF EXISTS #drug_concepts_of_interest;
19 | SELECT DISTINCT
20 | CONCEPT.concept_id,
21 | CONCEPT.concept_name
22 | INTO #drug_concepts_of_interest
23 | FROM [Results].[YOUR_CDM]
24 | LEFT JOIN CONCEPT
25 | ON CONCEPT.concept_id = [Results].[YOUR_CDM].drug_concept_id;
26 |
27 | --Roll up drugs into ingredients
28 | DROP TABLE IF EXISTS #ingredients_of_interest;
29 | SELECT
30 | dci.concept_id AS drug_concept_id,
31 | dci.concept_name AS drug_concept_name,
32 | CONCEPT.concept_id AS ingredient_concept_id,
33 | CONCEPT.concept_name AS ingredient_name
34 | INTO #ingredients_of_interest
35 | FROM #drug_concepts_of_interest AS dci
36 | LEFT JOIN
37 | CONCEPT_ANCESTOR
38 | ON
39 | CONCEPT_ANCESTOR.descendant_concept_id = dci.concept_id
40 | LEFT JOIN CONCEPT
41 | ON CONCEPT.concept_id = CONCEPT_ANCESTOR.ancestor_concept_id
42 | WHERE
43 | CONCEPT.concept_class_id = 'Ingredient'
44 |
45 | --Create table of drug exposures by ingredient
46 | DROP TABLE IF EXISTS #drug_exposure_by_ingredient
47 | SELECT
48 | i.ingredient_name,
49 | i.ingredient_concept_id,
50 | d.drug_concept_id,
51 | d.person_id
52 | INTO #drug_exposure_by_ingredient
53 | FROM [Results].[YOUR_CDM] AS d
54 | LEFT JOIN #ingredients_of_interest AS i
55 | ON i.drug_concept_id = d.drug_concept_id
56 |
57 | --Ingredient use by person
58 | DROP TABLE IF EXISTS #ingredient_use_by_person;
59 | SELECT
60 | ingredient_name,
61 | ingredient_concept_id,
62 | COUNT(person_id) AS person_count,
63 | (
64 | 100 * COUNT(person_id)
65 | / (SELECT COUNT(DISTINCT person_id) FROM #drug_exposure_by_ingredient)
66 | ) AS person_perc
67 | INTO #ingredient_use_by_person
68 | FROM
69 | (
70 | SELECT DISTINCT
71 | person_id,
72 | ingredient_concept_id,
73 | ingredient_name
74 | FROM
75 | #drug_exposure_by_ingredient
76 | ) AS x1
77 | GROUP BY
78 | ingredient_concept_id,
79 | ingredient_name
80 | ORDER BY
81 | person_count DESC
82 |
83 | DROP TABLE IF EXISTS #ingredient_count_by_person
84 | SELECT
85 | ingredient_name,
86 | ingredient_concept_id,
87 | AVG(ingredient_admin_count_per_person) AS average_admin_per_person,
88 | MAX(ingredient_admin_count_per_person) AS max_admin_per_person
89 | INTO #ingredient_count_by_person
90 | FROM
91 | (
92 | SELECT
93 | ingredient_name,
94 | ingredient_concept_id,
95 | person_id,
96 | COUNT(ingredient_concept_id) AS ingredient_admin_count_per_person
97 | FROM #drug_exposure_by_ingredient
98 | GROUP BY person_id, ingredient_concept_id, ingredient_name
99 | ) AS x1
100 | GROUP BY
101 | ingredient_concept_id,
102 | ingredient_name
103 |
104 | --Display summary table for each drug ingredient:
105 | ----the number of persons who took the drug ingredient
106 | ----percent of persons who took the drug ingredient
107 | ----average administrations of the drug ingredient per person who took the drug
108 | ----maximum administrations of the drug ingredient per person
109 | SELECT
110 | #ingredient_use_by_person.ingredient_name,
111 | #ingredient_use_by_person.ingredient_concept_id,
112 | #ingredient_use_by_person.person_count,
113 | #ingredient_use_by_person.person_perc,
114 | #ingredient_count_by_person.average_admin_per_person,
115 | #ingredient_count_by_person.max_admin_per_person
116 | FROM
117 | #ingredient_use_by_person
118 | LEFT JOIN
119 | #ingredient_count_by_person
120 | ON
121 | #ingredient_use_by_person.ingredient_concept_id = #ingredient_count_by_person.ingredient_concept_id
122 | ORDER BY #ingredient_use_by_person.person_count DESC
123 |
--------------------------------------------------------------------------------
/CURE ID Concepts/old/cure_id_conditions.json:
--------------------------------------------------------------------------------
1 | {
2 | "items": [
3 | {
4 | "concept": {
5 | "CONCEPT_CLASS_ID": "Clinical Finding",
6 | "CONCEPT_CODE": "195967001",
7 | "CONCEPT_ID": 317009,
8 | "CONCEPT_NAME": "Asthma",
9 | "DOMAIN_ID": "Condition",
10 | "INVALID_REASON": "V",
11 | "INVALID_REASON_CAPTION": "Valid",
12 | "STANDARD_CONCEPT": "S",
13 | "STANDARD_CONCEPT_CAPTION": "Standard",
14 | "VOCABULARY_ID": "SNOMED"
15 | },
16 | "isExcluded": false,
17 | "includeDescendants": true,
18 | "includeMapped": false
19 | },
20 | {
21 | "concept": {
22 | "CONCEPT_CLASS_ID": "Clinical Finding",
23 | "CONCEPT_CODE": "77386006",
24 | "CONCEPT_ID": 4299535,
25 | "CONCEPT_NAME": "Pregnant",
26 | "DOMAIN_ID": "Condition",
27 | "INVALID_REASON": "V",
28 | "INVALID_REASON_CAPTION": "Valid",
29 | "STANDARD_CONCEPT": "S",
30 | "STANDARD_CONCEPT_CAPTION": "Standard",
31 | "VOCABULARY_ID": "SNOMED"
32 | },
33 | "isExcluded": false,
34 | "includeDescendants": true,
35 | "includeMapped": false
36 | },
37 | {
38 | "concept": {
39 | "CONCEPT_CLASS_ID": "Clinical Finding",
40 | "CONCEPT_CODE": "86406008",
41 | "CONCEPT_ID": 439727,
42 | "CONCEPT_NAME": "Human immunodeficiency virus infection",
43 | "DOMAIN_ID": "Condition",
44 | "INVALID_REASON": "V",
45 | "INVALID_REASON_CAPTION": "Valid",
46 | "STANDARD_CONCEPT": "S",
47 | "STANDARD_CONCEPT_CAPTION": "Standard",
48 | "VOCABULARY_ID": "SNOMED"
49 | },
50 | "isExcluded": false,
51 | "includeDescendants": true,
52 | "includeMapped": true
53 | },
54 | {
55 | "concept": {
56 | "CONCEPT_CLASS_ID": "Clinical Finding",
57 | "CONCEPT_CODE": "73211009",
58 | "CONCEPT_ID": 201820,
59 | "CONCEPT_NAME": "Diabetes mellitus",
60 | "DOMAIN_ID": "Condition",
61 | "INVALID_REASON": "V",
62 | "INVALID_REASON_CAPTION": "Valid",
63 | "STANDARD_CONCEPT": "S",
64 | "STANDARD_CONCEPT_CAPTION": "Standard",
65 | "VOCABULARY_ID": "SNOMED"
66 | },
67 | "isExcluded": false,
68 | "includeDescendants": true,
69 | "includeMapped": false
70 | },
71 | {
72 | "concept": {
73 | "CONCEPT_CLASS_ID": "Clinical Finding",
74 | "CONCEPT_CODE": "13645005",
75 | "CONCEPT_ID": 255573,
76 | "CONCEPT_NAME": "Chronic obstructive lung disease",
77 | "DOMAIN_ID": "Condition",
78 | "INVALID_REASON": "V",
79 | "INVALID_REASON_CAPTION": "Valid",
80 | "STANDARD_CONCEPT": "S",
81 | "STANDARD_CONCEPT_CAPTION": "Standard",
82 | "VOCABULARY_ID": "SNOMED"
83 | },
84 | "isExcluded": false,
85 | "includeDescendants": true,
86 | "includeMapped": false
87 | },
88 | {
89 | "concept": {
90 | "CONCEPT_CLASS_ID": "Clinical Finding",
91 | "CONCEPT_CODE": "17097001",
92 | "CONCEPT_ID": 4063381,
93 | "CONCEPT_NAME": "Chronic disease of respiratory system",
94 | "DOMAIN_ID": "Condition",
95 | "INVALID_REASON": "V",
96 | "INVALID_REASON_CAPTION": "Valid",
97 | "STANDARD_CONCEPT": "S",
98 | "STANDARD_CONCEPT_CAPTION": "Standard",
99 | "VOCABULARY_ID": "SNOMED"
100 | },
101 | "isExcluded": false,
102 | "includeDescendants": true,
103 | "includeMapped": false
104 | },
105 | {
106 | "concept": {
107 | "CONCEPT_CLASS_ID": "Clinical Finding",
108 | "CONCEPT_CODE": "38341003",
109 | "CONCEPT_ID": 316866,
110 | "CONCEPT_NAME": "Hypertensive disorder",
111 | "DOMAIN_ID": "Condition",
112 | "INVALID_REASON": "V",
113 | "INVALID_REASON_CAPTION": "Valid",
114 | "STANDARD_CONCEPT": "S",
115 | "STANDARD_CONCEPT_CAPTION": "Standard",
116 | "VOCABULARY_ID": "SNOMED"
117 | },
118 | "isExcluded": false,
119 | "includeDescendants": true,
120 | "includeMapped": false
121 | },
122 | {
123 | "concept": {
124 | "CONCEPT_CLASS_ID": "Clinical Finding",
125 | "CONCEPT_CODE": "128292002",
126 | "CONCEPT_ID": 4028244,
127 | "CONCEPT_NAME": "Chronic disease of cardiovascular system",
128 | "DOMAIN_ID": "Condition",
129 | "INVALID_REASON": "V",
130 | "INVALID_REASON_CAPTION": "Valid",
131 | "STANDARD_CONCEPT": "S",
132 | "STANDARD_CONCEPT_CAPTION": "Standard",
133 | "VOCABULARY_ID": "SNOMED"
134 | },
135 | "isExcluded": false,
136 | "includeDescendants": true,
137 | "includeMapped": false
138 | }
139 | ]
140 | }
--------------------------------------------------------------------------------
/Cohort curation scripts/07_B_measurement_profile.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 07_B_measurement_profile.sql
4 |
5 | Purpose:
6 | Generate a profile of measurement prevalence in the final cohort
7 |
8 | Description:
9 | Measurement counts are calculated per patient and are aggregated by parent concepts
10 | for each measurement concept present in the final OMOP Measurement table.
11 |
12 | Dependencies:
13 |
14 | */
15 |
16 | -- Create table which includes the measurement concepts included in the cohort and their names
17 |
18 | DROP TABLE IF EXISTS #measurement_parent_concepts_of_interest;
19 | SELECT
20 | CONCEPT_ANCESTOR.descendant_concept_id AS concept_id,
21 | CONCEPT_ANCESTOR.ancestor_concept_id,
22 | [Results].[cure_id_concepts].concept_name
23 | INTO #measurement_parent_concepts_of_interest
24 | FROM [Results].[cure_id_concepts]
25 | INNER JOIN CONCEPT_ANCESTOR
26 | ON CONCEPT_ANCESTOR.ancestor_concept_id = [Results].[cure_id_concepts].concept_id
27 | WHERE
28 | [Results].[cure_id_concepts].domain = 'Measurement'
29 | AND (
30 | [Results].[cure_id_concepts].include_descendants = 'TRUE'
31 | OR CONCEPT_ANCESTOR.ancestor_concept_id = CONCEPT_ANCESTOR.descendant_concept_id
32 | )
33 | ORDER BY [Results].[cure_id_concepts].concept_name
34 |
35 | --The measurement_count_temp table counts the number of times that each concept is present for each patient in the cohort.
36 | --It is rolled up into ancestor concepts grouped as above
37 | --If no records for the patient of that concept are present, a record of 0 will be present
38 | DROP TABLE IF EXISTS #measurement_count_temp;
39 | SELECT
40 | p.person_id,
41 | mpci.ancestor_concept_id AS concept_id,
42 | mpci.concept_name,
43 | COUNT(CASE WHEN m.measurement_concept_id IS NOT NULL THEN 1 END) AS concept_count
44 | INTO #measurement_count_temp
45 | FROM
46 | #measurement_parent_concepts_of_interest AS mpci
47 | CROSS JOIN
48 | [Results].[deident_CURE_ID_person] AS p
49 | LEFT JOIN
50 | [Results].[deident_CURE_ID_measurement] AS m
51 | ON
52 | mpci.concept_id = m.measurement_concept_id
53 | AND m.person_id = p.person_id
54 | GROUP BY
55 | p.person_id,
56 | mpci.ancestor_concept_id,
57 | mpci.concept_name
58 |
59 | --This orders patients by how frequently the record occurs and does so for each individual concept
60 | DROP TABLE IF EXISTS #measurment_concept_count_rank;
61 | SELECT
62 | concept_name,
63 | concept_id,
64 | concept_count,
65 | ROW_NUMBER() OVER (PARTITION BY concept_id ORDER BY concept_count) AS rownumber
66 | INTO #measurment_concept_count_rank
67 | FROM #measurement_count_temp;
68 |
69 | -- This summary table aims to show how many measurement records are present per patient.
70 | -- Because the clinical course for patients varies considerably, some patients have very few records; others have many.
71 | -- The summary table has a row for each ancestor concept included in the measurement table
72 | -- For each measurement, each patient in the cohort is ranked according to how many records of the measurement are present during the defined visit
73 | -- The columns show how many measurement records are present per patient per measurement concept for the 25th percentile, median, 75th percentile, and 95th percentile of patients
74 | WITH p25 AS (
75 | SELECT
76 | concept_id,
77 | concept_count AS percentile_25
78 | FROM #measurment_concept_count_rank
79 | WHERE rownumber = FLOOR(0.25 * (
80 | SELECT COUNT(person_id)
81 | FROM [Results].[deident_CURE_ID_person]
82 | ))
83 | ),
84 |
85 | p50 AS (
86 | SELECT
87 | concept_id,
88 | concept_count AS median
89 | FROM #measurment_concept_count_rank
90 | WHERE rownumber = FLOOR(0.50 * (
91 | SELECT COUNT(person_id)
92 | FROM [Results].[deident_CURE_ID_person]
93 | ))
94 | ),
95 |
96 | p75 AS (
97 | SELECT
98 | concept_id,
99 | concept_count AS percentile_75
100 | FROM #measurment_concept_count_rank
101 | WHERE rownumber = FLOOR(0.75 * (
102 | SELECT COUNT(person_id)
103 | FROM [Results].[deident_CURE_ID_person]
104 | ))
105 | ),
106 |
107 | p95 AS (
108 | SELECT
109 | concept_id,
110 | concept_count AS percentile_95
111 | FROM #measurment_concept_count_rank
112 | WHERE rownumber = FLOOR(0.95 * (
113 | SELECT COUNT(person_id)
114 | FROM [Results].[deident_CURE_ID_person]
115 | ))
116 | )
117 |
118 | SELECT
119 | x1.concept_name,
120 | x1.concept_id,
121 | p25.percentile_25,
122 | p50.median,
123 | p75.percentile_75,
124 | p95.percentile_95,
125 | CASE
126 | WHEN p50.median = 0
127 | THEN
128 | 'For half of patients, there were no records of this measurement. 5% of patients had '
129 | + CAST(p95.percentile_95 AS VARCHAR(10))
130 | + ' or more records.'
131 | ELSE
132 | 'For half of patients, there were at least '
133 | + CAST(p50.median AS VARCHAR(10))
134 | + ' records. Most patients (25th-75th percentile) had '
135 | + CAST(p25.percentile_25 AS VARCHAR(10)) + '-'
136 | + CAST(p75.percentile_75 AS VARCHAR(10))
137 | + ' records. 5% of patients had '
138 | + CAST(p95.percentile_95 AS VARCHAR(10))
139 | + ' or more records.'
140 | END AS interpretation
141 | FROM (
142 | SELECT DISTINCT
143 | ancestor_concept_id AS concept_id,
144 | concept_name
145 | FROM #measurement_parent_concepts_of_interest
146 | ) AS x1
147 | FULL JOIN p25
148 | ON x1.concept_id = p25.concept_id
149 | FULL JOIN p50
150 | ON x1.concept_id = p50.concept_id
151 | FULL JOIN p75
152 | ON x1.concept_id = p75.concept_id
153 | FULL JOIN p95
154 | ON x1.concept_id = p95.concept_id
155 | ORDER BY p50.median DESC, p75.percentile_75 DESC, p95.percentile_95 DESC;
156 |
--------------------------------------------------------------------------------
/Cohort curation scripts/old/measurement_count_profile.sql:
--------------------------------------------------------------------------------
1 | --Create table which includes the measurement concepts included in the cohort and their names
2 | DROP TABLE IF EXISTS #measurement_concepts_of_interest;
3 | select
4 | concept_id,
5 | concept_name
6 | into #measurement_concepts_of_interest
7 | from
8 | concept
9 | where
10 | concept_id in (703443, 3000285, 3000483, 3000905, 3000963, 3001122, 3001604, 3001657, 3002385, 3002888, 3002937,
11 | 3003215, 3003282, 3004077, 3004144, 3004249, 3004295, 3004327, 3004501, 3005225, 3005456, 3005629,
12 | 3005755, 3005949, 3006315, 3006898, 3006923, 3007220, 3007328, 3007461, 3007760, 3007858, 3008037,
13 | 3008766, 3008791, 3009347, 3009542, 3009932, 3010335, 3010424, 3010813, 3010834, 3011424, 3012481,
14 | 3012888, 3013115, 3013429, 3013650, 3013682, 3013721, 3013752, 3014053, 3014111, 3015182, 3015242,
15 | 3016407, 3016436, 3016502, 3016723, 3017501, 3017732, 3018198, 3018405, 3018677, 3018928, 3019198,
16 | 3019550, 3019897, 3019909, 3020460, 3020891, 3021337, 3022217, 3022250, 3022893, 3023091, 3023103,
17 | 3023314, 3023361, 3023919, 3024128, 3024171, 3024830, 3024929, 3025315, 3026238, 3026617, 3027018,
18 | 3027219, 3027388, 3027651, 3027801, 3028271, 3028615, 3028833, 3029829, 3031219, 3031266, 3031579,
19 | 3032393, 3032971, 3033408, 3033575, 3034022, 3034107, 3034426, 3034962, 3036277, 3038425, 3038547,
20 | 3038553, 3038668, 3038702, 3039283, 3040598, 3040623, 3040681, 3040743, 3040750, 3040893, 3041232,
21 | 3041354, 3041473, 3041944, 3041974, 3042294, 3042436, 3042449, 3042634, 3043409, 3043706, 3045262,
22 | 3045524, 3045961, 3046279, 3046900, 3047181, 3049187, 3049516, 3050746, 3051714, 3051825, 3052648,
23 | 3052964, 3052968, 3053283, 4141684, 4353936, 36033639, 36303797, 36304114, 36306105, 36306178,
24 | 37032427, 37041261, 37041593, 37042222, 37043992, 37051715, 37063873, 37070108, 37070654, 40652525,
25 | 40652709, 40652870, 40653085, 40653238, 40653596, 40653762, 40653900, 40653994, 40654045, 40654069,
26 | 40654088, 40762499, 40762888, 40762889, 40764999, 40771922, 42869588, 44782836, 44816672, 46235078,
27 | 46235106, 46235784, 46236949)
28 |
29 | --Create an empty table that for each person in the cohort has every measurement requested.
30 | --The purpose for this is to create counts of 0 later for concepts that are not present for sopme patients
31 | DROP TABLE IF EXISTS #concept_person;
32 | select
33 | person_id,
34 | concept_id,
35 | concept_name
36 | into #concept_person
37 | from
38 | #measurement_concepts_of_interest
39 | cross join
40 | results.CURE_ID_Cohort
41 |
42 | --The measurement_count_temp table counts the number of times that each concept is present for each patient in the cohort.
43 | --Because this count is left joined onto the #concept_person table, if no records for the patient of that concept are present, a record of 0 will be present
44 | DROP TABLE IF EXISTS #measurement_count_temp;
45 | select
46 | #concept_person.person_id,
47 | concept_name,
48 | concept_id,
49 | count(measurement_concept_id) as concept_count
50 | into #measurement_count_temp
51 | from
52 | #concept_person
53 | left join
54 | Results.CURE_ID_Measurement m on measurement_concept_id = concept_id and
55 | m.person_id = #concept_person.person_id
56 | group by #concept_person.person_id, measurement_concept_id, concept_id, concept_name
57 |
58 | --This orders patients by how frequently the record occurs and does so for each individual concept
59 | DROP TABLE IF EXISTS #measurment_concept_count_rank;
60 | select
61 | concept_name,
62 | concept_id,
63 | concept_count,
64 | row_number() over (partition by concept_id order by concept_count) as rownumber
65 | into
66 | #measurment_concept_count_rank
67 | from
68 | #measurement_count_temp
69 |
70 | --This summary table aims to show how many measurement records are present per patient.
71 | --Because the clinical course for patients varies considerably, some patients have very few records; others have many.
72 | --The summary table has a row for each concept included in the measurement table
73 | --For each measurement, each patient in the cohort is ranked according to how many records of the measurement are present during the defined visit
74 | --The columns show how many measurement records are present per patient per measurement concept for the 25th percentile, median, 75th percentile, and 95th percentile of patients
75 | select
76 | concept_name,
77 | #measurement_concepts_of_interest.concept_id,
78 | percentile_25,
79 | median,
80 | percentile_75,
81 | percentile_95
82 | from
83 | #measurement_concepts_of_interest
84 | full join
85 | (select concept_id, concept_count as percentile_25
86 | FROM #measurment_concept_count_rank
87 | where rownumber = floor(0.25 * (select count(person_id) from results.CURE_ID_Cohort))
88 | ) as p25
89 | on p25.concept_id = #measurement_concepts_of_interest.concept_id
90 | full join
91 | (select concept_id, concept_count as median
92 | FROM #measurment_concept_count_rank
93 | where rownumber = floor(0.50 * (select count(person_id) from results.CURE_ID_Cohort))
94 | ) as p50
95 | on p50.concept_id = #measurement_concepts_of_interest.concept_id
96 | full join
97 | (select concept_id, concept_count as percentile_75
98 | FROM #measurment_concept_count_rank
99 | where rownumber = floor(0.75 * (select count(person_id) from results.CURE_ID_Cohort))
100 | ) as p75
101 | on p75.concept_id = #measurement_concepts_of_interest.concept_id
102 | full join
103 | (select concept_id, concept_count as percentile_95
104 | FROM #measurment_concept_count_rank
105 | where rownumber = floor(0.95 * (select count(person_id) from results.CURE_ID_Cohort))
106 | ) as p95
107 | on p95.concept_id = #measurement_concepts_of_interest.concept_id
108 | order by median desc,
109 | percentile_75 desc,
110 | percentile_95 desc
111 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # CureIdRegistry
2 |
3 | The Cure-ID Registry is a clinical registry leveraging OMOP and EHR automation. Cure-ID is a collaboration between the FDA and the National Center for Advancing Translational Sciences (NCATS), part of the National Institutes of Health (NIH).
4 |
5 | This Github repository is the migrated documentation from the FDA Cure ID project. This move was motivated by the inconsistencies of the current storage method in Microsoft Teams. This repository takes the Concept list from the Cure-ID Registry group, within the Health Special Interests Teams group, and combines it with the Cohort Creation scripts from the Cure-ID Registry group, also within the same Teams environment. Essentially, it is meant to be the central authority of the definition of the registry, e.g. what concepts to include, how to generate the cohort, who is included, etc.
6 |
7 | The Cohort is comprised of the anonymized person_id, birthdate, and first date of a positive COVID test from the OMOP CDM.
8 |
9 | --------------------------------------------------------------------------------------------------
10 |
11 | ## Explanation of the Curation Script Files:
12 |
13 | **01 - Create Cohort**
14 | - Identifies all patients with a positive lab result measurement, patient_id and first positive lab result
15 | - Identifies all patients with a "strong" or "weak" COVID diagnosis based on condition codes
16 | - Combines the "strong" and "weak" results into a "comb" table
17 | - Creates an intermediary table "inpat_intermed" for all patients with a positive lab result, who were flagged as inpatient treatment
18 | - Joins the positive lab result, "inpat_intermed" and "comb" tables to get the criteria of the Cohort (sans edge cases)
19 |
20 | In summary, the Cohort contains patients who were hospitalized with COVID, and experienced symptoms that suggest COVID played a significant role in their hospitalization. These patients tested positive for COVID, started in-patient care 7 days before through 21 days after a positive test, and experienced COVID-symptoms around 2 weeks before or after their in-patient period. If the patient was hospitalized more than once, we prioritize the earliest occurrence.
21 |
22 | **02 - Load All Tables**
23 | - From the Cohort created in 01, create tables for Person, Measurement, Drug Exposure, Death, Observation, Procedure, Condition, Visit Occurrence and Device Exposure
24 | - This is limited to a hardcoded list of measurements that is relevant to the topic of COVID inpatient stay. Any measurements not on the list are not exposed.
25 |
26 | **03 - Replace Rare Conditions**
27 | - Uses the Conditions table from 02.
28 | - Find and replace conditions occurring 10 or less times with parent concepts that have at least 10 counts
29 |
30 | **04 - Create Deidentification CDM Tables**
31 | - Defines the DDL for generating the empty OMOP CDM tables to hold your deidentified data.
32 | - The tables are blank and will be loaded with data in 04.
33 |
34 | **05 - Perform Deidentification**
35 | - Table by table, loads the data from 02 script, parses and deidentifies it.
36 | - The results are inserted into the OMOP CDM tables from 03.
37 |
38 | **06 - Perform Quality Checks**
39 | - Read the count, min, and max for various columns and tables.
40 | - Comments say what results are expected, if the script succeeded (more documentation is needed here)
41 |
42 | **07 - Utilize Profile Scripts**
43 | - Five different scripts to create different profiles from the Cohort created in previous steps.
44 | - Condition, Measurement, Drug Exposure, Unmapped Drugs, Device
45 |
46 | --------------------------------------------------------------------------------------------------
47 |
48 | ## Explanation of the Concept Files
49 |
50 | **Parent Only**: A csv that contains only the parent (highest in the hierarchy) concepts used within the registry. When adding concepts, check 1) is the concept a parent concept and 2) if not, is the parent concept already included within the file
51 |
52 | **Parent Only with Descendants**: A list of all parent concepts, where we track and include all descendants. This is primarily used for ATLAS concept set creation.
53 |
54 | **Parent Only no Descendants**: A list of all parent concepts, where we do not track descendants. This is primarily used for ATLAS concept set creation.
55 |
56 | **Concept All**: All concepts, parents or descendents. When adding concepts, check if you wish to include or exclude specific descendent concepts.
57 |
58 | **Conditions, Device Exposure, Measurements, Observations, Person, Procedures** :JSON representations of each of the parent concepts, separated by OMOP domain. You can use this JSON format to directly import/export as concept sets within ATLAS. When changing concepts, it may be easier to create the respective concept set already within ATLAS, make the edits there, export as JSON and overwrite this file.
59 |
60 | --------------------------------------------------------------------------------------------------
61 |
62 | ## Workflow of Adding a Concept
63 | ##### (Having ATLAS set up extremely recommended)
64 |
65 |
66 |
67 | #### Section 1: I Do Not See/Have Access to the CURE ID Concept Set in ATLAS (if you do, skip to Section 2)
68 |
69 | If you do not see the pre-existing concept set, you will need to create a version yourself first.
70 | 1. In ATLAS, click the "Concept Sets" tab on the sidebar.
71 | 2. In the upper right corner, click "New Concept Set".
72 | 3. Click the "Import Tab"
73 | 4. Copy and paste the contents of the "OMOP_concepts_parent_with_descendants.txt" folder, and click the "Descendants" button. Add these to the concept set.
74 | 5. Copy and paste the contents of the "OMOP_concepts_parent_without_descendants.txt" folder, making sure NOT to tick the "Descendants" button. Add these to the concept set.
75 |
76 | #### Section 2: I Have Access to the CURE ID Concept Set in ATLAS
77 |
78 | Say we want to add a concept X into the set.
79 |
80 | 1. Consider if X is a parent concept, or if it is a child concept of a pre-existing one.
81 | 2. Append it to the corresponding file: "OMOP_concepts_parent" with or without.
82 | 3. Go to the Cure ID Concept Set.
83 | 4. Click Import, and paste X. Click the "Descendants" button, if you are including descendants.
84 | 5. Click the "Included Concepts" tab. Depending on what X's domain is (Drug, Condition, etc) filter to see just those concepts.
85 | 6. Click the "CSV" button. This will download these concepts to a CSV file.
86 | 7. Override the corresponding "cure_id_{domain}.csv" file in the repo.
87 | 8. Save the concept set in ATLAS, push changes to repo.
88 |
--------------------------------------------------------------------------------
/Cohort curation scripts/SEPSIS/04_SEPSIS_COHORT_SUMMARY.v2sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 04_SEPSIS_COHORT_SUMMARYv2.sql
4 |
5 | Purpose:
6 | Generate a summary report for YOUR SEPSIS COHORT, including demographics, age distribution, race, ethnicity, death information,
7 | and the median and IQR of the length of stay (LOS) for the first visit per person_id.
8 |
9 | Description:
10 | This script calculates summary statistics for key demographic variables (age at first visit date, race, ethnicity),
11 | details about death occurrences, including the list of cause_source_value and concept_name from the death table,
12 | and the median and IQR for the length of stay (LOS). Per OMOP CDM documentation: "The Visit duration, or ‘length of stay’, is defined as VISIT_END_DATE - VISIT_START_DATE."
13 |
14 | Dependencies:
15 | Requires person, visit_occurrence, concept, and death tables in the specified schema.
16 | */
17 |
18 | WITH first_visit AS (
19 | SELECT
20 | person_id,
21 | MIN(visit_start_date) AS first_visit_date
22 | FROM
23 | YOUR_SEPSIS_COHORT vo
24 | GROUP BY
25 | person_id
26 | ),
27 | age_calculations AS (
28 | SELECT
29 | p.person_id,
30 | EXTRACT(YEAR FROM fv.first_visit_date) - p.year_of_birth AS age_at_first_visit
31 | FROM
32 | YOUR_SEPSIS_COHORT.person p
33 | JOIN
34 | first_visit fv
35 | ON p.person_id = fv.person_id
36 | ),
37 | demographics AS (
38 | SELECT
39 | p.person_id,
40 | p.gender_concept_id,
41 | p.race_concept_id,
42 | p.ethnicity_concept_id,
43 | p.year_of_birth,
44 | ac.age_at_first_visit
45 | FROM
46 | YOUR_SEPSIS_COHORT.person p
47 | JOIN
48 | age_calculations ac
49 | ON p.person_id = ac.person_id
50 | ),
51 | death_info AS (
52 | SELECT
53 | d.person_id,
54 | d.death_date,
55 | d.cause_source_value,
56 | c.concept_name AS cause_of_death
57 | FROM
58 | YOUR_SEPSIS_COHORT.death d
59 | LEFT JOIN
60 | YOUR_VOCAB.concept c
61 | ON d.cause_concept_id = c.concept_id
62 | ),
63 | los_calculations AS (
64 | SELECT
65 | fv.person_id,
66 | (vo.visit_end_date - vo.visit_start_date) AS length_of_stay
67 | FROM
68 | first_visit fv
69 | JOIN
70 | YOUR_SEPSIS_COHORT vo
71 | ON fv.person_id = vo.person_id
72 | AND fv.first_visit_date = vo.visit_start_date
73 | ),
74 | age_summary AS (
75 | SELECT
76 | AVG(age_at_first_visit) AS mean_age,
77 | PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY age_at_first_visit) AS median_age,
78 | MIN(age_at_first_visit) AS min_age,
79 | MAX(age_at_first_visit) AS max_age,
80 | STDDEV(age_at_first_visit) AS age_sd
81 | FROM
82 | age_calculations
83 | ),
84 | race_summary AS (
85 | SELECT
86 | c.concept_name AS race,
87 | COUNT(*) AS count,
88 | 100.0 * COUNT(*) / SUM(COUNT(*)) OVER () AS percent
89 | FROM
90 | demographics d
91 | JOIN
92 | YOUR_VOCAB.concept c
93 | ON d.race_concept_id = c.concept_id
94 | GROUP BY
95 | c.concept_name
96 | ),
97 | ethnicity_summary AS (
98 | SELECT
99 | c.concept_name AS ethnicity,
100 | COUNT(*) AS count,
101 | 100.0 * COUNT(*) / SUM(COUNT(*)) OVER () AS percent
102 | FROM
103 | demographics d
104 | JOIN
105 | YOUR_VOCAB.concept c
106 | ON d.ethnicity_concept_id = c.concept_id
107 | GROUP BY
108 | c.concept_name
109 | ),
110 | death_summary AS (
111 | SELECT
112 | COUNT(*) AS total_deaths,
113 | COUNT(DISTINCT cause_of_death) AS causes_of_death,
114 | COUNT(DISTINCT cause_source_value) AS causes_source_value
115 | FROM
116 | death_info
117 | ),
118 | los_summary AS (
119 | SELECT
120 | PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY length_of_stay) AS median_los,
121 | PERCENTILE_CONT(0.25) WITHIN GROUP (ORDER BY length_of_stay) AS iqr_los_25,
122 | PERCENTILE_CONT(0.75) WITHIN GROUP (ORDER BY length_of_stay) AS iqr_los_75
123 | FROM
124 | los_calculations
125 | )
126 | SELECT
127 | 'Age Summary' AS section,
128 | NULL::text AS category,
129 | age_summary.mean_age::text AS mean,
130 | age_summary.median_age::text AS median,
131 | age_summary.min_age::text AS min,
132 | age_summary.max_age::text AS max,
133 | age_summary.age_sd::text AS standard_deviation,
134 | NULL::text AS count,
135 | NULL::text AS percent
136 | FROM
137 | age_summary
138 | UNION ALL
139 | SELECT
140 | 'Race Summary' AS section,
141 | race AS category,
142 | NULL::text AS mean,
143 | NULL::text AS median,
144 | NULL::text AS min,
145 | NULL::text AS max,
146 | NULL::text AS standard_deviation,
147 | count::text AS count,
148 | percent::text AS percent
149 | FROM
150 | race_summary
151 | UNION ALL
152 | SELECT
153 | 'Ethnicity Summary' AS section,
154 | ethnicity AS category,
155 | NULL::text AS mean,
156 | NULL::text AS median,
157 | NULL::text AS min,
158 | NULL::text AS max,
159 | NULL::text AS standard_deviation,
160 | count::text AS count,
161 | percent::text AS percent
162 | FROM
163 | ethnicity_summary
164 | UNION ALL
165 | SELECT
166 | 'Death Summary' AS section,
167 | 'Total Deaths' AS category,
168 | NULL::text AS mean,
169 | NULL::text AS median,
170 | NULL::text AS min,
171 | NULL::text AS max,
172 | NULL::text AS standard_deviation,
173 | total_deaths::text AS count,
174 | NULL::text AS percent
175 | FROM
176 | death_summary
177 | UNION ALL
178 | SELECT
179 | 'Death Summary' AS section,
180 | 'Causes of Death' AS category,
181 | NULL::text AS mean,
182 | NULL::text AS median,
183 | NULL::text AS min,
184 | NULL::text AS max,
185 | NULL::text AS standard_deviation,
186 | causes_of_death::text AS count,
187 | NULL::text AS percent
188 | FROM
189 | death_summary
190 | UNION ALL
191 | SELECT
192 | 'Death Summary' AS section,
193 | 'Cause Source Values' AS category,
194 | NULL::text AS mean,
195 | NULL::text AS median,
196 | NULL::text AS min,
197 | NULL::text AS max,
198 | NULL::text AS standard_deviation,
199 | causes_source_value::text AS count,
200 | NULL::text AS percent
201 | FROM
202 | death_summary
203 | UNION ALL
204 | SELECT
205 | 'Length of Stay Summary' AS section,
206 | 'Median Length of Stay (days)' AS category,
207 | NULL::text AS mean,
208 | los_summary.median_los::text AS median,
209 | los_summary.iqr_los_25::text AS min,
210 | los_summary.iqr_los_75::text AS max,
211 | NULL::text AS standard_deviation,
212 | NULL::text AS count,
213 | NULL::text AS percent
214 | FROM
215 | los_summary;
216 |
--------------------------------------------------------------------------------
/CURE ID Concepts/old/cure_id_person.json:
--------------------------------------------------------------------------------
1 | {
2 | "items": [
3 | {
4 | "concept": {
5 | "CONCEPT_CLASS_ID": "Ethnicity",
6 | "CONCEPT_CODE": "Hispanic",
7 | "CONCEPT_ID": 38003563,
8 | "CONCEPT_NAME": "Hispanic or Latino",
9 | "DOMAIN_ID": "Ethnicity",
10 | "INVALID_REASON": "V",
11 | "INVALID_REASON_CAPTION": "Valid",
12 | "STANDARD_CONCEPT": "S",
13 | "STANDARD_CONCEPT_CAPTION": "Standard",
14 | "VOCABULARY_ID": "Ethnicity"
15 | },
16 | "isExcluded": false,
17 | "includeDescendants": false,
18 | "includeMapped": false
19 | },
20 | {
21 | "concept": {
22 | "CONCEPT_CLASS_ID": "Ethnicity",
23 | "CONCEPT_CODE": "Not Hispanic",
24 | "CONCEPT_ID": 38003564,
25 | "CONCEPT_NAME": "Not Hispanic or Latino",
26 | "DOMAIN_ID": "Ethnicity",
27 | "INVALID_REASON": "V",
28 | "INVALID_REASON_CAPTION": "Valid",
29 | "STANDARD_CONCEPT": "S",
30 | "STANDARD_CONCEPT_CAPTION": "Standard",
31 | "VOCABULARY_ID": "Ethnicity"
32 | },
33 | "isExcluded": false,
34 | "includeDescendants": false,
35 | "includeMapped": false
36 | },
37 | {
38 | "concept": {
39 | "CONCEPT_CLASS_ID": "Gender",
40 | "CONCEPT_CODE": "A",
41 | "CONCEPT_ID": 8570,
42 | "CONCEPT_NAME": "AMBIGUOUS",
43 | "DOMAIN_ID": "Gender",
44 | "INVALID_REASON": "D",
45 | "INVALID_REASON_CAPTION": "Invalid",
46 | "STANDARD_CONCEPT": "N",
47 | "STANDARD_CONCEPT_CAPTION": "Non-Standard",
48 | "VOCABULARY_ID": "Gender"
49 | },
50 | "isExcluded": false,
51 | "includeDescendants": false,
52 | "includeMapped": false
53 | },
54 | {
55 | "concept": {
56 | "CONCEPT_CLASS_ID": "Gender",
57 | "CONCEPT_CODE": "F",
58 | "CONCEPT_ID": 8532,
59 | "CONCEPT_NAME": "FEMALE",
60 | "DOMAIN_ID": "Gender",
61 | "INVALID_REASON": "V",
62 | "INVALID_REASON_CAPTION": "Valid",
63 | "STANDARD_CONCEPT": "S",
64 | "STANDARD_CONCEPT_CAPTION": "Standard",
65 | "VOCABULARY_ID": "Gender"
66 | },
67 | "isExcluded": false,
68 | "includeDescendants": false,
69 | "includeMapped": false
70 | },
71 | {
72 | "concept": {
73 | "CONCEPT_CLASS_ID": "Gender",
74 | "CONCEPT_CODE": "M",
75 | "CONCEPT_ID": 8507,
76 | "CONCEPT_NAME": "MALE",
77 | "DOMAIN_ID": "Gender",
78 | "INVALID_REASON": "V",
79 | "INVALID_REASON_CAPTION": "Valid",
80 | "STANDARD_CONCEPT": "S",
81 | "STANDARD_CONCEPT_CAPTION": "Standard",
82 | "VOCABULARY_ID": "Gender"
83 | },
84 | "isExcluded": false,
85 | "includeDescendants": false,
86 | "includeMapped": false
87 | },
88 | {
89 | "concept": {
90 | "CONCEPT_CLASS_ID": "Gender",
91 | "CONCEPT_CODE": "O",
92 | "CONCEPT_ID": 8521,
93 | "CONCEPT_NAME": "OTHER",
94 | "DOMAIN_ID": "Gender",
95 | "INVALID_REASON": "D",
96 | "INVALID_REASON_CAPTION": "Invalid",
97 | "STANDARD_CONCEPT": "N",
98 | "STANDARD_CONCEPT_CAPTION": "Non-Standard",
99 | "VOCABULARY_ID": "Gender"
100 | },
101 | "isExcluded": false,
102 | "includeDescendants": false,
103 | "includeMapped": false
104 | },
105 | {
106 | "concept": {
107 | "CONCEPT_CLASS_ID": "Gender",
108 | "CONCEPT_CODE": "U",
109 | "CONCEPT_ID": 8551,
110 | "CONCEPT_NAME": "UNKNOWN",
111 | "DOMAIN_ID": "Gender",
112 | "INVALID_REASON": "D",
113 | "INVALID_REASON_CAPTION": "Invalid",
114 | "STANDARD_CONCEPT": "N",
115 | "STANDARD_CONCEPT_CAPTION": "Non-Standard",
116 | "VOCABULARY_ID": "Gender"
117 | },
118 | "isExcluded": false,
119 | "includeDescendants": false,
120 | "includeMapped": false
121 | },
122 | {
123 | "concept": {
124 | "CONCEPT_CLASS_ID": "Race",
125 | "CONCEPT_CODE": "1",
126 | "CONCEPT_ID": 8657,
127 | "CONCEPT_NAME": "American Indian or Alaska Native",
128 | "DOMAIN_ID": "Race",
129 | "INVALID_REASON": "V",
130 | "INVALID_REASON_CAPTION": "Valid",
131 | "STANDARD_CONCEPT": "S",
132 | "STANDARD_CONCEPT_CAPTION": "Standard",
133 | "VOCABULARY_ID": "Race"
134 | },
135 | "isExcluded": false,
136 | "includeDescendants": false,
137 | "includeMapped": false
138 | },
139 | {
140 | "concept": {
141 | "CONCEPT_CLASS_ID": "Race",
142 | "CONCEPT_CODE": "2",
143 | "CONCEPT_ID": 8515,
144 | "CONCEPT_NAME": "Asian",
145 | "DOMAIN_ID": "Race",
146 | "INVALID_REASON": "V",
147 | "INVALID_REASON_CAPTION": "Valid",
148 | "STANDARD_CONCEPT": "S",
149 | "STANDARD_CONCEPT_CAPTION": "Standard",
150 | "VOCABULARY_ID": "Race"
151 | },
152 | "isExcluded": false,
153 | "includeDescendants": false,
154 | "includeMapped": false
155 | },
156 | {
157 | "concept": {
158 | "CONCEPT_CLASS_ID": "Race",
159 | "CONCEPT_CODE": "3",
160 | "CONCEPT_ID": 8516,
161 | "CONCEPT_NAME": "Black or African American",
162 | "DOMAIN_ID": "Race",
163 | "INVALID_REASON": "V",
164 | "INVALID_REASON_CAPTION": "Valid",
165 | "STANDARD_CONCEPT": "S",
166 | "STANDARD_CONCEPT_CAPTION": "Standard",
167 | "VOCABULARY_ID": "Race"
168 | },
169 | "isExcluded": false,
170 | "includeDescendants": false,
171 | "includeMapped": false
172 | },
173 | {
174 | "concept": {
175 | "CONCEPT_CLASS_ID": "Race",
176 | "CONCEPT_CODE": "4",
177 | "CONCEPT_ID": 8557,
178 | "CONCEPT_NAME": "Native Hawaiian or Other Pacific Islander",
179 | "DOMAIN_ID": "Race",
180 | "INVALID_REASON": "V",
181 | "INVALID_REASON_CAPTION": "Valid",
182 | "STANDARD_CONCEPT": "S",
183 | "STANDARD_CONCEPT_CAPTION": "Standard",
184 | "VOCABULARY_ID": "Race"
185 | },
186 | "isExcluded": false,
187 | "includeDescendants": false,
188 | "includeMapped": false
189 | },
190 | {
191 | "concept": {
192 | "CONCEPT_CLASS_ID": "Race",
193 | "CONCEPT_CODE": "5",
194 | "CONCEPT_ID": 8527,
195 | "CONCEPT_NAME": "White",
196 | "DOMAIN_ID": "Race",
197 | "INVALID_REASON": "V",
198 | "INVALID_REASON_CAPTION": "Valid",
199 | "STANDARD_CONCEPT": "S",
200 | "STANDARD_CONCEPT_CAPTION": "Standard",
201 | "VOCABULARY_ID": "Race"
202 | },
203 | "isExcluded": false,
204 | "includeDescendants": false,
205 | "includeMapped": false
206 | }
207 | ]
208 | }
--------------------------------------------------------------------------------
/Cohort curation scripts/SEPSIS/04_SEPSIS_COHORT_SUMMARY.v2_standard_SQLsql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 04_SEPSIS_COHORT_SUMMARYv2_standard_sql.sql
4 |
5 | Purpose:
6 | Generate a summary report for YOUR SEPSIS COHORT, including demographics, age distribution, race, ethnicity, death information,
7 | and the median and IQR of the length of stay (LOS) for the first visit per person_id.
8 |
9 | Description:
10 | This script calculates summary statistics for key demographic variables (age at first visit date, race, ethnicity),
11 | details about death occurrences, including the list of cause_source_value and concept_name from the death table,
12 | and the median and IQR for the length of stay (LOS). Per OMOP CDM documentation: "The Visit duration, or ‘length of stay’, is defined as VISIT_END_DATE - VISIT_START_DATE."
13 |
14 | This version of the script is written in a more standard SQL dialect for broader compatibility across different SQL database systems and avoids PostgreSQL-specific syntax and features.
15 |
16 | Dependencies:
17 | Requires person, visit_occurrence, concept, and death tables in the specified schema.
18 | */
19 |
20 | WITH first_visit AS (
21 | SELECT
22 | person_id,
23 | MIN(visit_start_date) AS first_visit_date
24 | FROM
25 | YOUR_SEPSIS_COHORT vo
26 | GROUP BY
27 | person_id
28 | ),
29 | age_calculations AS (
30 | SELECT
31 | p.person_id,
32 | YEAR(fv.first_visit_date) - p.year_of_birth AS age_at_first_visit
33 | FROM
34 | YOUR_SEPSIS_COHORT.person p
35 | JOIN
36 | first_visit fv
37 | ON p.person_id = fv.person_id
38 | ),
39 | demographics AS (
40 | SELECT
41 | p.person_id,
42 | p.gender_concept_id,
43 | p.race_concept_id,
44 | p.ethnicity_concept_id,
45 | p.year_of_birth,
46 | ac.age_at_first_visit
47 | FROM
48 | YOUR_SEPSIS_COHORT.person p
49 | JOIN
50 | age_calculations ac
51 | ON p.person_id = ac.person_id
52 | ),
53 | death_info AS (
54 | SELECT
55 | d.person_id,
56 | d.death_date,
57 | d.cause_source_value,
58 | c.concept_name AS cause_of_death
59 | FROM
60 | YOUR_SEPSIS_COHORT.death d
61 | LEFT JOIN
62 | YOUR_VOCAB.concept c
63 | ON d.cause_concept_id = c.concept_id
64 | ),
65 | los_calculations AS (
66 | SELECT
67 | fv.person_id,
68 | DATEDIFF(day, vo.visit_start_date, vo.visit_end_date) AS length_of_stay
69 | FROM
70 | first_visit fv
71 | JOIN
72 | YOUR_SEPSIS_COHORT vo
73 | ON fv.person_id = vo.person_id
74 | AND fv.first_visit_date = vo.visit_start_date
75 | ),
76 | age_summary AS (
77 | SELECT
78 | AVG(age_at_first_visit) AS mean_age,
79 | PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY age_at_first_visit) OVER () AS median_age,
80 | MIN(age_at_first_visit) AS min_age,
81 | MAX(age_at_first_visit) AS max_age,
82 | STDEV(age_at_first_visit) AS age_sd
83 | FROM
84 | age_calculations
85 | ),
86 | race_summary AS (
87 | SELECT
88 | c.concept_name AS race,
89 | COUNT(*) AS count,
90 | 100.0 * COUNT(*) / SUM(COUNT(*)) OVER () AS percent
91 | FROM
92 | demographics d
93 | JOIN
94 | YOUR_VOCAB.concept c
95 | ON d.race_concept_id = c.concept_id
96 | GROUP BY
97 | c.concept_name
98 | ),
99 | ethnicity_summary AS (
100 | SELECT
101 | c.concept_name AS ethnicity,
102 | COUNT(*) AS count,
103 | 100.0 * COUNT(*) / SUM(COUNT(*)) OVER () AS percent
104 | FROM
105 | demographics d
106 | JOIN
107 | YOUR_VOCAB.concept c
108 | ON d.ethnicity_concept_id = c.concept_id
109 | GROUP BY
110 | c.concept_name
111 | ),
112 | death_summary AS (
113 | SELECT
114 | COUNT(*) AS total_deaths,
115 | COUNT(DISTINCT cause_of_death) AS causes_of_death,
116 | COUNT(DISTINCT cause_source_value) AS causes_source_value
117 | FROM
118 | death_info
119 | ),
120 | los_summary AS (
121 | SELECT
122 | PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY length_of_stay) OVER () AS median_los,
123 | PERCENTILE_CONT(0.25) WITHIN GROUP (ORDER BY length_of_stay) OVER () AS iqr_los_25,
124 | PERCENTILE_CONT(0.75) WITHIN GROUP (ORDER BY length_of_stay) OVER () AS iqr_los_75
125 | FROM
126 | los_calculations
127 | )
128 | SELECT
129 | 'Age Summary' AS section,
130 | NULL AS category,
131 | CAST(age_summary.mean_age AS VARCHAR) AS mean,
132 | CAST(age_summary.median_age AS VARCHAR) AS median,
133 | CAST(age_summary.min_age AS VARCHAR) AS min,
134 | CAST(age_summary.max_age AS VARCHAR) AS max,
135 | CAST(age_summary.age_sd AS VARCHAR) AS standard_deviation,
136 | NULL AS count,
137 | NULL AS percent
138 | FROM
139 | age_summary
140 | UNION ALL
141 | SELECT
142 | 'Race Summary' AS section,
143 | race AS category,
144 | NULL AS mean,
145 | NULL AS median,
146 | NULL AS min,
147 | NULL AS max,
148 | NULL AS standard_deviation,
149 | CAST(count AS VARCHAR) AS count,
150 | CAST(percent AS VARCHAR) AS percent
151 | FROM
152 | race_summary
153 | UNION ALL
154 | SELECT
155 | 'Ethnicity Summary' AS section,
156 | ethnicity AS category,
157 | NULL AS mean,
158 | NULL AS median,
159 | NULL AS min,
160 | NULL AS max,
161 | NULL AS standard_deviation,
162 | CAST(count AS VARCHAR) AS count,
163 | CAST(percent AS VARCHAR) AS percent
164 | FROM
165 | ethnicity_summary
166 | UNION ALL
167 | SELECT
168 | 'Death Summary' AS section,
169 | 'Total Deaths' AS category,
170 | NULL AS mean,
171 | NULL AS median,
172 | NULL AS min,
173 | NULL AS max,
174 | NULL AS standard_deviation,
175 | CAST(total_deaths AS VARCHAR) AS count,
176 | NULL AS percent
177 | FROM
178 | death_summary
179 | UNION ALL
180 | SELECT
181 | 'Death Summary' AS section,
182 | 'Causes of Death' AS category,
183 | NULL AS mean,
184 | NULL AS median,
185 | NULL AS min,
186 | NULL AS max,
187 | NULL AS standard_deviation,
188 | CAST(causes_of_death AS VARCHAR) AS count,
189 | NULL AS percent
190 | FROM
191 | death_summary
192 | UNION ALL
193 | SELECT
194 | 'Death Summary' AS section,
195 | 'Cause Source Values' AS category,
196 | NULL AS mean,
197 | NULL AS median,
198 | NULL AS min,
199 | NULL AS max,
200 | NULL AS standard_deviation,
201 | CAST(causes_source_value AS VARCHAR) AS count,
202 | NULL AS percent
203 | FROM
204 | death_summary
205 | UNION ALL
206 | SELECT
207 | 'Length of Stay Summary' AS section,
208 | 'Median Length of Stay (days)' AS category,
209 | NULL AS mean,
210 | CAST(los_summary.median_los AS VARCHAR) AS median,
211 | CAST(los_summary.iqr_los_25 AS VARCHAR) AS min,
212 | CAST(los_summary.iqr_los_75 AS VARCHAR) AS max,
213 | NULL AS standard_deviation,
214 | NULL AS count,
215 | NULL AS percent
216 | FROM
217 | los_summary;
218 |
--------------------------------------------------------------------------------
/Cohort curation scripts/03_CURE_ID_replace_rare_conditions_with_parents.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 03_CURE_ID_replace_rare_conditions_with_parents.sql
4 |
5 | Purpose:
6 | Replace conditions occurring 10 or less times in the dataset with parent concepts
7 | that have at least 10 counts.
8 |
9 | Description:
10 |
11 | Dependencies:
12 | 01_CURE_ID_Cohort.sql
13 | 02_CURE_ID_All_Tables.sql
14 | */
15 |
16 | USE YOUR_DATABASE;
17 |
18 | DROP TABLE IF EXISTS Results.CURE_ID_Condition_Occurrence_Rare_Removed
19 |
20 | ---Condition roll up
21 | DROP TABLE IF EXISTS #condition_rollup
22 | SELECT DISTINCT
23 | cond.person_id,
24 | cond.condition_concept_id AS original_concept_id,
25 | concept.concept_name AS ancestor_concept_name,
26 | CONCEPT_ancestor.ancestor_concept_id,
27 | CONCEPT_ancestor.min_levels_of_separation
28 | INTO #condition_rollup
29 | FROM Results.CURE_ID_Condition_Occurrence AS cond
30 | LEFT JOIN CONCEPT_ancestor
31 | ON CONCEPT_ancestor.descendant_concept_id = cond.condition_concept_id
32 | LEFT JOIN concept
33 | ON concept.concept_id = CONCEPT_ancestor.ancestor_concept_id
34 |
35 | --Create table that counts the ancestor concepts for each original concept
36 | DROP TABLE IF EXISTS #condition_rollup_counts
37 | SELECT
38 | ancestor_concept_name,
39 | ancestor_concept_id,
40 | COUNT(ancestor_concept_id) AS ancestor_concept_count
41 | INTO #condition_rollup_counts
42 | FROM #condition_rollup
43 | GROUP BY ancestor_concept_id, ancestor_concept_name
44 |
45 | --Create table that counts the original concepts
46 | DROP TABLE IF EXISTS #original_condition_counts
47 | SELECT
48 | condition_concept_id AS original_concept_id,
49 | concept_name AS original_concept_name,
50 | COUNT(condition_concept_id) AS original_concept_count
51 | INTO #original_condition_counts
52 | FROM (
53 | SELECT DISTINCT
54 | cond.person_id,
55 | cond.condition_concept_id,
56 | concept.concept_name
57 | FROM Results.CURE_ID_Condition_Occurrence AS cond
58 | LEFT JOIN concept
59 | ON concept.concept_id = cond.condition_concept_id
60 | ) AS x1
61 | GROUP BY condition_concept_id, concept_name
62 |
63 | --Limit to conditions to those that have more than 10 counts
64 | DROP TABLE IF EXISTS #condition_rollup_morethan10
65 | SELECT
66 | #condition_rollup.person_id,
67 | #condition_rollup.original_concept_id,
68 | #condition_rollup.ancestor_concept_id,
69 | #condition_rollup.ancestor_concept_name,
70 | #condition_rollup_counts.ancestor_concept_count,
71 | #condition_rollup.min_levels_of_separation
72 | INTO #condition_rollup_morethan10
73 | FROM #condition_rollup
74 | LEFT JOIN #condition_rollup_counts
75 | ON #condition_rollup_counts.ancestor_concept_id = #condition_rollup.ancestor_concept_id
76 | WHERE
77 | #condition_rollup_counts.ancestor_concept_count > 10;
78 |
79 | --Get just the most specfic condition in the ancestor-descendent hierarchy
80 | DROP TABLE IF EXISTS #condition_rollup_morethan10_min_counts
81 | WITH tb1 AS (
82 | SELECT DISTINCT
83 | #condition_rollup_morethan10.person_id,
84 | #condition_rollup_morethan10.original_concept_id,
85 | MIN(#condition_rollup_morethan10.ancestor_concept_count) AS min_ancestor_concept_count
86 | FROM #condition_rollup_morethan10
87 | --GROUP BY person_id, original_concept_id
88 | )
89 |
90 | SELECT DISTINCT
91 | #condition_rollup_morethan10.person_id,
92 | #condition_rollup_morethan10.original_concept_id,
93 | #condition_rollup_morethan10.ancestor_concept_id,
94 | #condition_rollup_morethan10.ancestor_concept_name,
95 | #condition_rollup_morethan10.ancestor_concept_count,
96 | #condition_rollup_morethan10.min_levels_of_separation
97 | INTO #condition_rollup_morethan10_min_counts
98 | FROM #condition_rollup_morethan10
99 | INNER JOIN tb1
100 | ON
101 | #condition_rollup_morethan10.person_id = tb1.person_id
102 | AND #condition_rollup_morethan10.original_concept_id = tb1.original_concept_id
103 | WHERE
104 | #condition_rollup_morethan10.ancestor_concept_count = tb1.min_ancestor_concept_count
105 |
106 | DROP TABLE IF EXISTS #condition_rollup_morethan10_min_counts_and_levels
107 | WITH tb1 AS (
108 | SELECT DISTINCT
109 | person_id,
110 | original_concept_id,
111 | MIN(min_levels_of_separation) AS min_min_levels_of_separation
112 | FROM #condition_rollup_morethan10_min_counts
113 | --GROUP BY person_id, original_concept_id
114 | )
115 |
116 | SELECT DISTINCT
117 | #condition_rollup_morethan10_min_counts.person_id,
118 | #condition_rollup_morethan10_min_counts.original_concept_id,
119 | #condition_rollup_morethan10_min_counts.ancestor_concept_id AS revised_concept_id,
120 | #condition_rollup_morethan10_min_counts.ancestor_concept_name AS revised_concept_name,
121 | #condition_rollup_morethan10_min_counts.ancestor_concept_count,
122 | #condition_rollup_morethan10_min_counts.min_levels_of_separation
123 | INTO #condition_rollup_morethan10_min_counts_and_levels
124 | FROM #condition_rollup_morethan10_min_counts
125 | INNER JOIN tb1
126 | ON
127 | #condition_rollup_morethan10_min_counts.person_id = tb1.person_id
128 | AND #condition_rollup_morethan10_min_counts.original_concept_id = tb1.original_concept_id
129 | WHERE
130 | #condition_rollup_morethan10_min_counts.min_levels_of_separation = tb1.min_min_levels_of_separation
131 |
132 | DROP TABLE IF EXISTS #condition_rollup_morethan10_min_counts_and_levels_forced_unique
133 | SELECT
134 | x1.person_id,
135 | x1.original_concept_id,
136 | #original_condition_counts.original_concept_name,
137 | #original_condition_counts.original_concept_count,
138 | x1.revised_concept_id,
139 | x1.revised_concept_name,
140 | x1.min_levels_of_separation,
141 | x1.ancestor_concept_count
142 | INTO #condition_rollup_morethan10_min_counts_and_levels_forced_unique
143 | FROM (
144 | SELECT
145 | *,
146 | ROW_NUMBER() OVER (PARTITION BY person_id, original_concept_id ORDER BY revised_concept_id DESC) AS row_num
147 | FROM #condition_rollup_morethan10_min_counts_and_levels
148 | ) AS x1
149 | LEFT JOIN #original_condition_counts
150 | ON x1.original_concept_id = #original_condition_counts.original_concept_id
151 | WHERE x1.row_num = 1;
152 |
153 | --SELECT top 10 * FROM #condition_rollup_morethan10_min_counts_and_levels_forced_unique where original_concept_id != revised_concept_id;
154 |
155 | SELECT
156 | c.condition_occurrence_id,
157 | c.person_id,
158 | rare.revised_concept_id AS condition_concept_id,
159 | c.condition_start_date,
160 | c.condition_start_datetime,
161 | c.condition_end_date,
162 | c.condition_end_datetime,
163 | c.condition_type_concept_id,
164 | c.condition_status_concept_id,
165 | c.stop_reason,
166 | c.provider_id,
167 | c.visit_occurrence_id,
168 | c.visit_detail_id,
169 | c.condition_source_value,
170 | c.condition_source_concept_id,
171 | c.condition_status_source_value
172 | INTO Results.CURE_ID_Condition_Occurrence_Rare_Removed
173 | FROM Results.CURE_ID_Condition_Occurrence AS c
174 | INNER JOIN #condition_rollup_morethan10_min_counts_and_levels_forced_unique AS rare
175 | ON
176 | c.condition_concept_id = rare.original_concept_id
177 | AND c.person_id = rare.person_id;
178 |
179 | DROP TABLE IF EXISTS Results.CURE_ID_Condition_Occurrence;
180 |
--------------------------------------------------------------------------------
/Cohort curation scripts/04_DE_ID_CDM_Table_ddl.sql:
--------------------------------------------------------------------------------
1 | /*********************************************************************************
2 | # Copyright 2017-11 Observational Health Data Sciences and Informatics
3 | #
4 | #
5 | # Licensed under the Apache License, Version 2.0 (the "License")
6 | # you may not use this file except in compliance with the License.
7 | # You may obtain a copy of the License at
8 | #
9 | # http://www.apache.org/licenses/LICENSE-2.0
10 | #
11 | # Unless required by applicable law or agreed to in writing, software
12 | # distributed under the License is distributed on an "AS IS" BASIS,
13 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
14 | # See the License for the specific language governing permissions and
15 | # limitations under the License.
16 | ********************************************************************************/
17 |
18 | /************************
19 |
20 |
21 | sql server script to create OMOP common data model version 5.4
22 |
23 | last revised: 14-June-2018
24 |
25 | Authors: Patrick Ryan, Christian Reich, Clair Blacketer
26 |
27 |
28 | *************************/
29 |
30 | /*
31 | Filename:
32 | 04_DE_ID_CDM_Table_ddl.sql
33 |
34 | Purpose:
35 | Generate the necessary tables for the de-identified version of the CURE ID Cohort
36 |
37 | Description:
38 | By default this script will create tables in a schema titled “deident,”
39 | however this can be set to whatever value you desire.
40 |
41 | Dependencies:
42 | None
43 | */
44 |
45 | USE YOUR_DATABASE;
46 |
47 | /******* TABLE CLEANUP *******/
48 | DROP TABLE IF EXISTS [Results].[source_id_person];
49 | DROP TABLE IF EXISTS [Results].[source_id_visit];
50 | DROP TABLE IF EXISTS [Results].[deident_CURE_ID_condition_occurrence];
51 | DROP TABLE IF EXISTS [Results].[deident_CURE_ID_death];
52 | DROP TABLE IF EXISTS [Results].[deident_CURE_ID_drug_exposure];
53 | DROP TABLE IF EXISTS [Results].[deident_CURE_ID_device_exposure];
54 | DROP TABLE IF EXISTS [Results].[deident_CURE_ID_measurement];
55 | DROP TABLE IF EXISTS [Results].[deident_CURE_ID_observation];
56 | DROP TABLE IF EXISTS [Results].[deident_CURE_ID_person];
57 | DROP TABLE IF EXISTS [Results].[deident_CURE_ID_procedure_occurrence];
58 | DROP TABLE IF EXISTS [Results].[deident_CURE_ID_visit_occurrence];
59 |
60 |
61 | /******* TABLE CREATION *******/
62 | CREATE TABLE [Results].[source_id_person] (
63 | sourceKey INT NOT NULL,
64 | id INT NOT NULL,
65 | date_shift INT,
66 | over_89_birth_year INT
67 | );
68 |
69 | CREATE TABLE [Results].[source_id_visit] (
70 | sourceKey INT NOT NULL,
71 | new_id INT NOT NULL
72 | );
73 |
74 | --HINT DISTRIBUTE_ON_KEY(person_id)
75 | CREATE TABLE Results.deident_CURE_ID_person (
76 | person_id INTEGER NOT NULL,
77 | gender_concept_id INTEGER NOT NULL,
78 | year_of_birth INTEGER NOT NULL,
79 | month_of_birth INTEGER NULL,
80 | day_of_birth INTEGER NULL,
81 | birth_datetime DATETIME2 NULL,
82 | race_concept_id INTEGER NOT NULL,
83 | ethnicity_concept_id INTEGER NOT NULL,
84 | location_id INTEGER NULL,
85 | provider_id INTEGER NULL,
86 | care_site_id INTEGER NULL,
87 | person_source_value VARCHAR(50) NULL,
88 | gender_source_value VARCHAR(50) NULL,
89 | gender_source_concept_id INTEGER NULL,
90 | race_source_value VARCHAR(50) NULL,
91 | race_source_concept_id INTEGER NULL,
92 | ethnicity_source_value VARCHAR(50) NULL,
93 | ethnicity_source_concept_id INTEGER NULL
94 | );
95 |
96 | --HINT DISTRIBUTE_ON_KEY(person_id)
97 | CREATE TABLE Results.deident_CURE_ID_death (
98 | person_id INTEGER NOT NULL,
99 | death_date DATE NOT NULL,
100 | death_datetime DATETIME2 NULL,
101 | death_type_concept_id INTEGER NOT NULL,
102 | cause_concept_id INTEGER NULL,
103 | cause_source_value VARCHAR(50) NULL,
104 | cause_source_concept_id INTEGER NULL
105 | );
106 |
107 | --HINT DISTRIBUTE_ON_KEY(person_id)
108 | CREATE TABLE Results.deident_CURE_ID_visit_occurrence
109 | (
110 | visit_occurrence_id INTEGER NOT NULL,
111 | person_id INTEGER NOT NULL,
112 | visit_concept_id INTEGER NOT NULL,
113 | visit_start_date DATE NOT NULL,
114 | visit_start_datetime DATETIME2 NULL,
115 | visit_end_date DATE NOT NULL,
116 | visit_end_datetime DATETIME2 NULL,
117 | visit_type_concept_id INTEGER NOT NULL,
118 | provider_id INTEGER NULL,
119 | care_site_id INTEGER NULL,
120 | visit_source_value VARCHAR(50) NULL,
121 | visit_source_concept_id INTEGER NULL,
122 | admitted_from_concept_id INTEGER NULL,
123 | admitted_from_source_value VARCHAR(50) NULL,
124 | discharged_to_concept_id INTEGER NULL,
125 | discharged_to_source_value VARCHAR(50) NULL,
126 | preceding_visit_occurrence_id INTEGER NULL
127 | );
128 |
129 | --HINT DISTRIBUTE_ON_KEY(person_id)
130 | CREATE TABLE Results.deident_CURE_ID_procedure_occurrence (
131 | procedure_occurrence_id INTEGER NOT NULL,
132 | person_id INTEGER NOT NULL,
133 | procedure_concept_id INTEGER NOT NULL,
134 | procedure_date DATE NOT NULL,
135 | procedure_datetime DATETIME2 NULL,
136 | procedure_type_concept_id INTEGER NOT NULL,
137 | modifier_concept_id INTEGER NULL,
138 | quantity INTEGER NULL,
139 | provider_id INTEGER NULL,
140 | visit_occurrence_id INTEGER NULL,
141 | visit_detail_id INTEGER NULL,
142 | procedure_source_value VARCHAR(50) NULL,
143 | procedure_source_concept_id INTEGER NULL,
144 | modifier_source_value VARCHAR(50) NULL
145 | );
146 |
147 | --HINT DISTRIBUTE_ON_KEY(person_id)
148 | CREATE TABLE Results.deident_CURE_ID_drug_exposure (
149 | drug_exposure_id INTEGER NOT NULL,
150 | person_id INTEGER NOT NULL,
151 | drug_concept_id INTEGER NOT NULL,
152 | drug_exposure_start_date DATE NOT NULL,
153 | drug_exposure_start_datetime DATETIME2 NULL,
154 | drug_exposure_end_date DATE NOT NULL,
155 | drug_exposure_end_datetime DATETIME2 NULL,
156 | verbatim_end_date DATE NULL,
157 | drug_type_concept_id INTEGER NOT NULL,
158 | stop_reason VARCHAR(20) NULL,
159 | refills INTEGER NULL,
160 | quantity FLOAT NULL,
161 | days_supply INTEGER NULL,
162 | sig VARCHAR(MAX) NULL,
163 | route_concept_id INTEGER NULL,
164 | lot_number VARCHAR(50) NULL,
165 | provider_id INTEGER NULL,
166 | visit_occurrence_id INTEGER NULL,
167 | visit_detail_id INTEGER NULL,
168 | drug_source_value VARCHAR(50) NULL,
169 | drug_source_concept_id INTEGER NULL,
170 | route_source_value VARCHAR(50) NULL,
171 | dose_unit_source_value VARCHAR(50) NULL
172 | );
173 |
174 | --HINT DISTRIBUTE_ON_KEY(person_id)
175 | CREATE TABLE Results.deident_CURE_ID_device_exposure (
176 | device_exposure_id INTEGER NOT NULL,
177 | person_id INTEGER NOT NULL,
178 | device_concept_id INTEGER NOT NULL,
179 | device_exposure_start_date DATE NOT NULL,
180 | device_exposure_start_datetime DATETIME2 NULL,
181 | device_exposure_end_date DATE NULL,
182 | device_exposure_end_datetime DATETIME2 NULL,
183 | device_type_concept_id INTEGER NOT NULL,
184 | unique_device_id VARCHAR(50) NULL,
185 | quantity INTEGER NULL,
186 | provider_id INTEGER NULL,
187 | visit_occurrence_id INTEGER NULL,
188 | visit_detail_id INTEGER NULL,
189 | device_source_value VARCHAR(100) NULL,
190 | device_source_concept_id INTEGER NULL
191 | );
192 |
193 | --HINT DISTRIBUTE_ON_KEY(person_id)
194 | CREATE TABLE Results.deident_CURE_ID_condition_occurrence (
195 | condition_occurrence_id INTEGER NOT NULL,
196 | person_id INTEGER NOT NULL,
197 | condition_concept_id INTEGER NOT NULL,
198 | condition_start_date DATE NOT NULL,
199 | condition_start_datetime DATETIME2 NULL,
200 | condition_end_date DATE NULL,
201 | condition_end_datetime DATETIME2 NULL,
202 | condition_type_concept_id INTEGER NOT NULL,
203 | stop_reason VARCHAR(20) NULL,
204 | provider_id INTEGER NULL,
205 | visit_occurrence_id INTEGER NULL,
206 | visit_detail_id INTEGER NULL,
207 | condition_source_value VARCHAR(50) NULL,
208 | condition_source_concept_id INTEGER NULL,
209 | condition_status_source_value VARCHAR(50) NULL,
210 | condition_status_concept_id INTEGER NULL
211 | );
212 |
213 | --HINT DISTRIBUTE_ON_KEY(person_id)
214 | CREATE TABLE Results.deident_CURE_ID_measurement (
215 | measurement_id INTEGER NOT NULL,
216 | person_id INTEGER NOT NULL,
217 | measurement_concept_id INTEGER NOT NULL,
218 | measurement_date DATE NOT NULL,
219 | measurement_datetime DATETIME2 NULL,
220 | measurement_time VARCHAR(10) NULL,
221 | measurement_type_concept_id INTEGER NOT NULL,
222 | operator_concept_id INTEGER NULL,
223 | value_as_number FLOAT NULL,
224 | value_as_concept_id INTEGER NULL,
225 | unit_concept_id INTEGER NULL,
226 | range_low FLOAT NULL,
227 | range_high FLOAT NULL,
228 | provider_id INTEGER NULL,
229 | visit_occurrence_id INTEGER NULL,
230 | visit_detail_id INTEGER NULL,
231 | measurement_source_value VARCHAR(50) NULL,
232 | measurement_source_concept_id INTEGER NULL,
233 | unit_source_value VARCHAR(50) NULL,
234 | value_source_value VARCHAR(50) NULL
235 | );
236 |
237 | --HINT DISTRIBUTE_ON_KEY(person_id)
238 | CREATE TABLE Results.deident_CURE_ID_observation (
239 | observation_id INTEGER NOT NULL,
240 | person_id INTEGER NOT NULL,
241 | observation_concept_id INTEGER NOT NULL,
242 | observation_date DATE NOT NULL,
243 | observation_datetime DATETIME2 NULL,
244 | observation_type_concept_id INTEGER NOT NULL,
245 | value_as_number FLOAT NULL,
246 | value_as_string VARCHAR(60) NULL,
247 | value_as_concept_id INTEGER NULL,
248 | qualifier_concept_id INTEGER NULL,
249 | unit_concept_id INTEGER NULL,
250 | provider_id INTEGER NULL,
251 | visit_occurrence_id INTEGER NULL,
252 | visit_detail_id INTEGER NULL,
253 | observation_source_value VARCHAR(50) NULL,
254 | observation_source_concept_id INTEGER NULL,
255 | unit_source_value VARCHAR(50) NULL,
256 | qualifier_source_value VARCHAR(50) NULL
257 | );
258 |
--------------------------------------------------------------------------------
/CURE ID Concepts/old/OMOP_concept_list_parent_only.csv:
--------------------------------------------------------------------------------
1 | OMOP concept_ID,Concept code,Concept name,OMOP domain,Vocabulary,Standard,Descendents
2 | 317009,195967001,Asthma,Condition,SNOMED,S,TRUE
3 | 4299535,77386006,Pregnant,Condition,SNOMED,S,TRUE
4 | 439727,86406008,Human immunodeficiency virus infection,Condition,SNOMED,S,TRUE
5 | 201820,73211009,Diabetes mellitus,Condition,SNOMED,S,TRUE
6 | 255573,13645005,Chronic obstructive lung disease,Condition,SNOMED,S,TRUE
7 | 4063381,17097001,Chronic disease of respiratory system,Condition,SNOMED,S,TRUE
8 | 316866,38341003,Hypertensive disorder,Condition,SNOMED,S,TRUE
9 | 4028244,128292002,Chronic disease of cardiovascular system,Condition,SNOMED,S,TRUE
10 | 438112,55342001,Neoplastic disease,Condition,SNOMED,S,TRUE
11 | 38003563,Hispanic,Hispanic or Latino,Ethnicity,Ethnicity,S,FALSE
12 | 38003564,Not Hispanic,Not Hispanic or Latino,Ethnicity,Ethnicity,S,FALSE
13 | 8570,A,AMBIGUOUS,Gender,Gender,N,FALSE
14 | 8532,F,FEMALE,Gender,Gender,S,FALSE
15 | 8507,M,MALE,Gender,Gender,S,FALSE
16 | 8521,O,OTHER,Gender,Gender,N,FALSE
17 | 8551,U,UNKNOWN,Gender,Gender,N,FALSE
18 | 8657,1,American Indian or Alaska Native,Race,Race,S,FALSE
19 | 8515,2,Asian,Race,Race,S,FALSE
20 | 8516,3,Black or African American,Race,Race,S,FALSE
21 | 8557,4,Native Hawaiian or Other Pacific Islander,Race,Race,S,FALSE
22 | 8527,5,White,Race,Race,S,FALSE
23 | 4298794,77176002,Smoker,Observation,SNOMED,S,TRUE
24 | 4275495,365981007,Tobacco smoking behavior - finding,Observation,SNOMED,S,TRUE
25 | 3046853,32624-9,Race,Observation,LOINC,S,TRUE
26 | 46235215,76691-5,Gender identity,Observation,LOINC,S,TRUE
27 | 4039922,229306004,Positive pressure therapy,Observation,SNOMED,S,TRUE
28 | 3655896,870386000,Vasopressor therapy,Procedure,SNOMED,S,TRUE
29 | 4230167,40617009,Artificial respiration,Procedure,SNOMED,S,FALSE
30 | 4052536,233573008,Extracorporeal membrane oxygenation,Procedure,SNOMED,S,TRUE
31 | 3655950,870533002,Heated and humidified high flow oxygen therapy,Procedure,SNOMED,S,FALSE
32 | 4177224,428311008,Noninvasive ventilation,Procedure,SNOMED,S,FALSE
33 | 4201025,315041000,High concentration oxygen therapy,Procedure,SNOMED,S,FALSE
34 | 4162736,371908008,Oxygen administration by mask,Procedure,SNOMED,S,FALSE
35 | 4119964,304577004,Humidified oxygen therapy,Procedure,SNOMED,S,FALSE
36 | 4155151,371907003,Oxygen administration by nasal cannula,Procedure,SNOMED,S,FALSE
37 | 4216695,71786000,Intranasal oxygen therapy,Procedure,SNOMED,S,FALSE
38 | 44790731,2.40051E+14,Oxygen administration by non rebreather mask,Procedure,SNOMED,S,FALSE
39 | 4082249,182714002,Oxygenator therapy,Procedure,SNOMED,S,FALSE
40 | 40486624,447837008,Noninvasive positive pressure ventilation,Procedure,SNOMED,S,FALSE
41 | 4237460,408853006,Intermittent positive pressure ventilation via endotracheal tube,Procedure,SNOMED,S,TRUE
42 | 4146536,265764009,Renal dialysis,Procedure,SNOMED,S,FALSE
43 | 37018292,714749008,Continuous renal replacement therapy,Procedure,SNOMED,S,FALSE
44 | 4120120,302497006,Hemodialysis,Procedure,SNOMED,S,FALSE
45 | 3171077,2.869E+16,Emergent dialysis,Procedure,Nebraska Lexicon,S,FALSE
46 | 4324124,71192002,Peritoneal dialysis,Procedure,SNOMED,S,FALSE
47 | 2213573,90937,Hemodialysis procedure requiring repeated evaluation(s) with or without substantial revision of dialysis prescription,Procedure,CPT4,S,FALSE
48 | 2213572,90935,Hemodialysis procedure with single evaluation by a physician or other qualified health care professional,Procedure,CPT4,S,FALSE
49 | 3007220,2157-6,Creatine kinase [Enzymatic activity/volume] in Serum or Plasma,Measurement,LOINC,S,TRUE
50 | 3045262,45066-8,"Creatinine and Glomerular filtration rate.predicted panel - Serum, Plasma or Blood",Measurement,LOINC,S,TRUE
51 | 40771922,69405-9,"Glomerular filtration rate/1.73 sq M.predicted [Volume Rate/Area] in Serum, Plasma or Blood",Measurement,LOINC,S,TRUE
52 | 37032427,LP394019-6,Fibrinogen | Platelet poor plasma | Coagulation,Measurement,LOINC,C,TRUE
53 | 3023091,26881-3,Interleukin 6 [Mass/volume] in Serum or Plasma,Measurement,LOINC,S,TRUE
54 | 37070654,LP385083-3,Ferritin | Serum or Plasma | Chemistry - non-challenge,Measurement,LOINC,C,TRUE
55 | 3023361,7799-0,Fibrin D-dimer [Units/volume] in Platelet poor plasma,Measurement,LOINC,S,TRUE
56 | 37051715,LP394015-4,Fibrin D-dimer FEU | Platelet poor plasma | Coagulation,Measurement,LOINC,C,TRUE
57 | 3038553,39156-5,Body mass index (BMI) [Ratio],Measurement,LOINC,S,FALSE
58 | 3024171,9279-1,Respiratory rate,Measurement,LOINC,S,FALSE
59 | 3025315,29463-7,Body weight,Measurement,LOINC,S,FALSE
60 | 3036277,8302-2,Body height,Measurement,LOINC,S,FALSE
61 | 3027018,8867-4,Heart rate,Measurement,LOINC,S,FALSE
62 | 3004249,8480-6,Systolic blood pressure,Measurement,LOINC,S,FALSE
63 | 3012888,8462-4,Diastolic blood pressure,Measurement,LOINC,S,TRUE
64 | 37063873,LP385942-0,Troponin I.cardiac | Serum or Plasma | Chemistry - non-challenge,Measurement,LOINC,C,TRUE
65 | 3034022,42929-0,Lactate dehydrogenase panel - Serum or Plasma,Measurement,LOINC,S,TRUE
66 | 3020460,1988-5,C reactive protein [Mass/volume] in Serum or Plasma,Measurement,LOINC,S,FALSE
67 | 3046279,33959-8,Procalcitonin [Mass/volume] in Serum or Plasma,Measurement,LOINC,S,FALSE
68 | 40653596,LG10990-6,Potassium|SCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,TRUE
69 | 40653762,LG11363-5,Sodium|SCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,TRUE
70 | 40652870,LG6657-3,Creatinine|MCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,TRUE
71 | 40653238,LG6039-4,Lactate|SCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,TRUE
72 | 40653900,LG1314-6,Urea nitrogen|MCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,TRUE
73 | 40653085,LG7967-5,Glucose|MCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,TRUE
74 | 3022893,1916-6,Aspartate aminotransferase/Alanine aminotransferase [Enzymatic activity ratio] in Serum or Plasma,Measurement,LOINC,S,FALSE
75 | 3013721,1920-8,Aspartate aminotransferase [Enzymatic activity/volume] in Serum or Plasma,Measurement,LOINC,S,FALSE
76 | 40652709,LG6199-6,Bilirubin|MCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,TRUE
77 | 3045524,34543-9,Bilirubin direct and total panel [Mass/volume] - Serum or Plasma,Measurement,LOINC,S,FALSE
78 | 40652525,LG5272-2,Alanine aminotransferase|CCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,TRUE
79 | 4353936,250774007,Inspired oxygen concentration,Measurement,SNOMED,S,FALSE
80 | 40653994,LG32849-8,Eosinophils|NCnc|Pt|Bld,Measurement,LOINC,C,TRUE
81 | 3010834,778-1,Platelets [#/volume] in Blood by Manual count,Measurement,LOINC,S,FALSE
82 | 3027801,2703-7,Oxygen [Partial pressure] in Arterial blood,Measurement,LOINC,S,FALSE
83 | 3016502,2708-6,Oxygen saturation in Arterial blood,Measurement,LOINC,S,FALSE
84 | 3026238,19996-8,Oxygen/Inspired gas Respiratory system --on ventilator,Measurement,LOINC,S,FALSE
85 | 3022217,6301-6,INR in Platelet poor plasma by Coagulation assay,Measurement,LOINC,S,FALSE
86 | 37043992,LP392599-9,Leukocytes | Blood | Hematology and Cell counts,Measurement,LOINC,C,TRUE
87 | 3034426,5902-2,Prothrombin time (PT),Measurement,LOINC,S,FALSE
88 | 3018677,14979-9,aPTT in Platelet poor plasma by Coagulation assay,Measurement,LOINC,S,FALSE
89 | 3006315,26444-0,Basophils [#/volume] in Blood,Measurement,LOINC,S,FALSE
90 | 3002385,30385-9,Erythrocyte distribution width [Ratio],Measurement,LOINC,S,FALSE
91 | 3000963,718-7,Hemoglobin [Mass/volume] in Blood,Measurement,LOINC,S,FALSE
92 | 3007461,26515-7,Platelets [#/volume] in Blood,Measurement,LOINC,S,FALSE
93 | 3024929,777-3,Platelets [#/volume] in Blood by Automated count,Measurement,LOINC,S,FALSE
94 | 37041593,LP393946-1,aPTT | Platelet poor plasma | Coagulation,Measurement,LOINC,C,TRUE
95 | 37041261,LP393348-0,Erythrocyte distribution width | Red Blood Cells | Hematology and Cell counts,Measurement,LOINC,C,TRUE
96 | 37042222,LP392736-7,Basophils | Blood | Hematology and Cell counts,Measurement,LOINC,C,TRUE
97 | 40654069,LG32885-2,Monocytes|NCnc|Pt|Bld,Measurement,LOINC,C,TRUE
98 | 37070108,LP392479-4,Hematocrit | Blood | Hematology and Cell counts,Measurement,LOINC,C,TRUE
99 | 40654088,LG32886-0,Neutrophils|NCnc|Pt|Bld,Measurement,LOINC,C,TRUE
100 | 40654045,LG32863-9,Lymphocytes|NCnc|Pt|Bld,Measurement,LOINC,C,TRUE
101 | 40762499,59408-5,Oxygen saturation in Arterial blood by Pulse oximetry,Measurement,LOINC,S,FALSE
102 | 36033639,97155-6,SARS coronavirus 2 (COVID-19) immunization status,Measurement,LOINC,S,TRUE
103 | 703443,1.30067E+15,COVID-19 severity scale,Measurement,SNOMED,S,FALSE
104 | 3020891,8310-5,Body temperature,Measurement,LOINC,S,TRUE
105 | 4141684,427081008,Delivered oxygen flow rate,Measurement,SNOMED,S,TRUE
106 | 3005629,3151-8,Inhaled oxygen flow rate,Measurement,LOINC,S,FALSE
107 | 4224038,336623009,Oxygen nasal cannula,Device,SNOMED,S,TRUE
108 | 45768197,706172005,Ventilator,Device,SNOMED,S,TRUE
109 | 4222966,336602003,Oxygen mask,Device,SNOMED,S,TRUE
110 | 4138487,426294006,Face tent oxygen delivery device,Device,SNOMED,S,FALSE
111 | 4281167,36965003,Hemodialysis machine,Device,SNOMED,S,TRUE
112 | 4164918,45633005,Peritoneal dialyzer,Device,SNOMED,S,FALSE
113 | 2004208004,NA,Other oxygen device,Devcice,Custom,,FALSE
114 | 2004208005,NA,Room air (in the context of a device),Devcice,Custom,,FALSE
115 | 2004208006,NA,CPAP (continuous positive airway pressure),Devcice,Custom,,FALSE
116 | 2004208007,NA,BiPAP (bilevel positive airway pressure),Devcice,Custom,,FALSE
117 | 2004208008,NA,NIPPV (non-invasive positive pressure ventilation or nasal intermittent positive pressure ventilation),Devcice,Custom,,FALSE
118 | 1321341,7512,norepinephrine,Drug,RxNorm,S,FALSE
119 | 1343916,3992,epinephrine,Drug,RxNorm,S,FALSE
120 | 1135766,8163,phenylephrine,Drug,RxNorm,S,FALSE
121 | 1337720,3616,dobutamine,Drug,RxNorm,S,FALSE
122 | 1507835,11149,vasopressin (USP),Drug,RxNorm,S,FALSE
123 | 21600280,C01CA,Adrenergic and dopaminergic agents,Drug,ATC,C,TRUE
124 | 3655950,870533002,Heated and humidified high flow oxygen therapy,Procedure,SNOMED,S,FALSE
125 | 46257585,1022227,Extracorporeal membrane oxygenation,Procedure,CPT4,S,TRUE
126 | 45889034,1012752,Hemodialysis procedure,Procedure,CPT4,S,TRUE
127 | 45889365,1012740,Dialysis Services and Procedures,Procedure,CPT4,S,TRUE
128 | 2213576,90945,"Dialysis procedure other than hemodialysis (eg, peritoneal dialysis, hemofiltration, or other continuous renal replacement therapies)",Procedure,CPT4,S,TRUE
129 |
--------------------------------------------------------------------------------
/Cohort curation scripts/01_CURE_ID_Cohort.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 01_CURE_ID_Cohort.sql
4 |
5 | Purpose:
6 | This script creates a cohort of patients for the CURE ID registry.
7 | The patient list is saved in the cohort table, along with other useful data elements.
8 |
9 | Description:
10 | This SQL script creates a cohort of COVID-positive hospitalized patients
11 | based on specific criteria. The script performs several steps to identify and filter
12 | the patients before finally creating the cohort table. The script sets the context to
13 | use a specific database, but the actual name of the database is meant to be provided
14 | by the user.
15 |
16 | Dependencies:
17 | None
18 | */
19 |
20 | USE YOUR_DATABASE;
21 |
22 | --Drop all tables
23 | DROP TABLE IF EXISTS [Results].[CURE_ID_Cohort]; --Change schema as appropriate
24 | DROP TABLE IF EXISTS #covid_lab_pos;
25 | DROP TABLE IF EXISTS #first_pos;
26 | DROP TABLE IF EXISTS #inpat_intermed;
27 | DROP TABLE IF EXISTS #inpat;
28 | DROP TABLE IF EXISTS #inpat_closest_vis;
29 | DROP TABLE IF EXISTS #inpat_first_vis;
30 | DROP TABLE IF EXISTS #los;
31 | DROP TABLE IF EXISTS #closest_vis;
32 | DROP TABLE IF EXISTS #first_vis;
33 | DROP TABLE IF EXISTS #los_max;
34 | DROP TABLE IF EXISTS #Vis_Occ;
35 |
36 |
37 | --Create cohort table (again specify schema as appropriate)
38 | CREATE TABLE [Results].[CURE_ID_Cohort] (
39 | [person_id] [int] NOT NULL,
40 | [visit_occurrence_id] [int] NOT NULL,
41 | [visit_start_date] [date] NOT NULL,
42 | [visit_end_date] [date] NOT NULL,
43 | [First_Pos_Date] [date] NULL,
44 | [Days_From_First_Pos] [int] NULL,
45 | [Abs_Days_From_First_Pos] [int] NULL,
46 | [Before_Or_After] [int] NOT NULL,
47 | [birth_datetime] [datetime2](7) NULL,
48 | [death_datetime] [datetime2](7) NULL
49 | ) ON [PRIMARY];
50 |
51 |
52 | --First identify patients (inpatient and outpatient) with covid positive lab results
53 | SELECT DISTINCT
54 | person_id,
55 | measurement_date
56 | INTO #covid_lab_pos
57 | FROM dbo.MEASUREMENT
58 | WHERE measurement_concept_id IN (
59 | SELECT concept_id
60 | FROM dbo.CONCEPT
61 | -- here we look for the concepts that represent the LOINC codes for SARS-COV-2 nucleic acid test
62 | WHERE
63 | concept_id IN (
64 | '706169', '706156', '706154', '706170', '706157', '706155', '706173', '706175', '706163',
65 | '706167', '706168', '706158', '706161', '706160', '723478', '723476', '723464', '723465',
66 | '723466', '723467', '723468', '723469', '723470', '723471', '723463', '586528', '586529',
67 | '586524', '586525', '586526', '715272', '586517', '586520', '586519', '715262', '715261',
68 | '715260', '757677', '757678', '36661377', '36661378', '36661370', '36661371', '36031238',
69 | '36031213', '36031506', '36032061', '36031944', '36032174', '36031652', '36031453', '36032258'
70 | )
71 | UNION
72 | SELECT c.concept_id
73 | FROM dbo.CONCEPT AS c
74 | INNER JOIN dbo.CONCEPT_ANCESTOR AS ca ON c.concept_id = ca.descendant_concept_id
75 | -- Most of the LOINC codes do not have descendants but there is one OMOP Extension code (765055) in use that has descendants which we want to pull
76 | -- This statement pulls the descendants of that specific code
77 | AND ca.ancestor_concept_id IN (756055)
78 | AND c.invalid_reason IS NULL
79 | )
80 | -- Here we add a date restriction: after January 1, 2020
81 | AND measurement_date >= DATEFROMPARTS(2020, 01, 01)
82 | AND (
83 | -- The value_as_concept field is where we store standardized qualitative results
84 | -- The concept ids here represent LOINC or SNOMED codes for standard ways to code a lab that is positive
85 | value_as_concept_id IN (
86 | 4126681, -- Detected
87 | 45877985, -- Detected
88 | 45884084, -- Positive
89 | 9191, --- Positive
90 | 4181412, -- Present
91 | 45879438, -- Present
92 | 45881802 -- Reactive
93 | )
94 | -- To be exhaustive, we also look for Positive strings in the value_source_value field
95 | OR value_source_value IN ('Positive', 'Present', 'Detected', 'Reactive')
96 | );
97 |
98 | --Show counts of unique covid-positive labs (not unique patients)
99 | SELECT COUNT(*) AS "covid_positive_lab_count" FROM #covid_lab_pos;
100 |
101 | --First positive test per patient
102 | SELECT
103 | person_id,
104 | MIN(measurement_date) AS "First_Pos_Date"
105 | INTO #first_pos
106 | FROM #covid_lab_pos
107 | GROUP BY person_id;
108 |
109 | --Show count of unique patients so far
110 | SELECT COUNT(DISTINCT person_id) AS "covid_positive_lab_person_count" FROM #first_pos;
111 |
112 | --Covid-positive patients with inpatient encounters (intermediate table for debugging)
113 | SELECT
114 | v.person_id,
115 | v.visit_occurrence_id,
116 | v.visit_start_date,
117 | v.visit_end_date,
118 | p.First_Pos_Date,
119 | DATEDIFF(DAY, p.First_Pos_Date, v.visit_start_date) AS "Days_From_First_Pos",
120 | ABS(DATEDIFF(DAY, p.First_Pos_Date, v.visit_start_date)) AS "Abs_Days_From_First_Pos"
121 | INTO #inpat_intermed
122 | FROM visit_occurrence AS v
123 | INNER JOIN #first_pos AS p ON v.person_id = p.person_id
124 | WHERE v.visit_concept_id IN (9201, 262); --Inpatient visit/ED and inpt visit
125 |
126 | --Intermediate count of Covid-positive patients with inpatient encounters
127 | SELECT COUNT(DISTINCT person_id) AS "covid_pos_inpatients_count" FROM #inpat_intermed;
128 |
129 | --Count of patients after temporal constraints applied
130 | SELECT COUNT(DISTINCT person_id) AS "covid_pos_inpatients_date_filtered_count"
131 | FROM #inpat_intermed
132 | WHERE
133 | visit_start_date >= '2020-01-01'
134 | AND (
135 | DATEDIFF(DAY, First_Pos_Date, visit_start_date) > -7
136 | AND DATEDIFF(DAY, First_Pos_Date, visit_start_date) < 21
137 | )
138 |
139 | --Apply all incl/excl criteria to identify all patients hospitalized with symptomatic covid-19 up to 21 days after a positive SARS-CoV-2 test or up to 7 days prior to a positive SARS-CoV-2 test
140 | SELECT
141 | v.person_id,
142 | v.visit_occurrence_id,
143 | v.visit_start_date,
144 | v.visit_end_date,
145 | p.First_Pos_Date,
146 | DATEDIFF(MINUTE, v.visit_start_datetime, v.visit_end_datetime) AS "Length_Of_Stay",
147 | DATEDIFF(DAY, p.First_Pos_Date, v.visit_start_date) AS "Days_From_First_Pos",
148 | ABS(DATEDIFF(DAY, p.First_Pos_Date, v.visit_start_date)) AS "Abs_Days_From_First_Pos",
149 | CASE
150 | WHEN DATEDIFF(DAY, p.First_Pos_Date, v.visit_start_date) < 0 THEN -1
151 | ELSE 1
152 | END AS Before_Or_After
153 | INTO #inpat
154 | FROM visit_occurrence AS v
155 | INNER JOIN #first_pos AS p ON v.person_id = p.person_id
156 | WHERE
157 | v.visit_concept_id IN (9201, 262) --Inpatient visit/ED and inpt visit
158 | AND v.visit_start_date >= '2020-01-01'
159 | AND (
160 | DATEDIFF(DAY, p.First_Pos_Date, v.visit_start_date) > -7
161 | AND DATEDIFF(DAY, p.First_Pos_Date, v.visit_start_date) < 21
162 | );
163 |
164 | --Count of patients and encounters that meet the criteria
165 | SELECT
166 | COUNT(DISTINCT person_id) AS "covid_pos_inpatients",
167 | COUNT(DISTINCT visit_occurrence_id) AS "covid_pos_inpatient_visits"
168 | FROM #inpat;
169 |
170 | --Finds closest encounter to first positive SARS-COV-2 test (for patients hospitalized more than once)
171 | SELECT
172 | person_id,
173 | MIN(Abs_Days_From_First_Pos) AS "Closest_Vis"
174 | INTO #inpat_closest_vis
175 | FROM #inpat
176 | GROUP BY person_id;
177 |
178 | --Account for edge cases where patients have two hospitalizations same number of absolute days from SARS-COV-2 test
179 | --Ex: Patient hospitalized separately 3 days before and 3 days after SARS-COV-2 test
180 | SELECT
181 | i.person_id,
182 | MAX(i.Before_Or_After) AS "Flag"
183 | INTO #inpat_first_vis
184 | FROM #inpat AS i
185 | INNER JOIN #inpat_closest_vis AS v
186 | ON
187 | i.person_id = v.person_id
188 | AND i.Abs_Days_From_First_Pos = v.Closest_Vis
189 | GROUP BY i.person_id;
190 |
191 | --Create flag for longest LOs per person per visit_start_date
192 | SELECT
193 | i.person_id,
194 | i.visit_start_date,
195 | MAX(i.Length_Of_Stay) AS "max_los"
196 | INTO #los
197 | FROM #inpat AS i
198 | GROUP BY i.person_id, i.visit_start_date;
199 |
200 | --Apply criteria in sequence
201 | SELECT i.*
202 | INTO #closest_vis
203 | FROM #inpat AS i
204 | INNER JOIN #inpat_closest_vis
205 | AS c ON i.person_id = c.person_id
206 | AND i.Abs_Days_From_First_Pos = c.Closest_Vis;
207 |
208 | SELECT i.*
209 | INTO #first_vis
210 | FROM #closest_vis AS i
211 | INNER JOIN #inpat_first_vis
212 | AS v ON i.person_id = v.person_id
213 | AND i.Before_Or_After = v.Flag;
214 |
215 | SELECT i.*
216 | INTO #los_max
217 | FROM #first_vis AS i
218 | INNER JOIN #los
219 | AS los ON i.person_id = los.person_id
220 | AND i.visit_start_date = los.visit_start_date
221 | AND i.Length_Of_Stay = los.max_los;
222 |
223 | --Make cohort table
224 | SELECT
225 | v.*,
226 | p.birth_datetime,
227 | d.death_datetime
228 | INTO #Vis_Occ
229 | FROM #los_max AS v
230 | INNER JOIN person AS p ON v.person_id = p.person_id
231 | LEFT JOIN death AS d ON v.person_id = d.person_id;
232 |
233 | --Creates cohort by adding on birth date and death date
234 | INSERT INTO [Results].[CURE_ID_Cohort] --Change schema if not using Results
235 | (
236 | [person_id], [visit_occurrence_id], [visit_start_date], [visit_end_date], [First_Pos_Date],
237 | [Days_From_First_Pos], [Abs_Days_From_First_Pos], [Before_Or_After],
238 | [birth_datetime], [death_datetime]
239 | )
240 | SELECT
241 | v.[person_id],
242 | v.[visit_occurrence_id],
243 | v.[visit_start_date],
244 | v.[visit_end_date],
245 | v.[First_Pos_Date],
246 | v.[Days_From_First_Pos],
247 | v.[Abs_Days_From_First_Pos],
248 | v.[Before_Or_After],
249 | v.[birth_datetime],
250 | v.[death_datetime]
251 | FROM #Vis_Occ AS v;
252 |
253 | --Final count of patients
254 | SELECT COUNT(DISTINCT person_id) AS "Final_patient_count" FROM #Vis_Occ;
255 |
256 | --View data
257 | SELECT TOP 100 *
258 | FROM [Results].[CURE_ID_Cohort]
259 |
--------------------------------------------------------------------------------
/CURE ID Concepts/old/cure_id_concepts.csv:
--------------------------------------------------------------------------------
1 | Concept ID,Concept Code,Concept Name,Domain,Vocabulary,Standard Concept,Exclude,Descendants,Mapped
2 | 38003563,Hispanic,Hispanic or Latino,Ethnicity,Ethnicity,S,FALSE,FALSE,FALSE
3 | 38003564,Not Hispanic,Not Hispanic or Latino,Ethnicity,Ethnicity,S,FALSE,FALSE,FALSE
4 | 8570,A,AMBIGUOUS,Gender,Gender,N,FALSE,FALSE,FALSE
5 | 8532,F,FEMALE,Gender,Gender,S,FALSE,FALSE,FALSE
6 | 8507,M,MALE,Gender,Gender,S,FALSE,FALSE,FALSE
7 | 8521,O,OTHER,Gender,Gender,N,FALSE,FALSE,FALSE
8 | 8551,U,UNKNOWN,Gender,Gender,N,FALSE,FALSE,FALSE
9 | 8657,1,American Indian or Alaska Native,Race,Race,S,FALSE,FALSE,FALSE
10 | 8515,2,Asian,Race,Race,S,FALSE,FALSE,FALSE
11 | 8516,3,Black or African American,Race,Race,S,FALSE,FALSE,FALSE
12 | 8557,4,Native Hawaiian or Other Pacific Islander,Race,Race,S,FALSE,FALSE,FALSE
13 | 8527,5,White,Race,Race,S,FALSE,FALSE,FALSE
14 | 3655896,870386000,Vasopressor therapy,Procedure,SNOMED,S,FALSE,TRUE,FALSE
15 | 4230167,40617009,Artificial respiration,Procedure,SNOMED,S,FALSE,FALSE,FALSE
16 | 4052536,233573008,Extracorporeal membrane oxygenation,Procedure,SNOMED,S,FALSE,TRUE,FALSE
17 | 3655950,870533002,Heated and humidified high flow oxygen therapy,Procedure,SNOMED,S,FALSE,FALSE,FALSE
18 | 4177224,428311008,Noninvasive ventilation,Procedure,SNOMED,S,FALSE,FALSE,FALSE
19 | 4201025,315041000,High concentration oxygen therapy,Procedure,SNOMED,S,FALSE,FALSE,FALSE
20 | 4162736,371908008,Oxygen administration by mask,Procedure,SNOMED,S,FALSE,FALSE,FALSE
21 | 4119964,304577004,Humidified oxygen therapy,Procedure,SNOMED,S,FALSE,FALSE,FALSE
22 | 4155151,371907003,Oxygen administration by nasal cannula,Procedure,SNOMED,S,FALSE,FALSE,FALSE
23 | 4216695,71786000,Intranasal oxygen therapy,Procedure,SNOMED,S,FALSE,FALSE,FALSE
24 | 44790731,2.40051E+14,Oxygen administration by non rebreather mask,Procedure,SNOMED,S,FALSE,FALSE,FALSE
25 | 4082249,182714002,Oxygenator therapy,Procedure,SNOMED,S,FALSE,FALSE,FALSE
26 | 40486624,447837008,Noninvasive positive pressure ventilation,Procedure,SNOMED,S,FALSE,FALSE,FALSE
27 | 4237460,408853006,Intermittent positive pressure ventilation via endotracheal tube,Procedure,SNOMED,S,FALSE,TRUE,FALSE
28 | 4146536,265764009,Renal dialysis,Procedure,SNOMED,S,FALSE,FALSE,FALSE
29 | 37018292,714749008,Continuous renal replacement therapy,Procedure,SNOMED,S,FALSE,FALSE,FALSE
30 | 4120120,302497006,Hemodialysis,Procedure,SNOMED,S,FALSE,FALSE,FALSE
31 | 3171077,2.869E+16,Emergent dialysis,Procedure,Nebraska Lexicon,S,FALSE,FALSE,FALSE
32 | 4324124,71192002,Peritoneal dialysis,Procedure,SNOMED,S,FALSE,FALSE,FALSE
33 | 2213573,90937,Hemodialysis procedure requiring repeated evaluation(s) with or without substantial revision of dialysis prescription,Procedure,CPT4,S,FALSE,FALSE,FALSE
34 | 2213572,90935,Hemodialysis procedure with single evaluation by a physician or other qualified health care professional,Procedure,CPT4,S,FALSE,FALSE,FALSE
35 | 3655950,870533002,Heated and humidified high flow oxygen therapy,Procedure,SNOMED,S,FALSE,FALSE,FALSE
36 | 3007220,2157-6,Creatine kinase [Enzymatic activity/volume] in Serum or Plasma,Measurement,LOINC,S,FALSE,TRUE,FALSE
37 | 3045262,45066-8,"Creatinine and Glomerular filtration rate.predicted panel - Serum, Plasma or Blood",Measurement,LOINC,S,FALSE,TRUE,FALSE
38 | 40771922,69405-9,"Glomerular filtration rate/1.73 sq M.predicted [Volume Rate/Area] in Serum, Plasma or Blood",Measurement,LOINC,S,FALSE,TRUE,FALSE
39 | 37032427,LP394019-6,Fibrinogen | Platelet poor plasma | Coagulation,Measurement,LOINC,C,FALSE,TRUE,FALSE
40 | 3023091,26881-3,Interleukin 6 [Mass/volume] in Serum or Plasma,Measurement,LOINC,S,FALSE,TRUE,FALSE
41 | 37070654,LP385083-3,Ferritin | Serum or Plasma | Chemistry - non-challenge,Measurement,LOINC,C,FALSE,TRUE,FALSE
42 | 3023361,7799-0,Fibrin D-dimer [Units/volume] in Platelet poor plasma,Measurement,LOINC,S,FALSE,TRUE,FALSE
43 | 37051715,LP394015-4,Fibrin D-dimer FEU | Platelet poor plasma | Coagulation,Measurement,LOINC,C,FALSE,TRUE,FALSE
44 | 3038553,39156-5,Body mass index (BMI) [Ratio],Measurement,LOINC,S,FALSE,FALSE,FALSE
45 | 3024171,9279-1,Respiratory rate,Measurement,LOINC,S,FALSE,FALSE,FALSE
46 | 3025315,29463-7,Body weight,Measurement,LOINC,S,FALSE,FALSE,FALSE
47 | 3036277,8302-2,Body height,Measurement,LOINC,S,FALSE,FALSE,FALSE
48 | 3027018,8867-4,Heart rate,Measurement,LOINC,S,FALSE,FALSE,FALSE
49 | 3004249,8480-6,Systolic blood pressure,Measurement,LOINC,S,FALSE,FALSE,FALSE
50 | 3012888,8462-4,Diastolic blood pressure,Measurement,LOINC,S,FALSE,TRUE,FALSE
51 | 37063873,LP385942-0,Troponin I.cardiac | Serum or Plasma | Chemistry - non-challenge,Measurement,LOINC,C,FALSE,TRUE,FALSE
52 | 3034022,42929-0,Lactate dehydrogenase panel - Serum or Plasma,Measurement,LOINC,S,FALSE,TRUE,FALSE
53 | 3020460,1988-5,C reactive protein [Mass/volume] in Serum or Plasma,Measurement,LOINC,S,FALSE,FALSE,FALSE
54 | 3046279,33959-8,Procalcitonin [Mass/volume] in Serum or Plasma,Measurement,LOINC,S,FALSE,FALSE,FALSE
55 | 40653596,LG10990-6,Potassium|SCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,FALSE,TRUE,FALSE
56 | 40653762,LG11363-5,Sodium|SCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,FALSE,TRUE,FALSE
57 | 40652870,LG6657-3,Creatinine|MCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,FALSE,TRUE,FALSE
58 | 40653238,LG6039-4,Lactate|SCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,FALSE,TRUE,FALSE
59 | 40653900,LG1314-6,Urea nitrogen|MCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,FALSE,TRUE,FALSE
60 | 40653085,LG7967-5,Glucose|MCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,FALSE,TRUE,FALSE
61 | 3022893,1916-6,Aspartate aminotransferase/Alanine aminotransferase [Enzymatic activity ratio] in Serum or Plasma,Measurement,LOINC,S,FALSE,FALSE,FALSE
62 | 3013721,1920-8,Aspartate aminotransferase [Enzymatic activity/volume] in Serum or Plasma,Measurement,LOINC,S,FALSE,FALSE,FALSE
63 | 40652709,LG6199-6,Bilirubin|MCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,FALSE,TRUE,FALSE
64 | 3045524,34543-9,Bilirubin direct and total panel [Mass/volume] - Serum or Plasma,Measurement,LOINC,S,FALSE,FALSE,FALSE
65 | 40652525,LG5272-2,Alanine aminotransferase|CCnc|Pt|ANYBldSerPl,Measurement,LOINC,C,FALSE,TRUE,FALSE
66 | 4353936,250774007,Inspired oxygen concentration,Measurement,SNOMED,S,FALSE,FALSE,FALSE
67 | 40653994,LG32849-8,Eosinophils|NCnc|Pt|Bld,Measurement,LOINC,C,FALSE,TRUE,FALSE
68 | 3010834,778-1,Platelets [#/volume] in Blood by Manual count,Measurement,LOINC,S,FALSE,FALSE,FALSE
69 | 3027801,2703-7,Oxygen [Partial pressure] in Arterial blood,Measurement,LOINC,S,FALSE,FALSE,FALSE
70 | 3016502,2708-6,Oxygen saturation in Arterial blood,Measurement,LOINC,S,FALSE,FALSE,FALSE
71 | 3026238,19996-8,Oxygen/Inspired gas Respiratory system --on ventilator,Measurement,LOINC,S,FALSE,FALSE,FALSE
72 | 3022217,6301-6,INR in Platelet poor plasma by Coagulation assay,Measurement,LOINC,S,FALSE,FALSE,FALSE
73 | 37043992,LP392599-9,Leukocytes | Blood | Hematology and Cell counts,Measurement,LOINC,C,FALSE,TRUE,FALSE
74 | 3034426,5902-2,Prothrombin time (PT),Measurement,LOINC,S,FALSE,FALSE,FALSE
75 | 3018677,14979-9,aPTT in Platelet poor plasma by Coagulation assay,Measurement,LOINC,S,FALSE,FALSE,FALSE
76 | 3006315,26444-0,Basophils [#/volume] in Blood,Measurement,LOINC,S,FALSE,FALSE,FALSE
77 | 3002385,30385-9,Erythrocyte distribution width [Ratio],Measurement,LOINC,S,FALSE,FALSE,FALSE
78 | 3018198,7889-9,Francisella tularensis IgG Ab [Presence] in Serum,Measurement,LOINC,S,FALSE,FALSE,FALSE
79 | 3000963,718-7,Hemoglobin [Mass/volume] in Blood,Measurement,LOINC,S,FALSE,FALSE,FALSE
80 | 3007461,26515-7,Platelets [#/volume] in Blood,Measurement,LOINC,S,FALSE,FALSE,FALSE
81 | 3024929,777-3,Platelets [#/volume] in Blood by Automated count,Measurement,LOINC,S,FALSE,FALSE,FALSE
82 | 37041593,LP393946-1,aPTT | Platelet poor plasma | Coagulation,Measurement,LOINC,C,FALSE,TRUE,FALSE
83 | 37041261,LP393348-0,Erythrocyte distribution width | Red Blood Cells | Hematology and Cell counts,Measurement,LOINC,C,FALSE,TRUE,FALSE
84 | 37042222,LP392736-7,Basophils | Blood | Hematology and Cell counts,Measurement,LOINC,C,FALSE,TRUE,FALSE
85 | 40654069,LG32885-2,Monocytes|NCnc|Pt|Bld,Measurement,LOINC,C,FALSE,TRUE,FALSE
86 | 37070108,LP392479-4,Hematocrit | Blood | Hematology and Cell counts,Measurement,LOINC,C,FALSE,TRUE,FALSE
87 | 40654088,LG32886-0,Neutrophils|NCnc|Pt|Bld,Measurement,LOINC,C,FALSE,TRUE,FALSE
88 | 40654045,LG32863-9,Lymphocytes|NCnc|Pt|Bld,Measurement,LOINC,C,FALSE,TRUE,FALSE
89 | 40762499,59408-5,Oxygen saturation in Arterial blood by Pulse oximetry,Measurement,LOINC,S,FALSE,FALSE,FALSE
90 | 36033639,97155-6,SARS coronavirus 2 (COVID-19) immunization status,Measurement,LOINC,S,FALSE,TRUE,FALSE
91 | 703443,1.30067E+15,COVID-19 severity scale,Measurement,SNOMED,S,FALSE,FALSE,FALSE
92 | 3020891,8310-5,Body temperature,Measurement,LOINC,S,FALSE,TRUE,FALSE
93 | 4141684,427081008,Delivered oxygen flow rate,Measurement,SNOMED,S,FALSE,TRUE,FALSE
94 | 3005629,3151-8,Inhaled oxygen flow rate,Measurement,LOINC,S,FALSE,FALSE,FALSE
95 | 4298794,77176002,Smoker,Observation,SNOMED,S,FALSE,TRUE,FALSE
96 | 3046853,32624-9,Race,Observation,LOINC,S,FALSE,TRUE,FALSE
97 | 46235215,76691-5,Gender identity,Observation,LOINC,S,FALSE,TRUE,FALSE
98 | 4306655,419620001,Death,Observation,SNOMED,S,FALSE,TRUE,FALSE
99 | 4039922,229306004,Positive pressure therapy,Observation,SNOMED,S,FALSE,TRUE,FALSE
100 | 4224038,336623009,Oxygen nasal cannula,Device,SNOMED,S,FALSE,TRUE,FALSE
101 | 45768197,706172005,Ventilator,Device,SNOMED,S,FALSE,TRUE,FALSE
102 | 4222966,336602003,Oxygen mask,Device,SNOMED,S,FALSE,TRUE,FALSE
103 | 4138487,426294006,Face tent oxygen delivery device,Device,SNOMED,S,FALSE,FALSE,FALSE
104 | 317009,195967001,Asthma,Condition,SNOMED,S,FALSE,TRUE,FALSE
105 | 4299535,77386006,Pregnant,Condition,SNOMED,S,FALSE,TRUE,FALSE
106 | 439727,86406008,Human immunodeficiency virus infection,Condition,SNOMED,S,FALSE,TRUE,TRUE
107 | 201820,73211009,Diabetes mellitus,Condition,SNOMED,S,FALSE,TRUE,FALSE
108 | 255573,13645005,Chronic obstructive lung disease,Condition,SNOMED,S,FALSE,TRUE,FALSE
109 | 4063381,17097001,Chronic disease of respiratory system,Condition,SNOMED,S,FALSE,TRUE,FALSE
110 | 316866,38341003,Hypertensive disorder,Condition,SNOMED,S,FALSE,TRUE,FALSE
111 | 4028244,128292002,Chronic disease of cardiovascular system,Condition,SNOMED,S,FALSE,TRUE,FALSE
112 |
--------------------------------------------------------------------------------
/Cohort curation scripts/02_CURE_ID_All_Tables.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 02_CURE_ID_All_Tables.sql
4 |
5 | Purpose:
6 | This script takes your OMOP dataset and generates a copy of key tables that have
7 | been filtered down to only include people and records related to the CURE ID registry.
8 |
9 | Description:
10 | Creates CURE_ID tables from the generated CURE_ID cohort.
11 |
12 | Dependencies:
13 | 01_CURE_ID_Cohort.sql
14 | */
15 |
16 | USE YOUR_DATABASE;
17 |
18 | --Drop existing tables
19 | DROP TABLE IF EXISTS [Results].[CURE_ID_Person];
20 | DROP TABLE IF EXISTS [Results].[CURE_ID_Measurement];
21 | DROP TABLE IF EXISTS [Results].[CURE_ID_Drug_Exposure];
22 | DROP TABLE IF EXISTS [Results].[CURE_ID_Death];
23 | DROP TABLE IF EXISTS [Results].[CURE_ID_Observation];
24 | DROP TABLE IF EXISTS [Results].[CURE_ID_Procedure_Occurrence];
25 | DROP TABLE IF EXISTS [Results].[CURE_ID_Condition_Occurrence];
26 | DROP TABLE IF EXISTS [Results].[CURE_ID_Visit_Occurrence];
27 | DROP TABLE IF EXISTS [Results].[CURE_ID_Device_Exposure];
28 |
29 | --Load person table
30 | SELECT DISTINCT
31 | pe.person_id,
32 | pe.gender_concept_id,
33 | pe.year_of_birth,
34 | pe.month_of_birth,
35 | pe.day_of_birth,
36 | pe.birth_datetime,
37 | pe.race_concept_id,
38 | pe.ethnicity_concept_id,
39 | pe.location_id,
40 | pe.provider_id,
41 | pe.care_site_id,
42 | NULL AS person_source_value,
43 | NULL AS gender_source_value,
44 | pe.gender_source_concept_id,
45 | NULL AS race_source_value,
46 | pe.race_source_concept_id,
47 | NULL AS ethnicity_source_value,
48 | pe.ethnicity_source_concept_id
49 | INTO [Results].[CURE_ID_Person]
50 | FROM person AS pe
51 | INNER JOIN [Results].[CURE_ID_Cohort] AS coh
52 | ON pe.person_id = coh.person_id
53 |
54 | --Load measurements table
55 | SELECT DISTINCT
56 | m.measurement_id,
57 | m.person_id,
58 | m.measurement_concept_id,
59 | m.measurement_date,
60 | m.measurement_datetime,
61 | m.measurement_time,
62 | m.measurement_type_concept_id,
63 | m.operator_concept_id,
64 | m.value_as_number,
65 | m.value_as_concept_id,
66 | m.unit_concept_id,
67 | m.range_low,
68 | m.range_high,
69 | m.provider_id,
70 | m.visit_occurrence_id,
71 | m.visit_detail_id,
72 | NULL AS measurement_source_value,
73 | m.measurement_source_concept_id,
74 | NULL AS unit_source_value,
75 | m.unit_source_concept_id,
76 | NULL AS value_source_value,
77 | m.measurement_event_id,
78 | m.meas_event_field_concept_id
79 | INTO [Results].[CURE_ID_Measurement]
80 | FROM measurement AS m
81 | INNER JOIN [Results].[CURE_ID_Cohort] AS coh
82 | ON
83 | m.person_id = coh.person_id
84 | AND m.measurement_date BETWEEN DATEADD(DAY, -1, coh.visit_start_date) AND DATEADD(DAY, 1, coh.visit_end_date)
85 | INNER JOIN CONCEPT_ANCESTOR
86 | ON CONCEPT_ANCESTOR.descendant_concept_id = m.measurement_concept_id
87 | INNER JOIN [Results].[cure_id_concepts]
88 | ON CONCEPT_ANCESTOR.ancestor_concept_id = [Results].[cure_id_concepts].concept_id
89 | WHERE
90 | [Results].[cure_id_concepts].domain = 'Measurement'
91 | AND ([Results].[cure_id_concepts]include_descendants = 'TRUE' OR CONCEPT_ANCESTOR.ancestor_concept_id = CONCEPT_ANCESTOR.descendant_concept_id)
92 |
93 | --Load drug_exposure table
94 | SELECT
95 | d.drug_exposure_id,
96 | d.person_id,
97 | d.drug_concept_id,
98 | d.drug_exposure_start_date,
99 | d.drug_exposure_start_datetime,
100 | d.drug_exposure_end_date,
101 | d.drug_exposure_end_datetime,
102 | d.verbatim_end_date,
103 | d.drug_type_concept_id,
104 | d.stop_reason,
105 | d.refills,
106 | d.quantity,
107 | d.days_supply,
108 | d.sig,
109 | d.route_concept_id,
110 | d.lot_number,
111 | d.provider_id,
112 | d.visit_occurrence_id,
113 | d.visit_detail_id,
114 | NULL AS drug_source_value,
115 | d.drug_source_concept_id,
116 | NULL AS route_source_value,
117 | NULL AS dose_unit_source_value
118 | INTO [Results].[CURE_ID_Drug_exposure]
119 | FROM drug_exposure AS d
120 | INNER JOIN [Results].[CURE_ID_Cohort] AS coh
121 | ON
122 | d.person_id = coh.person_id
123 | AND d.drug_exposure_start_date BETWEEN DATEADD(DAY, -1, coh.visit_start_date) AND DATEADD(DAY, 1, coh.visit_end_date)
124 | INNER JOIN concept AS con
125 | ON con.concept_id = d.drug_concept_id
126 | ORDER BY
127 | coh.person_id,
128 | d.drug_exposure_start_datetime
129 |
130 | --Load Death table
131 | SELECT
132 | death.person_id,
133 | death.death_date,
134 | death.death_datetime,
135 | death.death_type_concept_id,
136 | death.cause_concept_id,
137 | NULL AS cause_source_value,
138 | death.cause_source_concept_id
139 | INTO [Results].[CURE_ID_Death]
140 | FROM death
141 | INNER JOIN [Results].[CURE_ID_Cohort] AS coh
142 | ON death.person_id = coh.person_id
143 |
144 | --Load Observation data
145 | SELECT DISTINCT
146 | o.observation_id,
147 | o.person_id,
148 | o.observation_concept_id,
149 | o.observation_date,
150 | o.observation_datetime,
151 | o.observation_type_concept_id,
152 | o.value_as_number,
153 | o.value_as_string,
154 | o.value_as_concept_id,
155 | o.qualifier_concept_id,
156 | o.unit_concept_id,
157 | o.provider_id,
158 | o.visit_occurrence_id,
159 | o.visit_detail_id,
160 | NULL AS observation_source_value,
161 | o.observation_source_concept_id,
162 | NULL AS unit_source_value,
163 | NULL AS qualifier_source_value,
164 | NULL AS value_source_value,
165 | o.observation_event_id,
166 | o.obs_event_field_concept_id
167 | INTO [Results].[CURE_ID_Observation]
168 | FROM observation AS o
169 | INNER JOIN [Results].[CURE_ID_Cohort] AS coh
170 | ON
171 | o.person_id = coh.person_id
172 | AND o.observation_date BETWEEN DATEADD(YEAR, -1, coh.visit_start_date) AND DATEADD(YEAR, 1, coh.visit_end_date)
173 | INNER JOIN CONCEPT_ANCESTOR
174 | ON CONCEPT_ANCESTOR.descendant_concept_id = o.observation_concept_id
175 | INNER JOIN [Results].[cure_id_concepts]
176 | ON CONCEPT_ANCESTOR.ancestor_concept_id = [Results].[cure_id_concepts].concept_id
177 | WHERE
178 | [Results].[cure_id_concepts].domain = 'Observation'
179 | AND ([Results].[cure_id_concepts].include_descendants = 'TRUE' OR CONCEPT_ANCESTOR.ancestor_concept_id = CONCEPT_ANCESTOR.descendant_concept_id)
180 |
181 | --Load Procedure Occurrence Table
182 | SELECT
183 | p.procedure_occurrence_id,
184 | p.person_id,
185 | p.procedure_concept_id,
186 | p.procedure_date,
187 | p.procedure_datetime,
188 | p.procedure_end_date,
189 | p.procedure_end_datetime,
190 | p.procedure_type_concept_id,
191 | p.modifier_concept_id,
192 | p.quantity,
193 | p.provider_id,
194 | p.visit_occurrence_id,
195 | p.visit_detail_id,
196 | NULL AS procedure_source_value,
197 | p.procedure_source_concept_id,
198 | NULL AS modifier_source_value
199 | INTO [Results].[CURE_ID_Procedure_Occurrence]
200 | FROM procedure_occurrence AS p
201 | INNER JOIN [Results].[CURE_ID_Cohort] AS coh
202 | ON
203 | p.person_id = coh.person_id
204 | AND p.procedure_date BETWEEN DATEADD(DAY, -1, coh.visit_start_date) AND DATEADD(DAY, 1, coh.visit_end_date)
205 | INNER JOIN CONCEPT_ANCESTOR
206 | ON CONCEPT_ANCESTOR.descendant_concept_id = p.procedure_concept_id
207 | INNER JOIN [Results].[cure_id_concepts]
208 | ON CONCEPT_ANCESTOR.ancestor_concept_id = [Results].[cure_id_concepts].concept_id
209 | WHERE
210 | [Results].[cure_id_concepts].domain = 'Procedure'
211 | AND ([Results].[cure_id_concepts].include_descendants = 'TRUE' OR CONCEPT_ANCESTOR.ancestor_concept_id = CONCEPT_ANCESTOR.descendant_concept_id)
212 |
213 | --Load Condition Occurrence table
214 | SELECT
215 | c.condition_occurrence_id,
216 | c.person_id,
217 | c.condition_concept_id,
218 | c.condition_start_date,
219 | c.condition_start_datetime,
220 | c.condition_end_date,
221 | c.condition_end_datetime,
222 | c.condition_type_concept_id,
223 | c.condition_status_concept_id,
224 | c.stop_reason,
225 | c.provider_id,
226 | c.visit_occurrence_id,
227 | c.visit_detail_id,
228 | NULL AS condition_source_value,
229 | c.condition_source_concept_id,
230 | NULL AS condition_status_source_value
231 | INTO [Results].[CURE_ID_Condition_Occurrence]
232 | FROM condition_occurrence AS c
233 | INNER JOIN [Results].[CURE_ID_Cohort] AS coh
234 | ON
235 | c.person_id = coh.person_id
236 | AND (
237 | c.condition_start_date < coh.visit_end_date
238 | OR c.condition_end_date > coh.visit_start_date
239 | OR c.condition_end_date IS NULL
240 | )
241 | INNER JOIN CONCEPT_ANCESTOR
242 | ON CONCEPT_ANCESTOR.descendant_concept_id = c.condition_concept_id
243 | INNER JOIN [Results].[cure_id_concepts]
244 | ON CONCEPT_ANCESTOR.ancestor_concept_id = [Results].[cure_id_concepts].concept_id
245 | WHERE
246 | [Results].[cure_id_concepts].domain = 'Condition'
247 | AND ([Results].[cure_id_concepts].include_descendants = 'TRUE' OR CONCEPT_ANCESTOR.ancestor_concept_id = CONCEPT_ANCESTOR.descendant_concept_id)
248 |
249 | --Load Visit Occurrence table
250 | SELECT DISTINCT
251 | v.visit_occurrence_id,
252 | v.person_id,
253 | v.visit_concept_id,
254 | v.visit_start_date,
255 | v.visit_start_datetime,
256 | v.visit_end_date,
257 | v.visit_end_datetime,
258 | v.visit_type_concept_id,
259 | v.provider_id,
260 | v.care_site_id,
261 | NULL AS visit_source_value,
262 | v.visit_source_concept_id,
263 | v.admitted_from_concept_id,
264 | NULL AS admitted_from_source_value,
265 | v.discharged_to_concept_id,
266 | NULL AS discharged_to_source_value,
267 | v.preceding_visit_occurrence_id
268 | INTO [Results].[CURE_ID_Visit_Occurrence]
269 | FROM visit_occurrence AS v
270 | INNER JOIN [Results].[CURE_ID_Cohort] AS coh
271 | ON
272 | v.person_id = coh.person_id
273 | AND v.visit_occurrence_id = coh.visit_occurrence_id
274 | WHERE v.visit_start_date >= '2020-03-01'
275 |
276 | --Load Device Exposure table
277 | SELECT
278 | dev.device_exposure_id,
279 | dev.person_id,
280 | dev.device_concept_id,
281 | dev.device_exposure_start_date,
282 | dev.device_exposure_start_datetime,
283 | dev.device_exposure_end_date,
284 | dev.device_exposure_end_datetime,
285 | dev.device_type_concept_id,
286 | dev.unique_device_id,
287 | dev.production_id,
288 | dev.quantity,
289 | dev.provider_id,
290 | dev.visit_occurrence_id,
291 | dev.visit_detail_id,
292 | NULL AS device_source_value,
293 | dev.device_source_concept_id,
294 | dev.unit_concept_id,
295 | NULL AS unit_source_value,
296 | dev.unit_source_concept_id
297 | INTO [Results].[CURE_ID_Device_Exposure]
298 | FROM device_exposure AS dev
299 | INNER JOIN [Results].[CURE_ID_Cohort] AS coh
300 | ON
301 | dev.person_id = coh.person_id
302 | AND dev.device_exposure_start_date BETWEEN DATEADD(DAY, -1, coh.visit_start_date) AND DATEADD(DAY, 1, coh.visit_end_date)
303 | INNER JOIN CONCEPT_ANCESTOR
304 | ON CONCEPT_ANCESTOR.descendant_concept_id = dev.device_concept_id
305 | INNER JOIN [Results].[cure_id_concepts]
306 | ON CONCEPT_ANCESTOR.ancestor_concept_id = [Results].[cure_id_concepts].concept_id
307 | WHERE
308 | [Results].[cure_id_concepts].domain = 'Device'
309 | AND ([Results].[cure_id_concepts].include_descendants = 'TRUE' OR CONCEPT_ANCESTOR.ancestor_concept_id = CONCEPT_ANCESTOR.descendant_concept_id)
310 |
--------------------------------------------------------------------------------
/CureID Cohort Creation Guide.md:
--------------------------------------------------------------------------------
1 | # OMOP Cohort Creation and Deidentification Guide
2 |
3 | The following scripts are to be run on a site’s full OMOP dataset in order to prepare the relevant data for sharing with the VIRUS registry. Each script should be run on the same server as the OMOP data but can be customized to run on the preferred Database and Schema.
4 |
5 | ## Instructions
6 | Replace the database name and schema in each of these scripts with your own, then run the cohort creation and deidentification scripts in the following sequence:
7 |
8 | 1. Cohort Creation (Filename: 01_CURE_ID_Cohort.sql)
9 |
10 | 2. Generate CURE ID Tables (Filename: 02_CURE_ID_All_Tables.sql)
11 |
12 | 3. Deidentify Rare Conditions (Filename: 03_CURE_ID_replace_rare_conditions_with_parents.sql)
13 |
14 | 4. Generate OMOP Tables (Filename: 04_DE_ID_CDM_Table_ddl.sql)
15 |
16 | 5. Remove Identifiers (Filename: 05_DE_ID_script.sql)
17 |
18 | 6. Run Data Quality Checks (Filename: 06_DE_ID_Quality_Checks.sql)
19 |
20 | 7. Profile Scripts
21 | - Profile Conditions (Filename: 07_A_condition_profile.sql)
22 | - Profile Measurements (Filename: 07_B_measurement_profile.sql)
23 | - Profile Drug Exposure (Filename: 07_C_drug_exposure_profile.sql)
24 | - Profile Unmapped Drugs (Filename: 07_D_review_unmapped_drugs.sql)
25 | - Profile Devices (Filename: 07_E_device_profile.sql)
26 |
27 | ## OMOP Cohort Creation and Deidentification Process
28 |
29 | ### 1. Cohort Creation Script
30 |
31 | **Filename**: 01_CURE_ID_Cohort.sql
32 |
33 | **Purpose**: This script creates a cohort of patients for the CURE ID registry. The patient list is saved in the cohort table, along with other useful data elements.
34 |
35 | **Description**: This SQL script creates a cohort of COVID-positive hospitalized patients based on specific criteria. The script performs several steps to identify and filter the patients before finally creating the cohort table. The script sets the context to use a specific database, but the actual name of the database is meant to be provided by the user.
36 |
37 | **Dependencies**: None
38 |
39 | **Steps**:
40 |
41 | 1. Create cohort table.
42 | 2. Identify patients (inpatient and outpatient) with COVID positive lab results after January 1, 2020
43 | - Use OMOP concepts that represent the LOINC codes for SARS-COV-2 nucleic acid test
44 | - The concept ids here represent LOINC or SNOMED codes for standard ways to code a lab that is positive
45 | 3. Identify the first positive COVID test per patient
46 | 4. Limit to COVID-positive patients with inpatient encounters
47 | 5. Apply all inclusion/exclusion criteria to identify all patients hospitalized with symptomatic COVID-19 up to 21 days after a positive SARS-COV-2 test or up to 7 days prior to a positive SARS-COV-2 test
48 | 6. Find the closest inpatient encounter to first positive SARS-COV-2 test (for patients hospitalized more than once)
49 | 7. Account for edge cases where patients have two hospitalizations same number of absolute days from SARS-COV-2 test (Ex: Patient hospitalized separately 3 days before and 3 days after SARS-COV-2 test)
50 | 8. Create the cohort by adding on birth date and death date
51 |
52 | ### 2. CURE ID Tables Script
53 |
54 | **Filename**: 02_CURE_ID_All_Tables.sql
55 |
56 | **Purpose**: This script takes your OMOP dataset and generates a copy of key tables that have been filtered down to only include people and records related to the CURE ID registry.
57 |
58 | **Description**: Creates CURE_ID tables from the generated CURE_ID cohort.
59 |
60 | **Dependencies**:
61 | - 01_CURE_ID_Cohort.sql
62 |
63 | **Steps**:
64 |
65 | 1. Load Person table
66 | 2. Load Measurements table
67 | 3. Load Drug Exposure table
68 | 4. Load Death table
69 | 5. Load Observation data
70 | 6. Load Procedure Occurrence Table
71 | 7. Load Condition Occurrence Table
72 | 8. Load Visit Occurrence table
73 | 9. Load Device Exposure table
74 |
75 | ### 3. Replace Rare Conditions Script
76 |
77 | **Filename**: 03_CURE_ID_replace_rare_conditions_with_parents.sql
78 |
79 | **Purpose**: Replace conditions occurring 10 or less times in the dataset with parent concepts that have at least 10 counts
80 |
81 | **Description**: This script is run after scripts 01 and 02
82 |
83 | **Dependencies**:
84 | - 01_CURE_ID_Cohort.sql
85 | - 02_CURE_ID_All_Tables.sql
86 |
87 | **Steps**:
88 |
89 | 1. Create Condition roll up: concepts are mapped to their corresponding ancestor concept(s)
90 | 2. Create table that counts the ancestor concepts for each original concept
91 | 3. Create table that counts the original concepts
92 | 4. Filter to only include conditions that have more than 10 counts
93 | 5. Get just the most specific condition in the ancestor-descendent hierarchy
94 |
95 | ### 4. Deidentified Data DDL Script
96 |
97 | **Filename**: 04_DE_ID_CDM_Table_ddl.sql
98 |
99 | **Purpose**: Generate the necessary tables for the de-identified version of the CURE ID Cohort
100 |
101 | **Description**: This script will create tables in the Results schema and preface the table names with 'deident.' However, the preface can be set to whatever value you desire.
102 |
103 | **Dependencies**: None
104 |
105 | **Steps**:
106 |
107 | 1. Create the Person table
108 | 2. Create the Death table
109 | 3. Create the Visit Occurrence table
110 | 4. Create the Procedure Occurrence table
111 | 4. Create the Drug Exposure table
112 | 5. Create the Device Exposure table
113 | 6. Create the Condition Occurrence table
114 | 7. Create the Measurement table
115 | 8. Create the Observation table
116 |
117 | ### 5. Deidentification Script
118 |
119 | **Filename**: 05_DE_ID_script.sql
120 |
121 | **Purpose**: This script creates a copy of the Cohort and removes identifying characteristics to prepare the data for sharing with the VIRUS registry.
122 |
123 | **Description**: Run this script to generate a deidentified copy of your target data. The following actions are performed:
124 | - Reassignment of Person IDs: Person IDs are regenerated sequentially from a sorted copy of the Person table. These new Person IDs are carried throughout the CDM to all tables that reference it.
125 |
126 | - Date Shifting: Each person is assigned a random date shift value between -186 and +186 days. All dates for that person are then shifted shifted by that amount.
127 |
128 | - Birthdays: After date shifting a person’s birthday, the day is then set to the first of the new birth month. If the person would be \> 89 years old then they are assigned a random birth year that would make them 90-99 years old.
129 |
130 | - Date Truncation: A user-defined Start and End date are used to exclude any date shifted data that falls outside of the target date range (e.g. procedures, conditions occurrences, etc.). Does not include Birthdates.
131 |
132 | - Removal of Other Identifiers: Other potentially identifying datapoints are removed from the dataset such as location_id, provider_id, and care_site_id
133 |
134 | **Dependencies**:
135 | - 01_CURE_ID_Cohort.sql
136 | - 02_CURE_ID_All_Tables.sql
137 | - 03_CURE_ID_replace_rare_conditions_with_parents.sql
138 | - 04_DE_ID_CDM_Table_ddl.sql
139 |
140 | **Steps**:
141 |
142 | 1. Use find and replace to set source and target DB and Schema names
143 | 2. Load the OMOP Person table, and de-identify
144 | 3. Load the OMOP Visit Occurrence table, and de-identify
145 | 4. Load the OMOP Condition Occurrence table, and de-identify
146 | 5. Load the OMOP Procedure Occurrence table, and de-identify
147 | 6. Load the OMOP Drug Exposure table, and de-identify
148 | 7. Load the OMOP Observation table, and de-identify
149 | 8. Load the OMOP Death table, and de-identify
150 | 9. Load the OMOP Device Exposure table, and de-identify
151 | 10. Load the OMOP Measurement table, and de-identify
152 |
153 | ### 6. Quality Checks Script (optional)
154 |
155 | **Filename**: 06_DE_ID_Quality_Checks.sql
156 |
157 | **Purpose**: This script checks basic metrics for each table in the deidentified dataset to ensure the previous scripts were successful.
158 |
159 | **Description**: This script runs a number of summary level quality checks for each table to audit basic data counts and date ranges.
160 |
161 | **Dependencies**:
162 | - 01_CURE_ID_Cohort.sql
163 | - 02_CURE_ID_All_Tables.sql
164 | - 03_CURE_ID_replace_rare_conditions_with_parents.sql
165 | - 04_DE_ID_CDM_Table_ddl.sql
166 | - 05_DE_ID_script.sql
167 |
168 | **Steps**:
169 |
170 | 1. Count distinct person_ids and find the maximum and minimum birthdates in the OMOP Person table.
171 | 2. Count distinct person_ids in the OMOP Death table.
172 | 3. Count distinct person_ids, count number of records per observation_concept_id, and find the maximum and minimum observation dates for all records in the OMOP Observation table.
173 | 4. Count distinct person_ids, count number of records per procedure_concept_id, and find the maximum and minimum procedure dates for all records in the OMOP Procedure Occurrence table.
174 | 5. Count distinct person_ids, count number of records per condition_concept_id, and find the maximum and minimum condition dates for all records in the OMOP Condition Occurrence table.
175 | 6. Count distinct person_ids, count number of records per measurement_concept_id, and find the maximum and minimum measurement dates for all records in the OMOP Measurement table.
176 | 7. Count distinct person_ids, count number of records per device_concept_id, and find the maximum and minimum device exposure dates for all records in the OMOP Device Exposure table.
177 | 8. Count distinct person_ids, count number of records per drug_concept_id, and find the maximum and minimum drug exposure dates for all records in the OMOP Drug Exposure table.
178 |
179 | ### 7. Cohort Profile Scripts
180 |
181 | **Dependencies**: These scripts require the populated deidentified OMOP tables generated from the sequence of running scripts 1-5:
182 |
183 | - 01_CURE_ID_Cohort.sql
184 | - 02_CURE_ID_All_Tables.sql
185 | - 03_CURE_ID_replace_rare_conditions_with_parents.sql
186 | - 04_DE_ID_CDM_Table_ddl.sql
187 | - 05_DE_ID_script.sql
188 |
189 | ##### 07-A – Condition Profile
190 |
191 | **Filename**: 07_A_condition_profile.sql
192 |
193 | **Purpose**: Generate a profile of condition prevalence in the final cohort.
194 |
195 | **Description**: Condition counts are calculated per patient and are aggregated by parent concepts for each condition concept present in the final OMOP Condition Occurrence table.
196 |
197 | ##### 07-B – Measurement Profile
198 |
199 | **Filename**: 07_B_measurement_profile.sql
200 |
201 | **Purpose**: Generate a profile of measurement prevalence in the final cohort.
202 |
203 | **Description**: Measurement counts are calculated per patient and are aggregated by parent concepts for each measurement concept present in the final OMOP Measurement table.
204 |
205 | ##### 07-C – Drug Exposure Profile
206 |
207 | **Filename**: 07_C_drug_exposure_profile.sql
208 |
209 | **Purpose**: Generate a profile of drug prevalence in the final cohort.
210 |
211 | **Description**: Drug counts are calculated per patient and are aggregated by ingredient for each drug concept present in the final OMOP Drug Exposure table.
212 |
213 | ##### 07-D – Unmapped Drugs Profile
214 |
215 | **Filename**: 07_D_review_unmapped_drugs.sql
216 |
217 | **Purpose**: Generate a profile of drugs that are not mapped to drug_concept_ids in the final cohort.
218 |
219 | **Description**: This file filters drugs that were unsuccessfully mapped to a drug_concept_id when running the 02_CURE_ID_All_Tables.sql script. Drug source values for which the drug_concept_id is “0” and have at least 20 instances in the final cohort are aggregated for manual review.
220 | \*\* Drug source values can contain PHI. Please review the output for PHI before sharing.
221 |
222 | ##### 07-E – Device Profile
223 |
224 | **Filename**: 07_E_device_profile.sql
225 |
226 | **Purpose**: Generate a profile of device prevalence in the final cohort.
227 |
228 | **Description**: Device counts are calculated per patient and are aggregated by parent concepts for each device concept present in the final OMOP Device Exposure table.
229 |
--------------------------------------------------------------------------------
/Cohort curation scripts/05_DE_ID_script.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Filename:
3 | 05_DE_ID_script.sql
4 |
5 | Purpose:
6 | This script creates a copy of the Cohort and removes identifying characteristics
7 | to prepare the data for sharing with the VIRUS registry.
8 |
9 |
10 | Description:
11 | Run this file to generate a deidentified copy of your target data. Insert your data
12 | into the OMOP tables, and de-identify person_id, and date fields using date.shift.
13 | If a person is 90 years of age or older, assign a random age between 90-99 years.
14 |
15 | Dependencies:
16 | 01_CURE_ID_Cohort.sql
17 | 02_CURE_ID_All_Tables.sql
18 | 03_CURE_ID_replace_rare_conditions_with_parents.sql
19 | 04_DE_ID_CDM_Table_ddl.sql
20 | */
21 |
22 |
23 | /******* VARIABLES *******/
24 | --SOURCE_SCHEMA: Results
25 | --TARGET_SCHEMA: [Results]
26 | DECLARE @START_DATE DATE = CAST('2016-01-01' AS DATE)
27 | DECLARE @END_DATE DATE = CAST('2029-12-31' AS DATE)
28 |
29 |
30 | /******* GENERATE MAP TABLES *******/
31 |
32 | --Tables are dropped and created in a separate script.
33 | --Please run that script first.
34 |
35 | USE YOUR_DATABASE;
36 |
37 |
38 | /******* GENERATE MAP TABLES *******/
39 | INSERT INTO [Results].[source_id_person]
40 | SELECT
41 | p.person_id AS sourceKey,
42 | ROW_NUMBER() OVER (ORDER BY p.gender_concept_id DESC, p.person_id DESC) AS id,
43 | (FLOOR(RAND(CAST(NEWID() AS VARBINARY)) * 367)) - 183 AS date_shift,
44 | CAST((DATEPART(YEAR, GETDATE()) - 90 - (FLOOR(RAND(CAST(NEWID() AS VARBINARY)) * 10))) AS INT) AS over_89_birth_year --If a person is > 89, then assign them a random age between 90 - 99
45 | FROM [Results].[CURE_ID_Person] AS p;
46 |
47 | INSERT INTO [Results].[source_id_visit]
48 | SELECT
49 | p.visit_occurrence_id AS sourceKey,
50 | ROW_NUMBER() OVER (ORDER BY p.visit_occurrence_id) AS new_id
51 | FROM [Results].[CURE_ID_Visit_Occurrence] AS p
52 | INNER JOIN [Results].[source_id_person] AS s ON s.sourceKey = p.person_id
53 | LEFT JOIN [Results].[source_id_visit] AS v ON v.sourceKey = p.visit_occurrence_id --Ask Ben about this self join?
54 | WHERE v.new_id IS NULL AND (
55 | DATEADD(DAY, s.date_shift, p.visit_start_date) >= @START_DATE
56 | AND DATEADD(DAY, s.date_shift, p.visit_end_date) <= @END_DATE
57 | ) ORDER BY p.person_id, p.visit_start_date;
58 |
59 | /******* PERSON *******/
60 | INSERT INTO [Results].[deident_CURE_ID_Person]
61 | SELECT
62 | s.id AS person_id,
63 | p.gender_concept_id,
64 | CASE
65 | WHEN DATEDIFF(DAY, p.birth_datetime, GETDATE()) / 365.25 > 89 THEN s.over_89_birth_year
66 | ELSE DATEPART(YEAR, DATEADD(DAY, s.date_shift, p.birth_datetime))
67 | END AS year_of_birth,
68 | DATEPART(MONTH, DATEADD(DAY, s.date_shift, p.birth_datetime)) AS month_of_birth,
69 | 1 AS day_of_birth,
70 | DATEFROMPARTS(
71 | CASE WHEN DATEDIFF(DAY, p.birth_datetime, GETDATE()) / 365.25 > 89 THEN s.over_89_birth_year ELSE DATEPART(YEAR, DATEADD(DAY, s.date_shift, p.birth_datetime)) END,
72 | DATEPART(MONTH, DATEADD(DAY, s.date_shift, p.birth_datetime)),
73 | 1
74 | ) AS birth_datetime,
75 | p.race_concept_id,
76 | p.ethnicity_concept_id,
77 | 1 AS location_id,
78 | 1 AS provider_id,
79 | 1 AS care_site_id,
80 | 0 AS person_source_value,
81 | 0 AS gender_source_value,
82 | 0 AS gender_source_concept_id,
83 | 0 AS race_source_value,
84 | 0 AS race_source_concept_id,
85 | 0 AS ethnicity_source_value,
86 | 0 AS ethnicity_source_concept_id
87 | FROM [Results].[CURE_ID_Person] AS p
88 | INNER JOIN [Results].[source_id_person] AS s ON s.sourceKey = p.person_id;
89 |
90 | /******* VISIT *******/
91 | INSERT INTO [Results].[deident_CURE_ID_Visit_Occurrence]
92 | SELECT
93 | v.new_id AS visit_occurrence_id,
94 | s.id AS person_id,
95 | p.visit_concept_id,
96 | DATEADD(DAY, s.date_shift, p.visit_start_date) AS visit_start_date,
97 | DATEADD(DAY, s.date_shift, p.visit_start_datetime) AS visit_start_datetime,
98 | DATEADD(DAY, s.date_shift, p.visit_end_date) AS visit_end_date,
99 | DATEADD(DAY, s.date_shift, p.visit_end_datetime) AS visit_end_datetime,
100 | p.visit_type_concept_id,
101 | 1 AS provider_id,
102 | 1 AS care_site_id,
103 | NULL AS visit_source_value,
104 | p.visit_source_concept_id,
105 | p.admitted_from_concept_id,
106 | NULL AS admitted_from_source_value,
107 | p.discharged_to_concept_id,
108 | NULL AS discharged_to_source_value,
109 | p.preceding_visit_occurrence_id
110 | FROM [Results].[CURE_ID_Visit_Occurrence] AS p
111 | INNER JOIN [Results].[source_id_person] AS s ON s.sourceKey = p.person_id
112 | LEFT JOIN [Results].[source_id_visit] AS v ON v.sourceKey = p.visit_occurrence_id
113 | WHERE (DATEADD(DAY, s.date_shift, visit_start_date) >= @START_DATE AND DATEADD(DAY, s.date_shift, visit_end_date) <= @END_DATE);
114 |
115 | /******* CONDITION OCCURENCE *******/
116 | INSERT INTO [Results].[deident_CURE_ID_Condition_Occurrence]
117 | SELECT
118 | p.condition_occurrence_id,
119 | s.id AS person_id,
120 | p.condition_concept_id,
121 | DATEADD(DAY, s.date_shift, p.condition_start_date) AS condition_start_date,
122 | DATEADD(DAY, s.date_shift, p.condition_start_datetime) AS condition_start_datetime,
123 | DATEADD(DAY, s.date_shift, p.condition_end_date) AS condition_end_date,
124 | DATEADD(DAY, s.date_shift, p.condition_end_datetime) AS condition_end_datetime,
125 | p.condition_type_concept_id,
126 | p.stop_reason,
127 | 1 AS provider_id,
128 | v.new_id AS visit_occurrence_id,
129 | p.visit_detail_id,
130 | p.condition_source_value,
131 | p.condition_source_concept_id,
132 | p.condition_status_source_value,
133 | p.condition_status_concept_id
134 | FROM [Results].[CURE_ID_Condition_Occurrence_Rare_Removed] AS p
135 | INNER JOIN [Results].[source_id_person] AS s ON s.sourceKey = p.person_id
136 | LEFT JOIN [Results].[source_id_visit] AS v ON v.sourceKey = p.visit_occurrence_id
137 | WHERE (
138 | DATEADD(DAY, s.date_shift, condition_start_date) < @END_DATE
139 | AND DATEADD(DAY, s.date_shift, COALESCE(condition_end_date, condition_start_date)) > @START_DATE
140 | );
141 |
142 | /******* PROCEDURE OCCURENCE *******/
143 | INSERT INTO [Results].[deident_CURE_ID_Procedure_Occurrence]
144 | SELECT
145 | p.procedure_occurrence_id,
146 | s.id AS person_id,
147 | p.procedure_concept_id,
148 | DATEADD(DAY, s.date_shift, p.procedure_date) AS procedure_date,
149 | DATEADD(DAY, s.date_shift, p.procedure_date) AS procedure_datetime,
150 | p.procedure_type_concept_id,
151 | p.modifier_concept_id,
152 | p.quantity,
153 | 1 AS provider_id,
154 | v.new_id AS visit_occurrence_id,
155 | p.visit_detail_id,
156 | p.procedure_source_value,
157 | p.procedure_source_concept_id,
158 | p.modifier_source_value
159 | FROM [Results].[CURE_ID_Procedure_Occurrence] AS p
160 | INNER JOIN [Results].[source_id_person] AS s ON s.sourceKey = p.person_id
161 | LEFT JOIN [Results].[source_id_visit] AS v ON v.sourceKey = p.visit_occurrence_id
162 | WHERE (
163 | DATEADD(DAY, s.date_shift, procedure_date) < @END_DATE
164 | AND DATEADD(DAY, s.date_shift, procedure_date) > @START_DATE
165 | );
166 |
167 | /******* DRUG EXPOSURE *******/
168 | INSERT INTO [Results].[deident_CURE_ID_Drug_Exposure]
169 | SELECT
170 | p.drug_exposure_id,
171 | s.id AS person_id,
172 | p.drug_concept_id,
173 | DATEADD(DAY, s.date_shift, p.drug_exposure_start_date) AS drug_exposure_start_date,
174 | DATEADD(DAY, s.date_shift, p.drug_exposure_start_date) AS drug_exposure_start_datetime,
175 | DATEADD(DAY, s.date_shift, p.drug_exposure_end_date) AS drug_exposure_end_date,
176 | DATEADD(DAY, s.date_shift, p.drug_exposure_end_date) AS drug_exposure_end_datetime,
177 | DATEADD(DAY, s.date_shift, p.verbatim_end_date) AS verbatim_end_date,
178 | p.drug_type_concept_id,
179 | p.stop_reason,
180 | p.refills,
181 | p.quantity,
182 | p.days_supply,
183 | p.sig,
184 | p.route_concept_id,
185 | p.lot_number,
186 | 1 AS provider_id,
187 | v.new_id AS visit_occurrence_id,
188 | p.visit_detail_id,
189 | p.drug_source_value,
190 | p.drug_source_concept_id,
191 | p.route_source_value,
192 | p.dose_unit_source_value
193 | FROM [Results].[CURE_ID_Drug_Exposure] AS p
194 | INNER JOIN [Results].[source_id_person] AS s ON s.sourceKey = p.person_id
195 | LEFT JOIN [Results].[source_id_visit] AS v ON v.sourceKey = p.visit_occurrence_id
196 | WHERE (
197 | DATEADD(DAY, s.date_shift, drug_exposure_start_date) < @END_DATE
198 | AND DATEADD(DAY, s.date_shift, drug_exposure_end_date) > @START_DATE
199 | );
200 |
201 | /******* OBSERVATION *******/
202 | INSERT INTO [Results].[deident_CURE_ID_Observation]
203 | SELECT
204 | p.observation_id,
205 | s.id AS person_id,
206 | p.observation_concept_id,
207 | DATEADD(DAY, s.date_shift, p.observation_date) AS observation_date,
208 | DATEADD(DAY, s.date_shift, p.observation_date) AS observation_datetime,
209 | p.observation_type_concept_id,
210 | p.value_as_number,
211 | p.value_as_string,
212 | p.value_as_concept_id,
213 | p.qualifier_concept_id,
214 | p.unit_concept_id,
215 | 1 AS provider_id,
216 | v.new_id AS visit_occurrence_id,
217 | p.visit_detail_id,
218 | p.observation_source_value,
219 | p.observation_source_concept_id,
220 | p.unit_source_value,
221 | p.qualifier_source_value
222 | FROM [Results].[CURE_ID_Observation] AS p
223 | INNER JOIN [Results].[source_id_person] AS s ON s.sourceKey = p.person_id
224 | LEFT JOIN [Results].[source_id_visit] AS v ON v.sourceKey = p.visit_occurrence_id
225 | WHERE (
226 | DATEADD(DAY, s.date_shift, observation_date) < @END_DATE
227 | AND DATEADD(DAY, s.date_shift, observation_date) > @START_DATE
228 | );
229 |
230 | /******* DEATH *******/
231 | INSERT INTO [Results].[deident_CURE_ID_Death]
232 | SELECT
233 | s.id AS person_id,
234 | DATEADD(DAY, s.date_shift, p.death_date) AS death_date,
235 | DATEADD(DAY, s.date_shift, p.death_date) AS death_datetime,
236 | p.death_type_concept_id,
237 | p.cause_concept_id,
238 | p.cause_source_value,
239 | p.cause_source_concept_id
240 | FROM [Results].[CURE_ID_Death] AS p
241 | INNER JOIN [Results].[source_id_person] AS s ON s.sourceKey = p.person_id;
242 |
243 | /******* DEVICE EXPOSURE *******/
244 | INSERT INTO [Results].[deident_CURE_ID_Device_Exposure]
245 | SELECT
246 | p.device_exposure_id,
247 | s.id AS person_id,
248 | p.device_concept_id,
249 | DATEADD(DAY, s.date_shift, p.device_exposure_start_date) AS device_exposure_start_date,
250 | DATEADD(DAY, s.date_shift, p.device_exposure_start_date) AS device_exposure_start_datetime,
251 | DATEADD(DAY, s.date_shift, p.device_exposure_end_date) AS device_exposure_end_date,
252 | DATEADD(DAY, s.date_shift, p.device_exposure_end_date) AS device_exposure_end_datetime,
253 | p.device_type_concept_id,
254 | p.unique_device_id,
255 | p.quantity,
256 | 1 AS provider_id,
257 | v.new_id AS visit_occurrence_id,
258 | p.visit_detail_id,
259 | p.device_source_value,
260 | p.device_source_concept_id
261 | FROM [Results].[CURE_ID_Device_Exposure] AS p
262 | INNER JOIN [Results].[source_id_person] AS s ON s.sourceKey = p.person_id
263 | LEFT JOIN [Results].[source_id_visit] AS v ON v.sourceKey = p.visit_occurrence_id
264 | WHERE (
265 | DATEADD(DAY, s.date_shift, device_exposure_start_date) < @END_DATE
266 | AND DATEADD(DAY, s.date_shift, COALESCE(device_exposure_end_date, device_exposure_start_date)) > @START_DATE
267 | );
268 |
269 | /******* MEASUREMENT *******/
270 | INSERT INTO [Results].[deident_CURE_ID_Measurement]
271 | SELECT
272 | p.measurement_id,
273 | s.id AS person_id,
274 | p.measurement_concept_id,
275 | DATEADD(DAY, s.date_shift, p.measurement_date) AS measurement_date,
276 | DATEADD(DAY, s.date_shift, p.measurement_date) AS measurement_datetime,
277 | p.measurement_time,
278 | p.measurement_type_concept_id,
279 | p.operator_concept_id,
280 | p.value_as_number,
281 | p.value_as_concept_id,
282 | p.unit_concept_id,
283 | p.range_low,
284 | p.range_high,
285 | 1 AS provider_id,
286 | v.new_id AS visit_occurrence_id,
287 | p.visit_detail_id,
288 | p.measurement_source_value,
289 | p.measurement_source_concept_id,
290 | p.unit_source_value,
291 | p.value_source_value
292 | FROM [Results].[CURE_ID_Measurement] AS p
293 | INNER JOIN [Results].[source_id_person] AS s ON s.sourceKey = p.person_id
294 | LEFT JOIN [Results].[source_id_visit] AS v ON v.sourceKey = p.visit_occurrence_id
295 | WHERE (
296 | DATEADD(DAY, s.date_shift, measurement_date) < @END_DATE
297 | AND DATEADD(DAY, s.date_shift, measurement_date) > @START_DATE
298 | );
299 |
--------------------------------------------------------------------------------
/CURE ID Concepts/old/conceptcountcheck.sql:
--------------------------------------------------------------------------------
1 | Select concept_id, count(*) from condition_occurrence where concept_id in(4125022, 45769441, 45771045, 46273452, 40481763, 43530693, 45773005, 46270082, 46273487, 36684328, 45769438, 46269767, 45769442, 45769443, 46274124, 46269777, 45769352, 46273462, 45769351, 46269785, 46274059, 45769350, 46269771, 37116845, 4191479, 45766728, 45766727, 4271333, 257583, 45757063, 4250128, 46269801, 317009, 46274062, 4211530, 45772073, 42535716, 43530745, 4206340, 4233784, 4143474, 4075237, 4225553, 4245676, 4051466, 44810117, 256448, 46269802, 4119300, 313236, 4217558, 42538744, 36684335, 257581, 4138760, 45768911, 45772937, 45768912, 443801, 4123253, 312950, 761844, 37310241, 4141978, 46270030, 46270322, 4145497, 252658, 4225554, 4119298, 35609846, 42536207, 35609847, 4057952, 4155468, 4146581, 46269776, 4143828, 46270029, 4022592, 4110051, 42536208, 4155469, 46269784, 4142738, 46273454, 37206717, 4309833, 4155470, 4212099, 37109103, 764677, 764949, 4232595, 4080516, 40483397, 4152913, 37208352, 37108580, 46269770, 4145356, 46270028, 37108581, 46273635, 4312524, 4120261, 4301938, 3661412, 42539549, 45768910, 45768963, 45768964, 42536649, 45768965, 4245292, 4345926, 37204495, 44782655, 44782733, 40481043, 764874, 37309625, 40480602, 761828, 761827, 761826, 4293711, 4343930, 4347061, 436642, 4211990, 4203452, 4202809, 4070155, 4138971, 764011, 765535, 762000, 762001, 765536, 760850, 762420, 35623289, 4181182, 761837, 765302, 761839, 761838, 44784282, 36715042, 4141360, 4137382, 4330696, 4006976, 765568, 36716727, 4119596, 44782719, 4229440, 4203625, 4195892, 3174315, 765152, 35616026, 761439, 761418, 46271548, 765539, 35616025, 761441, 762007, 761417, 36712971, 761026, 762011, 761445, 765542, 762019, 761440, 762023, 761449, 762006, 44782734, 44782739, 765153, 765154, 762014, 44782740, 44782755, 762012, 761447, 765543, 765544, 762421, 761446, 765538, 44782735, 46270070, 44782736, 762024, 762025, 761450, 762016, 765545, 762422, 761448, 44782738, 44782737, 762027, 762028, 762029, 44782741, 44782765, 4242036, 40479576, 4028244, 37016883, 4098133, 4097815, 4168162, 4211001, 201885, 4294973, 196442, 197018, 198801, 4148257, 433515, 436729, 4164920, 437326, 4244406, 443779, 4134586, 444031, 764876, 4304837, 4291933, 4080325, 4227607, 316447, 4117864, 4006165, 4119595, 4264536, 43530652, 315286, 4206009, 4009047, 4001578, 762769, 760968, 765701, 46272972, 4318560, 4119593, 4185302, 764141, 4059463, 4137219, 44782819, 4327471, 200451, 4053008, 4313767, 44782715, 3172731, 44782732, 315831, 45768887, 45771016, 4332085, 4122085, 4263730, 4227150, 4264740, 4235735, 4117862, 4192358, 321307, 4231452, 4284562, 4014159, 4325525, 40479192, 762050, 46270157, 762051, 45757409, 762046, 36712891, 44782759, 761460, 763926, 761459, 46271475, 761451, 761458, 44782754, 765228, 44782756, 36712779, 4164798, 4196809, 199064, 36717599, 35615125, 37312010, 37110890, 4242231, 4163687, 4311437, 37110519, 40493243, 40480082, 4208824, 4164289, 37119072, 45771067, 45771064, 45757447, 45757446, 45757445, 45757444, 44784621, 44784637, 44784640, 43021836, 43021835, 44784639, 44784638, 36679002, 35624116, 4112021, 4088332, 4173466, 4284682, 35622345, 762033, 762034, 4112769, 3656065, 37110251, 4209301, 201347, 4214249, 3174548, 45757356, 45757137, 45757139, 43020511, 43021871, 4161973, 4271703, 4309357, 4201941, 4178622, 46271900, 37018345, 4120115, 4236271, 4062117, 42709778, 42709779, 45771051, 37204863, 4345565, 4031011, 4119942, 37209632, 4219464, 4141827, 4297648, 312940, 765888, 40481763, 4137525, 257004, 43530693, 46270376, 37312199, 4115044, 44807895, 36716978, 35615340, 37016114, 4199450, 4241525, 256439, 4241526, 4240899, 46274062, 4148124, 4273688, 4321845, 4052553, 4050877, 3185549, 4145496, 4286497, 4049259, 439851, 24978, 4230358, 4048184, 37116455, 256448, 4048081, 4110489, 4111455, 761761, 42539089, 255841, 37206130, 4110048, 4110498, 4145495, 4144107, 45757644, 4063381, 432347, 4112836, 3654571, 759819, 132932, 45768998, 4110490, 4275496, 4112500, 139841, 4051488, 4049243, 4126438, 37396824, 4140438, 4112509, 4112497, 4177862, 4084689, 4110027, 762964, 45767051, 24970, 4112534, 26719, 761762, 4186898, 45768981, 134668, 4112498, 441321, 4289844, 4166517, 3654836, 3654837, 46269802, 255573, 46269701, 4110056, 4048185, 4051487, 4230641, 4048188, 26711, 46270074, 46269693, 4243667, 4051486, 4221767, 4084973, 37118654, 4080753, 260034, 4274468, 4188331, 3655115, 4096917, 252348, 4179673, 4333202, 3655114, 3655112, 3655113, 37204512, 314971, 4179670, 259848, 765276, 4119447, 4112508, 4112367, 257012, 134661, 23220, 4254103, 4200851, 4051493, 4112529, 261895, 4166508, 4281815, 4167920, 4104506, 3189821, 4328679, 36674977, 45765445, 259043, 258780, 4046986, 765431, 4247588, 3187037, 4140134, 4309350, 443775, 4050961, 4123253, 4246105, 36675042, 37110292, 45763750, 440748, 36714681, 4173466, 4112518, 4048501, 4241326, 4112737, 4198434, 4196712, 4112826, 4193588, 257905, 4040469, 4050876, 4056405, 4172303, 4297463, 35622370, 4288156, 4181738, 4177944, 4136683, 3174548, 37208102, 37397178, 4112530, 4112499, 42536541, 261325, 45769389, 4050732, 3183290, 4048489, 42534820, 4110362, 4049242, 4334649, 37017277, 37017278, 4110637, 46270340, 3188190, 40491473, 44782989, 43021940, 3184237, 4110492, 4110479, 4049245, 4051475, 4316066, 4316067, 4315386, 4050734, 4280726, 40483397, 4119431, 4110635, 4209097, 36715408, 261889, 3661412, 4050733, 4052552, 4078695, 4083395, 44791725, 4112365, 4112828, 257004, 43530693, 4115044, 44807895, 46274062, 4148124, 4321845, 3185549, 4145496, 4286497, 4110048, 4112836, 3654571, 4166517, 3654836, 3654837, 255573, 46269701, 4110056, 261895, 4166508, 4281815, 259043, 4046986, 4050961, 4246105, 440748, 4196712, 4193588, 4056405, 4177944, 4136683, 261325, 45769389, 4050732, 4315386, 4050734, 4110635, 4209097, 4050733, 4083395, 44791725, 4112828, 36715051, 36713275, 36715417, 4129516, 201820, 4322638, 4143529, 4245270, 4240589, 4178452, 4178790, 42537681, 765478, 3178281, 4144583, 43531011, 43531642, 4192852, 45757077, 4237068, 443012, 192691, 4058243, 45757129, 194700, 4079850, 45766050, 4062685, 4062686, 4235410, 4136889, 45757674, 36684827, 45757474, 44793113, 4008576, 43531645, 43531019, 43531020, 42535539, 4202383, 4084643, 4099741, 3183244, 4024659, 37018765, 45757124, 4326434, 4263902, 37396524, 46274096, 4048202, 4034962, 4252384, 4047906, 4102018, 4129524, 4129525, 4130162, 36717215, 36685758, 4145827, 4006979, 4131907, 44787902, 4030061, 4096671, 4096670, 4096042, 4327944, 4166381, 44792134, 43531640, 43531017, 43531018, 43531012, 43531013, 43531014, 43531643, 43531015, 43531644, 43531016, 43531006, 4130164, 4034963, 37204818, 193323, 36716258, 43531641, 37110041, 4030066, 3198118, 3194119, 3193274, 3192767, 3194082, 3191208, 3194332, 45757789, 40482883, 44793114, 45757079, 43531007, 4062687, 4063042, 43531008, 4063043, 43531010, 43531009, 4129519, 37204277, 37204232, 4212631, 4140808, 195771, 4034960, 4099334, 4099653, 37116379, 4129378, 201254, 4099215, 4099214, 443412, 201826, 4230254, 4304377, 4099651, 4193704, 45766051, 45766052, 37116960, 37311329, 37017285, 4128060, 45757102, 37017266, 4008081, 37017282, 4267414, 37017132, 37019055, 37017456, 42538959, 42538960, 4241530, 4239722, 37019058, 37017595, 37017092, 37017254, 36714339, 37017276, 3654682, 37017210, 37017453, 4171124, 4180254, 4171125, 37017549, 37017294, 37018935, 37017442, 37017319, 37018711, 37017094, 37017260, 37017279, 37017244, 37017125, 37017259, 37017655, 37019052, 3654950, 3654900, 37017265, 37017106, 37116831, 37017586, 37017261, 37017093, 37017209, 46284256, 4314426, 4201627, 4172009, 4124361, 45769839, 45773072, 45769855, 45769856, 36715476, 4161950, 4262297, 4340791, 4253472, 432554, 45757132, 439727, 4087603, 36687122, 4087604, 4092686, 4047624, 4347288, 42536591, 42536590, 42536593, 42536592, 42536594, 42539031, 42536596, 42536595, 37018063, 36674252, 37017550, 37017446, 37017454, 37017457, 36674254, 37017295, 37017248, 37019042, 37017124, 36674253, 37017318, 37017284, 37116830, 37017296, 37017263, 37017320, 4225193, 37017580, 37017652, 37017126, 37017108, 37017424, 37019034, 37017262, 4048033, 37017579, 37017249, 36716524, 4236860, 4320032, 37018721, 37017247, 37017112, 37017246, 37017455, 37018714, 37017278, 37018755, 37017425, 37017243, 37017082, 37017071, 45769864, 43531586, 37017283, 312648, 4215640, 4034031, 4148205, 321638, 314103, 320456, 314423, 4062811, 4269358, 4028741, 314958, 4249016, 36715087, 4304837, 4291933, 4080325, 4227607, 4167358, 42538697, 4289142, 45757119, 320128, 4083723, 4302591, 4321603, 4217486, 4179379, 4048212, 4316372, 4058987, 4322735, 42538946, 321080, 42873163, 3656115, 35624277, 45771067, 45771064, 45757447, 45757446, 45757445, 45757444, 4279525, 44784484, 4061667, 44809548, 4108213, 4110948, 4178312, 4094374, 4174979, 4219323, 4006325, 4262182, 3169253, 3191244, 45768449, 316866, 43020424, 40481896, 4034095, 44783643, 4276511, 4159755, 44783644, 36713024, 4263067, 317898, 4289933, 4023318, 4162306, 4028951, 4218088, 318437, 4110947, 4118910, 314090, 4034094, 4071202, 44811110, 4146627, 4212496, 4049389, 762994, 43021830, 35622939, 45757787, 45757788, 439393, 4283352, 141084, 135601, 134414, 136743, 4062550, 4146816, 4277110, 4151903, 321074, 4311246, 45757356, 45757137, 4057978, 4057979, 4167493, 44784483, 4221991, 4305599, 443771, 197930, 200157, 201912, 192684, 4032952, 317895, 37208172, 4253928, 319826, 44809027, 433536, 438490, 439077, 132685, 4057976, 44809026, 44811933, 44811932, 44809569, 37016726, 4242878, 4180283, 4209293, 4035655, 4199306, 441922, 137940, 141639, 136760, 4062906, 40483581, 3170656, 4244660, 4163701, 3178184, 3183244, 4188598, 40480278, 37018878, 3168925, 4231507, 197031, 3173485, 4217975, 36684864, 4132562, 4031512, 3186698, 3177459, 3180298, 4061785, 4060237, 3184093, 4299535, 4059982, 4061784, 4061686, 4059981, 4059983, 4012559, 4307820, 4059985, 4239301) group by concept_id
2 | UNION ALL
3 | Select concept_id, count(*) from device_exposure where concept_id in(4138487, 4145694, 4137849, 36714464, 45768222, 45767333, 45767334, 45767335, 45767336, 45767337, 36676809, 45771595, 4145528, 4222966, 45759146, 4138748, 45772392, 45760053, 45760350, 45768221, 45760219, 4322904, 45759930, 45773303, 45760842, 4138614, 45761768, 45761494, 4139525, 36715214, 4224038, 36715213, 36715212, 45763257, 45763336, 45764073, 45768199, 45768198, 45758195, 45764556, 45764072, 45765049, 45771119, 45759002, 45764052, 45765048, 45761109, 45764253, 45765050, 45768197, 45760386, 45760156) group by concept_id
4 | UNION ALL
5 | Select concept_id, count(*) from measurement where concept_id in(46235106, 3006923, 3027388, 3005755, 46236949, 40652525, 3041944, 37041593, 3045961, 3018677, 3041974, 3038668, 3038547, 3040681, 3042449, 3042634, 3042294, 3039283, 3004144, 3040598, 3038425, 3007328, 3040750, 3008791, 3040623, 3040743, 3052968, 3042436, 3041232, 3018677, 3013721, 3022893, 3006315, 3006315, 3013429, 3027651, 37042222, 3045524, 40762888, 3028833, 3024128, 40762889, 40652709, 3036277, 3038553, 3020891, 3025315, 3020460, 703443, 3007220, 3016723, 3045262, 40764999, 36306178, 3053283, 3029829, 36303797, 3049187, 3007760, 3051825, 3016723, 40652870, 4141684, 44782836, 3012888, 3013115, 3028615, 3009932, 40653994, 3002385, 3002888, 3015182, 3002385, 3019897, 37041261, 3001122, 3015242, 37070654, 3023361, 3051714, 3052648, 37051715, 3008766, 3016407, 3052964, 3018928, 3002937, 37032427, 3018198, 40771922, 3031266, 3000483, 3011424, 3014053, 3004077, 3034962, 3004501, 44816672, 3033408, 40653085, 3027018, 42869588, 3009542, 3023314, 3019909, 3050746, 3013752, 37070108, 3000963, 3005629, 3022217, 4353936, 3023091, 3022250, 3005225, 3006898, 3023919, 3007858, 3024830, 3012481, 3009347, 3049516, 3034022, 3018405, 3047181, 3028271, 3005949, 3014111, 3008037, 40653238, 3001657, 3046900, 3010813, 3000905, 3032393, 3003282, 37043992, 3019198, 3004327, 3003215, 40654045, 3001604, 3033575, 3034107, 40654069, 3017732, 3013650, 3017501, 40654088, 3027801, 3016502, 40762499, 3026238, 3007461, 3024929, 3010834, 3043409, 3005456, 3040893, 3031219, 3023103, 46235078, 3041354, 40653596, 3046279, 3034426, 3024171, 36033639, 3043706, 3000285, 3038702, 3031579, 3019550, 46235784, 3041473, 40653762, 3004249, 36304114, 3021337, 3032971, 36306105, 37063873, 3026617, 3004295, 3010335, 3013682, 3027219, 40653900) group by concept_id
6 | UNION ALL
7 | Select concept_id, count(*) from observation where concept_id in(4244339, 46235215, 37208293, 3197551, 40488414, 4165535, 4055262, 3196459, 4042360, 4306204, 4061066, 4302668, 4039924, 3661882, 3661883, 4132745, 4039922, 3192256, 4060126, 4011629, 4061415, 4060231, 4061420, 4133724, 4132563, 4132099, 4132100, 4133030, 4132101, 4132564, 4133032, 4133033, 4132565, 4061672, 4012560, 40481872, 36684865, 4059977, 4061683, 4012089, 4061676, 4061411, 4221287, 4214878, 4069849, 4288592, 4060127, 4061418, 4060235, 3046853, 4044778, 4246415, 4276526, 764104, 764103, 4041511, 4052947, 4209006, 762499, 4042037, 4052029, 762498, 4044776, 4052030, 4209585, 4044775, 37395605, 4218917, 4058138, 4298794, 4204653, 4141787, 4144273, 4044777, 4058136) group by concept_id
8 | UNION ALL
9 | Select concept_id, count(*) from procedure_occurrence where concept_id in(4230167, 37018292, 3171077, 37206602, 4052536, 1531632, 1524105, 1531631, 1524104, 1531630, 1524103, 37206601, 37206603, 3655950, 3655950, 4120120, 2213573, 2213572, 4201025, 4119964, 2745440, 2745444, 2745447, 4237460, 4216695, 40486624, 4177224, 4162736, 4155151, 44790731, 4082249, 4324124, 2788019, 2788024, 2787823, 2314035, 738834, 4146536, 3655896, 46257510, 46257511, 46257682, 46257466, 46257543, 46257438, 46257683, 46257544, 46257399, 46257468, 46257467, 46257398, 46257680, 46257512, 46257730, 46257685, 46257684, 46257397, 46257729, 46257513, 46257439, 46257440) group by concept_id
10 |
--------------------------------------------------------------------------------
/CURE ID Concepts/CureID_concepts_parents_Version1.csv:
--------------------------------------------------------------------------------
1 | "","concept_id","concept_code","concept_name","domain","vocabulary","is_standard","include_descendants"
2 | "1","317009","195967001","Asthma","Condition","SNOMED","S",TRUE
3 | "2","4028244","128292002","Chronic disease of cardiovascular system","Condition","SNOMED","S",TRUE
4 | "3","4063381","17097001","Chronic disease of respiratory system","Condition","SNOMED","S",TRUE
5 | "4","255573","13645005","Chronic obstructive lung disease","Condition","SNOMED","S",TRUE
6 | "5","201820","73211009","Diabetes mellitus","Condition","SNOMED","S",TRUE
7 | "6","439727","86406008","Human immunodeficiency virus infection","Condition","SNOMED","S",TRUE
8 | "7","316866","38341003","Hypertensive disorder","Condition","SNOMED","S",TRUE
9 | "8","438112","55342001","Neoplastic disease","Condition","SNOMED","S",TRUE
10 | "9","4299535","77386006","Pregnant","Condition","SNOMED","S",TRUE
11 | "10","4281167","36965003","Hemodialysis machine","Device","SNOMED","S",TRUE
12 | "11","4222966","336602003","Oxygen mask","Device","SNOMED","S",TRUE
13 | "12","4224038","336623009","Oxygen nasal cannula","Device","SNOMED","S",TRUE
14 | "13","45768197","706172005","Ventilator","Device","SNOMED","S",TRUE
15 | "14","4138487","426294006","Face tent oxygen delivery device","Device","SNOMED","S",FALSE
16 | "15","4164918","45633005","Peritoneal dialyzer","Device","SNOMED","S",FALSE
17 | "16","40493026","449071006","Mechanical ventilator","Device","SNOMED","S",TRUE
18 | "17","4138916","426160001","Oxygen ventilator","Device","SNOMED","S",TRUE
19 | "18","21600280","C01CA","Adrenergic and dopaminergic agents","Drug","ATC","C",TRUE
20 | "19","1337720","3616","dobutamine","Drug","RxNorm","S",FALSE
21 | "20","1343916","3992","epinephrine","Drug","RxNorm","S",FALSE
22 | "21","1321341","7512","norepinephrine","Drug","RxNorm","S",FALSE
23 | "22","1135766","8163","phenylephrine","Drug","RxNorm","S",FALSE
24 | "23","1507835","11149","vasopressin (USP)","Drug","RxNorm","S",FALSE
25 | "24","38003563","Hispanic","Hispanic or Latino","Ethnicity","Ethnicity","S",FALSE
26 | "25","38003564","Not Hispanic","Not Hispanic or Latino","Ethnicity","Ethnicity","S",FALSE
27 | "26","8570","A","AMBIGUOUS","Gender","Gender","N",FALSE
28 | "27","8532","F","FEMALE","Gender","Gender","S",FALSE
29 | "28","8507","M","MALE","Gender","Gender","S",FALSE
30 | "29","8521","O","OTHER","Gender","Gender","N",FALSE
31 | "30","8551","U","UNKNOWN","Gender","Gender","N",FALSE
32 | "31","40652525","LG5272-2","Alanine aminotransferase|CCnc|Pt|ANYBldSerPl","Measurement","LOINC","C",TRUE
33 | "32","37041593","LP393946-1","aPTT | Platelet poor plasma | Coagulation","Measurement","LOINC","C",TRUE
34 | "33","37042222","LP392736-7","Basophils | Blood | Hematology and Cell counts","Measurement","LOINC","C",TRUE
35 | "34","40652709","LG6199-6","Bilirubin|MCnc|Pt|ANYBldSerPl","Measurement","LOINC","C",TRUE
36 | "35","3020891","8310-5","Body temperature","Measurement","LOINC","S",TRUE
37 | "36","3007220","2157-6","Creatine kinase [Enzymatic activity/volume] in Serum or Plasma","Measurement","LOINC","S",TRUE
38 | "37","3045262","45066-8","Creatinine and Glomerular filtration rate.predicted panel - Serum, Plasma or Blood","Measurement","LOINC","S",TRUE
39 | "38","40652870","LG6657-3","Creatinine|MCnc|Pt|ANYBldSerPl","Measurement","LOINC","C",TRUE
40 | "39","4141684","427081008","Delivered oxygen flow rate","Measurement","SNOMED","S",TRUE
41 | "40","3023361","7799-0","Deprecated Fibrin D-dimer [Units/volume] in Platelet poor plasma","Measurement","LOINC","N",TRUE
42 | "41","3012888","8462-4","Diastolic blood pressure","Measurement","LOINC","S",TRUE
43 | "42","40653994","LG32849-8","Eosinophils|NCnc|Pt|Bld","Measurement","LOINC","C",TRUE
44 | "43","37041261","LP393348-0","Erythrocyte distribution width | Red Blood Cells | Hematology and Cell counts","Measurement","LOINC","C",TRUE
45 | "44","37070654","LP385083-3","Ferritin | Serum or Plasma | Chemistry - non-challenge","Measurement","LOINC","C",TRUE
46 | "45","37051715","LP394015-4","Fibrin D-dimer FEU | Platelet poor plasma | Coagulation","Measurement","LOINC","C",TRUE
47 | "46","37032427","LP394019-6","Fibrinogen | Platelet poor plasma | Coagulation","Measurement","LOINC","C",TRUE
48 | "47","40771922","69405-9","Glomerular filtration rate/1.73 sq M.predicted [Volume Rate/Area] in Serum, Plasma or Blood","Measurement","LOINC","S",TRUE
49 | "48","40653085","LG7967-5","Glucose|MCnc|Pt|ANYBldSerPl","Measurement","LOINC","C",TRUE
50 | "49","37070108","LP392479-4","Hematocrit | Blood | Hematology and Cell counts","Measurement","LOINC","C",TRUE
51 | "50","3023091","26881-3","Interleukin 6 [Mass/volume] in Serum or Plasma","Measurement","LOINC","S",TRUE
52 | "51","3034022","42929-0","Lactate dehydrogenase panel - Serum or Plasma","Measurement","LOINC","S",TRUE
53 | "52","40653238","LG6039-4","Lactate|SCnc|Pt|ANYBldSerPl","Measurement","LOINC","C",TRUE
54 | "53","37043992","LP392599-9","Leukocytes | Blood | Hematology and Cell counts","Measurement","LOINC","C",TRUE
55 | "54","40654045","LG32863-9","Lymphocytes|NCnc|Pt|Bld","Measurement","LOINC","C",TRUE
56 | "55","40654069","LG32885-2","Monocytes|NCnc|Pt|Bld","Measurement","LOINC","C",TRUE
57 | "56","40654088","LG32886-0","Neutrophils|NCnc|Pt|Bld","Measurement","LOINC","C",TRUE
58 | "57","40653596","LG10990-6","Potassium|SCnc|Pt|ANYBldSerPl","Measurement","LOINC","C",TRUE
59 | "58","40653762","LG11363-5","Sodium|SCnc|Pt|ANYBldSerPl","Measurement","LOINC","C",TRUE
60 | "59","37063873","LP385942-0","Troponin I.cardiac | Serum or Plasma | Chemistry - non-challenge","Measurement","LOINC","C",TRUE
61 | "60","40653900","LG1314-6","Urea nitrogen|MCnc|Pt|ANYBldSerPl","Measurement","LOINC","C",TRUE
62 | "61","3018677","14979-9","aPTT in Platelet poor plasma by Coagulation assay","Measurement","LOINC","S",FALSE
63 | "62","3013721","1920-8","Aspartate aminotransferase [Enzymatic activity/volume] in Serum or Plasma","Measurement","LOINC","S",FALSE
64 | "63","3022893","1916-6","Aspartate aminotransferase/Alanine aminotransferase [Enzymatic activity ratio] in Serum or Plasma","Measurement","LOINC","S",FALSE
65 | "64","3006315","26444-0","Basophils [#/volume] in Blood","Measurement","LOINC","S",FALSE
66 | "65","3045524","34543-9","Bilirubin direct and total panel [Mass/volume] - Serum or Plasma","Measurement","LOINC","S",FALSE
67 | "66","3036277","8302-2","Body height","Measurement","LOINC","S",FALSE
68 | "67","3038553","39156-5","Body mass index (BMI) [Ratio]","Measurement","LOINC","S",FALSE
69 | "68","3020460","1988-5","C reactive protein [Mass/volume] in Serum or Plasma","Measurement","LOINC","S",FALSE
70 | "69","703443","1300671000000104","COVID-19 severity scale","Measurement","SNOMED","S",FALSE
71 | "70","3002385","30385-9","Erythrocyte distribution width [Ratio]","Measurement","LOINC","S",FALSE
72 | "71","3027018","8867-4","Heart rate","Measurement","LOINC","S",FALSE
73 | "72","3000963","718-7","Hemoglobin [Mass/volume] in Blood","Measurement","LOINC","S",FALSE
74 | "73","3005629","3151-8","Inhaled oxygen flow rate","Measurement","LOINC","S",FALSE
75 | "74","3022217","6301-6","INR in Platelet poor plasma by Coagulation assay","Measurement","LOINC","S",FALSE
76 | "75","4353936","250774007","Inspired oxygen concentration","Measurement","SNOMED","S",FALSE
77 | "76","3027801","2703-7","Oxygen [Partial pressure] in Arterial blood","Measurement","LOINC","S",FALSE
78 | "77","3016502","2708-6","Oxygen saturation in Arterial blood","Measurement","LOINC","S",FALSE
79 | "78","40762499","59408-5","Oxygen saturation in Arterial blood by Pulse oximetry","Measurement","LOINC","S",FALSE
80 | "79","3026238","19996-8","Oxygen/Inspired gas Respiratory system --on ventilator","Measurement","LOINC","S",FALSE
81 | "80","3007461","26515-7","Platelets [#/volume] in Blood","Measurement","LOINC","S",FALSE
82 | "81","3024929","777-3","Platelets [#/volume] in Blood by Automated count","Measurement","LOINC","S",FALSE
83 | "82","3010834","778-1","Platelets [#/volume] in Blood by Manual count","Measurement","LOINC","S",FALSE
84 | "83","3046279","33959-8","Procalcitonin [Mass/volume] in Serum or Plasma","Measurement","LOINC","S",FALSE
85 | "84","3034426","5902-2","Prothrombin time (PT)","Measurement","LOINC","S",FALSE
86 | "85","3024171","9279-1","Respiratory rate","Measurement","LOINC","S",FALSE
87 | "86","3004249","8480-6","Systolic blood pressure","Measurement","LOINC","S",FALSE
88 | "87","1004141","LP415675-0","Body weight | Patient | General body weight","Measurement","LOINC","C",TRUE
89 | "88","45889365","1012740","Dialysis Services and Procedures","Observation","CPT4","C",TRUE
90 | "89","46235215","76691-5","Gender identity","Observation","LOINC","S",TRUE
91 | "90","4039922","229306004","Positive pressure therapy","Observation","SNOMED","S",TRUE
92 | "91","3046853","32624-9","Race","Observation","LOINC","S",TRUE
93 | "92","36033639","97155-6","SARS coronavirus 2 (COVID-19) immunization status","Observation","LOINC","S",TRUE
94 | "93","4298794","77176002","Smoker","Observation","SNOMED","S",TRUE
95 | "94","4275495","365981007","Tobacco smoking behavior - finding","Observation","SNOMED","S",TRUE
96 | "95","2213576","90945","Dialysis procedure other than hemodialysis (eg, peritoneal dialysis, hemofiltration, or other continuous renal replacement therapies), with single evaluation by a physician or other qualified health care professional","Procedure","CPT4","S",TRUE
97 | "96","4052536","233573008","Extracorporeal membrane oxygenation","Procedure","SNOMED","S",TRUE
98 | "97","46257585","1022227","Extracorporeal membrane oxygenation (ECMO)/extracorporeal life support (ECLS) provided by physician","Procedure","CPT4","C",TRUE
99 | "98","45889034","1012752","Hemodialysis Procedures","Procedure","CPT4","C",TRUE
100 | "99","4237460","408853006","Intermittent positive pressure ventilation via endotracheal tube","Procedure","SNOMED","S",TRUE
101 | "100","3655896","870386000","Vasopressor therapy","Procedure","SNOMED","S",TRUE
102 | "101","4230167","40617009","Artificial respiration","Procedure","SNOMED","S",FALSE
103 | "102","37018292","714749008","Continuous renal replacement therapy","Procedure","SNOMED","S",FALSE
104 | "103","3171077","28690001000004105","Emergent dialysis","Procedure","Nebraska Lexicon","S",FALSE
105 | "104","3655950","870533002","Heated and humidified high flow oxygen therapy","Procedure","SNOMED","S",FALSE
106 | "105","4120120","302497006","Hemodialysis","Procedure","SNOMED","S",FALSE
107 | "106","2213573","90937","Hemodialysis procedure requiring repeated evaluation(s) with or without substantial revision of dialysis prescription","Procedure","CPT4","S",FALSE
108 | "107","2213572","90935","Hemodialysis procedure with single evaluation by a physician or other qualified health care professional","Procedure","CPT4","S",FALSE
109 | "108","4201025","315041000","High concentration oxygen therapy","Procedure","SNOMED","S",FALSE
110 | "109","4119964","304577004","Humidified oxygen therapy","Procedure","SNOMED","S",FALSE
111 | "110","4216695","71786000","Intranasal oxygen therapy","Procedure","SNOMED","S",FALSE
112 | "111","40486624","447837008","Noninvasive positive pressure ventilation","Procedure","SNOMED","S",FALSE
113 | "112","4177224","428311008","Noninvasive ventilation","Procedure","SNOMED","S",FALSE
114 | "113","4162736","371908008","Oxygen administration by mask","Procedure","SNOMED","S",FALSE
115 | "114","4155151","371907003","Oxygen administration by nasal cannula","Procedure","SNOMED","S",FALSE
116 | "115","44790731","240051000000102","Oxygen administration by non rebreather mask","Procedure","SNOMED","S",FALSE
117 | "116","4082249","182714002","Oxygenator therapy","Procedure","SNOMED","S",FALSE
118 | "117","4324124","71192002","Peritoneal dialysis","Procedure","SNOMED","S",FALSE
119 | "118","4146536","265764009","Renal dialysis","Procedure","SNOMED","S",FALSE
120 | "119","8657","1","American Indian or Alaska Native","Race","Race","S",FALSE
121 | "120","8515","2","Asian","Race","Race","S",FALSE
122 | "121","8516","3","Black or African American","Race","Race","S",FALSE
123 | "122","8557","4","Native Hawaiian or Other Pacific Islander","Race","Race","S",FALSE
124 | "123","8527","5","White","Race","Race","S",FALSE
125 | "124","2004208004",NA,"Other oxygen device","Device","Custom","C",FALSE
126 | "125","2004208005",NA,"Room air (in the context of a device)","Device","Custom","C",FALSE
127 | "126","2004208006",NA,"CPAP (continuous positive airway pressure)","Device","Custom","C",FALSE
128 | "127","2004208007",NA,"BiPAP (bilevel positive airway pressure)","Device","Custom","C",FALSE
129 | "128","2004208008",NA,"NIPPV (non-invasive positive pressure ventilation or nasal intermittent positive pressure ventilation)","Device","Custom","C",FALSE
130 | "129","4263457","NA","Aspartate aminotransferase measurement","Measurement","SNOMED","S",TRUE
131 | “130”,”3037256”,”9095-1”,”Fluid balance 10 hour”,”Measurement”,”LOINC”,”S”,”TRUE”
132 | “131”,”3037769”,”9096-9”,”Fluid balance 12 hour”,”Measurement”,”LOINC”,”S”,”TRUE”
133 | “132”,”4092647”,”251992000”,”Fluid intake”,”Measurement”,”SNOMED”,”S”,”TRUE”
134 | “133”,”4089845”,”251846002”,”Fluid loss”,”Measurement”,”SNOMED”,”S”,”TRUE”
135 | “134”,”4090192”,”251840008”,”Fluid output”,”Measurement”,”SNOMED”,”S”,”TRUE”
136 | “135”,”3038018”,”9097-7”,”Fluid balance 24 hour”,”Measurement”,”LOINC”,”S”,”TRUE”
137 | “136”,”3020997”,”9094-4”,”Fluid balance 8 hour”,”Measurement”,”LOINC”,”S”,”TRUE”
138 | “137”,”1259832”,”104103-7”,”Cumulative fluid balance”,”Measurement”,”LOINC”,”S”,”TRUE”
139 | “138”,”3002137”,”9093-6”,”Fluid balance 1 hour”,”Measurement”,”LOINC”,”S”,”TRUE”
140 |
--------------------------------------------------------------------------------
/CURE ID Concepts/old/cure_id_procedures.json:
--------------------------------------------------------------------------------
1 | {
2 | "items": [
3 | {
4 | "concept": {
5 | "CONCEPT_CLASS_ID": "Procedure",
6 | "CONCEPT_CODE": "870386000",
7 | "CONCEPT_ID": 3655896,
8 | "CONCEPT_NAME": "Vasopressor therapy",
9 | "DOMAIN_ID": "Procedure",
10 | "INVALID_REASON": "V",
11 | "INVALID_REASON_CAPTION": "Valid",
12 | "STANDARD_CONCEPT": "S",
13 | "STANDARD_CONCEPT_CAPTION": "Standard",
14 | "VOCABULARY_ID": "SNOMED"
15 | },
16 | "isExcluded": false,
17 | "includeDescendants": true,
18 | "includeMapped": false
19 | },
20 | {
21 | "concept": {
22 | "CONCEPT_CLASS_ID": "Procedure",
23 | "CONCEPT_CODE": "40617009",
24 | "CONCEPT_ID": 4230167,
25 | "CONCEPT_NAME": "Artificial respiration",
26 | "DOMAIN_ID": "Procedure",
27 | "INVALID_REASON": "V",
28 | "INVALID_REASON_CAPTION": "Valid",
29 | "STANDARD_CONCEPT": "S",
30 | "STANDARD_CONCEPT_CAPTION": "Standard",
31 | "VOCABULARY_ID": "SNOMED"
32 | },
33 | "isExcluded": false,
34 | "includeDescendants": false,
35 | "includeMapped": false
36 | },
37 | {
38 | "concept": {
39 | "CONCEPT_CLASS_ID": "Procedure",
40 | "CONCEPT_CODE": "233573008",
41 | "CONCEPT_ID": 4052536,
42 | "CONCEPT_NAME": "Extracorporeal membrane oxygenation",
43 | "DOMAIN_ID": "Procedure",
44 | "INVALID_REASON": "V",
45 | "INVALID_REASON_CAPTION": "Valid",
46 | "STANDARD_CONCEPT": "S",
47 | "STANDARD_CONCEPT_CAPTION": "Standard",
48 | "VOCABULARY_ID": "SNOMED"
49 | },
50 | "isExcluded": false,
51 | "includeDescendants": true,
52 | "includeMapped": false
53 | },
54 | {
55 | "concept": {
56 | "CONCEPT_CLASS_ID": "Procedure",
57 | "CONCEPT_CODE": "870533002",
58 | "CONCEPT_ID": 3655950,
59 | "CONCEPT_NAME": "Heated and humidified high flow oxygen therapy",
60 | "DOMAIN_ID": "Procedure",
61 | "INVALID_REASON": "V",
62 | "INVALID_REASON_CAPTION": "Valid",
63 | "STANDARD_CONCEPT": "S",
64 | "STANDARD_CONCEPT_CAPTION": "Standard",
65 | "VOCABULARY_ID": "SNOMED"
66 | },
67 | "isExcluded": false,
68 | "includeDescendants": false,
69 | "includeMapped": false
70 | },
71 | {
72 | "concept": {
73 | "CONCEPT_CLASS_ID": "Procedure",
74 | "CONCEPT_CODE": "428311008",
75 | "CONCEPT_ID": 4177224,
76 | "CONCEPT_NAME": "Noninvasive ventilation",
77 | "DOMAIN_ID": "Procedure",
78 | "INVALID_REASON": "V",
79 | "INVALID_REASON_CAPTION": "Valid",
80 | "STANDARD_CONCEPT": "S",
81 | "STANDARD_CONCEPT_CAPTION": "Standard",
82 | "VOCABULARY_ID": "SNOMED"
83 | },
84 | "isExcluded": false,
85 | "includeDescendants": false,
86 | "includeMapped": false
87 | },
88 | {
89 | "concept": {
90 | "CONCEPT_CLASS_ID": "Procedure",
91 | "CONCEPT_CODE": "315041000",
92 | "CONCEPT_ID": 4201025,
93 | "CONCEPT_NAME": "High concentration oxygen therapy",
94 | "DOMAIN_ID": "Procedure",
95 | "INVALID_REASON": "V",
96 | "INVALID_REASON_CAPTION": "Valid",
97 | "STANDARD_CONCEPT": "S",
98 | "STANDARD_CONCEPT_CAPTION": "Standard",
99 | "VOCABULARY_ID": "SNOMED"
100 | },
101 | "isExcluded": false,
102 | "includeDescendants": false,
103 | "includeMapped": false
104 | },
105 | {
106 | "concept": {
107 | "CONCEPT_CLASS_ID": "Procedure",
108 | "CONCEPT_CODE": "371908008",
109 | "CONCEPT_ID": 4162736,
110 | "CONCEPT_NAME": "Oxygen administration by mask",
111 | "DOMAIN_ID": "Procedure",
112 | "INVALID_REASON": "V",
113 | "INVALID_REASON_CAPTION": "Valid",
114 | "STANDARD_CONCEPT": "S",
115 | "STANDARD_CONCEPT_CAPTION": "Standard",
116 | "VOCABULARY_ID": "SNOMED"
117 | },
118 | "isExcluded": false,
119 | "includeDescendants": false,
120 | "includeMapped": false
121 | },
122 | {
123 | "concept": {
124 | "CONCEPT_CLASS_ID": "Procedure",
125 | "CONCEPT_CODE": "304577004",
126 | "CONCEPT_ID": 4119964,
127 | "CONCEPT_NAME": "Humidified oxygen therapy",
128 | "DOMAIN_ID": "Procedure",
129 | "INVALID_REASON": "V",
130 | "INVALID_REASON_CAPTION": "Valid",
131 | "STANDARD_CONCEPT": "S",
132 | "STANDARD_CONCEPT_CAPTION": "Standard",
133 | "VOCABULARY_ID": "SNOMED"
134 | },
135 | "isExcluded": false,
136 | "includeDescendants": false,
137 | "includeMapped": false
138 | },
139 | {
140 | "concept": {
141 | "CONCEPT_CLASS_ID": "Procedure",
142 | "CONCEPT_CODE": "371907003",
143 | "CONCEPT_ID": 4155151,
144 | "CONCEPT_NAME": "Oxygen administration by nasal cannula",
145 | "DOMAIN_ID": "Procedure",
146 | "INVALID_REASON": "V",
147 | "INVALID_REASON_CAPTION": "Valid",
148 | "STANDARD_CONCEPT": "S",
149 | "STANDARD_CONCEPT_CAPTION": "Standard",
150 | "VOCABULARY_ID": "SNOMED"
151 | },
152 | "isExcluded": false,
153 | "includeDescendants": false,
154 | "includeMapped": false
155 | },
156 | {
157 | "concept": {
158 | "CONCEPT_CLASS_ID": "Procedure",
159 | "CONCEPT_CODE": "71786000",
160 | "CONCEPT_ID": 4216695,
161 | "CONCEPT_NAME": "Intranasal oxygen therapy",
162 | "DOMAIN_ID": "Procedure",
163 | "INVALID_REASON": "V",
164 | "INVALID_REASON_CAPTION": "Valid",
165 | "STANDARD_CONCEPT": "S",
166 | "STANDARD_CONCEPT_CAPTION": "Standard",
167 | "VOCABULARY_ID": "SNOMED"
168 | },
169 | "isExcluded": false,
170 | "includeDescendants": false,
171 | "includeMapped": false
172 | },
173 | {
174 | "concept": {
175 | "CONCEPT_CLASS_ID": "Procedure",
176 | "CONCEPT_CODE": "240051000000102",
177 | "CONCEPT_ID": 44790731,
178 | "CONCEPT_NAME": "Oxygen administration by non rebreather mask",
179 | "DOMAIN_ID": "Procedure",
180 | "INVALID_REASON": "V",
181 | "INVALID_REASON_CAPTION": "Valid",
182 | "STANDARD_CONCEPT": "S",
183 | "STANDARD_CONCEPT_CAPTION": "Standard",
184 | "VOCABULARY_ID": "SNOMED"
185 | },
186 | "isExcluded": false,
187 | "includeDescendants": false,
188 | "includeMapped": false
189 | },
190 | {
191 | "concept": {
192 | "CONCEPT_CLASS_ID": "Procedure",
193 | "CONCEPT_CODE": "182714002",
194 | "CONCEPT_ID": 4082249,
195 | "CONCEPT_NAME": "Oxygenator therapy",
196 | "DOMAIN_ID": "Procedure",
197 | "INVALID_REASON": "V",
198 | "INVALID_REASON_CAPTION": "Valid",
199 | "STANDARD_CONCEPT": "S",
200 | "STANDARD_CONCEPT_CAPTION": "Standard",
201 | "VOCABULARY_ID": "SNOMED"
202 | },
203 | "isExcluded": false,
204 | "includeDescendants": false,
205 | "includeMapped": false
206 | },
207 | {
208 | "concept": {
209 | "CONCEPT_CLASS_ID": "Procedure",
210 | "CONCEPT_CODE": "447837008",
211 | "CONCEPT_ID": 40486624,
212 | "CONCEPT_NAME": "Noninvasive positive pressure ventilation",
213 | "DOMAIN_ID": "Procedure",
214 | "INVALID_REASON": "V",
215 | "INVALID_REASON_CAPTION": "Valid",
216 | "STANDARD_CONCEPT": "S",
217 | "STANDARD_CONCEPT_CAPTION": "Standard",
218 | "VOCABULARY_ID": "SNOMED"
219 | },
220 | "isExcluded": false,
221 | "includeDescendants": false,
222 | "includeMapped": false
223 | },
224 | {
225 | "concept": {
226 | "CONCEPT_CLASS_ID": "Procedure",
227 | "CONCEPT_CODE": "408853006",
228 | "CONCEPT_ID": 4237460,
229 | "CONCEPT_NAME": "Intermittent positive pressure ventilation via endotracheal tube",
230 | "DOMAIN_ID": "Procedure",
231 | "INVALID_REASON": "V",
232 | "INVALID_REASON_CAPTION": "Valid",
233 | "STANDARD_CONCEPT": "S",
234 | "STANDARD_CONCEPT_CAPTION": "Standard",
235 | "VOCABULARY_ID": "SNOMED"
236 | },
237 | "isExcluded": false,
238 | "includeDescendants": true,
239 | "includeMapped": false
240 | },
241 | {
242 | "concept": {
243 | "CONCEPT_CLASS_ID": "Procedure",
244 | "CONCEPT_CODE": "265764009",
245 | "CONCEPT_ID": 4146536,
246 | "CONCEPT_NAME": "Renal dialysis",
247 | "DOMAIN_ID": "Procedure",
248 | "INVALID_REASON": "V",
249 | "INVALID_REASON_CAPTION": "Valid",
250 | "STANDARD_CONCEPT": "S",
251 | "STANDARD_CONCEPT_CAPTION": "Standard",
252 | "VOCABULARY_ID": "SNOMED"
253 | },
254 | "isExcluded": false,
255 | "includeDescendants": false,
256 | "includeMapped": false
257 | },
258 | {
259 | "concept": {
260 | "CONCEPT_CLASS_ID": "Procedure",
261 | "CONCEPT_CODE": "714749008",
262 | "CONCEPT_ID": 37018292,
263 | "CONCEPT_NAME": "Continuous renal replacement therapy",
264 | "DOMAIN_ID": "Procedure",
265 | "INVALID_REASON": "V",
266 | "INVALID_REASON_CAPTION": "Valid",
267 | "STANDARD_CONCEPT": "S",
268 | "STANDARD_CONCEPT_CAPTION": "Standard",
269 | "VOCABULARY_ID": "SNOMED"
270 | },
271 | "isExcluded": false,
272 | "includeDescendants": false,
273 | "includeMapped": false
274 | },
275 | {
276 | "concept": {
277 | "CONCEPT_CLASS_ID": "Procedure",
278 | "CONCEPT_CODE": "302497006",
279 | "CONCEPT_ID": 4120120,
280 | "CONCEPT_NAME": "Hemodialysis",
281 | "DOMAIN_ID": "Procedure",
282 | "INVALID_REASON": "V",
283 | "INVALID_REASON_CAPTION": "Valid",
284 | "STANDARD_CONCEPT": "S",
285 | "STANDARD_CONCEPT_CAPTION": "Standard",
286 | "VOCABULARY_ID": "SNOMED"
287 | },
288 | "isExcluded": false,
289 | "includeDescendants": false,
290 | "includeMapped": false
291 | },
292 | {
293 | "concept": {
294 | "CONCEPT_CLASS_ID": "Procedure",
295 | "CONCEPT_CODE": "28690001000004105",
296 | "CONCEPT_ID": 3171077,
297 | "CONCEPT_NAME": "Emergent dialysis",
298 | "DOMAIN_ID": "Procedure",
299 | "INVALID_REASON": "V",
300 | "INVALID_REASON_CAPTION": "Valid",
301 | "STANDARD_CONCEPT": "S",
302 | "STANDARD_CONCEPT_CAPTION": "Standard",
303 | "VOCABULARY_ID": "Nebraska Lexicon"
304 | },
305 | "isExcluded": false,
306 | "includeDescendants": false,
307 | "includeMapped": false
308 | },
309 | {
310 | "concept": {
311 | "CONCEPT_CLASS_ID": "Procedure",
312 | "CONCEPT_CODE": "71192002",
313 | "CONCEPT_ID": 4324124,
314 | "CONCEPT_NAME": "Peritoneal dialysis",
315 | "DOMAIN_ID": "Procedure",
316 | "INVALID_REASON": "V",
317 | "INVALID_REASON_CAPTION": "Valid",
318 | "STANDARD_CONCEPT": "S",
319 | "STANDARD_CONCEPT_CAPTION": "Standard",
320 | "VOCABULARY_ID": "SNOMED"
321 | },
322 | "isExcluded": false,
323 | "includeDescendants": false,
324 | "includeMapped": false
325 | },
326 | {
327 | "concept": {
328 | "CONCEPT_CLASS_ID": "CPT4",
329 | "CONCEPT_CODE": "90937",
330 | "CONCEPT_ID": 2213573,
331 | "CONCEPT_NAME": "Hemodialysis procedure requiring repeated evaluation(s) with or without substantial revision of dialysis prescription",
332 | "DOMAIN_ID": "Procedure",
333 | "INVALID_REASON": "V",
334 | "INVALID_REASON_CAPTION": "Valid",
335 | "STANDARD_CONCEPT": "S",
336 | "STANDARD_CONCEPT_CAPTION": "Standard",
337 | "VOCABULARY_ID": "CPT4"
338 | },
339 | "isExcluded": false,
340 | "includeDescendants": false,
341 | "includeMapped": false
342 | },
343 | {
344 | "concept": {
345 | "CONCEPT_CLASS_ID": "CPT4",
346 | "CONCEPT_CODE": "90935",
347 | "CONCEPT_ID": 2213572,
348 | "CONCEPT_NAME": "Hemodialysis procedure with single evaluation by a physician or other qualified health care professional",
349 | "DOMAIN_ID": "Procedure",
350 | "INVALID_REASON": "V",
351 | "INVALID_REASON_CAPTION": "Valid",
352 | "STANDARD_CONCEPT": "S",
353 | "STANDARD_CONCEPT_CAPTION": "Standard",
354 | "VOCABULARY_ID": "CPT4"
355 | },
356 | "isExcluded": false,
357 | "includeDescendants": false,
358 | "includeMapped": false
359 | },
360 | {
361 | "concept": {
362 | "CONCEPT_CLASS_ID": "Procedure",
363 | "CONCEPT_CODE": "870533002",
364 | "CONCEPT_ID": 3655950,
365 | "CONCEPT_NAME": "Heated and humidified high flow oxygen therapy",
366 | "DOMAIN_ID": "Procedure",
367 | "INVALID_REASON": "V",
368 | "INVALID_REASON_CAPTION": "Valid",
369 | "STANDARD_CONCEPT": "S",
370 | "STANDARD_CONCEPT_CAPTION": "Standard",
371 | "VOCABULARY_ID": "SNOMED"
372 | },
373 | "isExcluded": false,
374 | "includeDescendants": false,
375 | "includeMapped": false
376 | }
377 | ]
378 | }
--------------------------------------------------------------------------------
/Cohort curation scripts/old/01_CURE_ID_Cohort_20220421.sql:
--------------------------------------------------------------------------------
1 | /*
2 | FDA CURE ID Cohort Script
3 |
4 | This script creates a cohort of covid-positive, hospitalized patients.
5 |
6 | Run this script first, then create your subsetted tables using the CURE_ID_All_Tables.sql script
7 |
8 | Will need to designate the name of your own OMOP database, and schema you want results to be loaded into.
9 | */
10 | USE [JHM_OMOP_20220203] --Change database name as appropriate
11 |
12 | --Drop all tables
13 | DROP TABLE IF EXISTS results.CURE_ID_Cohort; --Change schema as appropriate
14 | DROP TABLE IF EXISTS #covid_lab_pos;
15 | DROP TABLE IF EXISTS #first_pos;
16 | DROP TABLE IF EXISTS #dx_strong;
17 | DROP TABLE IF EXISTS #dx_weak;
18 | DROP TABLE IF EXISTS #inpat_intermed;
19 | DROP TABLE IF EXISTS #inpat;
20 | DROP TABLE IF EXISTS #inpat_closest_vis;
21 | DROP TABLE IF EXISTS #inpat_first_vis;
22 | DROP TABLE IF EXISTS #Vis_Occ;
23 |
24 | --Create cohort table (again specify schema as appropriate)
25 | CREATE TABLE [Results].[CURE_ID_Cohort] (
26 | [person_id] [int] NOT NULL, [visit_occurrence_id] [int] NOT NULL, [visit_start_date] [date] NOT NULL,
27 | [visit_end_date] [date] NOT NULL, [First_Pos_Date] [date] NULL, [Days_From_First_Pos] [int] NULL,
28 | [Abs_Days_From_First_Pos] [int] NULL, [Before_Or_After] [int] NOT NULL, [dx_strong] [int] NOT NULL,
29 | [dx_weak] [int] NOT NULL, [birth_datetime] [datetime2](7) NULL, [death_datetime] [datetime2](7) NULL
30 | ) ON [PRIMARY];
31 |
32 |
33 | --First identify patients (inpatient and outpatient) with covid positive lab results
34 | SELECT DISTINCT person_id
35 | ,measurement_date
36 | INTO #covid_lab_pos
37 | FROM dbo.MEASUREMENT
38 | WHERE measurement_concept_id IN (
39 | SELECT concept_id
40 | FROM dbo.CONCEPT
41 | -- here we look for the concepts that represent the LOINC codes for SARS-COV-2 nucleic acid test
42 | WHERE concept_id IN (
43 | '706169', '706156', '706154', '706170', '706157', '706155', '706173', '706175', '706163',
44 | '706167', '706168', '706158', '706161', '706160', '723478', '723476', '723464', '723465',
45 | '723466', '723467', '723468', '723469', '723470', '723471', '723463', '586528', '586529',
46 | '586524', '586525', '586526', '715272', '586517', '586520', '586519', '715262', '715261',
47 | '715260', '757677', '757678', '36661377', '36661378', '36661370', '36661371', '36031238',
48 | '36031213', '36031506', '36032061', '36031944', '36032174', '36031652', '36031453', '36032258'
49 | )
50 |
51 | UNION
52 |
53 | SELECT c.concept_id
54 | FROM dbo.CONCEPT c
55 | INNER JOIN dbo.CONCEPT_ANCESTOR ca ON c.concept_id = ca.descendant_concept_id
56 | -- Most of the LOINC codes do not have descendants but there is one OMOP Extension code (765055) in use that has descendants which we want to pull
57 | -- This statement pulls the descendants of that specific code
58 | AND ca.ancestor_concept_id IN (756055)
59 | AND c.invalid_reason IS NULL
60 | )
61 | -- Here we add a date restriction: after January 1, 2020
62 | AND measurement_date >= DATEFROMPARTS(2020, 01, 01)
63 | AND (
64 | -- The value_as_concept field is where we store standardized qualitative results
65 | -- The concept ids here represent LOINC or SNOMED codes for standard ways to code a lab that is positive
66 | value_as_concept_id IN (
67 | 4126681 -- Detected
68 | , 45877985 -- Detected
69 | , 45884084 -- Positive
70 | , 9191 --- Positive
71 | , 4181412 -- Present
72 | , 45879438 -- Present
73 | , 45881802 -- Reactive
74 | )
75 | -- To be exhaustive, we also look for Positive strings in the value_source_value field
76 | OR value_source_value IN ('Positive', 'Present', 'Detected', 'Reactive')
77 | );
78 |
79 | --Show counts of unique covid-positive labs (not unique patients)
80 | select count(*) "covid_positive_lab_count" from #covid_lab_pos;
81 |
82 | --First positive test per patient
83 | SELECT person_id
84 | ,min(measurement_date) "First_Pos_Date"
85 | INTO #first_pos
86 | FROM #covid_lab_pos
87 | GROUP BY person_id;
88 |
89 | --Show count of unique patients so far
90 | select count(distinct person_id) "covid_positive_lab_person_count" from #first_pos;
91 |
92 | --Phenotype Entry Criteria: visits with ONE or more of the Strong Positive diagnosis codes from the ICD-10 or SNOMED tables
93 | --Strong diagnoses are codes that indicate symptomatic COVID-19
94 | SELECT DISTINCT visit_occurrence_id
95 | INTO #dx_strong
96 | FROM dbo.CONDITION_OCCURRENCE
97 | WHERE condition_concept_id IN (
98 | SELECT concept_id
99 | FROM dbo.CONCEPT
100 | -- The list of ICD-10 codes in the Phenotype Wiki
101 | -- This is the list of standard concepts that represent those terms
102 | WHERE concept_id IN (3661405, 3661406, 3662381, 756031, 37311061, 3663281, 3661408, 756039, 320651
103 | )
104 | )
105 |
106 | UNION
107 |
108 | SELECT DISTINCT visit_occurrence_id
109 | FROM dbo.CONDITION_OCCURRENCE
110 | WHERE condition_concept_id IN (
111 | SELECT concept_id
112 | FROM dbo.CONCEPT
113 | -- The list of ICD-10 codes in the Phenotype Wiki were translated into OMOP standard concepts
114 | -- This is the list of standard concepts that represent those terms
115 | WHERE concept_id IN (37311061, 3661405, 756031, 756039, 3661406, 3662381, 3663281, 3661408)
116 |
117 | UNION
118 |
119 | SELECT c.concept_id
120 | FROM dbo.CONCEPT c
121 | INNER JOIN dbo.CONCEPT_ANCESTOR ca ON c.concept_id = ca.descendant_concept_id
122 | -- Here we pull the descendants (aka terms that are more specific than the concepts selected above)
123 | AND ca.ancestor_concept_id IN (
124 | 3661406, 3661408, 37310283, 3662381, 3663281, 37310287, 3661405, 756031, 37310286, 37311061,
125 | 37310284, 756039, 37310254
126 | )
127 | AND c.invalid_reason IS NULL
128 | )
129 | AND condition_start_date >= DATEFROMPARTS(2020, 04, 01);
130 |
131 | --number of encounters with strong diagnoses
132 | select count(*) "covid_enc_strong_count" from #dx_strong;
133 |
134 | --Phenotype Entry Criteria: visits with ONE or more of the Weak diagnosis codes from the ICD-10 or SNOMED tables
135 | --weak diagnoses are codes that indicate symptoms such as fever and cough that, in combination with a positive SARS-COV-2 test, indicate symptomatic covid
136 | SELECT DISTINCT visit_occurrence_id
137 | INTO #dx_weak
138 | FROM (
139 | SELECT visit_occurrence_id
140 | FROM dbo.CONDITION_OCCURRENCE
141 | WHERE condition_concept_id IN (
142 | SELECT concept_id
143 | FROM dbo.CONCEPT
144 | -- The list of ICD-10 codes in the Phenotype Wiki (https://github.com/National-COVID-Cohort-Collaborative/Phenotype_Data_Acquisition/wiki/Latest-Phenotype) were translated into OMOP standard concepts
145 | -- It also includes the OMOP only codes that are on the Phenotype Wiki
146 | -- This is the list of standard concepts that represent those terms
147 | WHERE
148 | --N3C Before 4/1/2020
149 | concept_id IN (
150 | 260125, 260139, 46271075, 4307774, 4195694, 257011, 442555, 4059022, 4059021, 256451,
151 | 4059003, 4168213, 434490, 439676, 254761, 4048098, 37311061, 4100065, 320136, 4038519,
152 | 312437, 4060052, 4263848, 37311059, 37016200, 4011766, 437663, 4141062, 4164645, 4047610,
153 | 4260205, 4185711, 4289517, 4140453, 4090569, 4109381, 4330445, 255848, 4102774, 436235,
154 | 261326, 436145, 40482061, 439857, 254677, 40479642, 256722, 4133224, 4310964, 4051332,
155 | 4112521, 4110484, 4112015, 4110023, 4112359, 4110483, 4110485, 254058, 40482069, 4256228,
156 | 37016114, 46273719, 312940, 36716978, 37395564, 4140438, 46271074, 319049, 314971, 320651
157 | )
158 | --N3C After 4/1/2020
159 | or concept_id IN (
160 | 260125, 260139, 46271075, 4307774, 4195694, 257011, 442555, 4059022, 4059021, 256451,
161 | 4059003, 4168213, 434490, 439676, 254761, 4048098, 37311061, 4100065, 320136, 4038519,
162 | 312437, 4060052, 4263848, 37311059, 37016200, 4011766, 437663, 4141062, 4164645, 4047610,
163 | 4260205, 4185711, 4289517, 4140453, 4090569, 4109381, 4330445, 255848, 4102774, 436235,
164 | 261326, 320651
165 | )
166 | )
167 | AND condition_start_date >= DATEFROMPARTS(2020, 04, 01)
168 | GROUP BY person_id
169 | ,visit_occurrence_id
170 | ) dx_same_encounter
171 |
172 | --number of encounters with weak diagnoses (independent of Covid testing status)
173 | select count(*) "covid_weak_enc_count" from #dx_weak;
174 |
175 | --Covid-positive patients with inpatient encounters (intermediate table for debugging)
176 | SELECT v.person_id
177 | ,v.visit_occurrence_id
178 | ,visit_start_date
179 | ,visit_end_date
180 | ,p.First_Pos_Date
181 | ,DATEDIFF(day, p.First_Pos_Date, v.visit_start_date) "Days_From_First_Pos"
182 | ,ABS(DATEDIFF(day, p.First_Pos_Date, v.visit_start_date)) "Abs_Days_From_First_Pos"
183 | INTO #inpat_intermed
184 | FROM visit_occurrence v
185 | INNER JOIN #first_pos p ON v.person_id = p.person_id
186 | WHERE visit_concept_id = 9201; --Inpatient visit
187 |
188 | --Intermediate count of Covid-positive patients with inpatient encounters
189 | select count(distinct person_id) "covid_pos_inpatients_count" from #inpat_intermed;
190 |
191 | --Count of patients after temporal constraints applied
192 | Select count(distinct person_id) "covid_pos_inpatients_date_filtered_count"
193 | from #inpat_intermed
194 | WHERE visit_start_date >= '2020-01-01'
195 | AND (
196 | DATEDIFF(day, First_Pos_Date, visit_start_date) > - 7
197 | AND DATEDIFF(day, First_Pos_Date, visit_start_date) < 21
198 | )
199 |
200 | --Apply all incl/excl criteria to identify all patients hospitalized with symptomatic covid-19 up to 21 days after a positive SARS-CoV-2 test or up to 7 days prior to a positive SARS-CoV-2 test
201 | SELECT v.person_id
202 | ,v.visit_occurrence_id
203 | ,visit_start_date
204 | ,visit_end_date
205 | ,p.First_Pos_Date
206 | ,DATEDIFF(day, p.First_Pos_Date, v.visit_start_date) "Days_From_First_Pos"
207 | ,ABS(DATEDIFF(day, p.First_Pos_Date, v.visit_start_date)) "Abs_Days_From_First_Pos"
208 | ,CASE
209 | WHEN DATEDIFF(day, p.First_Pos_Date, v.visit_start_date) < 0
210 | THEN - 1
211 | ELSE 1
212 | END AS Before_Or_After
213 | ,CASE
214 | WHEN #dx_strong.visit_occurrence_id IS NOT NULL
215 | THEN 1
216 | ELSE 0
217 | END AS dx_strong
218 | ,CASE
219 | WHEN #dx_weak.visit_occurrence_id IS NOT NULL
220 | THEN 1
221 | ELSE 0
222 | END AS dx_weak
223 | INTO #inpat
224 | FROM visit_occurrence v
225 | INNER JOIN #first_pos p ON v.person_id = p.person_id
226 | LEFT JOIN #dx_strong ON v.visit_occurrence_id = #dx_strong.visit_occurrence_id
227 | LEFT JOIN #dx_weak ON v.visit_occurrence_id = #dx_weak.visit_occurrence_id
228 | WHERE visit_concept_id = 9201 --Inpatient visit
229 | AND v.visit_start_date >= '2020-01-01'
230 | AND (
231 | DATEDIFF(day, p.First_Pos_Date, v.visit_start_date) > - 7
232 | AND DATEDIFF(day, p.First_Pos_Date, v.visit_start_date) < 21
233 | )
234 | AND (
235 | #dx_strong.visit_occurrence_id IS NOT NULL
236 | OR #dx_weak.visit_occurrence_id IS NOT NULL
237 | );
238 |
239 | --Count of patients and encounters that meet the criteria
240 | select count(distinct person_id) "covid_pos_inpatients",
241 | count(distinct visit_occurrence_id) "covid_pos_inpatient_visits"
242 | from #inpat;
243 |
244 | --Finds closest encounter to first positive SARS-COV-2 test (for patients hospitalized more than once)
245 | SELECT person_id
246 | ,min(Abs_Days_From_First_Pos) "Closest_Vis"
247 | INTO #inpat_closest_vis
248 | FROM #inpat
249 | GROUP BY person_id;
250 |
251 | --Account for edge cases where patients have two hospitalizations same number of absolute days from SARS-COV-2 test
252 | --Ex: Patient hospitalized separately 3 days before and 3 days after SARS-COV-2 test
253 | SELECT i.person_id
254 | ,max(Before_Or_After) "Flag"
255 | INTO #inpat_first_vis
256 | FROM #inpat i
257 | INNER JOIN #inpat_closest_vis v ON i.person_id = v.person_id
258 | AND i.Abs_Days_From_First_Pos = v.Closest_Vis
259 | GROUP BY i.person_id;
260 |
261 | --Applies previous two criteria
262 | SELECT DISTINCT i.* --, c.Closest_Vis, v.Flag
263 | INTO #Vis_Occ
264 | FROM #inpat i
265 | INNER JOIN #inpat_closest_vis c ON i.person_id = c.person_id
266 | AND i.Abs_Days_From_First_Pos = c.Closest_Vis
267 | INNER JOIN #inpat_first_vis v ON i.person_id = v.person_id
268 | AND i.Before_Or_After = v.Flag;
269 |
270 | --Creates cohort by adding on birth date and death date
271 | INSERT INTO [Results].[CURE_ID_Cohort] --Change schema if not using Results
272 | (
273 | [person_id], [visit_occurrence_id], [visit_start_date], [visit_end_date], [First_Pos_Date],
274 | [Days_From_First_Pos], [Abs_Days_From_First_Pos], [Before_Or_After], [dx_strong], [dx_weak],
275 | [birth_datetime], [death_datetime]
276 | )
277 | SELECT v.*, p.birth_datetime, d.death_datetime
278 | FROM #Vis_Occ v
279 | INNER JOIN person p ON v.person_id = p.person_id
280 | LEFT JOIN death d ON v.person_id = d.person_id;
281 |
282 | --Fianl count of patients
283 | Select count(distinct person_id) "Final_patient_count" from #Vis_Occ;
284 |
285 | --View data
286 | SELECT TOP 100 *
287 | FROM Results.CURE_ID_Cohort
--------------------------------------------------------------------------------