Skip to content

Cross border report phase II improvements #249

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

Open
wants to merge 2 commits into
base: master
Choose a base branch
from
Open
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
81 changes: 77 additions & 4 deletions etl-scripts/stored-procedures/generate_flat_hei_summary_v1_0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -88,6 +88,14 @@ CREATE TABLE IF NOT EXISTS flat_hei_summary (
ovc_non_enrolment_date DATETIME,
ovc_exit_reason INT,
ovc_exit_date DATETIME,
travelled_outside_last_3_months INT,
travelled_outside_last_6_months INT,
travelled_outside_last_12_months INT,
last_cross_boarder_screening_datetime DATETIME,
is_cross_border_country INT,
cross_border_service_offered INT,
is_cross_border INT,
country_of_residence INT,
PRIMARY KEY encounter_id (encounter_id),
INDEX person_date (person_id , encounter_datetime),
INDEX location_id_rtc_date (location_id),
Expand Down Expand Up @@ -225,7 +233,7 @@ SELECT 'created table successfully ...';
set @total_time=0;
set @cycle_number = 0;


while @person_ids_count > 0 do

set @loop_start_time = now();
Expand Down Expand Up @@ -276,7 +284,7 @@ SELECT 'created table successfully ...';
join amrs.location l using (location_id)
left join etl.flat_orders t2 using(encounter_id)
left join amrs.visit v on (v.visit_id = t1.visit_id)
where t1.encounter_type in (21,67,110,111,114,115,116,121,123,154,158,168,186,116,212,214,220)
where t1.encounter_type in (21,67,110,111,114,115,116,121,123,154,158,168,186,116,212,214,220,218)
AND NOT obs regexp "!!5303=703!!"
);

Expand Down Expand Up @@ -820,7 +828,64 @@ SELECT 'created table successfully ...';
when t1.encounter_type = 220 then @ovc_exit_date := encounter_datetime
when @prev_id = @cur_id then @ovc_exit_date
else @ovc_exit_date := null
end as ovc_exit_date
end as ovc_exit_date,

case
when obs regexp "!!11237=1065" then @travelled_outside_last_3_months := 1
when obs regexp "!!11237=1066" then @travelled_outside_last_3_months := 0
when @prev_id = @cur_id then @travelled_outside_last_3_months
else @travelled_outside_last_3_months := null
end as travelled_outside_last_3_months,

case
when obs regexp "!!11238=1065" then @travelled_outside_last_6_months := 1
when obs regexp "!!11238=1066" then @travelled_outside_last_6_months := 0
when @prev_id = @cur_id then @travelled_outside_last_6_months
else @travelled_outside_last_6_months := null
end as travelled_outside_last_6_months,

case
when obs regexp "!!11239=1065" then @travelled_outside_last_12_months := 1
when obs regexp "!!11239=1066" then @travelled_outside_last_12_months := 0
when @prev_id = @cur_id then @travelled_outside_last_12_months
else @travelled_outside_last_12_months := null
end as travelled_outside_last_12_months,

case
when t1.encounter_type = 218 then @last_cross_boarder_screening_datetime := encounter_datetime
when @prev_id = @cur_id then @last_cross_boarder_screening_datetime
else @last_cross_boarder_screening_datetime := null
end as last_cross_boarder_screening_datetime,

case
when @travelled_outside_last_3_months = 1 or @travelled_outside_last_6_months = 1 or @travelled_outside_last_12_months = 1 then @is_cross_border_country := 1
else @is_cross_border_country := 0
end as is_cross_border_country,

case
when obs regexp "!!11243=10739" then @cross_border_service_offered := 10739
when obs regexp "!!11243=10649" then @cross_border_service_offered := 10649
when obs regexp "!!11243=5483" then @cross_border_service_offered := 5483
when obs regexp "!!11243=2050" then @cross_border_service_offered := 2050
when obs regexp "!!11243=11244" then @cross_border_service_offered := 11244
when obs regexp "!!11243=1964" then @cross_border_service_offered := 1964
when obs regexp "!!11243=7913" then @cross_border_service_offered := 7913
when obs regexp "!!11243=5622" then @cross_border_service_offered := 5622
when @prev_id = @cur_id then @cross_border_service_offered
else @cross_border_service_offered := null
end as cross_border_service_offered,

case
when obs regexp "!!11252=11197" then @country_of_residence := 11197
when obs regexp "!!11252=11118" then @country_of_residence := 11118
when @prev_id = @cur_id then @country_of_residence
else @country_of_residence := null
end as country_of_residence,

case
when @is_cross_border_country = 1 then @is_cross_border := 1
else @is_cross_border := 0
end as is_cross_border

from flat_hei_summary_0 t1
join amrs.person p using (person_id)
Expand Down Expand Up @@ -1087,7 +1152,15 @@ SELECT @total_rows_written;
ovc_non_enrolment_reason,
ovc_non_enrolment_date,
ovc_exit_reason,
ovc_exit_date
ovc_exit_date,
travelled_outside_last_3_months,
travelled_outside_last_6_months,
travelled_outside_last_12_months,
last_cross_boarder_screening_datetime,
is_cross_border_country,
cross_border_service_offered,
is_cross_border,
country_of_residence
from flat_hei_summary_4 t1)');

PREPARE s1 from @dyn_sql;
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -61,6 +61,14 @@ CREATE TABLE IF NOT EXISTS hei_monthly_report_dataset (
ovc_non_enrolment_out_of_catchment_area tinyint,
newly_exited_from_ovc_this_month tinyint,
exited_from_ovc_this_month tinyint,
is_cross_border_country_this_month int,
is_cross_border_county_this_month int,
is_cross_border_this_month int,
last_cross_boarder_screening_datetime date,
travelled_outside_last_3_months int,
travelled_outside_last_6_months int,
travelled_outside_last_12_months int,
country_of_residence int,
PRIMARY KEY elastic_id (elastic_id),
INDEX person_enc_date (person_id , encounter_date),
INDEX person_report_date (person_id , endDate),
Expand Down Expand Up @@ -281,7 +289,40 @@ CREATE TABLE IF NOT EXISTS hei_monthly_report_dataset (
case
when t2.ovc_exit_date is not null then 1
else 0
end as exited_from_ovc_this_month
end as exited_from_ovc_this_month,
t2.is_cross_border_country as is_cross_border_country_this_month,

case
when t2.is_cross_border_country = 0 and t2.location_id in (20,19,55,83,12,23,100,130,78,91,106,65,90) and t4.address1 != 'Busia' then @is_cross_border_county_this_month := 1
else @is_cross_border_county_this_month := 0
end as is_cross_border_county_this_month,

IF(t2.is_cross_border_country = 1 or @is_cross_border_county_this_month = 1, 1, 0) as is_cross_border_this_month,

date(t2.last_cross_boarder_screening_datetime) as last_cross_boarder_screening_datetime,

case
when t2.travelled_outside_last_3_months = 1
AND timestampdiff(month,t2.last_cross_boarder_screening_datetime,t1.endDate) <= 3
then 1
else 0
end as travelled_outside_last_3_months,

case
when (t2.travelled_outside_last_6_months = 1 or t2.travelled_outside_last_3_months = 1)
AND timestampdiff(month,t2.last_cross_boarder_screening_datetime,t1.endDate) <= 6
then 1
else 0
end as travelled_outside_last_6_months,

case
when ( t2.travelled_outside_last_12_months = 1 or t2.travelled_outside_last_6_months = 1 or t2.travelled_outside_last_3_months = 1)
AND timestampdiff(month,t2.last_cross_boarder_screening_datetime,t1.endDate) <= 12
then 1
else 0
end as travelled_outside_last_12_months,

t2.country_of_residence

from etl.dates t1
join etl.flat_hei_summary t2
Expand Down Expand Up @@ -392,7 +433,15 @@ FROM
ovc_non_enrolment_declined,
ovc_non_enrolment_out_of_catchment_area,
newly_exited_from_ovc_this_month,
exited_from_ovc_this_month
exited_from_ovc_this_month,
is_cross_border_country_this_month,
is_cross_border_county_this_month,
is_cross_border_this_month,
last_cross_boarder_screening_datetime,
travelled_outside_last_3_months,
travelled_outside_last_6_months,
travelled_outside_last_12_months,
country_of_residence
from hei_monthly_report_dataset_2
);

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -35,6 +35,13 @@ CREATE TABLE if not exists `patient_monthly_enrollment` (
`newly_enrolled_ovc_this_month` int(4) DEFAULT NULL,
`exited_ovc_this_month` int(4) DEFAULT NULL,
`in_ovc_this_month` int(0) DEFAULT NULL,
`pmtct_date_enrolled` datetime DEFAULT NULL,
`pmtct_date_completed` datetime DEFAULT NULL,
`pmtct_location_id` int(11) DEFAULT NULL,
`pmtct_patient_program_id` int(11) DEFAULT '0',
`newly_enrolled_pmtct_this_month` int(4) DEFAULT NULL,
`exited_pmtct_this_month` int(4) DEFAULT NULL,
`in_pmtct_this_month` int(0) DEFAULT NULL,
KEY `person_id` (`person_id`),
KEY `person_id_2` (`person_id`, `endDate`),
KEY `endDate` (`endDate`)
Expand Down Expand Up @@ -197,7 +204,6 @@ while @person_ids_count > 0 do
) p
group by person_id, endDate);
select count(*) from ovc_patient_date_enrollments;
select * from ovc_patient_date_enrollments;

set @prev_id = -1;
set @cur_id = -1;
Expand Down Expand Up @@ -232,7 +238,71 @@ while @person_ids_count > 0 do
ovc_patient_date_enrollments e
);
select count(*) from ovc_patient_enrollments_1;
select * from ovc_patient_enrollments_1;

drop temporary table if exists pmtct_patient_date_enrollments;
create temporary table pmtct_patient_date_enrollments
(index (person_id), index (endDate), UNIQUE e_person_id_date(person_id, endDate))
(
select
person_id,
endDate,
date_enrolled as pmtct_date_enrolled,
date_completed as pmtct_date_completed,
program_id as pmtct_program_id,
location_id as pmtct_location_id,
patient_program_id as pmtct_patient_program_id
from
(select
h.person_id,
d.endDate,
date_enrolled,
date_completed,
patient_program_id,
program_id,
location_id
from
dates d
join
enrollments_in_queue h
WHERE
h.date_enrolled < DATE_ADD(endDate, INTERVAL 1 DAY)
and program_id IN (4)
ORDER BY h.person_id , d.endDate, h.date_enrolled desc
) p
group by person_id, endDate);

set @prev_id = -1;
set @cur_id = -1;
drop temporary table if exists pmtct_patient_enrollments_1;
create temporary table pmtct_patient_enrollments_1
(index (person_id), index (endDate), UNIQUE e_person_id_date(person_id, endDate))
(
select
e.*,
@prev_id := @cur_id AS prev_id,
@cur_id := person_id AS cur_id,
case
when EXTRACT( YEAR_MONTH FROM endDate ) = EXTRACT( YEAR_MONTH FROM pmtct_date_enrolled ) then
@newly_enrolled_pmtct_this_month := 1
else
@newly_enrolled_pmtct_this_month := 0
end as newly_enrolled_pmtct_this_month,
case
when EXTRACT( YEAR_MONTH FROM endDate ) = EXTRACT( YEAR_MONTH FROM pmtct_date_completed ) then
@exited_pmtct_this_month := 1
else
@exited_pmtct_this_month := 0
end as exited_pmtct_this_month,
case
when EXTRACT( YEAR_MONTH FROM pmtct_date_enrolled ) <= EXTRACT( YEAR_MONTH FROM endDate ) and
(!(EXTRACT( YEAR_MONTH FROM pmtct_date_completed ) <= EXTRACT( YEAR_MONTH FROM endDate )) or pmtct_date_completed is null) then
1
else
0
end as in_pmtct_this_month
from
pmtct_patient_date_enrollments e
);

drop temporary table if exists retention_patient_date_enrollments;
create temporary table retention_patient_date_enrollments
Expand Down Expand Up @@ -266,7 +336,6 @@ while @person_ids_count > 0 do
) p
group by person_id, endDate);
select count(*) from retention_patient_date_enrollments;
select * from retention_patient_date_enrollments;

set @prev_id = -1;
set @cur_id = -1;
Expand Down Expand Up @@ -301,15 +370,16 @@ while @person_ids_count > 0 do
retention_patient_date_enrollments e
);
select count(*) from retention_patient_enrollments_1;
select * from retention_patient_enrollments_1;

drop temporary table if exists patient_dates;
create temporary table patient_dates
(index (person_id), index(person_id, endDate), index(endDate))
(select * from
(select person_id, endDate from retention_patient_enrollments_1
union
select person_id, endDate from ovc_patient_enrollments_1) pd
select person_id, endDate from ovc_patient_enrollments_1
union
select person_id, endDate from pmtct_patient_enrollments_1) pd
);

replace into patient_monthly_enrollment
Expand All @@ -330,11 +400,19 @@ while @person_ids_count > 0 do
ovc_patient_program_id,
newly_enrolled_ovc_this_month,
exited_ovc_this_month,
in_ovc_this_month
in_ovc_this_month,
pmtct_date_enrolled,
pmtct_date_completed,
pmtct_location_id,
pmtct_patient_program_id,
newly_enrolled_pmtct_this_month,
exited_pmtct_this_month,
in_pmtct_this_month
from
patient_dates pd
left outer join retention_patient_enrollments_1 re on (pd.person_id = re.person_id and pd.endDate = re.endDate)
left outer join ovc_patient_enrollments_1 ovc on (pd.person_id = ovc.person_id and pd.endDate = ovc.endDate)
left outer join pmtct_patient_enrollments_1 pmtct on (pd.person_id = pmtct.person_id and pd.endDate = pmtct.endDate)
order by pd.person_id, pd.endDate
);

Expand Down