Skip to content

Commit

Permalink
encounter.sql
Browse files Browse the repository at this point in the history
added support for encounter "type", "service", ""priority", "reasonCode"

valueset.py added EncounterPriority and PatientClass

count_core.py affects
patient.sql (moved counts to count_core.sql)

#31
#66
  • Loading branch information
comorbidity committed Jul 5, 2023
1 parent f630f01 commit 221a855
Show file tree
Hide file tree
Showing 7 changed files with 300 additions and 103 deletions.
4 changes: 3 additions & 1 deletion cumulus_library/schema/valueset.py
Original file line number Diff line number Diff line change
Expand Up @@ -13,7 +13,9 @@ class ValueSet(Enum):
Ethnicity = "http://hl7.org/fhir/us/core/StructureDefinition/us-core-ethnicity"
DurationUnits = "http://hl7.org/fhir/valueset-duration-units.html"
Units = "http://hl7.org/fhir/ValueSet/ucum-units"
EncounterCode = "http://hl7.org/fhir/v3/ActEncounterCode/vs.html"
PatientClass = 'http://terminology.hl7.org/CodeSystem/v2-0004'
EncounterCode = "http://terminology.hl7.org/ValueSet/v3-ActEncounterCode"
EncounterPriority = 'http://terminology.hl7.org/CodeSystem/v3-ActPriority'
EncounterStatus = "http://hl7.org/fhir/ValueSet/encounter-status"
EncounterType = "http://hl7.org/fhir/ValueSet/encounter-type"
EncounterReason = "http://hl7.org/fhir/ValueSet/encounter-reason"
Expand Down
102 changes: 102 additions & 0 deletions cumulus_library/studies/core/count_core.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,102 @@
from typing import List
from cumulus_library.schema import counts

STUDY_PREFIX = 'core'

def table(tablename: str, duration=None) -> str:
if duration:
return f'{STUDY_PREFIX}__{tablename}_{duration}'
else:
return f'{STUDY_PREFIX}__{tablename}'

def count_patient():
view_name = table('count_patient')
from_table = table('patient')
cols = ['age', 'gender', 'race_display', 'ethnicity_display']

return counts.count_patient(view_name, from_table, cols)

def count_encounter_demographics(duration=None):
view_name = table('count_encounter_demographics', duration)
from_table = table('encounter')

cols = [f'start_{duration}',
'enc_class_display',
'age_at_visit',
'gender',
'race_display',
'ethnicity_display']

return counts.count_encounter(view_name, from_table, cols)

def _count_encounter_type(view_name, cols, duration):
"""
Encounter Type information is for every visit, and therefore this
SQL should be precise in which fields to select (This is a BIG query).
:param view_name: name of the view from "core__encounter_type"
:param cols: from "core__encounter_type"
:param duration: None or ''month', 'year'
:return: SQL commands
"""
view_name = table(view_name, duration)
from_table = table('encounter_type')

if duration:
cols.append(f'start_{duration}')

where = counts.where_clauses(min_subject=100)

return counts.count_encounter(view_name, from_table, cols, where)

def count_encounter_type(duration=None):
cols = ['enc_class_display',
'enc_type_display',
'enc_service_display',
'enc_priority_display']
return _count_encounter_type('count_encounter_type', cols, duration)

def count_encounter_enc_type(duration='month'):
cols = ['enc_class_display', 'enc_type_display']
return _count_encounter_type('count_encounter_enc_type', cols, duration)

def count_encounter_service(duration='month'):
cols = ['enc_class_display', 'enc_service_display']
return _count_encounter_type('count_encounter_service', cols, duration)

def count_encounter_priority(duration='month'):
cols = ['enc_class_display', 'enc_priority_display']
return _count_encounter_type('count_encounter_priority', cols, duration)

def concat_view_sql(create_view_list: List[str]) -> str:
"""
:param create_view_list: SQL prepared statements
:param filename: path to output file, default 'count.sql' in PWD
"""
seperator = '-- ###########################################################'
concat = list()

for create_view in create_view_list:
concat.append(seperator + '\n'+create_view + '\n')

return '\n'.join(concat)

def write_view_sql(view_list_sql: List[str], filename='count_core.sql') -> None:
"""
:param view_list_sql: SQL prepared statements
:param filename: path to output file, default 'count_core.sql'
"""
with open(filename, 'w') as fout:
fout.write(concat_view_sql(view_list_sql))


if __name__ == '__main__':
write_view_sql([
count_patient(),
count_encounter_demographics('month'),
count_encounter_type(),
count_encounter_type('month'),
count_encounter_enc_type('month'),
count_encounter_service('month'),
count_encounter_priority('month'),
])
132 changes: 132 additions & 0 deletions cumulus_library/studies/core/count_core.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,132 @@
-- ###########################################################
CREATE or replace VIEW core__count_patient AS
with powerset as
(
select
count(distinct subject_ref) as cnt_subject

, age, gender, race_display, ethnicity_display
FROM core__patient
group by CUBE
( age, gender, race_display, ethnicity_display )
)
select
cnt_subject as cnt
, age, gender, race_display, ethnicity_display
from powerset
WHERE cnt_subject >= 10
ORDER BY cnt desc;

-- ###########################################################
CREATE or replace VIEW core__count_encounter_demographics_month AS
with powerset as
(
select
count(distinct subject_ref) as cnt_subject
, count(distinct encounter_ref) as cnt_encounter
, start_month, enc_class_display, age_at_visit, gender, race_display, ethnicity_display
FROM core__encounter
group by CUBE
( start_month, enc_class_display, age_at_visit, gender, race_display, ethnicity_display )
)
select
cnt_encounter as cnt
, start_month, enc_class_display, age_at_visit, gender, race_display, ethnicity_display
from powerset
WHERE cnt_subject >= 10
ORDER BY cnt desc;

-- ###########################################################
CREATE or replace VIEW core__count_encounter_type AS
with powerset as
(
select
count(distinct subject_ref) as cnt_subject
, count(distinct encounter_ref) as cnt_encounter
, enc_class_display, enc_type_display, enc_service_display, enc_priority_display
FROM core__encounter_type
group by CUBE
( enc_class_display, enc_type_display, enc_service_display, enc_priority_display )
)
select
cnt_encounter as cnt
, enc_class_display, enc_type_display, enc_service_display, enc_priority_display
from powerset
WHERE cnt_subject >= 100
ORDER BY cnt desc;

-- ###########################################################
CREATE or replace VIEW core__count_encounter_type_month AS
with powerset as
(
select
count(distinct subject_ref) as cnt_subject
, count(distinct encounter_ref) as cnt_encounter
, enc_class_display, enc_type_display, enc_service_display, enc_priority_display, start_month
FROM core__encounter_type
group by CUBE
( enc_class_display, enc_type_display, enc_service_display, enc_priority_display, start_month )
)
select
cnt_encounter as cnt
, enc_class_display, enc_type_display, enc_service_display, enc_priority_display, start_month
from powerset
WHERE cnt_subject >= 100
ORDER BY cnt desc;

-- ###########################################################
CREATE or replace VIEW core__count_encounter_enc_type_month AS
with powerset as
(
select
count(distinct subject_ref) as cnt_subject
, count(distinct encounter_ref) as cnt_encounter
, enc_class_display, enc_type_display, start_month
FROM core__encounter_type
group by CUBE
( enc_class_display, enc_type_display, start_month )
)
select
cnt_encounter as cnt
, enc_class_display, enc_type_display, start_month
from powerset
WHERE cnt_subject >= 100
ORDER BY cnt desc;

-- ###########################################################
CREATE or replace VIEW core__count_encounter_service_month AS
with powerset as
(
select
count(distinct subject_ref) as cnt_subject
, count(distinct encounter_ref) as cnt_encounter
, enc_class_display, enc_service_display, start_month
FROM core__encounter_type
group by CUBE
( enc_class_display, enc_service_display, start_month )
)
select
cnt_encounter as cnt
, enc_class_display, enc_service_display, start_month
from powerset
WHERE cnt_subject >= 100
ORDER BY cnt desc;

-- ###########################################################
CREATE or replace VIEW core__count_encounter_priority_month AS
with powerset as
(
select
count(distinct subject_ref) as cnt_subject
, count(distinct encounter_ref) as cnt_encounter
, enc_class_display, enc_priority_display, start_month
FROM core__encounter_type
group by CUBE
( enc_class_display, enc_priority_display, start_month )
)
select
cnt_encounter as cnt
, enc_class_display, enc_priority_display, start_month
from powerset
WHERE cnt_subject >= 100
ORDER BY cnt desc;
Loading

0 comments on commit 221a855

Please sign in to comment.