diff --git a/Scripts/NDWH/C&T FACT TABLES/load_FactNCDs.sql b/Scripts/NDWH/C&T FACT TABLES/load_FactNCDs.sql new file mode 100644 index 00000000..0fce528d --- /dev/null +++ b/Scripts/NDWH/C&T FACT TABLES/load_FactNCDs.sql @@ -0,0 +1,168 @@ +IF OBJECT_ID(N'[NDWH].[dbo].[FactNCD]', N'U') IS NOT NULL + DROP TABLE [NDWH].[dbo].[FactNCD] + +GO + +BEGIN + +with ncd_source_data as ( + select + * + from ( + select + distinct + case + when value = 'Alzheimers Disease and other Dementias' then 'Alzheimer''s Disease and other Dementias' + else value + end as value, + PatientPKHash, + PatientPK, + SiteCode + from ODS.dbo.CT_AllergiesChronicIllness as chronic + cross apply STRING_SPLIT(chronic.ChronicIllness, '|') + ) as chronic + pivot( + count(value) + for value IN ( + "Alzheimers Disease and other Dementias", + "Alzheimer's Disease and other Dementias", + "Arthritis", + "Asthma", + "Cancer", + "Cardiovascular diseases", + "Chronic Hepatitis", + "Chronic Kidney Disease", + "Chronic Obstructive Pulmonary Disease(COPD)", + "Chronic Renal Failure", + "Cystic Fibrosis", + "Deafness and Hearing Impairment", + "Diabetes", + "Endometriosis", + "Epilepsy", + "Glaucoma", + "Heart Disease", + "Hyperlipidaemia", + "Hypertension", + "Hypothyroidism", + "Mental illness", + "Multiple Sclerosis", + "Obesity", + "Osteoporosis", + "Sickle Cell Anaemia", + "Thyroid disease" + ) + ) as pivot_table +), +MFL_partner_agency_combination as ( + select + distinct MFL_Code, + SDP, + SDP_Agency as Agency + from ODS.dbo.All_EMRSites +), +diabetes_tests_ordering as ( + /* get all Diabetes tests and order by date*/ + SELECT + ROW_NUMBER() OVER (PARTITION BY PatientPKHash, Sitecode ORDER BY OrderedbyDate DESC) AS RowNum, + PatientPKHash, + SiteCode, + TestName, + TRY_CAST(TestResult AS NUMERIC(18, 2)) AS NumericTestResult + FROM ODS.dbo.CT_PatientLabs + WHERE + TestName in ('HgB', 'HbsAg', 'HBA1C') + or TestName in ('FBS', 'Blood Sugar') + +), +latest_diabetes_test as ( + select + * + from diabetes_tests_ordering where RowNum = 1 +), +latest_diabetes_test_controlled as ( + /* get all last Diabetes tests that are within the controlled range*/ + select + * + from latest_diabetes_test + where (TestName IN ('HgB', 'HbsAg', 'HBA1C') AND NumericTestResult <= 6.5) + or (TestName IN ('FBS', 'Blood Sugar') AND NumericTestResult < 7.0) +), +visits_ordering as ( + select + PatientPKHash, + PatientPK, + SiteCode, + VisitDate, + row_number() over (partition by PatientPK, Sitecode order by VisitDate desc) as rank + from ODS.dbo.CT_AllergiesChronicIllness as chronic +), +age_as_of_last_visit as ( + select + visits_ordering.PatientPKHash, + visits_ordering.PatientPK, + visits_ordering.SiteCode, + datediff(yy, patient.DOB, coalesce(visits_ordering.VisitDate, getdate() )) As AgeLastVisit + from visits_ordering + inner join ODS.dbo.CT_Patient as patient on patient.PatientPKHash = visits_ordering.PatientPKHash + and patient.SiteCode = visits_ordering.SiteCode + where rank = 1 +) +select + Factkey = IDENTITY(INT, 1, 1), + patient.PatientKey, + facility.FacilityKey, + partner.PartnerKey, + agency.AgencyKey, + age_group.AgeGroupKey, + ncd_source_data."Alzheimer's Disease and other Dementias", + ncd_source_data."Arthritis", + ncd_source_data."Asthma", + ncd_source_data."Cancer", + ncd_source_data."Cardiovascular diseases", + ncd_source_data."Chronic Hepatitis", + ncd_source_data."Chronic Kidney Disease", + ncd_source_data."Chronic Obstructive Pulmonary Disease(COPD)", + ncd_source_data."Chronic Renal Failure", + ncd_source_data."Cystic Fibrosis", + ncd_source_data."Deafness and Hearing Impairment", + ncd_source_data."Diabetes", + ncd_source_data."Endometriosis", + ncd_source_data."Epilepsy", + ncd_source_data."Glaucoma", + ncd_source_data."Heart Disease", + ncd_source_data."Hyperlipidaemia", + ncd_source_data."Hypertension", + ncd_source_data."Hypothyroidism", + ncd_source_data."Mental illness", + ncd_source_data."Multiple Sclerosis", + ncd_source_data."Obesity", + ncd_source_data."Osteoporosis", + ncd_source_data."Sickle Cell Anaemia", + ncd_source_data."Thyroid disease", + case when latest_diabetes_test.PatientPKHash is not null then 1 else 0 end as ScreenedDiabetes, + case when latest_diabetes_test_controlled.PatientPKHash is not null then 1 else 0 end as IsDiabetesControlledAtLastTest, + coalesce(visit.ScreenedBPLastVisit,0) as ScreenedBPLastVisit, + coalesce(visit.IsBPControlledAtLastVisit, 0) as IsBPControlledAtLastVisit +into NDWH.dbo.FactNCD +from ncd_source_data +left join latest_diabetes_test on latest_diabetes_test.PatientPKHash = ncd_source_data.PatientPKHash + and latest_diabetes_test.SiteCode = ncd_source_data.SiteCode +left join latest_diabetes_test_controlled on latest_diabetes_test_controlled.PatientPKHash = ncd_source_data.PatientPKHash + and latest_diabetes_test_controlled.SiteCode = ncd_source_data.SiteCode +left join NDWH.dbo.DimPatient as patient on patient.PatientPKHash = ncd_source_data.PatientPKHash + and patient.SiteCode = ncd_source_data.SiteCode +left join ODS.dbo.Intermediate_LastVisitDate as visit on visit.PatientPK = ncd_source_data.PatientPK + and visit.SiteCode = ncd_source_data.SiteCode +left join age_as_of_last_visit on age_as_of_last_visit.PatientPKHash = ncd_source_data.PatientPKHash + and age_as_of_last_visit.SiteCode = ncd_source_data.SiteCode +left join NDWH.dbo.DimFacility as facility on facility.MFLCode = ncd_source_data.SiteCode +left join MFL_partner_agency_combination on MFL_partner_agency_combination.MFL_Code = ncd_source_data.SiteCode +left join NDWH.dbo.DimPartner as partner on partner.PartnerName = MFL_partner_agency_combination.SDP +left join NDWH.dbo.DimAgency as agency on agency.AgencyName = MFL_partner_agency_combination.Agency +left join NDWH.dbo.DimAgeGroup as age_group on age_group.Age = age_as_of_last_visit.AgeLastVisit; + + + +alter table NDWH.dbo.FactNCD add primary key(FactKey); + +END \ No newline at end of file diff --git a/Scripts/ODS/data_quality/CT_cleaning_scripts/clean_CT_allergies_chronic_illness.sql b/Scripts/ODS/data_quality/CT_cleaning_scripts/clean_CT_allergies_chronic_illness.sql index 2a239e46..39e4dc26 100644 --- a/Scripts/ODS/data_quality/CT_cleaning_scripts/clean_CT_allergies_chronic_illness.sql +++ b/Scripts/ODS/data_quality/CT_cleaning_scripts/clean_CT_allergies_chronic_illness.sql @@ -1,11 +1,3 @@ --- clean ChronicIllness -UPDATE [ODS].[DBO].[CT_AllergiesChronicIllness] - SET ChronicIllness = lkp_chronic_illness.target_name -FROM [ODS].[DBO].[CT_AllergiesChronicIllness] AS allergies_chronic_illness -INNER JOIN ods.dbo.lkp_chronic_illness ON lkp_chronic_illness.source_name = allergies_chronic_illness.ChronicIllness - -GO - -- clean ChronicOnsetDate UPDATE [ODS].[DBO].[CT_AllergiesChronicIllness] SET ChronicOnsetDate = NULL diff --git a/Scripts/ODS/data_quality/look_up_tables/lkp_chronic_illness.sql b/Scripts/ODS/data_quality/look_up_tables/lkp_chronic_illness.sql deleted file mode 100644 index d4c4bf63..00000000 --- a/Scripts/ODS/data_quality/look_up_tables/lkp_chronic_illness.sql +++ /dev/null @@ -1,159 +0,0 @@ -IF OBJECT_ID(N'[ODS].[DBO].[lkp_chronic_illness]', N'U') IS NOT NULL - DROP TABLE [ODS].[DBO].[lkp_chronic_illness]; -BEGIN - -- create table statement - CREATE TABLE [ODS].[DBO].[lkp_chronic_illness]( - source_name VARCHAR(100) NOT NULL PRIMARY KEY WITH (IGNORE_DUP_KEY = ON), - target_name VARCHAR(100) NOT NULL, - date_created DATE NOT NULL - ) - - -- insert to table statement - INSERT INTO [ODS].[DBO].[lkp_chronic_illness]( - source_name, - target_name, - date_created - ) - VALUES - ('Alzheimers Disease and other Dementias','Alzheimer''s Disease and other Dementias',GETDATE()), - ('Arthritis','Arthritis',GETDATE()), - ('Arthritis|Asthma','Arthritis',GETDATE()), - ('Arthritis|Asthma|Hypertension','Arthritis',GETDATE()), - ('Arthritis|Chronic Renal Failure|Osteoporosis','Arthritis',GETDATE()), - ('Arthritis|Diabetes|Hypertension','Arthritis',GETDATE()), - ('Arthritis|Hypertension','Arthritis',GETDATE()), - ('Arthritis|Hypertension|Asthma','Arthritis',GETDATE()), - ('Arthritis|Hypertension|Mental illness','Arthritis',GETDATE()), - ('Arthritis|Hypertension|Obesity','Arthritis',GETDATE()), - ('Arthritis|Obesity','Arthritis',GETDATE()), - ('Arthritis|Osteoporosis','Arthritis',GETDATE()), - ('Asthma','Asthma',GETDATE()), - ('Asthma|Asthma','Asthma',GETDATE()), - ('Asthma|Diabetes','Asthma',GETDATE()), - ('Asthma|Hypertension','Asthma',GETDATE()), - ('Asthma|Hypothyroidism','Asthma',GETDATE()), - ('Asthma|Obesity','Asthma',GETDATE()), - ('Cancer','Cancer',GETDATE()), - ('Cancer|Asthma','Cancer',GETDATE()), - ('Cancer|Chronic Kidney Disease','Cancer',GETDATE()), - ('Cancer|Hypertension','Cancer',GETDATE()), - ('Cancer|Hypertension|Chronic Kidney Disease','Cancer',GETDATE()), - ('Cancer|Mental illness','Cancer',GETDATE()), - ('Cancer|Obesity','Cancer',GETDATE()), - ('Cardiovascular diseases','Cardiovascular diseases',GETDATE()), - ('Cardiovascular diseases|Asthma|Cardiovascular diseases|Asthma','Cardiovascular diseases',GETDATE()), - ('Cardiovascular diseases|Hypertension','Cardiovascular diseases',GETDATE()), - ('Chronic Hepatitis','Chronic Hepatitis',GETDATE()), - ('Chronic Kidney Disease','Chronic Kidney Disease',GETDATE()), - ('Chronic Kidney Disease|Chronic Hepatitis','Chronic Kidney Disease',GETDATE()), - ('Chronic Kidney Disease|Diabetes|Hypertension','Chronic Kidney Disease',GETDATE()), - ('Chronic Kidney Disease|Hypertension','Chronic Kidney Disease',GETDATE()), - ('Chronic Kidney Disease|Thyroid disease','Chronic Kidney Disease',GETDATE()), - ('Chronic Obstructive Pulmonary Disease(COPD)','Chronic Kidney Disease',GETDATE()), - ('Chronic Renal Failure','Chronic Renal Failure',GETDATE()), - ('Chronic Renal Failure|Diabetes|Hypertension','Chronic Renal Failure',GETDATE()), - ('Chronic Renal Failure|Hypertension','Chronic Renal Failure',GETDATE()), - ('Chronic Renal Failure|Hypertension|Diabetes','Chronic Renal Failure',GETDATE()), - ('Chronic Renal Failure|Hypertension|Heart Disease','Chronic Renal Failure',GETDATE()), - ('Cystic Fibrosis','Cystic Fibrosis',GETDATE()), - ('Deafness and Hearing impairment','Deafness and Hearing Impairment',GETDATE()), - ('Deafness and Hearing impairment|Deafness and Hearing impairment','Deafness and Hearing Impairment',GETDATE()), - ('Deafness and Hearing impairment|Hypertension','Deafness and Hearing Impairment',GETDATE()), - ('Diabetes','Diabetes',GETDATE()), - ('Diabetes|Arthritis','Diabetes',GETDATE()), - ('Diabetes|Arthritis|Hypertension','Diabetes',GETDATE()), - ('Diabetes|Asthma','Diabetes',GETDATE()), - ('Diabetes|Asthma|Hypertension','Diabetes',GETDATE()), - ('Diabetes|Cardiovascular diseases','Diabetes',GETDATE()), - ('Diabetes|Chronic Kidney Disease','Diabetes',GETDATE()), - ('Diabetes|Diabetes','Diabetes',GETDATE()), - ('Diabetes|Epilepsy','Diabetes',GETDATE()), - ('Diabetes|Glaucoma','Diabetes',GETDATE()), - ('Diabetes|Heart Disease','Diabetes',GETDATE()), - ('Diabetes|Hyperlipidaemia','Diabetes',GETDATE()), - ('Diabetes|Hypertension','Diabetes',GETDATE()), - ('Diabetes|Hypertension|Arthritis','Diabetes',GETDATE()), - ('Diabetes|Hypertension|Asthma','Diabetes',GETDATE()), - ('Diabetes|Hypertension|Hypertension','Diabetes',GETDATE()), - ('Diabetes|Hypertension|Mental illness','Diabetes',GETDATE()), - ('Diabetes|Hypertension|Obesity','Diabetes',GETDATE()), - ('Diabetes|Hypothyroidism','Diabetes',GETDATE()), - ('Diabetes|Obesity|Hypertension','Diabetes',GETDATE()), - ('Diabetes|Thyroid disease','Diabetes',GETDATE()), - ('Endometriosis','Endometriosis',GETDATE()), - ('Epilepsy','Epilepsy',GETDATE()), - ('Epilepsy|Diabetes','Epilepsy',GETDATE()), - ('Epilepsy|Epilepsy','Epilepsy',GETDATE()), - ('Epilepsy|Hypertension','Epilepsy',GETDATE()), - ('Epilepsy|Hypertension|Diabetes','Epilepsy',GETDATE()), - ('Epilepsy|Mental illness','Epilepsy',GETDATE()), - ('Epilepsy|Obesity','Epilepsy',GETDATE()), - ('Glaucoma','Glaucoma',GETDATE()), - ('Heart Disease','Heart Disease',GETDATE()), - ('Heart Disease|Diabetes|Hypertension','Heart Disease',GETDATE()), - ('Heart Disease|Hypertension','Heart Disease',GETDATE()), - ('Heart Disease|Hypertension|Chronic Kidney Disease','Heart Disease',GETDATE()), - ('Hyperlipidaemia','Hyperlipidaemia',GETDATE()), - ('Hyperlipidaemia|Diabetes|Hypertension','Hyperlipidaemia',GETDATE()), - ('Hyperlipidaemia|Hypertension','Hyperlipidaemia',GETDATE()), - ('Hyperlipidaemia|Obesity','Hypertension',GETDATE()), - ('Hypertension','Hypertension',GETDATE()), - ('Hypertension|Arthritis','Hypertension',GETDATE()), - ('Hypertension|Arthritis|Diabetes','Hypertension',GETDATE()), - ('Hypertension|Asthma','Hypertension',GETDATE()), - ('Hypertension|Asthma|Arthritis','Hypertension',GETDATE()), - ('Hypertension|Asthma|Epilepsy','Hypertension',GETDATE()), - ('Hypertension|Cancer','Hypertension',GETDATE()), - ('Hypertension|Cardiovascular diseases','Hypertension',GETDATE()), - ('Hypertension|Chronic Kidney Disease','Hypertension',GETDATE()), - ('Hypertension|Chronic Kidney Disease|Diabetes','Hypertension',GETDATE()), - ('Hypertension|Chronic Renal Failure','Hypertension',GETDATE()), - ('Hypertension|Deafness and Hearing impairment','Hypertension',GETDATE()), - ('Hypertension|Diabetes','Hypertension',GETDATE()), - ('Hypertension|Diabetes|Chronic Obstructive Pulmonary Disease(COPD)','Hypertension',GETDATE()), - ('Hypertension|Diabetes|Diabetes','Hypertension',GETDATE()), - ('Hypertension|Diabetes|Heart Disease','Hypertension',GETDATE()), - ('Hypertension|Diabetes|Obesity','Hypertension',GETDATE()), - ('Hypertension|Endometriosis','Hypertension',GETDATE()), - ('Hypertension|Epilepsy','Hypertension',GETDATE()), - ('Hypertension|Glaucoma','Hypertension',GETDATE()), - ('Hypertension|Heart Disease','Hypertension',GETDATE()), - ('Hypertension|Hyperlipidaemia','Hypertension',GETDATE()), - ('Hypertension|Hypertension','Hypertension',GETDATE()), - ('Hypertension|Hypertension|Obesity','Hypertension',GETDATE()), - ('Hypertension|Hypothyroidism','Hypertension',GETDATE()), - ('Hypertension|Mental illness','Hypertension',GETDATE()), - ('Hypertension|Mental illness|Diabetes','Hypertension',GETDATE()), - ('Hypertension|Obesity','Hypertension',GETDATE()), - ('Hypertension|Obesity|Diabetes','Hypertension',GETDATE()), - ('Hypertension|Thyroid disease','Hypertension',GETDATE()), - ('Hypothyroidism','Hypothyroidism',GETDATE()), - ('Hypothyroidism|Hypertension','Hypothyroidism',GETDATE()), - ('Hypothyroidism|Hypothyroidism','Hypothyroidism',GETDATE()), - ('Hypothyroidism|Obesity','Hypothyroidism',GETDATE()), - ('Mental illness','Mental illness',GETDATE()), - ('Mental illness|Asthma|Hypertension','Mental illness',GETDATE()), - ('Mental illness|Chronic Kidney Disease','Mental illness',GETDATE()), - ('Mental illness|Chronic Obstructive Pulmonary Disease(COPD)','Mental illness',GETDATE()), - ('Mental illness|Deafness and Hearing impairment','Mental illness',GETDATE()), - ('Mental illness|Hypertension','Mental illness',GETDATE()), - ('Mental illness|Mental illness','Mental illness',GETDATE()), - ('Mental illness|Mental illness|Mental illness','Mental illness',GETDATE()), - ('Mental illness|Multiple Sclerosis','Mental illness',GETDATE()), - ('Multiple Sclerosis','Multiple Sclerosis',GETDATE()), - ('Obesity','Obesity',GETDATE()), - ('Obesity|Asthma','Obesity',GETDATE()), - ('Obesity|Hypertension','Obesity',GETDATE()), - ('Obesity|Hypothyroidism','Obesity',GETDATE()), - ('Obesity|Obesity','Obesity',GETDATE()), - ('Obesity|Obesity|Diabetes','Obesity',GETDATE()), - ('Osteoporosis','Osteoporosis',GETDATE()), - ('Sickle Cell Anaemia','Sickle Cell Anaemia',GETDATE()), - ('Thyroid disease','Thyroid disease',GETDATE()), - ('Thyroid disease|Chronic Kidney Disease','Thyroid disease',GETDATE()), - ('Thyroid disease|Diabetes','Thyroid disease',GETDATE()), - ('Thyroid disease|Hypertension','Thyroid disease',GETDATE()), - ('Thyroid disease|Hypertension|Obesity','Thyroid disease',GETDATE()), - ('Thyroid disease|Thyroid disease','Thyroid disease',GETDATE()) - -END \ No newline at end of file diff --git a/Scripts/ODS/load_intermediate_tables/CT_intermediate_tables/1_load_intermediate_LastVisit.sql b/Scripts/ODS/load_intermediate_tables/CT_intermediate_tables/1_load_intermediate_LastVisit.sql index 89108c6c..65fbffae 100644 --- a/Scripts/ODS/load_intermediate_tables/CT_intermediate_tables/1_load_intermediate_LastVisit.sql +++ b/Scripts/ODS/load_intermediate_tables/CT_intermediate_tables/1_load_intermediate_LastVisit.sql @@ -1,8 +1,9 @@ IF OBJECT_ID(N'[ODS].[dbo].[Intermediate_LastVisitDate]', N'U') IS NOT NULL DROP TABLE [ODS].[dbo].[Intermediate_LastVisitDate]; BEGIN + ---Load_LatestVisit - With LatestVisit AS ( +With source_data as ( SELECT row_number() OVER (PARTITION BY SiteCode,PatientPK ORDER BY VisitDate DESC) AS NUM, PatientID, SiteCode, @@ -11,20 +12,33 @@ BEGIN cast( '' as nvarchar(100))PatientIDHash, VisitDate as LastVisitDate, visitID, - CASE WHEN NextAppointmentDate IS NULL THEN DATEADD(dd,30,VisitDate) ELSE NextAppointmentDate End AS NextAppointment, - cast(getdate() as date) as LoadDate - + BP, + CASE WHEN NextAppointmentDate IS NULL THEN DATEADD(dd,30,VisitDate) ELSE NextAppointmentDate End AS NextAppointment FROM ODS.dbo.CT_PatientVisits - ) - Select LatestVisit.* - INTO [ODS].[dbo].[Intermediate_LastVisitDate] - from LatestVisit - where NUM=1 -END - - - - - - - +), +controlled_BP as ( + select + PatientPK, + SiteCode, + BP + from source_data + where + charindex('/', BP) > 0 + and isnumeric(left(BP, charindex('/', BP) - 1)) = 1 + and isnumeric(right(BP, len(BP) - charindex('/', BP))) = 1 + and try_cast(left(BP, charindex('/', BP) - 1) as float) < 140.0 + and try_cast(right(BP, len(BP) - charindex('/', BP)) as float) < 90.0 + and num = 1 +) +select + source_data.*, + case when source_data.BP is not null then 1 else 0 end as ScreenedBPLastVisit, + case when controlled_BP.PatientPK is not null then 1 else 0 end as IsBPControlledAtLastVisit, + cast(getdate() as date) as LoadDate +into [ODS].[dbo].[Intermediate_LastVisitDate] +from source_data as source_data +left join controlled_BP on controlled_BP.PatientPK = source_data.PatientPK + and controlled_BP.SiteCode = source_data.SiteCode +where NUM = 1 + +END \ No newline at end of file diff --git a/Scripts/ODS/load_intermediate_tables/CT_intermediate_tables/7_load_intermediate_LatestObs.sql b/Scripts/ODS/load_intermediate_tables/CT_intermediate_tables/7_load_intermediate_LatestObs.sql index 460011cb..e335bbf3 100644 --- a/Scripts/ODS/load_intermediate_tables/CT_intermediate_tables/7_load_intermediate_LatestObs.sql +++ b/Scripts/ODS/load_intermediate_tables/CT_intermediate_tables/7_load_intermediate_LatestObs.sql @@ -1,7 +1,6 @@ IF OBJECT_ID(N'[ODS].[dbo].[intermediate_LatestObs]', N'U') IS NOT NULL DROP TABLE [ODS].[dbo].[intermediate_LatestObs]; - BEGIN with MFL_partner_agency_combination as ( select @@ -126,13 +125,33 @@ latest_Who as ( and visits.PatientPK = last_visit.PatientPK and visits.VisitDate = last_visit.LastVisitDate and visits.VisitID = last_visit.visitID - ) + ), + last_TBScreening as ( + SELECT row_number() OVER (PARTITION BY visits.SiteCode,visits.PatientPK ORDER BY VisitDate DESC) AS NUM, + visits.PatientPK, + visits.TBScreening, + visits.SiteCode, + visits.VisitDate, + visits.VisitID + from ODS.dbo.CT_IPT as visits + ), + latest_TBScreening as ( + select + distinct Screening.PatientPK, + Screening.TBScreening, + Screening.SiteCode + from last_TBScreening as Screening + inner join ODS.dbo.Intermediate_LastVisitDate as last_visit on Screening.SiteCode = last_visit.SiteCode + and Screening.PatientPK = last_visit.PatientPK + and Screening.VisitDate = last_visit.LastVisitDate + and Screening.VisitID = last_visit.visitID + where Screening.NUM=1 + ) select patient.PatientPKHash, patient.PatientPK, patient.SiteCode, - --patient.PatientID, latest_weight_height.LatestHeight, latest_weight_height.LatestWeight, age_of_last_visit.AgeLastVisit, @@ -145,6 +164,7 @@ latest_Who as ( latest_breastfeeding.LMP, latest_breastfeeding.GestationAge, latest_Who.WhoStage, + latest_TBScreening.TBScreening, cast(getdate() as date) as LoadDate into ODS.dbo.intermediate_LatestObs from ODS.dbo.CT_Patient as patient @@ -164,8 +184,10 @@ latest_Who as ( and latest_pregnancy.SiteCode = patient.SiteCode left join latest_fp_method on latest_fp_method.PatientPK = patient.PatientPK and latest_fp_method.SiteCode = patient.SiteCode - left join latest_breastfeeding on latest_breastfeeding.PatientPK=patient.PatientPK + left join latest_breastfeeding on latest_breastfeeding.PatientPK=patient.PatientPK and latest_breastfeeding.Sitecode=patient.SiteCode - left join latest_Who on latest_Who.PatientPK=patient.PatientPK and latest_Who.Sitecode=patient.Sitecode + left join latest_Who on latest_Who.PatientPK=patient.PatientPK and latest_Who.Sitecode=patient.Sitecode + left join latest_TBScreening on latest_TBScreening.PatientPK=patient.PatientPK and latest_TBScreening.SiteCode=patient.SiteCode + +END -END \ No newline at end of file diff --git a/Scripts/REPORTING/1_load_Linelist-FACTART.sql b/Scripts/REPORTING/1_load_Linelist-FACTART.sql index eabe2d9c..6ddf02de 100644 --- a/Scripts/REPORTING/1_load_Linelist-FACTART.sql +++ b/Scripts/REPORTING/1_load_Linelist-FACTART.sql @@ -68,6 +68,13 @@ Select distinct coalesce(ncd.HasDiabetes, 0) as HasDiabetes, coalesce(ncd.ScreenedDiabetes, 0) as ScreenedDiabetes, coalesce(ncd.IsDiabetesControlledAtLastTest, 0) as IsDiabetesControlledAtLastTest, + CD4.LastCD4, + CD4.LastCD4Percentage, + WhoStage, + Case When WhoStage in (3,4) OR Age<5 + OR (Age >= 15 AND CONVERT(FLOAT, CD4.LastCD4) < 200) + Then 1 Else 0 End as AHD, + CASE WHEN startdate.Date > DATEADD(MONTH, DATEDIFF(MONTH, 0, GETDATE()) - 1, 0) OR WhoStage IN (3, 4) Or Try_cast (LastVL as float) >=200.00 Then 1 ELSE 0 END AS EligibleCD4, cast(getdate() as date) as LoadDate INTO [REPORTING].[dbo].[Linelist_FACTART] from NDWH.dbo.FACTART As ART @@ -83,5 +90,9 @@ left join NDWH.dbo.FactLatestObs as obs on obs.PatientKey = ART.PatientKey left join NDWH.dbo.DimDifferentiatedCare as dif on dif.DifferentiatedCareKey = obs.DifferentiatedCareKey left join NDWH.dbo.DimDate as lastVL on lastVL.DateKey = vl.LastVLDateKey left join ncd_indicators as ncd on ncd.PatientKey = ART.PatientKey +left join NDWH.dbo.FactCD4 as CD4 on CD4.PatientKey= ART.PatientKey WHERE ART.ARTOutcomeKey IS NOT NULL; -END \ No newline at end of file +END + + +