Skip to content

Commit

Permalink
Merge pull request #348 from coderxio/jrlegrand/synonyms
Browse files Browse the repository at this point in the history
Jrlegrand/synonyms
  • Loading branch information
jrlegrand authored Jan 16, 2025
2 parents 5c1a981 + cdf56b5 commit ba12771
Show file tree
Hide file tree
Showing 2 changed files with 114 additions and 3 deletions.
89 changes: 89 additions & 0 deletions dbt/sagerx/models/marts/products/product_synonyms.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,89 @@
with

rxnorm_synonyms as (

select
str as synonym,
rxcui as product_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,
'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,
'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.rxcui = all_synonyms.product_rxcui
where rxnorm_products.prescribable = true

)

select * from prescribable_product_synonyms
28 changes: 25 additions & 3 deletions dbt/sagerx/models/marts/products/products.sql
Original file line number Diff line number Diff line change
@@ -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'
Expand All @@ -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

0 comments on commit ba12771

Please sign in to comment.