Skip to content

Commit

Permalink
Service category bug 208 (#210)
Browse files Browse the repository at this point in the history
* adding logic to dedupe service categories

* updated docs

* updated version
  • Loading branch information
thutuva authored Sep 20, 2023
1 parent 50118ab commit 075c800
Show file tree
Hide file tree
Showing 5 changed files with 109 additions and 69 deletions.
2 changes: 1 addition & 1 deletion dbt_project.yml
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
name: 'the_tuva_project'
version: '0.5.2'
version: '0.5.3'
config-version: 2
require-dbt-version: ">=1.3.0"

Expand Down
2 changes: 1 addition & 1 deletion docs/catalog.json

Large diffs are not rendered by default.

2 changes: 1 addition & 1 deletion docs/manifest.json

Large diffs are not rendered by default.

2 changes: 1 addition & 1 deletion docs/run_results.json

Large diffs are not rendered by default.

Original file line number Diff line number Diff line change
Expand Up @@ -2,71 +2,111 @@
enabled = var('claims_preprocessing_enabled',var('claims_enabled',var('tuva_marts_enabled',False)))
)
}}
with service_category_1_mapping as(
select distinct
a.claim_id
, a.claim_line_number
, a.claim_type
, case
when service_category_2 = 'Acute Inpatient' then 'Inpatient'
when service_category_2 = 'Ambulance' then 'Ancillary'
when service_category_2 = 'Ambulatory Surgery' then 'Outpatient'
when service_category_2 = 'Dialysis' then 'Outpatient'
when service_category_2 = 'Durable Medical Equipment' then 'Ancillary'
when service_category_2 = 'Emergency Department' then 'Outpatient'
when service_category_2 = 'Home Health' then 'Outpatient'
when service_category_2 = 'Hospice' then 'Outpatient'
when service_category_2 = 'Inpatient Psychiatric' then 'Inpatient'
when service_category_2 = 'Inpatient Rehabilitation' then 'Inpatient'
when service_category_2 = 'Lab' then 'Ancillary'
when service_category_2 = 'Office Visit' then 'Office Visit'
when service_category_2 = 'Outpatient Hospital or Clinic' then 'Outpatient'
when service_category_2 = 'Outpatient Psychiatric' then 'Outpatient'
when service_category_2 = 'Outpatient Rehabilitation' then 'Outpatient'
when service_category_2 = 'Skilled Nursing' then 'Inpatient'
when service_category_2 = 'Urgent Care' then 'Outpatient'
when service_category_2 is null then 'Other'
end service_category_1
, case
when service_category_2 is null then 'Other'
else service_category_2
end service_category_2
, '{{ var('tuva_last_run')}}' as tuva_last_run
from {{ ref('service_category__stg_medical_claim') }} a
left join {{ ref('service_category__combined_professional') }} b
on a.claim_id = b.claim_id
and a.claim_line_number = b.claim_line_number
where a.claim_type = 'professional'

select distinct
a.claim_id
, a.claim_line_number
, a.claim_type
, case
when service_category_2 = 'Acute Inpatient' then 'Inpatient'
when service_category_2 = 'Ambulance' then 'Ancillary'
when service_category_2 = 'Ambulatory Surgery' then 'Outpatient'
when service_category_2 = 'Dialysis' then 'Outpatient'
when service_category_2 = 'Durable Medical Equipment' then 'Ancillary'
when service_category_2 = 'Emergency Department' then 'Outpatient'
when service_category_2 = 'Home Health' then 'Outpatient'
when service_category_2 = 'Hospice' then 'Outpatient'
when service_category_2 = 'Inpatient Psychiatric' then 'Inpatient'
when service_category_2 = 'Inpatient Rehabilitation' then 'Inpatient'
when service_category_2 = 'Lab' then 'Ancillary'
when service_category_2 = 'Office Visit' then 'Office Visit'
when service_category_2 = 'Outpatient Hospital or Clinic' then 'Outpatient'
when service_category_2 = 'Outpatient Psychiatric' then 'Outpatient'
when service_category_2 = 'Outpatient Rehabilitation' then 'Outpatient'
when service_category_2 = 'Skilled Nursing' then 'Inpatient'
when service_category_2 = 'Urgent Care' then 'Outpatient'
when service_category_2 is null then 'Other'
end service_category_1
, case
when service_category_2 is null then 'Other'
else service_category_2
end service_category_2
, '{{ var('tuva_last_run')}}' as tuva_last_run
from {{ ref('service_category__stg_medical_claim') }} a
left join {{ ref('service_category__combined_professional') }} b
on a.claim_id = b.claim_id
and a.claim_line_number = b.claim_line_number
where a.claim_type = 'professional'
union all

union all
select distinct
a.claim_id
, a.claim_line_number
, a.claim_type
, case
when service_category_2 = 'Acute Inpatient' then 'Inpatient'
when service_category_2 = 'Ambulatory Surgery' then 'Outpatient'
when service_category_2 = 'Dialysis' then 'Outpatient'
when service_category_2 = 'Emergency Department' then 'Outpatient'
when service_category_2 = 'Home Health' then 'Outpatient'
when service_category_2 = 'Hospice' then 'Outpatient'
when service_category_2 = 'Inpatient Psychiatric' then 'Inpatient'
when service_category_2 = 'Inpatient Rehabilitation' then 'Inpatient'
when service_category_2 = 'Lab' then 'Ancillary'
when service_category_2 = 'Office Visit' then 'Office Visit'
when service_category_2 = 'Outpatient Hospital or Clinic' then 'Outpatient'
when service_category_2 = 'Outpatient Psychiatric' then 'Outpatient'
when service_category_2 = 'Skilled Nursing' then 'Inpatient'
when service_category_2 = 'Urgent Care' then 'Outpatient'
when service_category_2 is null then 'Other'
end service_category_1
, case
when service_category_2 is null then 'Other'
else service_category_2
end service_category_2
, '{{ var('tuva_last_run')}}' as tuva_last_run
from {{ ref('service_category__stg_medical_claim') }} a
left join {{ ref('service_category__combined_institutional') }} b
on a.claim_id = b.claim_id
where a.claim_type = 'institutional'
)
, service_category_2_deduplication as(
select
claim_id
, claim_line_number
, claim_type
, service_category_1
, service_category_2
, row_number() over (partition by claim_id, claim_line_number order by
case
when service_category_2 = 'Acute Inpatient' then 3
when service_category_2 = 'Ambulance' then 7
when service_category_2 = 'Ambulatory Surgery' then 8
when service_category_2 = 'Dialysis' then 17
when service_category_2 = 'Durable Medical Equipment' then 1
when service_category_2 = 'Emergency Department' then 5
when service_category_2 = 'Home Health' then 9
when service_category_2 = 'Hospice' then 10
when service_category_2 = 'Inpatient Psychiatric' then 11
when service_category_2 = 'Inpatient Rehabilitation' then 12
when service_category_2 = 'Lab' then 13
when service_category_2 = 'Office Visit' then 4
when service_category_2 = 'Outpatient Hospital or Clinic' then 14
when service_category_2 = 'Outpatient Psychiatric' then 15
when service_category_2 = 'Outpatient Rehabilitation' then 16
when service_category_2 = 'Skilled Nursing' then 6
when service_category_2 = 'Urgent Care' then 2
when service_category_2 is null then 18
else 99 end) as duplicate_row_number
from claims_preprocessing.service_category_grouper
)

select distinct
a.claim_id
, a.claim_line_number
, a.claim_type
, case
when service_category_2 = 'Acute Inpatient' then 'Inpatient'
when service_category_2 = 'Ambulatory Surgery' then 'Outpatient'
when service_category_2 = 'Dialysis' then 'Outpatient'
when service_category_2 = 'Emergency Department' then 'Outpatient'
when service_category_2 = 'Home Health' then 'Outpatient'
when service_category_2 = 'Hospice' then 'Outpatient'
when service_category_2 = 'Inpatient Psychiatric' then 'Inpatient'
when service_category_2 = 'Inpatient Rehabilitation' then 'Inpatient'
when service_category_2 = 'Lab' then 'Ancillary'
when service_category_2 = 'Office Visit' then 'Office Visit'
when service_category_2 = 'Outpatient Hospital or Clinic' then 'Outpatient'
when service_category_2 = 'Outpatient Psychiatric' then 'Outpatient'
when service_category_2 = 'Skilled Nursing' then 'Inpatient'
when service_category_2 = 'Urgent Care' then 'Outpatient'
when service_category_2 is null then 'Other'
end service_category_1
, case
when service_category_2 is null then 'Other'
else service_category_2
end service_category_2
, '{{ var('tuva_last_run')}}' as tuva_last_run
from {{ ref('service_category__stg_medical_claim') }} a
left join {{ ref('service_category__combined_institutional') }} b
on a.claim_id = b.claim_id
where a.claim_type = 'institutional'
select
claim_id
, claim_line_number
, claim_type
, service_category_1
, service_category_2
from service_category_2_deduplication
where duplicate_row_number = 1

0 comments on commit 075c800

Please sign in to comment.