From 5e5ba9688733962a294a9d8e12082c1f8a157f3d Mon Sep 17 00:00:00 2001 From: Coco Zuloaga <85512182+cocozuloaga@users.noreply.github.com> Date: Thu, 25 Apr 2024 15:47:05 -0600 Subject: [PATCH] Tuva CC new (#447) * Tuva CC new * reverted test_date_override to default (false) * fixing bq error and escaping apostrophe --------- Co-authored-by: thutuva <101137626+thutuva@users.noreply.github.com> --- ...nditions__tuva_chronic_conditions_long.sql | 79 +--- ...nditions__tuva_chronic_conditions_wide.sql | 440 ++++++++++++++++-- .../clinical_concept_library_models.yml | 27 ++ .../value_set_member_relevant_fields.sql | 32 ++ .../clinical_concept_library_seeds.yml | 7 +- 5 files changed, 500 insertions(+), 85 deletions(-) create mode 100644 models/clinical_concept_library/clinical_concept_library_models.yml create mode 100644 models/clinical_concept_library/value_set_member_relevant_fields.sql diff --git a/models/chronic_conditions/final/chronic_conditions__tuva_chronic_conditions_long.sql b/models/chronic_conditions/final/chronic_conditions__tuva_chronic_conditions_long.sql index d6449c8d..c449513a 100644 --- a/models/chronic_conditions/final/chronic_conditions__tuva_chronic_conditions_long.sql +++ b/models/chronic_conditions/final/chronic_conditions__tuva_chronic_conditions_long.sql @@ -3,63 +3,34 @@ ) }} -with condition_row_number as ( - - select - patient_id - , normalized_code - , recorded_date - , row_number() over( - partition by - patient_id - , normalized_code - order by recorded_date asc - ) as rn_asc - , row_number() over( - partition by - patient_id - , normalized_code - order by recorded_date desc - ) as rn_desc +with all_conditions as ( +select + patient_id, + normalized_code, + recorded_date from {{ ref('tuva_chronic_conditions__stg_core__condition') }} +), -) - -, patient_conditions as ( - select - patient_id - , normalized_code as icd_10_cm - , max( - case - when rn_asc = 1 - then recorded_date - end - ) as first_diagnosis_date - , max( - case - when rn_desc = 1 - then recorded_date - end - ) as last_diagnosis_date - from condition_row_number - group by - patient_id - , normalized_code +conditions_with_first_and_last_diagnosis_date as ( +select + patient_id, + normalized_code as icd_10_cm, + min(recorded_date) as first_diagnosis_date, + max(recorded_date) as last_diagnosis_date +from all_conditions +group by patient_id, normalized_code ) -select - pc.patient_id - , h.condition_family - , h.condition - , min(first_diagnosis_date) as first_diagnosis_date - , max(last_diagnosis_date) as last_diagnosis_date - , '{{ var('tuva_last_run')}}' as tuva_last_run -from {{ ref('chronic_conditions__tuva_chronic_conditions_hierarchy') }} h - inner join patient_conditions pc - on h.icd_10_cm_code = pc.icd_10_cm -group by - pc.patient_id - , h.condition_family - , h.condition \ No newline at end of file + +select + aa.patient_id, + bb.concept_name as condition, + min(first_diagnosis_date) as first_diagnosis_date, + max(last_diagnosis_date) as last_diagnosis_date, + '{{ var('tuva_last_run')}}' as tuva_last_run +from conditions_with_first_and_last_diagnosis_date aa +inner join {{ ref('value_set_member_relevant_fields') }} bb +on aa.icd_10_cm = bb.code +group by aa.patient_id, bb.concept_name diff --git a/models/chronic_conditions/final/chronic_conditions__tuva_chronic_conditions_wide.sql b/models/chronic_conditions/final/chronic_conditions__tuva_chronic_conditions_wide.sql index ed5eac93..19ed497f 100644 --- a/models/chronic_conditions/final/chronic_conditions__tuva_chronic_conditions_wide.sql +++ b/models/chronic_conditions/final/chronic_conditions__tuva_chronic_conditions_wide.sql @@ -3,34 +3,422 @@ ) }} -with condition_columns as ( +with patients as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +), - select distinct - condition - , condition_column_name - from {{ ref('chronic_conditions__tuva_chronic_conditions_hierarchy') }} +obesity as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Obesity' +), + +osteoarthritis as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Osteoarthritis' +), + +copd as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Chronic Obstructive Pulmonary Disease' +), + +anxiety_disorders as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Anxiety Disorders' +), + +ckd as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Chronic Kidney Disease' +), + +t2d as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Type 2 Diabetes Mellitus' +), + +cll as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Chronic Lymphocytic Leukemia' +), + +dysplipidemias as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Dyslipidemias' +), + +hypertension as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Hypertension' +), + +atherosclerosis as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Atherosclerosis' +), + +dementia as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Dementia' +), + +rheumatoid_arthritis as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Rheumatoid Arthritis' +), + +celiac as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Celiac Disease' +), + +hip_fracture as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Hip Fracture' +), + +immunodeficiencies_and_white_blood_cell_disorders as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Specified Immunodeficiencies and White Blood Cell Disorders (HCC v28 concept #115)' +), + +asthma as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Asthma' +), + +t1d as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Type 1 Diabetes Mellitus' +), + +ulcerative_colitis as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Ulcerative colitis' +), + +chrohns as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Chrohn\'s Disease' +), + +holicobacter as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Helicobacter pylori Infection' +), + +bipolar as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Bipolar Affective Disorder' +), + +heart_failure as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Heart Failure' +), + +tabacco as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Tobacco Use' +), + +lyme as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Lyme Disease' +), + +breast_cancer as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Breast Cancer' +), + +osteoporosis as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Osteoporosis' +), + +pulmonary_embolism as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Pulmonary Embolism, Thrombotic or Unspecified' +), + +schizophrenia as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Schizophrenia' +), + +atrial_fibrillation as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Atrial Fibrillation' +), + +colorectal_cancer as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Colorectal Cancer' +), + +depression as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Major Depressive Disorder' +), + +deep_vein_thrombosis as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Deep Vein Thrombosis of Extremities or Central Veins' +), + +alzheimer as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Alzheimer Disease' +), + +stroke as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Stroke' +), + +myocardial_infraction as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Myocardial Infarction' +), + +opiod_use_disorder as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Opioid Use Disorder' +), + +lung_cancer as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Lung cancer, primary or unspecified' +), + +herpes as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Herpes Simplex Infection' +), + +rickettsiosis as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Rickettsiosis' +), + +ms as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Multiple Sclerosis' +), + +alchohol as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Alcohol Use Disorder' +), + +adhd as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Attention Deficit-Hyperactivity Disorder' +), + +hiv as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'HIV/AIDS (HCC v28 concept #1)' +), + +ptsd as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Post-Traumatic Stress Disorder' +), + +lupus as ( +select distinct patient_id +from {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} +where condition = 'Systemic Lupus Erythematosus' ) + + + select - p.patient_id - , {{ dbt_utils.pivot( - column='cc.condition_column_name' - , values=dbt_utils.get_column_values( - ref('chronic_conditions__tuva_chronic_conditions_hierarchy') - , 'condition_column_name' - ,'condition_column_name' - ) - , agg='max' - , then_value= 1 - , else_value= 0 - , quote_identifiers = False - ) }} - , '{{ var('tuva_last_run')}}' as tuva_last_run -from {{ ref('tuva_chronic_conditions__stg_core__patient') }} p - left join {{ ref('chronic_conditions__tuva_chronic_conditions_long') }} l - on p.patient_id = l.patient_id - left join condition_columns cc - on l.condition = cc.condition -group by - p.patient_id \ No newline at end of file + patient_id, + case when patient_id in (select * from obesity) then 1 + else 0 + end as obesity, + case when patient_id in (select * from osteoarthritis) then 1 + else 0 + end as osteoarthritis, + case when patient_id in (select * from copd) then 1 + else 0 + end as copd, + case when patient_id in (select * from anxiety_disorders) then 1 + else 0 + end as anxiety_disorders, + case when patient_id in (select * from ckd) then 1 + else 0 + end as ckd, + case when patient_id in (select * from t2d) then 1 + else 0 + end as t2d, + case when patient_id in (select * from cll) then 1 + else 0 + end as cll, + case when patient_id in (select * from dysplipidemias) then 1 + else 0 + end as dysplipidemias, + case when patient_id in (select * from hypertension) then 1 + else 0 + end as hypertension, + case when patient_id in (select * from atherosclerosis) then 1 + else 0 + end as atherosclerosis, + case when patient_id in (select * from dementia) then 1 + else 0 + end as dementia, + case when patient_id in (select * from rheumatoid_arthritis) then 1 + else 0 + end as rheumatoid_arthritis, + case when patient_id in (select * from celiac) then 1 + else 0 + end as celiac, + case when patient_id in (select * from hip_fracture) then 1 + else 0 + end as hip_fracture, + case when patient_id in (select * from immunodeficiencies_and_white_blood_cell_disorders) then 1 + else 0 + end as immunodeficiencies_and_white_blood_cell_disorders, + case when patient_id in (select * from asthma) then 1 + else 0 + end as asthma, + case when patient_id in (select * from t1d) then 1 + else 0 + end as t1d, + case when patient_id in (select * from ulcerative_colitis) then 1 + else 0 + end as ulcerative_colitis, + case when patient_id in (select * from chrohns) then 1 + else 0 + end as chrohns, + case when patient_id in (select * from holicobacter) then 1 + else 0 + end as holicobacter, + case when patient_id in (select * from bipolar) then 1 + else 0 + end as bipolar, + case when patient_id in (select * from heart_failure) then 1 + else 0 + end as heart_failure, + case when patient_id in (select * from tabacco) then 1 + else 0 + end as tabacco, + case when patient_id in (select * from lyme) then 1 + else 0 + end as lyme, + case when patient_id in (select * from breast_cancer) then 1 + else 0 + end as breast_cancer, + case when patient_id in (select * from osteoporosis) then 1 + else 0 + end as osteoporosis, + case when patient_id in (select * from pulmonary_embolism) then 1 + else 0 + end as pulmonary_embolism, + case when patient_id in (select * from schizophrenia) then 1 + else 0 + end as schizophrenia, + case when patient_id in (select * from atrial_fibrillation) then 1 + else 0 + end as atrial_fibrillation, + case when patient_id in (select * from colorectal_cancer) then 1 + else 0 + end as colorectal_cancer, + case when patient_id in (select * from depression) then 1 + else 0 + end as depression, + case when patient_id in (select * from deep_vein_thrombosis) then 1 + else 0 + end as deep_vein_thrombosis, + case when patient_id in (select * from alzheimer) then 1 + else 0 + end as alzheimer, + case when patient_id in (select * from stroke) then 1 + else 0 + end as stroke, + case when patient_id in (select * from myocardial_infraction) then 1 + else 0 + end as myocardial_infraction, + case when patient_id in (select * from opiod_use_disorder) then 1 + else 0 + end as opiod_use_disorder, + case when patient_id in (select * from lung_cancer) then 1 + else 0 + end as lung_cancer, + case when patient_id in (select * from herpes) then 1 + else 0 + end as herpes, + case when patient_id in (select * from rickettsiosis) then 1 + else 0 + end as rickettsiosis, + case when patient_id in (select * from ms) then 1 + else 0 + end as ms, + case when patient_id in (select * from alchohol) then 1 + else 0 + end as alchohol, + case when patient_id in (select * from adhd) then 1 + else 0 + end as adhd, + case when patient_id in (select * from hiv) then 1 + else 0 + end as hiv, + case when patient_id in (select * from ptsd) then 1 + else 0 + end as ptsd, + case when patient_id in (select * from lupus) then 1 + else 0 + end as lupus, + '{{ var('tuva_last_run')}}' as tuva_last_run + +from patients diff --git a/models/clinical_concept_library/clinical_concept_library_models.yml b/models/clinical_concept_library/clinical_concept_library_models.yml new file mode 100644 index 00000000..f4d70739 --- /dev/null +++ b/models/clinical_concept_library/clinical_concept_library_models.yml @@ -0,0 +1,27 @@ +version: 2 + +models: + + - name: value_set_member_relevant_fields + description: > + This model creates one record per value set member, but it includes + relevant fields for each value set member taken from the clnical_concepts + and coding_systems tables. + config: + schema: | + {%- if var('tuva_schema_prefix',None) != None -%}{{var('tuva_schema_prefix')}}_clinical_concept_library + {% else %}clinical_concept_library{%- endif -%} + alias: value_set_member_relevant_fields + tags: + - clinical_concept_library + materialized: table + columns: + - name: concept_id + - name: concept_name + - name: concept_type + - name: value_set_member_id + - name: code + - name: coding_system_id + - name: include_descendants + - name: coding_system_name + diff --git a/models/clinical_concept_library/value_set_member_relevant_fields.sql b/models/clinical_concept_library/value_set_member_relevant_fields.sql new file mode 100644 index 00000000..e92ee24d --- /dev/null +++ b/models/clinical_concept_library/value_set_member_relevant_fields.sql @@ -0,0 +1,32 @@ + + + +with value_set_member_relevant_fields as ( +select + aa.concept_id, + aa.concept_name, + aa.concept_type, + + bb.value_set_member_id, + bb.code, + bb.coding_system_id, + bb.include_descendants, + + cc.coding_system_name + +from {{ ref('clinical_concepts') }} aa + +left join {{ ref('value_set_members') }} bb +on aa.concept_id = bb.concept_id + +left join {{ ref('coding_systems') }} cc +on bb.coding_system_id = cc.coding_system_id +) + + +select * +from value_set_member_relevant_fields + + + + diff --git a/seeds/value_sets/clinical_concept_library/clinical_concept_library_seeds.yml b/seeds/value_sets/clinical_concept_library/clinical_concept_library_seeds.yml index 04b9d39c..d47bda15 100644 --- a/seeds/value_sets/clinical_concept_library/clinical_concept_library_seeds.yml +++ b/seeds/value_sets/clinical_concept_library/clinical_concept_library_seeds.yml @@ -7,7 +7,6 @@ seeds: {%- if var('tuva_schema_prefix',None) != None -%}{{var('tuva_schema_prefix')}}_clinical_concept_library{% else %}clinical_concept_library{%- endif -%} alias: clinical_concepts tags: clinical_concept_library - quote_columns: true column_types: concept_id: | {%- if target.type in ("bigquery", "databricks") -%} string {%- else -%} varchar {%- endif -%} @@ -17,8 +16,7 @@ seeds: {%- if target.type in ("bigquery", "databricks") -%} string {%- else -%} varchar {%- endif -%} concept_oid: | {%- if target.type in ("bigquery", "databricks") -%} string {%- else -%} varchar {%- endif -%} - last_update_date: | - {%- if target.type in ("bigquery", "databricks") -%} string {%- else -%} varchar {%- endif -%} + last_update_date: date last_update_note: | {%- if target.type in ("bigquery", "databricks") -%} string {%- else -%} varchar {%- endif -%} concept_type: | @@ -54,8 +52,7 @@ seeds: {%- if target.type in ("bigquery", "databricks") -%} string {%- else -%} varchar {%- endif -%} status: | {%- if target.type in ("bigquery", "databricks") -%} string {%- else -%} varchar {%- endif -%} - last_update_date: | - {%- if target.type in ("bigquery", "databricks") -%} string {%- else -%} varchar {%- endif -%} + last_update_date: date last_update_note: | {%- if target.type in ("bigquery", "databricks") -%} string {%- else -%} varchar {%- endif -%} code: |