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

Adding CS Linelist MTCT for assessing PMTCT gaps #549

Open
wants to merge 7 commits into
base: dev
Choose a base branch
from
117 changes: 117 additions & 0 deletions Scripts/REPORTING/HIVCaseSurveillance/load_cs_LinelistMTCT.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,117 @@
IF OBJECT_ID(N'[HIVCaseSurveillance].[dbo].[CsLinelistMTCT]', N'U') IS NOT NULL
DROP TABLE [HIVCaseSurveillance].[dbo].[CsLinelistMTCT]
Begin
WITH Viralloads As (
SELECT
vlhist.PatientKey,
pat.PatientPKHash,
row_number () over (partition by vlhist.PatientKey order by OrderedbyDate desc) as rank,
vlhist.FacilityKey,
fac.MFLCode,
AgeGroupKey,
TestResult,
IsPBFW,
fac.FacilityName
from NDWH.Fact.FactViralLoad_Historical as vlhist
left join NDWH.Dim.DimPatient as pat on pat.PatientKey=vlhist.Patientkey
left join NDWH.Dim.DimFacility as fac on fac.FacilityKey=vlhist.Facilitykey
where IsPBFW=1 and TRY_CAST(REPLACE(TestResult, ',', '') AS FLOAT) >= 200.00
Copy link
Contributor

Choose a reason for hiding this comment

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

suggestion (performance): Consider reordering WHERE clause conditions for better performance

Moving the IsPBFW=1 condition before the expensive TRY_CAST operation would allow rows to be filtered out earlier, potentially improving query performance.

Suggested change
where IsPBFW=1 and TRY_CAST(REPLACE(TestResult, ',', '') AS FLOAT) >= 200.00
where IsPBFW=1
and TRY_CAST(REPLACE(TestResult, ',', '') AS FLOAT) >= 200.00

),
Viralloads_LatestRecord as (
SELECT
PatientKey,
PatientPKHash,
MFLCode,
TestResult,
IsPBFW
from Viralloads
where rank=1
),
HEIs AS (
SELECT
heis.Patientkey,
pat.DOB,
eomonth(DOB) as CohortYearMonth,
fac.MFLCode,
fac.FacilityName,
fac.County,
fac.SubCounty,
agency.AgencyName,
partner.PartnerName,
age.DATIMAgeGroup,
MothersPatientpkhash,
Paired,
MotherOnART,
OnProhylaxis as InfantGivenProphylaxis,
InfectedAt24mnths,
HEIHIVStatus,
HasFinalAntibody,
age.DatimAgeGroup as AgeGroup,
pat.Gender,
case when vls.patientpkhash is not null then 1 Else 0 End as MotherUnsuppressedDuringPBF
from NDWH.Fact.FactHEI as heis
left join NDWH.Dim.DimFacility as fac on fac.FacilityKey=heis.FacilityKey
left join NDWH.Dim.DimAgency as agency on agency.AgencyKey=heis.AgencyKey
left join NDWH.Dim.DimPartner as partner on partner.PartnerKey=heis.PartnerKey
left join NDWH.Dim.DimAgeGroup as age on age.AgeGroupKey=heis.AgeGroupKey
left join NDWH.Dim.DimPatient as pat on pat.PatientKey=heis.PatientKey
left join Viralloads_LatestRecord as vls on vls.patientpkhash = heis.MothersPatientPkHash and vls.mflcode=fac.MFLCode


),
PBFW_StartDate as (
Select
Row_number() OVER ( Partition BY pbfw.Patientkey ORDER BY Ancdate1 desc ) as num,
pbfw.Patientkey,
pat.PatientPKHash,
fac.MFLCode,
coalesce (Ancdate1,Ancdate2,Ancdate3,Ancdate4) as FirstVisitDuringPBFW
from NDWH.Fact.Factpbfw as pbfw
left join NDWH.Dim.DimPatient as pat on pat.PatientKey=pbfw.Patientkey
left join NDWH.Dim.DimFacility as fac on fac.FacilityKey=pbfw.Facilitykey
where Ancdate1 is not null
),
IIT as (
Select
arthist.PatientKey,
Row_number() OVER ( Partition BY arthist.Patientkey ORDER BY AsOfDate desc ) as num,
AsOfDate,
ARTOutcome
from NDWH.Fact.FactARTHistory as arthist
left join PBFW_StartDate on PBFW_StartDate.Patientkey=arthist.PatientKey
WHERE ARTOutcome IN ('UNDOCUMENTED LOSS', 'LOSS TO FOLLOW UP') AND AsOfDate BETWEEN
(SELECT MIN(FirstVisitDuringPBFW) FROM PBFW_StartDate)
AND (SELECT MAX(FirstVisitDuringPBFW) FROM PBFW_StartDate)
)
Select
HEIs.PatientKey,
DOB,
HEIs.MFLCode,
AgencyName,
PartnerName,
CohortYearMonth,
County,
SubCounty,
DATIMAgeGroup as Agegroup,
MothersPatientpkhash,
Paired,
MotherOnART,
case when HEIs.PatientKey is not null then 1 Else 0 End as IsHEI,
case when MotherOnART=0 Then 1 Else 0 End as MothersNotonART,
InfantGivenProphylaxis,
case when InfantGivenProphylaxis =0 Then 1 Else 0 End as InfantNotGivenProphylaxis,
case when MothersPatientPkHash is not null then 1 Else 0 End as KPandP,
InfectedAt24mnths as PositiveInfants,
MotherUnsuppressedDuringPBF,
FirstVisitDuringPBFW,
case when IIT.PatientKey is not null then 1 Else 0 End as IITEpisode
Into [HIVCaseSurveillance].[dbo].[CsLinelistMTCT]
from HEIs
left JOIN PBFW_StartDate on PBFW_StartDate.PatientPKHash=HEIs.MothersPatientPkHash and PBFW_StartDate.MFLCode=HEIs.MFLCode
left join IIT on IIT.PatientKey=HEIs.PatientKey and IIT.num=1
End