From 7696552a916bfaaa1b4a2d6bcc30dd1540484abb Mon Sep 17 00:00:00 2001 From: Joey LeGrand Date: Mon, 16 Sep 2024 21:28:55 +0000 Subject: [PATCH 1/2] Add synonyms mart --- .../marts/products/product_synonyms.sql | 89 +++++++++++++++++++ 1 file changed, 89 insertions(+) create mode 100644 dbt/sagerx/models/marts/products/product_synonyms.sql diff --git a/dbt/sagerx/models/marts/products/product_synonyms.sql b/dbt/sagerx/models/marts/products/product_synonyms.sql new file mode 100644 index 0000000..25cd86d --- /dev/null +++ b/dbt/sagerx/models/marts/products/product_synonyms.sql @@ -0,0 +1,89 @@ +with + +rxnorm_synonyms as ( + + select + str as synonym, + rxcui, + 'RXNORM' as source + from {{ source('rxnorm', 'rxnorm_rxnconso') }} + where sab = 'RXNORM' + and tty in('PSN', 'SY', 'TMSY', 'ET') + +), + +nadac_synonyms as ( + + select distinct + ndc_description as synonym, + product_rxcui as rxcui, + 'NADAC' as source + from {{ source('nadac', 'nadac') }} n + left join {{ ref('int_rxnorm_ndcs_to_products') }} r + on r.ndc = n.ndc + where r.product_rxcui is not null + +), + +fda_synonyms as ( + + select distinct + trim(concat( + nonproprietaryname + , ' ' + , active_numerator_strength + , ' ' + , active_ingred_unit + , ' ' + , lower(dosageformname) + , case when proprietaryname is not null then concat( + ' [' + , proprietaryname + , case when proprietarynamesuffix is not null then concat( + ' ' + , proprietarynamesuffix + ) else '' end + , ']' + ) else '' end + )) as synonym, + product_rxcui as rxcui, + 'FDA' as source + from sagerx_dev.stg_fda_ndc__ndcs f + left join sagerx_dev.int_rxnorm_ndcs_to_products r + on r.ndc = f.ndc11 + where r.product_rxcui is not null + +), + +all_synonyms as ( + + select * from rxnorm_synonyms + + union + + select * from nadac_synonyms + + union + + select * from fda_synonyms + +), + +rxnorm_products as ( + + select * from {{ ref('stg_rxnorm__products') }} + +), + +prescribable_product_synonyms as ( + + select + all_synonyms.* + from all_synonyms + inner join rxnorm_products + on rxnorm_products.product_rxcui = all_synonyms.rxcui + where rxnorm_products.prescribable = true + +) + +select * from prescribable_product_synonyms From fbb06a58ff2346a864c6b57b796ce33be86be360 Mon Sep 17 00:00:00 2001 From: Joey LeGrand Date: Tue, 17 Sep 2024 02:16:25 +0000 Subject: [PATCH 2/2] Adding products to image NDCs --- .../models/marts/ndc/ndcs_to_label_images.sql | 56 ++++++++++++++++--- .../marts/products/product_synonyms.sql | 8 +-- dbt/sagerx/models/marts/products/products.sql | 28 +++++++++- 3 files changed, 76 insertions(+), 16 deletions(-) diff --git a/dbt/sagerx/models/marts/ndc/ndcs_to_label_images.sql b/dbt/sagerx/models/marts/ndc/ndcs_to_label_images.sql index 40c3248..c579c4c 100644 --- a/dbt/sagerx/models/marts/ndc/ndcs_to_label_images.sql +++ b/dbt/sagerx/models/marts/ndc/ndcs_to_label_images.sql @@ -1,9 +1,47 @@ -select - img.set_id, - ndc.ndc, - img.image -from sagerx_dev.int_dailymed_ranked_package_label_images img -left join sagerx_dev.int_dailymed_ranked_package_label_ndcs ndc - on ndc.package_label_section_id = img.package_label_section_id - and ndc.rn = img.rn -where ndc.ndc is not null +with + +images as ( + + select * from {{ ref('int_dailymed_ranked_package_label_images') }} +), + +ndcs as ( + + select * from {{ ref('int_dailymed_ranked_package_label_ndcs') }} +), + +ndcs_to_products as ( + + select * from {{ ref('int_rxnorm_ndcs_to_products') }} + +), + +ndcs_to_label_images as ( + + select + img.set_id, + ndc.ndc, + {{ ndc_to_11('ndc.ndc') }} as ndc11, + img.image, + concat('https://dailymed.nlm.nih.gov/dailymed/image.cfm?name=', img.image, '&setid=', img.set_id, '&type=img') as image_url, + concat('https://dailymed.nlm.nih.gov/dailymed/drugInfo.cfm?setid=', img.set_id) as spl_url + from images img + left join ndcs ndc + on ndc.package_label_section_id = img.package_label_section_id + and ndc.rn = img.rn + where ndc.ndc is not null + +), + +ndcs_to_label_images_with_product_rxcuis as ( + + select + ndcs_to_label_images.*, + ndcs_to_products.product_rxcui + from ndcs_to_label_images + inner join ndcs_to_products + on ndcs_to_products.ndc = ndcs_to_label_images.ndc11 + +) + +select * from ndcs_to_label_images_with_product_rxcuis \ No newline at end of file diff --git a/dbt/sagerx/models/marts/products/product_synonyms.sql b/dbt/sagerx/models/marts/products/product_synonyms.sql index 25cd86d..bcf1d35 100644 --- a/dbt/sagerx/models/marts/products/product_synonyms.sql +++ b/dbt/sagerx/models/marts/products/product_synonyms.sql @@ -4,7 +4,7 @@ rxnorm_synonyms as ( select str as synonym, - rxcui, + rxcui as product_rxcui, 'RXNORM' as source from {{ source('rxnorm', 'rxnorm_rxnconso') }} where sab = 'RXNORM' @@ -16,7 +16,7 @@ nadac_synonyms as ( select distinct ndc_description as synonym, - product_rxcui as rxcui, + product_rxcui, 'NADAC' as source from {{ source('nadac', 'nadac') }} n left join {{ ref('int_rxnorm_ndcs_to_products') }} r @@ -46,7 +46,7 @@ fda_synonyms as ( , ']' ) else '' end )) as synonym, - product_rxcui as rxcui, + product_rxcui, 'FDA' as source from sagerx_dev.stg_fda_ndc__ndcs f left join sagerx_dev.int_rxnorm_ndcs_to_products r @@ -81,7 +81,7 @@ prescribable_product_synonyms as ( all_synonyms.* from all_synonyms inner join rxnorm_products - on rxnorm_products.product_rxcui = all_synonyms.rxcui + on rxnorm_products.rxcui = all_synonyms.product_rxcui where rxnorm_products.prescribable = true ) diff --git a/dbt/sagerx/models/marts/products/products.sql b/dbt/sagerx/models/marts/products/products.sql index 97134bb..0c983ea 100644 --- a/dbt/sagerx/models/marts/products/products.sql +++ b/dbt/sagerx/models/marts/products/products.sql @@ -1,15 +1,33 @@ -with rxnorm_products as ( +with + +rxnorm_products as ( + select * from {{ ref('stg_rxnorm__products') }} -) -, rxnorm_clinical_products_to_ingredients as ( +), + +rxnorm_psn as ( + + select + rxcui, + str + from {{ source('rxnorm', 'rxnorm_rxnconso') }} + where sab = 'RXNORM' + and tty = 'PSN' + +), + +rxnorm_clinical_products_to_ingredients as ( + select * from {{ ref('int_rxnorm_clinical_products_to_ingredients') }} + ) select prod.rxcui as product_rxcui , prod.name as product_name , prod.tty as product_tty + , psn.str as prescribable_name , case when prod.tty in ('SBD', 'BPCK') then 'brand' when prod.tty in ('SCD', 'GPCK') then 'generic' @@ -21,6 +39,10 @@ select , cping.ingredient_name -- strength - couldn't easily get strength at this grain - can if needed , cping.dose_form_name + , prod.active + , prod.prescribable from rxnorm_products prod left join rxnorm_clinical_products_to_ingredients cping on cping.clinical_product_rxcui = prod.clinical_product_rxcui +left join rxnorm_psn psn + on psn.rxcui = prod.rxcui