Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

LAB_RESULT_CM transform #32

Merged
merged 17 commits into from
May 17, 2016
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
63 changes: 2 additions & 61 deletions Oracle/PCORNetLoader_ora.sql
Original file line number Diff line number Diff line change
Expand Up @@ -415,66 +415,6 @@ begin
end;
/

BEGIN
PMN_DROPSQL('DROP TABLE PMN_LabNormal');
END;
/
CREATE TABLE PMN_LabNormal (
LAB_NAME varchar(150) NULL,
NORM_RANGE_LOW varchar(10) NULL,
NORM_MODIFIER_LOW varchar(2) NULL,
NORM_RANGE_HIGH varchar(10) NULL,
NORM_MODIFIER_HIGH varchar(2) NULL
)
/

INSERT INTO PMN_LabNormal(LAB_NAME, NORM_RANGE_LOW, NORM_MODIFIER_LOW, NORM_RANGE_HIGH, NORM_MODIFIER_HIGH)
VALUES('LAB_NAME:LDL', '0', 'GE', '165', 'LE')
/

INSERT INTO PMN_LabNormal(LAB_NAME, NORM_RANGE_LOW, NORM_MODIFIER_LOW, NORM_RANGE_HIGH, NORM_MODIFIER_HIGH)
VALUES('LAB_NAME:A1C', '', 'NI', '', 'NI')
/

INSERT INTO PMN_LabNormal(LAB_NAME, NORM_RANGE_LOW, NORM_MODIFIER_LOW, NORM_RANGE_HIGH, NORM_MODIFIER_HIGH)
VALUES('LAB_NAME:CK', '50', 'GE', '236', 'LE')
/

INSERT INTO PMN_LabNormal(LAB_NAME, NORM_RANGE_LOW, NORM_MODIFIER_LOW, NORM_RANGE_HIGH, NORM_MODIFIER_HIGH)
VALUES('LAB_NAME:CK_MB', '', 'NI', '', 'NI')
/

INSERT INTO PMN_LabNormal(LAB_NAME, NORM_RANGE_LOW, NORM_MODIFIER_LOW, NORM_RANGE_HIGH, NORM_MODIFIER_HIGH)
VALUES('LAB_NAME:CK_MBI', '', 'NI', '', 'NI')
/

INSERT INTO PMN_LabNormal(LAB_NAME, NORM_RANGE_LOW, NORM_MODIFIER_LOW, NORM_RANGE_HIGH, NORM_MODIFIER_HIGH)
VALUES('LAB_NAME:CREATININE', '0', 'GE', '1.6', 'LE')
/

INSERT INTO PMN_LabNormal(LAB_NAME, NORM_RANGE_LOW, NORM_MODIFIER_LOW, NORM_RANGE_HIGH, NORM_MODIFIER_HIGH)
VALUES('LAB_NAME:CREATININE', '0', 'GE', '1.6', 'LE')
/

INSERT INTO PMN_LabNormal(LAB_NAME, NORM_RANGE_LOW, NORM_MODIFIER_LOW, NORM_RANGE_HIGH, NORM_MODIFIER_HIGH)
VALUES('LAB_NAME:HGB', '12', 'GE', '17.5', 'LE')
/

INSERT INTO PMN_LabNormal(LAB_NAME, NORM_RANGE_LOW, NORM_MODIFIER_LOW, NORM_RANGE_HIGH, NORM_MODIFIER_HIGH)
VALUES('LAB_NAME:INR', '0.8', 'GE', '1.3', 'LE')
/

INSERT INTO PMN_LabNormal(LAB_NAME, NORM_RANGE_LOW, NORM_MODIFIER_LOW, NORM_RANGE_HIGH, NORM_MODIFIER_HIGH)
VALUES('LAB_NAME:TROP_I', '0', 'GE', '0.49', 'LE')
/

INSERT INTO PMN_LabNormal(LAB_NAME, NORM_RANGE_LOW, NORM_MODIFIER_LOW, NORM_RANGE_HIGH, NORM_MODIFIER_HIGH)
VALUES('LAB_NAME:TROP_T_QL', '', 'NI', '', 'NI')
/

INSERT INTO PMN_LabNormal(LAB_NAME, NORM_RANGE_LOW, NORM_MODIFIER_LOW, NORM_RANGE_HIGH, NORM_MODIFIER_HIGH)
VALUES('LAB_NAME:TROP_T_QN', '0', 'GE', '0.09', 'LE')
/

Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@njgraham , @mprittie noted this is a somewhat invasive change to the SCILHS code but he said you and he chatted about it and couldn't think of a better idea. Does that sound about right?

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@dckc, yes, it seemed like it was best to create/populate the PMN_LabNormal table from a .csv rather than doing a bunch of inserts with hard-coded strings. As I recall, the motivation was that Mike needed access to those values earlier in the process.

We hoped this change would be something that SCILHS would merge back to their version.

BEGIN
PMN_DROPSQL('DROP TABLE death');
Expand Down Expand Up @@ -1335,7 +1275,8 @@ m.start_date SPECIMEN_DATE,
to_char(m.start_date,'HH:MI') SPECIMEN_TIME,
m.end_date RESULT_DATE,
to_char(m.end_date,'HH:MI') RESULT_TIME,
CASE WHEN m.ValType_Cd='T' THEN NVL(nullif(m.TVal_Char,''),'NI') ELSE 'NI' END RESULT_QUAL, -- TODO: Should be a standardized value
--CASE WHEN m.ValType_Cd='T' THEN NVL(nullif(m.TVal_Char,''),'NI') ELSE 'NI' END RESULT_QUAL, -- TODO: Should be a standardized value
'NI' RESULT_QUAL, -- Temporary fix for KUMC

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@mprittie: Do you have a design in mind that will allow you to revert this temporary fix?

Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@njgraham: The TODO on the original line indicated that they knew that this was an issue. After talking with Dan, he suggested this temporary fix and logging a bug with the SCHILS folks (which I did ARCH-commons#19). Jeff responded on Thursday, but it sounds like they haven't found the right solution yet.

CASE WHEN m.ValType_Cd='N' THEN m.NVAL_NUM ELSE null END RESULT_NUM,
CASE WHEN m.ValType_Cd='N' THEN (CASE NVL(nullif(m.TVal_Char,''),'NI') WHEN 'E' THEN 'EQ' WHEN 'NE' THEN 'OT' WHEN 'L' THEN 'LT' WHEN 'LE' THEN 'LE' WHEN 'G' THEN 'GT' WHEN 'GE' THEN 'GE' ELSE 'NI' END) ELSE 'TX' END RESULT_MODIFIER,
NVL(m.Units_CD,'NI') RESULT_UNIT, -- TODO: Should be standardized units
Expand Down
32 changes: 32 additions & 0 deletions Oracle/cdm_transform_tests.sql
Original file line number Diff line number Diff line change
Expand Up @@ -528,6 +528,38 @@ order by 2
;
*/


/* Verify that LAB_RESULT_CM contains data associated with a least half of the
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I'd like to see a test that the average lab value is close to clinical norms (which we should be able to find in wikipedia or the like).

labs defined in PMN_LABLOCAL.
*/
insert into test_cases (query_name, description, obs, by_value1, by_value2, record_pct, pass)
with partial_lab_counts as (
select lab_name, count(lab_name) lab_count
from lab_result_cm
group by lab_name
), complete_lab_counts as(
select replace(pmn.lab_name, 'LAB_NAME:', '') lab_name,
case when lc.lab_count is null then 0 else lc.lab_count end lab_count
from pmn_labnormal pmn
left outer join partial_lab_counts lc on concat('LAB_NAME:', lc.lab_name) = pmn.lab_name
), total_lab_types as (
select count(*) num_labs from complete_lab_counts
), present_lab_types as (
select count(*) num_labs from complete_lab_counts
where lab_count > 0
)
select
'LAB_RESULT_CM Test' query_name,
'LAB_RESULT_CM contains data associated with at least half of the defined labs' description,
rownum obs,
plt.num_labs by_value1,
tlt.num_labs by_values2,
round(plt.num_labs/tlt.num_labs, 4) record_pct,
case when (plt.num_labs/tlt.num_labs) > 0.5 then 1 else 0 end pass
from present_lab_types plt
cross join total_lab_types tlt
;

select case when count(*) > 0 then 1/0 else 1 end all_test_cases_pass from (
select * from test_cases where pass = 0
);
Expand Down
52 changes: 52 additions & 0 deletions Oracle/pcornet_mapping.sql
Original file line number Diff line number Diff line change
Expand Up @@ -424,3 +424,55 @@ join "&&i2b2_meta_schema".pcornet_med on med_mod_mapping.PCORI_PATH = pcornet_me
;

commit;

/* Add relevent nodes from local i2b2 lab hierarchy to PCORNet Labs hierarchy.
*/

insert into "&&i2b2_meta_schema".pcornet_lab
with lab_map as (
select distinct lab.c_hlevel, lab.c_path, lab.pcori_specimen_source, trim(CHR(13) from lab.pcori_basecode) as pcori_basecode
from "&&i2b2_meta_schema".pcornet_lab lab
inner JOIN "&&i2b2_meta_schema".pcornet_lab ont_parent on lab.c_path=ont_parent.c_fullname
inner join pmn_labnormal norm on ont_parent.c_basecode=norm.LAB_NAME
where lab.c_fullname like '\PCORI\LAB_RESULT_CM\%'
),
local_loinc_terms as (
select lm.C_HLEVEL, lt.C_FULLNAME, lm.C_PATH, lm.PCORI_BASECODE, lm.pcori_specimen_source
from "&&i2b2_meta_schema"."&&terms_table" lt, lab_map lm
where lm.pcori_basecode=replace(lt.c_basecode, 'LOINC:', '')
and lt.c_fullname like '\i2b2\Laboratory Tests\%' and lt.c_basecode like 'LOINC:%'
)
select
llt.C_HLEVEL,
concat(llt.c_path, substr(regexp_substr(lt.c_fullname, '\\[^\\]+\\$'), 2, length(regexp_substr(lt.c_fullname, '\\[^\\]+\\$')))) as c_fullname,
lt.C_NAME,
lt.C_SYNONYM_CD,
lt.C_VISUALATTRIBUTES,
lt.C_TOTALNUM,
lt.C_BASECODE,
lt.C_METADATAXML,
lt.C_FACTTABLECOLUMN,
lt.C_TABLENAME,
lt.C_COLUMNNAME,
lt.C_COLUMNDATATYPE,
lt.C_OPERATOR,
lt.C_DIMCODE,
lt.C_COMMENT,
lt.C_TOOLTIP,
lt.M_APPLIED_PATH,
lt.UPDATE_DATE,
lt.DOWNLOAD_DATE,
lt.IMPORT_DATE,
'MAPPING',
lt.VALUETYPE_CD,
lt.M_EXCLUSION_CD,
llt.C_PATH,
lt.C_SYMBOL,
llt.pcori_specimen_source,
llt.PCORI_BASECODE
from "&&i2b2_meta_schema"."&&terms_table" lt, local_loinc_terms llt
where lt.c_fullname like llt.c_fullname||'%\'
;

commit;

12 changes: 12 additions & 0 deletions Oracle/pmn_labnormal.csv
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
LAB_NAME,NORM_RANGE_LOW,NORM_MODIFIER_LOW,NORM_RANGE_HIGH,NORM_MODIFIER_HIGH
LAB_NAME:LDL,0,GE,165,LE
LAB_NAME:A1C,,NI,,NI
LAB_NAME:CK,50,GE,236,LE
LAB_NAME:CK_MB,,NI,,NI
LAB_NAME:CK_MBI,,NI,,NI
LAB_NAME:CREATININE,0,GE,1.6,LE
LAB_NAME:HGB,12,GE,17.5,LE
LAB_NAME:INR,0.8,GE,1.3,LE
LAB_NAME:TROP_I,0,GE,0.49,LE
LAB_NAME:TROP_T_QL,,NI,,NI
LAB_NAME:TROP_T_QN,0,GE,0.09,LE
2 changes: 1 addition & 1 deletion Oracle/run-i2p-transform.sh
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,7 @@ set -e
#export terms_table=

python load_csv.py harvest_local harvest_local.csv harvest_local.ctl pcornet_cdm_user pcornet_cdm
python load_csv.py PMN_LabNormal pmn_labnormal.csv pmn_labnormal.ctl pcornet_cdm_user pcornet_cdm
. ./load_pcornet_mapping.sh

# Run some tests
Expand Down Expand Up @@ -65,7 +66,6 @@ set timing on;

WHENEVER SQLERROR CONTINUE;

drop table PMN_LABNORMAL;
drop table DEMOGRAPHIC;
drop table ENROLLMENT;
drop table ENCOUNTER;
Expand Down