Skip to content

Commit

Permalink
changed demographics and encounter procedures to use OMOP references …
Browse files Browse the repository at this point in the history
…and column names. Changed PCORI_basecode to OMOP_basecode in these procs
  • Loading branch information
matthewjoss committed Jan 11, 2017
1 parent 9a3f78f commit c2c11e0
Show file tree
Hide file tree
Showing 2 changed files with 63 additions and 57 deletions.
112 changes: 59 additions & 53 deletions MSSQL/OMOPLoader.sql
Original file line number Diff line number Diff line change
Expand Up @@ -217,12 +217,14 @@ DECLARE @sqltext NVARCHAR(4000);
DECLARE @batchid numeric
declare getsql cursor local for
--1 -- S,R,NH
select 'insert into person(gender_source_value,person_id,year_of_birth,time_of_birth,gender_concept_id,ethnicity_source_value,race_source_value) '+ --person(raw_sex,PATID, BIRTH_DATE, BIRTH_TIME,SEX, HISPANIC, RACE)
' select ''1'',patient_num, '+
' birth_date, '+
select 'insert into person(gender_source_value,race_source_value,ethnicity_source_value,person_id,year_of_birth,month_of_birth,day_of_birth,time_of_birth,gender_concept_id,ethnicity_concept_id,race_concept_id) '+ --person(raw_sex,PATID, BIRTH_DATE, BIRTH_TIME,SEX, HISPANIC, RACE)
' select p.sex_cd,p.race_cd,p.race_cd,patient_num, '+
' year(birth_date), '+
' month(birth_date), '+
' day(birth_date), '+
' substring(convert(varchar,birth_date,20),12,5), '+
''''+sex.omop_basecode+''','+
'''NI'','+
'0,'+
''''+race.omop_basecode+''''+
' from i2b2patient p '+
' where lower(p.sex_cd) in ('+lower(sex.c_dimcode)+') '+
Expand All @@ -234,9 +236,11 @@ declare getsql cursor local for
and sex.c_fullname like '\PCORI\DEMOGRAPHIC\SEX%'
and sex.c_visualattributes like 'L%'
union -- A - S,R,H
select 'insert into person(raw_sex,PATID, BIRTH_DATE, BIRTH_TIME,SEX, HISPANIC, RACE) '+
' select ''A'',patient_num, '+
' birth_date, '+
select 'insert into person(gender_source_value,race_source_value,ethnicity_source_value,person_id,year_of_birth,month_of_birth,day_of_birth,time_of_birth,gender_concept_id,ethnicity_concept_id,race_concept_id) '+
' select p.sex_cd,p.race_cd,p.race_cd,patient_num, '+
' year(birth_date), '+
' month(birth_date), '+
' day(birth_date), '+
' substring(convert(varchar,birth_date,20),12,5), '+
''''+sex.omop_basecode+''','+
''''+hisp.omop_basecode+''','+
Expand All @@ -254,13 +258,15 @@ select 'insert into person(raw_sex,PATID, BIRTH_DATE, BIRTH_TIME,SEX, HISPANIC,
and sex.c_fullname like '\PCORI\DEMOGRAPHIC\SEX%'
and sex.c_visualattributes like 'L%'
union --2 S, nR, nH
select 'insert into person(raw_sex,PATID, BIRTH_DATE, BIRTH_TIME,SEX, HISPANIC, RACE) '+
' select ''2'',patient_num, '+
' birth_date, '+
select 'insert into person(gender_source_value,race_source_value,ethnicity_source_value,person_id,year_of_birth,month_of_birth,day_of_birth,time_of_birth,gender_concept_id,ethnicity_concept_id,race_concept_id) '+
' select p.sex_cd,p.race_cd,p.race_cd,patient_num, '+
' year(birth_date), '+
' month(birth_date), '+
' day(birth_date), '+
' substring(convert(varchar,birth_date,20),12,5), '+
''''+sex.omop_basecode+''','+
'''NI'','+
'''NI'''+
'0,'+
'0'+
' from i2b2patient p '+
' where lower(isnull(p.sex_cd,''xx'')) in ('+lower(sex.c_dimcode)+') '+
' and lower(isnull(p.race_cd,''xx'')) not in (select lower(code) from omop_codelist where codetype=''RACE'') '+
Expand All @@ -269,12 +275,14 @@ union --2 S, nR, nH
where sex.c_fullname like '\PCORI\DEMOGRAPHIC\SEX%'
and sex.c_visualattributes like 'L%'
union --3 -- nS,R, NH
select 'insert into person(raw_sex,PATID, BIRTH_DATE, BIRTH_TIME,SEX, HISPANIC, RACE) '+
' select ''3'',patient_num, '+
' birth_date, '+
select 'insert into person(gender_source_value,race_source_value,ethnicity_source_value,person_id,year_of_birth,month_of_birth,day_of_birth,time_of_birth,gender_concept_id,ethnicity_concept_id,race_concept_id) '+
' select p.sex_cd,p.race_cd,p.race_cd,patient_num, '+
' year(birth_date), '+
' month(birth_date), '+
' day(birth_date), '+
' substring(convert(varchar,birth_date,20),12,5), '+
'''NI'','+
'''NI'','+
'0,'+
'0,'+
''''+race.omop_basecode+''''+
' from i2b2patient p '+
' where lower(isnull(p.sex_cd,''xx'')) not in (select lower(code) from omop_codelist where codetype=''SEX'') '+
Expand All @@ -284,11 +292,13 @@ union --3 -- nS,R, NH
where race.c_fullname like '\PCORI\DEMOGRAPHIC\RACE%'
and race.c_visualattributes like 'L%'
union --B -- nS,R, H
select 'insert into person(raw_sex,PATID, BIRTH_DATE, BIRTH_TIME,SEX, HISPANIC, RACE) '+
' select ''B'',patient_num, '+
' birth_date, '+
select 'insert into person(gender_source_value,race_source_value,ethnicity_source_value,person_id,year_of_birth,month_of_birth,day_of_birth,time_of_birth,gender_concept_id,ethnicity_concept_id,race_concept_id) '+
' select p.sex_cd,p.race_cd,p.race_cd,patient_num, '+
' year(birth_date), '+
' month(birth_date), '+
' day(birth_date), '+
' substring(convert(varchar,birth_date,20),12,5), '+
'''NI'','+
'0,'+
''''+hisp.omop_basecode+''','+
''''+race.omop_basecode+''''+
' from i2b2patient p '+
Expand All @@ -302,13 +312,15 @@ union --B -- nS,R, H
and hisp.c_fullname like '\PCORI\DEMOGRAPHIC\HISPANIC\Y%'
and hisp.c_visualattributes like 'L%'
union --4 -- S, NR, H
select 'insert into person(raw_sex,PATID, BIRTH_DATE, BIRTH_TIME,SEX, HISPANIC, RACE) '+
' select ''4'',patient_num, '+
' birth_date, '+
select 'insert into person(gender_source_value,race_source_value,ethnicity_source_value,person_id,year_of_birth,month_of_birth,day_of_birth,time_of_birth,gender_concept_id,ethnicity_concept_id,race_concept_id) '+
' select p.sex_cd,p.race_cd,p.race_cd,patient_num, '+
' year(birth_date), '+
' month(birth_date), '+
' day(birth_date), '+
' substring(convert(varchar,birth_date,20),12,5), '+
''''+sex.omop_basecode+''','+
'''Y'','+
'''NI'''+
'38003563,'+
'0'+
' from i2b2patient p '+
' where lower(isnull(p.sex_cd,''NI'')) in ('+lower(sex.c_dimcode)+') '+
' and lower(isnull(p.race_cd,''xx'')) not in (select lower(code) from omop_codelist where codetype=''RACE'') '+
Expand All @@ -317,25 +329,29 @@ union --4 -- S, NR, H
where sex.c_fullname like '\PCORI\DEMOGRAPHIC\SEX%'
and sex.c_visualattributes like 'L%'
union --5 -- NS, NR, H
select 'insert into person(raw_sex,PATID, BIRTH_DATE, BIRTH_TIME,SEX, HISPANIC, RACE) '+
' select ''5'',patient_num, '+
' birth_date, '+
select 'insert into person(gender_source_value,race_source_value,ethnicity_source_value,person_id,year_of_birth,month_of_birth,day_of_birth,time_of_birth,gender_concept_id,ethnicity_concept_id,race_concept_id) '+
' select p.sex_cd,p.race_cd,p.race_cd,patient_num, '+
' year(birth_date), '+
' month(birth_date), '+
' day(birth_date), '+
' substring(convert(varchar,birth_date,20),12,5), '+
'''NI'','+
'''Y'','+
'''NI'''+
'0,'+
'38003563,'+
'0'+
' from i2b2patient p '+
' where lower(isnull(p.sex_cd,''xx'')) not in (select lower(code) from omop_codelist where codetype=''SEX'') '+
' and lower(isnull(p.race_cd,''xx'')) not in (select lower(code) from omop_codelist where codetype=''RACE'') '+
' and lower(isnull(p.race_cd,''xx'')) in (select lower(code) from omop_codelist where codetype=''HISPANIC'')'
union --6 -- NS, NR, nH
select 'insert into person(raw_sex,PATID, BIRTH_DATE, BIRTH_TIME,SEX, HISPANIC, RACE) '+
' select ''6'',patient_num, '+
' birth_date, '+
select 'insert into person(gender_source_value,race_source_value,ethnicity_source_value,person_id,year_of_birth,month_of_birth,day_of_birth,time_of_birth,gender_concept_id,ethnicity_concept_id,race_concept_id) '+
' select p.sex_cd,p.race_cd,p.race_cd,patient_num, '+
' year(birth_date), '+
' month(birth_date), '+
' day(birth_date), '+
' substring(convert(varchar,birth_date,20),12,5), '+
'''NI'','+
'''NI'','+
'''NI'''+
'0,'+
'0,'+
'0'+
' from i2b2patient p '+
' where lower(isnull(p.sex_cd,''xx'')) not in (select lower(code) from omop_codelist where codetype=''SEX'') '+
' and lower(isnull(p.race_cd,''xx'')) not in (select lower(code) from omop_codelist where codetype=''HISPANIC'') '+
Expand All @@ -359,16 +375,6 @@ END
CLOSE getsql;
DEALLOCATE getsql;

--UPDATE pmndemographic TO DISPLAY CORRECT BIOBANK_FLAG BASED ON CONCEPT CODE LISTED IN OBSERVATION_FACT: modified by Matthew Joss

UPDATE pmndemographic
SET BIOBANK_FLAG = 'Y'
WHERE PATID IN (SELECT PATID FROM pmndemographic demo INNER JOIN i2b2fact OBS
ON demo.PATID = OBS.PATIENT_NUM
INNER JOIN pcornet_demo P
ON OBS.CONCEPT_CD = P.C_BASECODE
WHERE P.C_FULLNAME LIKE '\PCORI\DEMOGRAPHIC\BIOBANK_FLAG\Y\%')

end

go
Expand All @@ -388,9 +394,9 @@ create procedure OMOPencounter as
DECLARE @sqltext NVARCHAR(4000);
begin

insert into pmnencounter(PATID,ENCOUNTERID,admit_date ,ADMIT_TIME ,
DISCHARGE_DATE ,DISCHARGE_TIME ,PROVIDERID ,FACILITY_LOCATION
,ENC_TYPE ,FACILITYID ,DISCHARGE_DISPOSITION ,
insert into visit_occurrence(person_id,visit_occurrence_id,visit_start_date,visit_start_time,
visit_end_date,visit_end_time,provider_id,FACILITY_LOCATION
,visit_concept_id ,care_site_id,DISCHARGE_DISPOSITION ,
DISCHARGE_STATUS ,DRG ,DRG_TYPE ,ADMITTING_SOURCE)
select distinct v.patient_num, v.encounter_num,
start_Date,
Expand All @@ -404,15 +410,15 @@ left outer join
(select * from
(select *,row_number() over (partition by patient_num, encounter_num order by drg_type desc) AS rn from
(select patient_num,encounter_num,drg_type,max(drg) drg from
(select distinct f.patient_num,encounter_num,substring(c_fullname,22,2) drg_type,substring(pcori_basecode,charindex(':',pcori_basecode)+1,3) drg from i2b2fact f
(select distinct f.patient_num,encounter_num,substring(c_fullname,22,2) drg_type,substring(omop_basecode,charindex(':',omop_basecode)+1,3) drg from i2b2fact f
inner join pmndemographic d on f.patient_num=d.patid
inner join pcornet_enc enc on enc.c_basecode = f.concept_cd
and enc.c_fullname like '\PCORI\ENCOUNTER\DRG\%') drg1 group by patient_num,encounter_num,drg_type) drg) drg
where rn=1) drg -- This section is bugfixed to only include 1 drg if multiple DRG types exist in a single encounter...
on drg.patient_num=v.patient_num and drg.encounter_num=v.encounter_num
left outer join
-- Encounter type. Note that this requires a full table scan on the ontology table, so it is not particularly efficient.
(select patient_num, encounter_num, inout_cd,substring(pcori_basecode,charindex(':',pcori_basecode)+1,2) pcori_enctype from i2b2visit v
(select patient_num, encounter_num, inout_cd,substring(omop_basecode,charindex(':',omop_basecode)+1,2) pcori_enctype from i2b2visit v
inner join pcornet_enc e on c_dimcode like '%'''+inout_cd+'''%' and e.c_fullname like '\PCORI\ENCOUNTER\ENC_TYPE\%') enctype
on enctype.patient_num=v.patient_num and enctype.encounter_num=v.encounter_num

Expand Down
8 changes: 4 additions & 4 deletions MSSQL/run.sql
Original file line number Diff line number Diff line change
Expand Up @@ -78,13 +78,13 @@ delete from pmnharvest
GO
exec PCORNetHarvest
GO
delete from pmndemographic
delete from person
GO
exec PCORNetDemographics
exec OMOPdemographics
GO
delete from pmnENCOUNTER
delete from visit_occurrence
GO
exec PCORNetEncounter
exec OMOPencounter
GO
delete from pmndiagnosis
GO
Expand Down

0 comments on commit c2c11e0

Please sign in to comment.