Skip to content

Commit

Permalink
Add scripts to load HealthPro data into Constrack and check and map A…
Browse files Browse the repository at this point in the history
…oU IDs to Constrack MRNs
  • Loading branch information
kembree1 committed Jul 6, 2017
1 parent d362b90 commit 7959d0c
Show file tree
Hide file tree
Showing 5 changed files with 340 additions and 0 deletions.
175 changes: 175 additions & 0 deletions PHS_MRN_PID_mapping/AOU_MATCHING.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,175 @@
DECLARE
CURSOR C_HEALTH_PRO_VIEW
IS
SELECT * FROM HEALTH_PRO_VIEW;

R_HEALTH_PRO_VIEW C_HEALTH_PRO_VIEW%ROWTYPE;
TYPE PMI_ID_LIST IS VARRAY(1000) OF HEALTH_PRO_VIEW.PMI_ID%TYPE;
A_NOT_IN_HEALTHPRO PMI_ID_LIST := PMI_ID_LIST();
V_NOT_IN_HEALTHPRO_COUNTER INTEGER;
A_LASTNAME_MISMATCH PMI_ID_LIST := PMI_ID_LIST();
V_LASTNAME_MISMATCH_COUNTER INTEGER;
A_DOB_MISMATCH PMI_ID_LIST := PMI_ID_LIST();
V_VALID_COUNTER INTEGER;
A_VALID PMI_ID_LIST := PMI_ID_LIST();
V_DOB_MISMATCH_COUNTER INTEGER;
V_NOT_VALIDATED_COUNTER INTEGER;
A_NOT_VALIDATED PMI_ID_LIST := PMI_ID_LIST();
V_WITHDRAWN_COUNTER INTEGER;
A_WITHDRAWN PMI_ID_LIST := PMI_ID_LIST();
V_NOT_CONSENTED_TO_EHR_COUNTER INTEGER;
A_NOT_CONSENTED_TO_EHR PMI_ID_LIST := PMI_ID_LIST();
V_NOT_CONSENTED_COUNTER INTEGER;
A_NOT_CONSENTED PMI_ID_LIST := PMI_ID_LIST();
V_SUCCESSFUL BOOLEAN;
V_FAILED_LASTNAME_CHECK BOOLEAN;
V_FAILED_DOB_CHECK BOOLEAN;
V_SHOW_ERRORS BOOLEAN;
V_SHOW_MAPPINGS BOOLEAN;
BEGIN
------------------------------------------------------------------------------------
-- CHANGE THESE VALUES DEPENDING ON WHAT INFORMATION YOU WANT TO SEE
------------------------------------------------------------------------------------
V_SHOW_ERRORS := FALSE;
V_SHOW_MAPPINGS := TRUE;
------------------------------------------------------------------------------------
--INITIALIZE
V_NOT_IN_HEALTHPRO_COUNTER := 0;
V_LASTNAME_MISMATCH_COUNTER := 0;
V_DOB_MISMATCH_COUNTER := 0;
V_NOT_VALIDATED_COUNTER :=0;
V_NOT_CONSENTED_COUNTER := 0;
V_NOT_CONSENTED_TO_EHR_COUNTER := 0;
V_WITHDRAWN_COUNTER :=0;
V_VALID_COUNTER :=0;

FOR R_HEALTH_PRO_VIEW
IN C_HEALTH_PRO_VIEW
LOOP
V_SUCCESSFUL := TRUE;
V_FAILED_LASTNAME_CHECK := FALSE;
V_FAILED_DOB_CHECK := FALSE;
--CHECK FOR PRESENCE IN HEALTH PRO
IF R_HEALTH_PRO_VIEW.HP_PMI_ID IS NULL THEN
V_NOT_IN_HEALTHPRO_COUNTER := V_NOT_IN_HEALTHPRO_COUNTER + 1;
A_NOT_IN_HEALTHPRO.EXTEND;
A_NOT_IN_HEALTHPRO(V_NOT_IN_HEALTHPRO_COUNTER) := R_HEALTH_PRO_VIEW.PMI_ID;
V_SUCCESSFUL := FALSE;
END IF;
--CHECK FOR ID_VALIDATION
IF UPPER(R_HEALTH_PRO_VIEW.VALIDATED_ID) = 'NO' THEN
V_NOT_VALIDATED_COUNTER := V_NOT_VALIDATED_COUNTER + 1;
A_NOT_VALIDATED.EXTEND;
A_NOT_VALIDATED(V_NOT_VALIDATED_COUNTER) := R_HEALTH_PRO_VIEW.PMI_ID;
V_SUCCESSFUL := FALSE;
END IF;
--CHECK FOR CONSENT
IF R_HEALTH_PRO_VIEW.HP_GENERAL_CONSENT_STATUS != 1 THEN
V_NOT_CONSENTED_COUNTER := V_NOT_CONSENTED_COUNTER + 1;
A_NOT_CONSENTED.EXTEND;
A_NOT_CONSENTED(V_NOT_CONSENTED_COUNTER) := R_HEALTH_PRO_VIEW.HP_PMI_ID;
V_SUCCESSFUL := FALSE;
END IF;
--CHECK FOR CONSENT TO EHR
IF R_HEALTH_PRO_VIEW.HP_EHR_CONSENT_STATUS != 1 THEN
V_NOT_CONSENTED_TO_EHR_COUNTER := V_NOT_CONSENTED_TO_EHR_COUNTER + 1;
A_NOT_CONSENTED_TO_EHR.EXTEND;
A_NOT_CONSENTED_TO_EHR(V_NOT_CONSENTED_TO_EHR_COUNTER) := R_HEALTH_PRO_VIEW.HP_PMI_ID;
V_SUCCESSFUL := FALSE;
END IF;
--CHECK FOR WITHDRAWAL
IF R_HEALTH_PRO_VIEW.HP_WITHDRAWAL_STATUS = 1 THEN
V_WITHDRAWN_COUNTER := V_WITHDRAWN_COUNTER + 1;
A_WITHDRAWN.EXTEND;
A_WITHDRAWN(V_WITHDRAWN_COUNTER) := R_HEALTH_PRO_VIEW.HP_PMI_ID;
V_SUCCESSFUL := FALSE;
END IF;
--CHECK FOR LASTNAME
IF UPPER(R_HEALTH_PRO_VIEW.HP_LAST_NAME) != UPPER(R_HEALTH_PRO_VIEW.LAST_NAME) THEN
V_LASTNAME_MISMATCH_COUNTER := V_LASTNAME_MISMATCH_COUNTER + 1;
A_LASTNAME_MISMATCH.EXTEND;
A_LASTNAME_MISMATCH(V_LASTNAME_MISMATCH_COUNTER) := R_HEALTH_PRO_VIEW.HP_PMI_ID;
V_FAILED_LASTNAME_CHECK := TRUE;
END IF;
--CHECK FOR DOB
IF UPPER(R_HEALTH_PRO_VIEW.HP_DATE_OF_BIRTH) != UPPER(R_HEALTH_PRO_VIEW.DATE_OF_BIRTH) THEN
V_DOB_MISMATCH_COUNTER := V_DOB_MISMATCH_COUNTER + 1;
A_DOB_MISMATCH.EXTEND;
A_DOB_MISMATCH(V_DOB_MISMATCH_COUNTER) := R_HEALTH_PRO_VIEW.HP_PMI_ID;
V_FAILED_DOB_CHECK := TRUE;
END IF;
-- IF BOTH FAILED THEN DON'T ADD
IF (V_FAILED_LASTNAME_CHECK AND V_FAILED_DOB_CHECK) THEN
V_SUCCESSFUL := FALSE;
END IF;

--DBMS_OUTPUT.PUT_LINE('DEBUG: Successful: ' || BOOLEAN_TO_VARCHAR(V_SUCCESSFUL) || ', MRN: ' || R_HEALTH_PRO_VIEW.MRN || ', MRN_FACILITY: ' || R_HEALTH_PRO_VIEW.MRN_FACILITY);
IF V_SUCCESSFUL AND R_HEALTH_PRO_VIEW.MRN IS NOT NULL AND R_HEALTH_PRO_VIEW.MRN_FACILITY IS NOT NULL THEN
V_VALID_COUNTER := V_VALID_COUNTER + 1;
A_VALID.EXTEND;
A_VALID(V_VALID_COUNTER) := R_HEALTH_PRO_VIEW.HP_PMI_ID;
END IF;
END LOOP;
--REPORT RESULTS
IF V_SHOW_ERRORS THEN
--REPORT MISSING PMI_IDS IF ANY
IF V_NOT_IN_HEALTHPRO_COUNTER > 0 THEN
DBMS_OUTPUT.PUT_LINE('ERROR: FOLLOWING PMI_IDS ARE IN CONSTRACK BUT NOT IN HEALTHPRO');
FOR i IN 1..A_NOT_IN_HEALTHPRO.COUNT LOOP
DBMS_OUTPUT.PUT_LINE('' || A_NOT_IN_HEALTHPRO(i));
END LOOP;
END IF;
--REPORT UNVALIDATED IDS IF ANY
IF V_DOB_MISMATCH_COUNTER > 0 THEN
DBMS_OUTPUT.PUT_LINE('ERROR: FOLLOWING PMI_IDS ARE FOR PATIENTS WHOS ID HAVE NOT BEEN VALIDATED');
FOR i IN 1..A_NOT_VALIDATED.COUNT LOOP
DBMS_OUTPUT.PUT_LINE('' || A_NOT_VALIDATED(i));
END LOOP;
END IF;
--REPORT NOT CONSENTED TO THE EHR IF ANY
IF V_NOT_CONSENTED_COUNTER > 0 THEN
DBMS_OUTPUT.PUT_LINE('ERROR: FOLLOWING PMI_IDS ARE FOR PATIENTS WHO HAVE NOT CONSENTED');
FOR i IN 1..A_NOT_CONSENTED.COUNT LOOP
DBMS_OUTPUT.PUT_LINE('' || A_NOT_CONSENTED(i));
END LOOP;
END IF;
--REPORT NOT CONSENTED TO THE EHR IF ANY
IF V_WITHDRAWN_COUNTER > 0 THEN
DBMS_OUTPUT.PUT_LINE('ERROR: FOLLOWING PMI_IDS ARE FOR PATIENTS WHO HAVE WITHDRAWN');
FOR i IN 1..A_WITHDRAWN.COUNT LOOP
DBMS_OUTPUT.PUT_LINE('' || A_WITHDRAWN(i));
END LOOP;
END IF;
--REPORT NOT CONSENTED TO THE EHR IF ANY
IF A_NOT_CONSENTED_TO_EHR.COUNT > 0 THEN
DBMS_OUTPUT.PUT_LINE('ERROR: FOLLOWING PMI_IDS ARE FOR PATIENTS WHO HAVE NOT CONSENTED TO THE EHR');
FOR i IN 1..A_NOT_CONSENTED_TO_EHR.COUNT LOOP
DBMS_OUTPUT.PUT_LINE('' || A_NOT_CONSENTED_TO_EHR(i));
END LOOP;
END IF;
--REPORT MISMATCHED LAST_NAMES IF ANY
IF V_LASTNAME_MISMATCH_COUNTER > 0 THEN
DBMS_OUTPUT.PUT_LINE('WARNING: FOLLOWING PMI_IDS ARE FOR PATIENTS WITH LASTNAMES THAT DO NOT MATCH');
FOR i IN 1..A_LASTNAME_MISMATCH.COUNT LOOP
DBMS_OUTPUT.PUT_LINE('' || A_LASTNAME_MISMATCH(i));
END LOOP;
END IF;
--REPORT MISMATCHED DOB IF ANY
IF V_DOB_MISMATCH_COUNTER > 0 THEN
DBMS_OUTPUT.PUT_LINE('WARNING: FOLLOWING PMI_IDS ARE FOR PATIENTS WITH DOBS THAT DO NOT MATCH');
FOR i IN 1..A_DOB_MISMATCH.COUNT LOOP
DBMS_OUTPUT.PUT_LINE('' || A_DOB_MISMATCH(i));
END LOOP;
END IF;
END IF;
--REPORT MAPPING
IF V_SHOW_MAPPINGS THEN
IF V_VALID_COUNTER > 0 THEN
DBMS_OUTPUT.PUT_LINE('MRN, MRN_FACILITY, PMI_ID');
FOR i IN 1..A_VALID.COUNT LOOP
SELECT * INTO R_HEALTH_PRO_VIEW FROM HEALTH_PRO_VIEW HPV WHERE HPV.PMI_ID = A_VALID(i);
DBMS_OUTPUT.PUT_LINE(R_HEALTH_PRO_VIEW.MRN||', '||R_HEALTH_PRO_VIEW.MRN_FACILITY||', '||TO_NUMBER(SUBSTR(A_VALID(i),2)));
END LOOP;
END IF;
END IF;
END;
63 changes: 63 additions & 0 deletions PHS_MRN_PID_mapping/Create_Health_Pro_Data_Table.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,63 @@
CREATE TABLE HEALTH_PRO_DATA ( PMI_ID VARCHAR2(10) NOT NULL,
Biobank_ID VARCHAR2(10),
Last_Name VARCHAR2(80),
First_Name VARCHAR2(80),
Date_of_Birth DATE,
Language VARCHAR2(80),
General_Consent_Status INTEGER,
General_Consent_Date DATE,
EHR_Consent_Status INTEGER,
EHR_Consent_Date DATE,
CABoR_Consent_Status INTEGER,
CABoR_Consent_Date DATE,
Withdrawal_Status INTEGER,
Withdrawal_Date DATE,
Street_Address VARCHAR2(255),
City VARCHAR2(80),
State VARCHAR2(2),
ZIP VARCHAR2(10),
Email VARCHAR2(255),
Phone VARCHAR2(14),
Sex VARCHAR2(80),
Gender_Identity VARCHAR2(80),
Sexual_Orientation VARCHAR2(80),
Race_Ethnicity VARCHAR2(80),
Education VARCHAR2(80),
Income VARCHAR2(80),
Required_PPI_Surveys_Complete INTEGER,
Completed_Surveys INTEGER,
Basics_PPI_Survey_Complete INTEGER,
Basics_PPI_Survey_Date DATE,
Health_PPI_Survey_Complete INTEGER,
Health_PPI_Survey_Date DATE,
Lifestyle_PPI_Survey_Complete INTEGER,
Lifestyle_PPI_Survey_Date DATE,
Hist_PPI_Survey_Complete INTEGER,
Hist_PPI_Survey_Date DATE,
Meds_PPI_Survey_Complete INTEGER,
Meds_PPI_Survey_Date DATE,
Family_PPI_Survey_Complete NUMBER(3),
Family_PPI_Survey_Date DATE,
Access_PPI_Survey_Complete INTEGER,
Access_PPI_Survey_Date DATE,
Physical_Measurements_Status INTEGER,
Physical_Measurements_Date DATE,
Samples_for_DNA_Received INTEGER,
Biospecimens INTEGER,
SST_Collected INTEGER,
SST_Collection_Date DATE,
PST_Collected INTEGER,
PST_Collection_Date DATE,
NaHep_Collected INTEGER,
NaHep_Collection_Date DATE,
EDTA_Collected INTEGER,
EDTA_Collection_Date INTEGER,
EDTA1_Collected INTEGER,
EDTA1_Collection_Date DATE,
EDTA2_Collected INTEGER,
EDTA2_Collection_Date DATE,
Urine_10_mL_Collected INTEGER,
Urine_Colletction_Date DATE,
Saliva_Collected INTEGER,
Saliva_Collection_Date DATE);

28 changes: 28 additions & 0 deletions PHS_MRN_PID_mapping/HealthProView.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
--------------------------------------------------------
-- DDL for View HEALTH_PRO_VIEW
--------------------------------------------------------

CREATE OR REPLACE FORCE VIEW "HEALTH_PRO_VIEW" ("HP_PMI_ID", "HP_LAST_NAME", "HP_FIRST_NAME", "HP_DATE_OF_BIRTH", "HP_GENERAL_CONSENT_STATUS", "HP_GENERAL_CONSENT_DATE", "HP_EHR_CONSENT_STATUS", "HP_EHR_CONSENT_DATE", "HP_WITHDRAWAL_STATUS", "HP_WITHDRAWAL_DATE", "PMI_ID", "MRN", "MRN_FACILITY", "LAST_NAME", "DATE_OF_BIRTH", "CONSENT_DATE", "CURRENT_STATUS", "VALIDATED_ID") AS
SELECT
"HP_PMI_ID","HP_LAST_NAME","HP_FIRST_NAME","HP_DATE_OF_BIRTH","HP_GENERAL_CONSENT_STATUS","HP_GENERAL_CONSENT_DATE","HP_EHR_CONSENT_STATUS","HP_EHR_CONSENT_DATE","HP_WITHDRAWAL_STATUS","HP_WITHDRAWAL_DATE","PMI_ID","MRN","MRN_FACILITY","LASTNAME", "DOB", "CONSENT_DATE","CURRENT_STATUS", "VALIDATED_ID"
FROM
(SELECT PMI_ID AS HP_PMI_ID, LAST_NAME AS HP_LAST_NAME, FIRST_NAME AS HP_FIRST_NAME, DATE_OF_BIRTH AS HP_DATE_OF_BIRTH, GENERAL_CONSENT_STATUS AS HP_GENERAL_CONSENT_STATUS, GENERAL_CONSENT_DATE AS HP_GENERAL_CONSENT_DATE, EHR_CONSENT_STATUS AS HP_EHR_CONSENT_STATUS, EHR_CONSENT_DATE AS HP_EHR_CONSENT_DATE, WITHDRAWAL_STATUS AS HP_WITHDRAWAL_STATUS, WITHDRAWAL_DATE AS HP_WITHDRAWAL_DATE FROM HEALTH_PRO_DATA) HPD
FULL OUTER JOIN
(SELECT SID.STUDY_ID AS PMI_ID, M.MRN, MF.NAME AS MRN_FACILITY, P.LASTNAME, P.DOB, PC.CONSENT_DATE, C.TEXT AS CURRENT_STATUS, VALIDATED.TEXT AS VALIDATED_ID FROM PATIENT_CONSENT PC
JOIN CONSENT_FORM CF ON PC.CONSENT_FORM_FK = CF.ID
JOIN IRB_PROTOCOL IRB ON CF.IRB_PROTOCOL_FK = IRB.ID AND IRB.PROTOCOL_NUMBER = '2016P111111'
JOIN MRN M ON PC.MRN_FK = M.ID
JOIN MRN_FACILITY MF ON M.MRN_FACILITY_FK = MF.ID
JOIN PATIENT P ON P.ID = M.PATIENT_FK
JOIN (SELECT STUDY_ID.PATIENT_FK, STUDY_ID.STUDY_ID FROM STUDY_ID JOIN IRB_PROTOCOL IRB ON STUDY_ID.IRB_PROTOCOL_FK = IRB.ID AND IRB.PROTOCOL_NUMBER = '2016P111111') SID ON SID.PATIENT_FK = P.ID
JOIN PT_CONSENT_STATUS PCS ON PC.ID = PCS.PATIENT_CONSENT_FK
JOIN CONSENT_STATUS_SINGLE CSS ON PCS.ID = CSS.ID
JOIN QUESTION Q ON PCS.QUESTION_FK = Q.ID
JOIN QUESTION_TYPE QT ON QT.ID = Q.QUESTION_TYPE_FK AND QT.TYPE = 'Consent'
JOIN CHOICE C ON CSS.CHOICE_FK = C.ID AND C.TEXT IN ('Consented')
JOIN (SELECT PCS.PATIENT_CONSENT_FK, C.TEXT FROM PT_CONSENT_STATUS PCS
JOIN CONSENT_STATUS_SINGLE CSS ON PCS.ID = CSS.ID
JOIN QUESTION Q ON PCS.QUESTION_FK = Q.ID
JOIN QUESTION_TAG QTAG ON QTAG.QUESTION_FK = Q.ID
JOIN TAG T ON T.ID = QTAG.TAG_FK AND T.CODE = 'VID'
JOIN CHOICE C ON C.ID = CSS.CHOICE_FK) VALIDATED ON VALIDATED.PATIENT_CONSENT_FK = PC.ID) PMI_CONSENTED ON PMI_CONSENTED.PMI_ID = HPD.HP_PMI_ID;
69 changes: 69 additions & 0 deletions PHS_MRN_PID_mapping/Health_Pro_data.ctl
Original file line number Diff line number Diff line change
@@ -0,0 +1,69 @@
load data
truncate
into table HEALTH_PRO_DATA
fields terminated by ','
OPTIONALLY ENCLOSED BY '"' AND '"'
trailing nullcols
( PMI_ID CHAR(4000),
Biobank_ID CHAR(4000),
Last_Name CHAR(4000),
First_Name CHAR(4000),
Date_of_Birth DATE "MM/DD/YYYY",
Language CHAR(4000),
General_Consent_Status CHAR(4000),
General_Consent_Date DATE "MM/DD/YYYY",
EHR_Consent_Status CHAR(4000),
EHR_Consent_Date DATE "MM/DD/YYYY",
CABoR_Consent_Status CHAR(4000),
CABoR_Consent_Date DATE "MM/DD/YYYY",
Withdrawal_Status CHAR(4000),
Withdrawal_Date DATE "MM/DD/YYYY",
Street_Address CHAR(4000),
City CHAR(4000),
State CHAR(4000),
ZIP CHAR(4000),
Email CHAR(4000),
Phone CHAR(4000),
Sex CHAR(4000),
Gender_Identity CHAR(4000),
Sexual_Orientation CHAR(4000),
Race_Ethnicity CHAR(4000),
Education CHAR(4000),
Income CHAR(4000),
Required_PPI_Surveys_Complete CHAR(4000),
Completed_Surveys CHAR(4000),
Basics_PPI_Survey_Complete CHAR(4000),
Basics_PPI_Survey_Date DATE "MM/DD/YYYY",
Health_PPI_Survey_Complete CHAR(4000),
Health_PPI_Survey_Date DATE "MM/DD/YYYY",
Lifestyle_PPI_Survey_Complete CHAR(4000),
Lifestyle_PPI_Survey_Date DATE "MM/DD/YYYY",
Hist_PPI_Survey_Complete CHAR(4000),
Hist_PPI_Survey_Date DATE "MM/DD/YYYY",
Meds_PPI_Survey_Complete CHAR(4000),
Meds_PPI_Survey_Date DATE "MM/DD/YYYY",
Family_PPI_Survey_Complete CHAR(4000),
Family_PPI_Survey_Date DATE "MM/DD/YYYY",
Access_PPI_Survey_Complete CHAR(4000),
Access_PPI_Survey_Date DATE "MM/DD/YYYY",
Physical_Measurements_Status CHAR(4000),
Physical_Measurements_Date DATE "MM/DD/YYYY",
Samples_for_DNA_Received CHAR(4000),
Biospecimens CHAR(4000),
SST_Collected CHAR(4000),
SST_Collection_Date DATE "MM/DD/YYYY",
PST_Collected CHAR(4000),
PST_Collection_Date DATE "MM/DD/YYYY",
NaHep_Collected CHAR(4000),
NaHep_Collection_Date DATE "MM/DD/YYYY",
EDTA_Collected CHAR(4000),
EDTA_Collection_Date CHAR(4000),
EDTA1_Collected CHAR(4000),
EDTA1_Collection_Date DATE "MM/DD/YYYY",
EDTA2_Collected CHAR(4000),
EDTA2_Collection_Date DATE "MM/DD/YYYY",
Urine_10_mL_Collected CHAR(4000),
Urine_Colletction_Date DATE "MM/DD/YYYY",
Saliva_Collected CHAR(4000),
Saliva_Collection_Date DATE "MM/DD/YYYY"
)
5 changes: 5 additions & 0 deletions PHS_MRN_PID_mapping/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
Create_Health_Pro_Data_Table.sql will create a table for storing a health pro 'work queue'
Health_Pro_data.ctl is a SQLLDR control file for importing health pro a 'work queue' into the Health_Pro_Data table
HealthProView.sql defines a table that joins Health Pro data to AoU consents tracked in Constrack
AOU_Matching.sql is a PL/SQL script that checks the data for issues and generates a Mapping between MRNs and AoU participant ids for use in the EHR ETL at PHS

0 comments on commit 7959d0c

Please sign in to comment.