-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
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
1 parent
f630f01
commit 221a855
Showing
7 changed files
with
300 additions
and
103 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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'), | ||
]) |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; |
Oops, something went wrong.