From 7b164ea03508fb91131c85d9c8dccfe40fdd9e22 Mon Sep 17 00:00:00 2001 From: henrykorir Date: Fri, 27 Oct 2023 12:04:05 +0300 Subject: [PATCH 1/9] POC-545: Create a Stored Procedure for the NCD Monthly Report --- ...erate_plhiv_ncd_monthly_report_dataset.sql | 265 ++++++ .../generate_plhiv_ncd_summary.sql | 823 ++++++++++++++++++ 2 files changed, 1088 insertions(+) create mode 100644 etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql create mode 100644 etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql diff --git a/etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql b/etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql new file mode 100644 index 0000000..6266644 --- /dev/null +++ b/etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql @@ -0,0 +1,265 @@ +DELIMITER $$ +CREATE PROCEDURE `generate_plhiv_ncd_monthly_report_dataset`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int , IN log boolean) +BEGIN + select @start := now(); + select @table_version := "plhiv_ncd_monthly_report_dataset"; + set @primary_table := "plhiv_ncd_monthly_report_dataset"; + set @query_type = query_type; + + set @total_rows_written = 0; + + set session sort_buffer_size=512000000; + + select @sep := " ## "; + select @last_date_created := (select max(max_date_created) from etl.flat_obs); + + CREATE TABLE IF NOT EXISTS `plhiv_ncd_monthly_report_dataset` ( + `elastic_id` varchar(21) NOT NULL DEFAULT '', + `location_id` bigint(60) DEFAULT NULL, + `person_id` int(11) DEFAULT NULL, + `person_uuid` char(38) CHARACTER SET utf8 NOT NULL, + `birthdate` date DEFAULT NULL, + `death_date` longtext CHARACTER SET utf8, + `age` decimal(23,2) DEFAULT NULL, + `gender` varchar(50) CHARACTER SET utf8 DEFAULT '', + `encounter_id` int(11) NOT NULL DEFAULT '0', + `encounter_datetime` datetime DEFAULT NULL, + `encounter_month` int(6) DEFAULT NULL, + `endDate` date DEFAULT NULL, + `prev_rtc_date` longtext, + `prev_rtc_month` int(6) DEFAULT NULL, + `rtc_date` varchar(10) CHARACTER SET utf8 DEFAULT NULL, + `rtc_month` int(6) DEFAULT NULL, + `visit_this_month` int(3) DEFAULT NULL, + `appointment_this_month` int(3) DEFAULT NULL, + `scheduled_visit_this_month` int(1) NOT NULL DEFAULT '0', + `early_appointment_this_month` int(1) NOT NULL DEFAULT '0', + `late_appointment_this_month` int(1) NOT NULL DEFAULT '0', + `missed_appointment_this_month` int(1) NOT NULL DEFAULT '0', + `days_since_rtc_date` varchar(23) CHARACTER SET utf8 DEFAULT NULL, + `has_comorbidity` TINYINT(1), + `has_mental_disorder_comorbidity` TINYINT(1), + `has_diabetic_comorbidity` TINYINT(1), + `has_hypertension_comorbidity` TINYINT(1), + `has_other_comorbidity` TINYINT(1), + PRIMARY KEY (`elastic_id`), + KEY `person_id` (`person_id`), + KEY `person_id_2` (`person_id`,`endDate`), + KEY `endDate` (`endDate`), + KEY `location_id` (`location_id`,`endDate`), + KEY `encounter_datetime` (`encounter_datetime`) + ) ENGINE=InnoDB DEFAULT CHARSET=latin1; + + + if(@query_type="build") then + select 'BUILDING..........................................'; + set @write_table = concat("plhiv_ncd_monthly_report_temp_",queue_number); + set @queue_table = concat("plhiv_ncd_monthly_report_build_queue_",queue_number); + + SET @dyn_sql=CONCAT('Create table if not exists ',@write_table,' like ',@primary_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('drop table if exists ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select person_id from plhiv_ncd_monthly_report_build_queue limit ', queue_size, ');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('delete t1 from plhiv_ncd_monthly_report_build_queue t1 join ',@queue_table, ' t2 on (t1.person_id = t2.person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + end if; + + # Display the important tables names + select @queue_table; + select @primary_table; + select @write_table; + + # Remove test patients + SET @dyn_sql=CONCAT('delete t1 FROM ',@queue_table,' t1 + join amrs.person_attribute t2 using (person_id) + where t2.person_attribute_type_id=28 and value="true" and voided=0'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('select count(*) as queue_size from ',@queue_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @person_ids_count = 0; + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + select @person_ids_count as 'num patients to sync'; + + + SET @dyn_sql=CONCAT('delete t1 from ',@primary_table, ' t1 join ',@queue_table,' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @total_time=0; + set @cycle_number = 0; + while @person_ids_count > 0 do + + set @loop_start_time = now(); + + drop temporary table if exists plhiv_ncd_monthly_report_temp_queue; + SET @dyn_sql=CONCAT('create temporary table plhiv_ncd_monthly_report_temp_queue (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + drop temporary table if exists plhiv_ncd_summary_in_queue; + create temporary table plhiv_ncd_summary_in_queue + (index (person_id), index(person_id, encounter_datetime), index(encounter_id), index(encounter_datetime), index(rtc_date)) + (select * + from + etl.plhiv_ncd_summary_v1 + where + encounter_datetime >= '2018-01-01' + order by person_id, encounter_datetime + ); + + drop table if exists plhiv_ncd_patient_encounters; + create table plhiv_ncd_patient_encounters + (index (person_id), index(person_id, endDate, encounter_id)) + ( + select + * + from ( + select + * + from etl.dates m + join plhiv_ncd_summary_in_queue h + WHERE h.encounter_datetime < DATE_ADD(endDate, INTERVAL 1 DAY) + and m.endDate BETWEEN '2018-01-01' AND DATE_ADD(now(), INTERVAL 2 YEAR) + ORDER BY h.person_id , month(endDate), h.encounter_datetime desc , rtc_date + ) p + group by person_id, month(endDate) + ); + + + drop temporary table if exists stage_1; + create temporary table stage_1 + ( + primary key elastic_id (elastic_id), + index (person_id), + index (person_id, endDate), + index(endDate), + index(location_id, endDate), + index(encounter_datetime)) + (SELECT + concat(month(endDate), t1.person_id) as elastic_id, + location_id, + t1.person_id, + t1.uuid AS person_uuid, + DATE(t1.birthdate) AS birthdate, + t1.death_date, + CASE + WHEN + TIMESTAMPDIFF(YEAR, t1.birthdate, endDate) > 0 + THEN + @age:=ROUND(TIMESTAMPDIFF(YEAR, t1.birthdate, endDate), + 0) + ELSE @age:=ROUND(TIMESTAMPDIFF(MONTH, + t1.birthdate, + endDate) / 12, + 2) + END AS age, + t1.gender, + encounter_id, + encounter_datetime, + @encounter_month := month(encounter_datetime) as encounter_month, + endDate, + prev_rtc_date, + @prev_rtc_month := month(prev_rtc_date) as prev_rtc_month, + rtc_date, + @rtc_month := month(rtc_date) as rtc_month, + + CASE + WHEN encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate THEN @visit_this_month := 1 + ELSE @visit_this_month := 0 + END AS visit_this_month, + + CASE + WHEN prev_rtc_date between date_format(endDate,"%Y-%m-01") and endDate THEN @appointment_this_month := 1 + WHEN rtc_date between date_format(endDate,"%Y-%m-01") and endDate THEN @appointment_this_month := 1 + ELSE @appointment_this_month := 0 + END AS appointment_this_month, + + IF(@visit_this_month = 1 AND @appointment_this_month = 1, 1, 0) AS scheduled_visit_this_month, + + IF(@visit_this_month = 1 AND @appointment_this_month <> 1 AND @encounter_month < @prev_rtc_month + ,1,0) AS early_appointment_this_month, + + IF(@visit_this_month = 1 AND @appointment_this_month <> 1 AND @encounter_month > @prev_rtc_month + ,1,0) AS late_appointment_this_month, + + IF(@visit_this_month = 0 AND @appointment_this_month = 1,1,0) AS missed_appointment_this_month, + + timestampdiff(day,rtc_date, endDate) as days_since_rtc_date, + t1.has_comorbidity, + t1.has_mental_disorder_comorbidity, + t1.has_diabetic_comorbidity, + t1.has_hypertension_comorbidity, + t1.has_other_comorbidity + from + plhiv_ncd_patient_encounters t1 + inner join amrs.person t2 on (t1.person_id = t2.person_id and t2.voided = 0) + ); + + replace into plhiv_ncd_monthly_report_dataset + ( + select + * + from stage_1 + ); + + SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join plhiv_ncd_monthly_report_temp_queue t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + + set @cycle_length = timestampdiff(second,@loop_start_time,now()); + + set @total_time = @total_time + @cycle_length; + set @cycle_number = @cycle_number + 1; + + + set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); + + + SELECT + @person_ids_count AS 'persons remaining', + @cycle_length AS 'Cycle time (s)', + CEIL(@person_ids_count / cycle_size) AS remaining_cycles, + @remaining_time AS 'Est time remaining (min)'; + + end while; + + select @end := now(); + insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); + select concat(@table_version," : Time to complete: ",timestampdiff(minute, @start, @end)," minutes"); + + END$$ +DELIMITER ; \ No newline at end of file diff --git a/etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql b/etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql new file mode 100644 index 0000000..1677c5f --- /dev/null +++ b/etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql @@ -0,0 +1,823 @@ + +DELIMITER $$ + +CREATE PROCEDURE `etl`.`generate_plhiv_ncd_summary`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int) +BEGIN + set @primary_table := "plhiv_ncd_summary_v1"; + set @query_type = query_type; + + set @total_rows_written = 0; + + set @encounter_types = "(54,55,75,76,77,78,79,83,96,99,100,104,107,108,109,131,171,172)"; + set @clinical_encounter_types = "(54,55,75,76,77,78,79,83,96,104,107,108,109,171,172)"; + set @non_clinical_encounter_types = "(131)"; + set @other_encounter_types = "(-1)"; + + set @start = now(); + set @table_version = "plhiv_ncd_summary_v1.0"; + + set session sort_buffer_size=512000000; + + set @sep = " ## "; + set @boundary = "!!"; + set @last_date_created = (select max(max_date_created) from etl.flat_obs); + + CREATE TABLE IF NOT EXISTS plhiv_ncd_summary_v1 ( + date_created TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + person_id INT, + uuid VARCHAR(100), + visit_id INT, + encounter_id INT, + encounter_datetime DATETIME, + encounter_type INT, + is_clinical_encounter INT, + location_id INT, + location_uuid VARCHAR(100), + death_date DATETIME, + prev_rtc_date DATETIME, + rtc_date DATETIME, + lmp DATE, + sbp SMALLINT, + dbp SMALLINT, + pulse SMALLINT, + fbs DECIMAL, + rbs DECIMAL, + hb_a1c DECIMAL, + hb_a1c_date DATETIME, + creatinine DECIMAL, + creatinine_date DATETIME, + total_cholesterol DECIMAL, + hdl DECIMAL, + ldl DECIMAL, + triglycerides DECIMAL, + lipid_panel_date DATETIME, + dm_status MEDIUMINT, + htn_status MEDIUMINT, + dm_meds VARCHAR(500), + htn_meds VARCHAR(500), + prescriptions TEXT, + problems TEXT, + has_comorbidity TINYINT(1), + has_mental_disorder_comorbidity TINYINT(1), + has_diabetic_comorbidity TINYINT(1), + has_hypertension_comorbidity TINYINT(1), + has_other_comorbidity TINYINT(1), + prev_encounter_datetime_plhiv_ncd DATETIME, + next_encounter_datetime_plhiv_ncd DATETIME, + prev_encounter_type_plhiv_ncd MEDIUMINT, + next_encounter_type_plhiv_ncd MEDIUMINT, + prev_clinical_datetime_plhiv_ncd DATETIME, + next_clinical_datetime_plhiv_ncd DATETIME, + prev_clinical_location_id_plhiv_ncd MEDIUMINT, + next_clinical_location_id_plhiv_ncd MEDIUMINT, + prev_clinical_rtc_date_plhiv_ncd DATETIME, + next_clinical_rtc_date_plhiv_ncd DATETIME, + PRIMARY KEY encounter_id (encounter_id), + INDEX person_date (person_id , encounter_datetime), + INDEX person_uuid (uuid), + INDEX location_enc_date (location_uuid , encounter_datetime), + INDEX enc_date_location (encounter_datetime , location_uuid), + INDEX location_id_rtc_date (location_id , rtc_date), + INDEX location_uuid_rtc_date (location_uuid , rtc_date), + INDEX loc_id_enc_date_next_clinical (location_id , encounter_datetime , next_clinical_datetime_plhiv_ncd), + INDEX encounter_type (encounter_type), + INDEX date_created (date_created) + ); + + if(@query_type="build") then + select 'BUILDING..........................................'; + + set @write_table = concat("plhiv_ncd_summary_temp_",queue_number); + set @queue_table = concat("plhiv_ncd_summary_build_queue_",queue_number); + + select @queue_table; + SET @dyn_sql=CONCAT('Create table if not exists ',@write_table,' like ',@primary_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #create table if not exists @queue_table (person_id int, primary key (person_id)); + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from plhiv_ncd_summary_build_queue limit ', queue_size, ');'); + #SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from plhiv_ncd_summary_build_queue limit 500);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #delete t1 from plhiv_ncd_summary_build_queue t1 join @queue_table t2 using (person_id) + SET @dyn_sql=CONCAT('delete t1 from plhiv_ncd_summary_build_queue t1 join ',@queue_table, ' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + end if; + + if(@query_type="sync") then + select 'SYNCING..........................................'; + set @write_table = "plhiv_ncd_summary_v1"; + set @queue_table = "plhiv_ncd_summary_sync_queue"; + CREATE TABLE IF NOT EXISTS plhiv_ncd_summary_sync_queue ( + person_id INT PRIMARY KEY + ); + + set @last_update = null; + + SELECT + MAX(date_updated) + INTO @last_update FROM + etl.flat_log + WHERE + table_name = @table_version; + + replace into plhiv_ncd_summary_sync_queue + (select distinct patient_id + from amrs.encounter + where date_changed > @last_update + ); + + replace into plhiv_ncd_summary_sync_queue + (select distinct person_id + from etl.flat_obs + where max_date_created > @last_update + ); + + replace into plhiv_ncd_summary_sync_queue + (select distinct person_id + from etl.flat_lab_obs + where max_date_created > @last_update + ); + + replace into plhiv_ncd_summary_sync_queue + (select distinct person_id + from etl.flat_orders + where max_date_created > @last_update + ); + + replace into plhiv_ncd_summary_sync_queue + (select person_id from + amrs.person + where date_voided > @last_update); + + + replace into plhiv_ncd_summary_sync_queue + (select person_id from + amrs.person + where date_changed > @last_update); + end if; + + + # Remove test patients + SET @dyn_sql=CONCAT('delete t1 FROM ',@queue_table,' t1 + join amrs.person_attribute t2 using (person_id) + where t2.person_attribute_type_id=28 and value="true" and voided=0'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @person_ids_count = 0; + + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SELECT @person_ids_count AS 'num patients to update'; + + + #delete t1 from plhiv_ncd_summary_v1.0 t1 join @queue_table t2 using (person_id); + SET @dyn_sql=CONCAT('delete t1 from ',@primary_table, ' t1 join ',@queue_table,' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + -- drop temporary table if exists prescriptions; + -- create temporary table prescriptions (encounter_id int primary key, prescriptions text) + -- ( + -- select + -- encounter_id, + -- group_concat(obs separator ' $ ') as prescriptions + -- from + -- ( + -- select + -- t2.encounter_id, + -- obs_group_id, + -- group_concat( + -- case + -- when value_coded is not null then concat(@boundary,o.concept_id,'=',value_coded,@boundary) + -- when value_numeric is not null then concat(@boundary,o.concept_id,'=',value_numeric,@boundary) + -- when value_datetime is not null then concat(@boundary,o.concept_id,'=',date(value_datetime),@boundary) + -- when value_text is not null then concat(@boundary,o.concept_id,'=',value_text,@boundary) + -- when value_drug is not null then concat(@boundary,o.concept_id,'=',value_drug,@boundary) + -- when value_modifier is not null then concat(@boundary,o.concept_id,'=',value_modifier,@boundary) + -- end + -- order by o.concept_id,value_coded + -- separator ' ## ' + -- ) as obs + + -- from amrs.obs o + -- join (select encounter_id, obs_id, concept_id as grouping_concept from amrs.obs where concept_id in (7307,7334)) t2 on o.obs_group_id = t2.obs_id + -- group by obs_group_id + -- ) t + -- group by encounter_id + -- ); + + set @total_time=0; + set @cycle_number = 0; + + while @person_ids_count > 0 do + + set @loop_start_time = now(); + + drop temporary table if exists plhiv_ncd_summary_build_queue__0; + + SET @dyn_sql=CONCAT('create temporary table plhiv_ncd_summary_build_queue__0 (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + + drop temporary table if exists plhiv_ncd_summary_0a; + SET @dyn_sql = CONCAT( + 'create temporary table plhiv_ncd_summary_0a + (select + t1.person_id, + t1.visit_id, + t1.encounter_id, + t1.encounter_datetime, + t1.encounter_type, + t1.location_id, + t1.obs, + t1.obs_datetimes, + case + when t1.encounter_type in ',@clinical_encounter_types,' then 1 + else null + end as is_clinical_encounter, + + case + when t1.encounter_type in ',@non_clinical_encounter_types,' then 20 + when t1.encounter_type in ',@clinical_encounter_types,' then 10 + when t1.encounter_type in', @other_encounter_types, ' then 5 + else 1 + end as encounter_type_sort_index, + t2.orders + from etl.flat_obs t1 + join plhiv_ncd_summary_build_queue__0 t0 using (person_id) + left join etl.flat_orders t2 using(encounter_id) + where t1.encounter_type in ',@encounter_types,');' + ); + + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + insert into plhiv_ncd_summary_0a + ( + select + t1.person_id, + null, + t1.encounter_id, + t1.test_datetime, + t1.encounter_type, + null, #t1.location_id, + t1.obs, + null, #obs_datetimes + # in any visit, there many be multiple encounters. for this dataset, we want to include only clinical encounters (e.g. not lab or triage visit) + 0 as is_clinical_encounter, + 1 as encounter_type_sort_index, + null + from etl.flat_lab_obs t1 + join plhiv_ncd_summary_build_queue__0 t0 using (person_id) + ); + + drop temporary table if exists plhiv_ncd_summary_0; + create temporary table plhiv_ncd_summary_0(index encounter_id (encounter_id), index person_enc (person_id,encounter_datetime)) + ( + select + * + from plhiv_ncd_summary_0a + order by person_id, date(encounter_datetime), encounter_type_sort_index + ); + + set @prev_id = null; + set @cur_id = null; + set @prev_encounter_date = null; + set @cur_encounter_date = null; + set @enrollment_date = null; + set @cur_location = null; + set @cur_rtc_date = null; + set @prev_rtc_date = null; + + set @death_date = null; + + #TO DO + # screened for cervical ca + # exposed infant + + drop temporary table if exists plhiv_ncd_summary_1; + CREATE temporary TABLE plhiv_ncd_summary_1 (INDEX encounter_id (encounter_id)) + ( + SELECT + obs, + encounter_type_sort_index, + @prev_id:=@cur_id AS prev_id, + @cur_id:=t1.person_id AS cur_id, + t1.person_id, + p.uuid, + t1.visit_id, + t1.encounter_id, + @prev_encounter_date:=DATE(@cur_encounter_date) AS prev_encounter_date, + @cur_encounter_date:=DATE(encounter_datetime) AS cur_encounter_date, + t1.encounter_datetime, + t1.encounter_type, + t1.is_clinical_encounter, + death_date, + CASE + WHEN location_id THEN @cur_location:=location_id + WHEN @prev_id = @cur_id THEN @cur_location + ELSE NULL + END AS location_id, + CASE + WHEN @prev_id = @cur_id THEN @prev_rtc_date:=@cur_rtc_date + ELSE @prev_rtc_date:=NULL + END AS prev_rtc_date, + CASE + WHEN obs REGEXP '!!5096=' THEN @cur_rtc_date:=GETVALUES(obs, 5096) + WHEN + @prev_id = @cur_id + THEN + IF(@cur_rtc_date > encounter_datetime, + @cur_rtc_date, + NULL) + ELSE @cur_rtc_date:=NULL + END AS cur_rtc_date, + @lmp:=GETVALUES(obs, 1836) AS lmp, + CASE + WHEN obs REGEXP '!!5085=' THEN @sbp:=GETVALUES(obs, 5085) + END AS sbp, + @dbp:=GETVALUES(obs, 5086) AS dbp, + @pulse:=GETVALUES(obs, 5087) AS pulse, + @fbs:=GETVALUES(obs, 6252) AS fbs, + @rbs:=GETVALUES(obs, 887) AS rbs, + CASE + WHEN obs REGEXP '!!6126=' THEN @hb_a1c:=GETVALUES(obs, 6126) + WHEN @prev_id = @cur_id THEN @hb_a1c + ELSE @hb_a1c:=NULL + END AS hb_a1c, + CASE + WHEN + obs REGEXP '!!6126=' + THEN + @hb_a1c_date:=IFNULL(GETVALUES(obs_datetimes, 6126), + encounter_datetime) + WHEN @prev_id = @cur_id THEN @hb_a1c_date + ELSE @hb_a1c_date:=NULL + END AS hb_a1c_date, + CASE + WHEN obs REGEXP '!!790=' THEN @creatinine:=GETVALUES(obs, 790) + WHEN @prev_id = @cur_id THEN @creatinine + ELSE @creatinine:=NULL + END AS creatinine, + CASE + WHEN + obs REGEXP '!!790=' + THEN + @creatinine_date:=IFNULL(GETVALUES(obs_datetimes, 790), + encounter_datetime) + WHEN @prev_id = @cur_id THEN @creatinine_date + ELSE @creatinine_date:=NULL + END AS creatinine_date, + CASE + WHEN obs REGEXP '!!1006=' THEN @total_cholesterol:=GETVALUES(obs, 1006) + WHEN @prev_id = @cur_id THEN @total_cholesterol + ELSE @total_cholesterol:=NULL + END AS total_cholesterol, + CASE + WHEN obs REGEXP '!!1007=' THEN @hdl:=GETVALUES(obs, 1007) + WHEN @prev_id = @cur_id THEN @hdl + ELSE @hdl:=NULL + END AS hdl, + CASE + WHEN obs REGEXP '!!1008=' THEN @ldl:=GETVALUES(obs, 1008) + WHEN @prev_id = @cur_id THEN @ldl + ELSE @ldl:=NULL + END AS ldl, + CASE + WHEN obs REGEXP '!!1009=' THEN @triglycerides:=GETVALUES(obs, 1009) + WHEN @prev_id = @cur_id THEN @triglycerides + ELSE @triglycerides:=NULL + END AS triglycerides, + CASE + WHEN + obs REGEXP '!!1006=' + THEN + @lipid_panel_date:=IFNULL(GETVALUES(obs_datetimes, 1006), + encounter_datetime) + WHEN @prev_id = @cur_id THEN @lipid_panel_date + ELSE @lipid_panel_date:=NULL + END AS lipid_panel_date, + @dm_status:=GETVALUES(obs, 7287) AS dm_status, + @htn_status:=GETVALUES(obs, 7288) AS htn_status, + @dm_meds:=GETVALUES(obs, 7290) AS dm_meds, + @htn_meds:=GETVALUES(obs, 10241) AS htn_meds, + -- t2.prescriptions AS prescriptions, + NULL AS prescriptions, + @problems:=GETVALUES(obs, 6042) AS problems, + case + when obs regexp '!!11200=10239!!' then 1 + when (obs regexp '!!10239=') = 1 and (obs not regexp '!!10239=1066!!') = 1 then 1 + when obs regexp '!!10239=7281!!' then 1 + when obs regexp '!!10239=7282!!' then 1 + when obs regexp '!!10239=1066!!' then 0 + else NULL + end as has_comorbidity, + case + when obs regexp '!!10239=175!!' then 1 + else NULL + end as has_diabetic_comorbidity, + case + when obs regexp '!!10239=7971!!' then 1 + when obs regexp '!!10239=903!!' then 1 + when obs regexp '!!9328=903!!' then 1 + when obs regexp '!!9328=7971!!' then 1 + else NULL + end as has_hypertension_comorbidity, + case + when obs regexp '!!10239=10860!!' then 1 + when obs regexp '!!10239=77!!' then 1 + else NULL + end as has_mental_disorder_comorbidity, + case + when obs regexp '!!10239=5622!!' then 1 + when (obs regexp '!!10239=')= 1 and (obs not regexp '!!10239=(77|175|903|7281|7282|7971|10860)!!')=1 then 1 + else NULL + end as has_other_comorbidity, + FROM plhiv_ncd_summary_0 t1 + JOIN amrs.person p USING (person_id) + ); + -- LEFT OUTER JOIN + -- prescriptions t2 USING (encounter_id) + -- ); + + set @prev_id = null; + set @cur_id = null; + set @prev_encounter_datetime = null; + set @cur_encounter_datetime = null; + + set @prev_clinical_datetime = null; + set @cur_clinical_datetime = null; + + set @next_encounter_type = null; + set @cur_encounter_type = null; + + set @prev_clinical_location_id = null; + set @cur_clinical_location_id = null; + + + alter table plhiv_ncd_summary_1 drop prev_id, drop cur_id; + + drop table if exists plhiv_ncd_summary_2; + create temporary table plhiv_ncd_summary_2 + ( + select + *, + @prev_id := @cur_id as prev_id, + @cur_id := person_id as cur_id, + + case + when @prev_id = @cur_id then @prev_encounter_datetime := @cur_encounter_datetime + else @prev_encounter_datetime := null + end as next_encounter_datetime_plhiv_ncd, + + @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, + + case + when @prev_id=@cur_id then @next_encounter_type := @cur_encounter_type + else @next_encounter_type := null + end as next_encounter_type_plhiv_ncd, + + @cur_encounter_type := encounter_type as cur_encounter_type, + + case + when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime + else @prev_clinical_datetime := null + end as next_clinical_datetime_plhiv_ncd, + + case + when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id + else @prev_clinical_location_id := null + end as next_clinical_location_id_plhiv_ncd, + + case + when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime + when @prev_id = @cur_id then @cur_clinical_datetime + else @cur_clinical_datetime := null + end as cur_clinic_datetime, + + case + when is_clinical_encounter then @cur_clinical_location_id := location_id + when @prev_id = @cur_id then @cur_clinical_location_id + else @cur_clinical_location_id := null + end as cur_clinic_location_id, + + case + when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date + else @prev_clinical_rtc_date := null + end as next_clinical_rtc_date_plhiv_ncd, + + case + when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date + when @prev_id = @cur_id then @cur_clinical_rtc_date + else @cur_clinical_rtc_date:= null + end as cur_clinical_rtc_date + + from plhiv_ncd_summary_1 + order by person_id, date(encounter_datetime) desc, encounter_type_sort_index desc + ); + + alter table plhiv_ncd_summary_2 drop prev_id, drop cur_id, drop cur_encounter_type, drop cur_encounter_datetime, drop cur_clinical_rtc_date; + + + set @prev_id = null; + set @cur_id = null; + set @prev_encounter_type = null; + set @cur_encounter_type = null; + set @prev_encounter_datetime = null; + set @cur_encounter_datetime = null; + set @prev_clinical_datetime = null; + set @cur_clinical_datetime = null; + set @prev_clinical_location_id = null; + set @cur_clinical_location_id = null; + + drop temporary table if exists plhiv_ncd_summary_3; + create temporary table plhiv_ncd_summary_3 (prev_encounter_datetime datetime, prev_encounter_type int, index person_enc (person_id, encounter_datetime desc)) + ( + select + *, + @prev_id := @cur_id as prev_id, + @cur_id := t1.person_id as cur_id, + + -- if same person then cur enc type is same as prev encounter type else null + case + when @prev_id=@cur_id then @prev_encounter_type := @cur_encounter_type + else @prev_encounter_type:=null + end as prev_encounter_type_plhiv_ncd, + @cur_encounter_type := encounter_type as cur_encounter_type, + + -- if same person then cur enc dt is same as prev enc dt else null + case + when @prev_id=@cur_id then @prev_encounter_datetime := @cur_encounter_datetime + else @prev_encounter_datetime := null + end as prev_encounter_datetime_plhiv_ncd, + + @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, + + -- if same person then cur clc dt is same as prev clc dt else null + case + when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime + else @prev_clinical_datetime := null + end as prev_clinical_datetime_plhiv_ncd, + + -- if same person then cur clc locid is same as prev clc locid else null + case + when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id + else @prev_clinical_location_id := null + end as prev_clinical_location_id_plhiv_ncd, + + -- if clc enc or same person then cur clc dt is enc_dt else null + case + when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime + when @prev_id = @cur_id then @cur_clinical_datetime + else @cur_clinical_datetime := null + end as cur_clinical_datetime, + + -- if clc enc or same person then cur clc loc is loc_id else null + case + when is_clinical_encounter then @cur_clinical_location_id := location_id + when @prev_id = @cur_id then @cur_clinical_location_id + else @cur_clinical_location_id := null + end as cur_clinical_location_id, + + -- if same person then prev clc rtc is cur rtc else null + case + when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date + else @prev_clinical_rtc_date := null + end as prev_clinical_rtc_date_plhiv_ncd, + + -- if clc enc or same person then cur clc rtc is cur rtc else null + case + when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date + when @prev_id = @cur_id then @cur_clinical_rtc_date + else @cur_clinical_rtc_date:= null + end as cur_clinic_rtc_date + + from plhiv_ncd_summary_2 t1 + order by person_id, date(encounter_datetime), encounter_type_sort_index + ); + + SELECT COUNT(*) INTO @new_encounter_rows FROM plhiv_ncd_summary_3; + + SELECT @new_encounter_rows; + set @total_rows_written = @total_rows_written + @new_encounter_rows; + SELECT @total_rows_written; + + select + null, + person_id, + t1.uuid, + visit_id, + encounter_id, + encounter_datetime, + encounter_type, + is_clinical_encounter, + location_id, + t2.uuid as location_uuid, + death_date, + prev_rtc_date, + cur_rtc_date, + lmp, + sbp, + dbp, + pulse, + fbs, + rbs, + hb_a1c, + hb_a1c_date, + creatinine, + creatinine_date, + total_cholesterol, + hdl, + ldl, + triglycerides, + lipid_panel_date, + dm_status, + htn_status, + dm_meds, + htn_meds, + prescriptions, + problems, + has_comorbidity, + has_mental_disorder_comorbidity, + has_diabetic_comorbidity, + has_hypertension_comorbidity, + has_other_comorbidity, + prev_encounter_datetime_plhiv_ncd, + next_encounter_datetime_plhiv_ncd, + prev_encounter_type_plhiv_ncd, + next_encounter_type_plhiv_ncd, + prev_clinical_datetime_plhiv_ncd, + next_clinical_datetime_plhiv_ncd, + prev_clinical_location_id_plhiv_ncd, + next_clinical_location_id_plhiv_ncd, + prev_clinical_rtc_date_plhiv_ncd, + next_clinical_rtc_date_plhiv_ncd + from plhiv_ncd_summary_3 t1 + join amrs.location t2 using (location_id); + + #add data to table + SET @dyn_sql=CONCAT('replace into ',@write_table, + '(select + null, + person_id, + t1.uuid, + visit_id, + encounter_id, + encounter_datetime, + encounter_type, + is_clinical_encounter, + location_id, + t2.uuid as location_uuid, + death_date, + prev_rtc_date, + cur_rtc_date, + lmp, + sbp, + dbp, + pulse, + fbs, + rbs, + hb_a1c, + hb_a1c_date, + creatinine, + creatinine_date, + total_cholesterol, + hdl, + ldl, + triglycerides, + lipid_panel_date, + dm_status, + htn_status, + dm_meds, + htn_meds, + prescriptions, + problems, + has_comorbidity, + has_mental_disorder_comorbidity, + has_diabetic_comorbidity, + has_hypertension_comorbidity, + has_other_comorbidity, + prev_encounter_datetime_plhiv_ncd, + next_encounter_datetime_plhiv_ncd, + prev_encounter_type_plhiv_ncd, + next_encounter_type_plhiv_ncd, + prev_clinical_datetime_plhiv_ncd, + next_clinical_datetime_plhiv_ncd, + prev_clinical_location_id_plhiv_ncd, + next_clinical_location_id_plhiv_ncd, + prev_clinical_rtc_date_plhiv_ncd, + next_clinical_rtc_date_plhiv_ncd + + from plhiv_ncd_summary_3 t1 + join amrs.location t2 using (location_id))'); + + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + #delete from @queue_table where person_id in (select person_id from plhiv_ncd_summary_build_queue__0); + + SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join plhiv_ncd_summary_build_queue__0 t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + #select @person_ids_count := (select count(*) from plhiv_ncd_summary_build_queue_2); + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #select @person_ids_count as remaining_in_build_queue; + + set @cycle_length = timestampdiff(second,@loop_start_time,now()); + #select concat('Cycle time: ',@cycle_length,' seconds'); + set @total_time = @total_time + @cycle_length; + set @cycle_number = @cycle_number + 1; + + #select ceil(@person_ids_count / cycle_size) as remaining_cycles; + set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); + + SELECT + @person_ids_count AS 'persons remaining', + @cycle_length AS 'Cycle time (s)', + CEIL(@person_ids_count / cycle_size) AS remaining_cycles, + @remaining_time AS 'Est time remaining (min)'; + end while; + + if(@query_type="build") then + SET @dyn_sql=CONCAT('drop table ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @total_rows_to_write=0; + SET @dyn_sql=CONCAT("Select count(*) into @total_rows_to_write from ",@write_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @start_write = now(); + + SELECT + CONCAT(@start_write, + ' : Writing ', + @total_rows_to_write, + ' to ', + @primary_table); + + SET @dyn_sql=CONCAT('replace into ', @primary_table, + '(select * from ',@write_table,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @finish_write = now(); + set @time_to_write = timestampdiff(second,@start_write,@finish_write); + + SELECT + CONCAT(@finish_write, + ' : Completed writing rows. Time to write to primary table: ', + @time_to_write, + ' seconds '); + + SET @dyn_sql=CONCAT('drop table ',@write_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + end if; + + set @ave_cycle_length = ceil(@total_time/@cycle_number); + SELECT + CONCAT('Average Cycle Length: ', + @ave_cycle_length, + ' second(s)'); + + set @end = now(); + insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); + SELECT + CONCAT(@table_version, + ' : Time to complete: ', + TIMESTAMPDIFF(MINUTE, @start, @end), + ' minutes'); +END$$ +DELIMITER ; \ No newline at end of file From 5aeb6859ca1c95361ac1445255fe93669e16d1b1 Mon Sep 17 00:00:00 2001 From: henrykorir Date: Sun, 10 Dec 2023 23:35:27 +0300 Subject: [PATCH 2/9] POC-545: Create a Stored Procedure for the NCD Monthly Report --- .../generate_flat_cdm_v1_1.sql | 768 ++++++++++++++++++ .../generate_ncd_monthly_report_dataset.sql | 455 +++++++++++ 2 files changed, 1223 insertions(+) create mode 100644 etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql create mode 100644 etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql diff --git a/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql b/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql new file mode 100644 index 0000000..08f6629 --- /dev/null +++ b/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql @@ -0,0 +1,768 @@ +DELIMITER $$ +CREATE PROCEDURE `generate_flat_cdm_v1_1`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int) +BEGIN + set @primary_table := "flat_cdm_v1"; + set @query_type = query_type; +#set @query_type = "build"; + + + set @total_rows_written = 0; + + set @encounter_types = "(54,55,75,76,77,78,79,83,96,99,100,104,107,108,109,131,171,172)"; + set @clinical_encounter_types = "(54,55,75,76,77,78,79,83,96,104,107,108,109,171,172)"; + set @non_clinical_encounter_types = "(131)"; + set @other_encounter_types = "(-1)"; + + set @start = now(); + set @table_version = "flat_cdm_v1.1"; + + set session sort_buffer_size=512000000; + + set @sep = " ## "; + set @boundary = "!!"; + set @last_date_created = (select max(max_date_created) from etl.flat_obs); + + create table if not exists flat_cdm_v1 ( + date_created TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + person_id int, + uuid varchar(100), + visit_id int, + encounter_id int, + encounter_datetime datetime, + encounter_type int, + is_clinical_encounter int, + location_id int, + location_uuid varchar(100), + death_date datetime, + prev_rtc_date datetime, + rtc_date datetime, + + lmp date, + + sbp smallint, + dbp smallint, + pulse smallint, + + fbs decimal, + rbs decimal, + hb_a1c decimal, + hb_a1c_date datetime, + + creatinine decimal, + creatinine_date datetime, + + total_cholesterol decimal, + hdl decimal, + ldl decimal, + triglycerides decimal, + lipid_panel_date datetime, + + dm_status mediumint, + htn_status mediumint, + dm_meds varchar(500), + htn_meds varchar(500), + prescriptions text, + + problems text, + + comorbidities text, + rheumatologic_disorder text, + kidney_disease text, + ckd_staging text, + cardiovascular_disorder text, + neurological_disease text, + has_past_mhd_tx text, + eligible_for_depression_care text, + anxiety_condition text, + convulsive_disorder text, + mood_disorder text, + indicated_mhd_tx text, + prev_hbp_findings text, + type_of_follow_up text, + review_of_med_history text, + + prev_encounter_datetime_cdm datetime, + next_encounter_datetime_cdm datetime, + prev_encounter_type_cdm mediumint, + next_encounter_type_cdm mediumint, + prev_clinical_datetime_cdm datetime, + next_clinical_datetime_cdm datetime, + prev_clinical_location_id_cdm mediumint, + next_clinical_location_id_cdm mediumint, + prev_clinical_rtc_date_cdm datetime, + next_clinical_rtc_date_cdm datetime, + + primary key encounter_id (encounter_id), + index person_date (person_id, encounter_datetime), + index person_uuid (uuid), + index location_enc_date (location_uuid,encounter_datetime), + index enc_date_location (encounter_datetime, location_uuid), + index location_id_rtc_date (location_id,rtc_date), + index location_uuid_rtc_date (location_uuid,rtc_date), + index loc_id_enc_date_next_clinical (location_id, encounter_datetime, next_clinical_datetime_cdm), + index encounter_type (encounter_type), + index date_created (date_created) + + ); + + + + if(@query_type="build") then + select 'BUILDING..........................................'; + + set @write_table = concat("flat_cdm_temp_",queue_number); + set @queue_table = concat("flat_cdm_build_queue_",queue_number); + + + SET @dyn_sql=CONCAT('Create table if not exists ',@write_table,' like ',@primary_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from flat_cdm_build_queue limit ', queue_size, ');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('delete t1 from flat_cdm_build_queue t1 join ',@queue_table, ' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + end if; + + + if (@query_type="sync") then + select 'SYNCING..........................................'; + set @write_table = "flat_cdm_v1"; + set @queue_table = "flat_cdm_sync_queue"; + create table if not exists flat_cdm_sync_queue (person_id int primary key); + + + + set @last_update = null; + + select max(date_updated) into @last_update from etl.flat_log where table_name=@table_version; + + replace into flat_cdm_sync_queue + (select distinct patient_id + from amrs.encounter + where date_changed > @last_update + ); + + replace into flat_cdm_sync_queue + (select distinct person_id + from etl.flat_obs + where max_date_created > @last_update + ); + + replace into flat_cdm_sync_queue + (select distinct person_id + from etl.flat_lab_obs + where max_date_created > @last_update + ); + + replace into flat_cdm_sync_queue + (select distinct person_id + from etl.flat_orders + where max_date_created > @last_update + ); + + replace into flat_cdm_sync_queue + (select person_id from + amrs.person + where date_voided > @last_update); + + + replace into flat_cdm_sync_queue + (select person_id from + amrs.person + where date_changed > @last_update); + + + end if; + + + # Remove test patients + SET @dyn_sql=CONCAT('delete t1 FROM ',@queue_table,' t1 + join amrs.person_attribute t2 using (person_id) + where t2.person_attribute_type_id=28 and value="true" and voided=0'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @person_ids_count = 0; + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + select @person_ids_count as 'num patients to update'; + + SET @dyn_sql=CONCAT('delete t1 from ',@primary_table, ' t1 join ',@queue_table,' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + drop temporary table if exists prescriptions; + create temporary table prescriptions (encounter_id int primary key, prescriptions text) + ( + select + encounter_id, + group_concat(obs separator ' $ ') as prescriptions + from + ( + select + t2.encounter_id, + obs_group_id, + group_concat( + case + when value_coded is not null then concat(@boundary,o.concept_id,'=',value_coded,@boundary) + when value_numeric is not null then concat(@boundary,o.concept_id,'=',value_numeric,@boundary) + when value_datetime is not null then concat(@boundary,o.concept_id,'=',date(value_datetime),@boundary) + when value_text is not null then concat(@boundary,o.concept_id,'=',value_text,@boundary) + when value_drug is not null then concat(@boundary,o.concept_id,'=',value_drug,@boundary) + when value_modifier is not null then concat(@boundary,o.concept_id,'=',value_modifier,@boundary) + end + order by o.concept_id,value_coded + separator ' ## ' + ) as obs + + from amrs.obs o + join (select encounter_id, obs_id, concept_id as grouping_concept from amrs.obs where concept_id in (7307,7334)) t2 on o.obs_group_id = t2.obs_id + group by obs_group_id + ) t + group by encounter_id + ); + + + set @total_time=0; + set @cycle_number = 0; + + + while @person_ids_count > 0 do + + set @loop_start_time = now(); + + #create temp table with a set of person ids + drop temporary table if exists flat_cdm_build_queue__0; + + SET @dyn_sql=CONCAT('create temporary table flat_cdm_build_queue__0 (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + + + + drop temporary table if exists flat_cdm_0a; + SET @dyn_sql = CONCAT( + 'create temporary table flat_cdm_0a + (select + t1.person_id, + t1.visit_id, + t1.encounter_id, + t1.encounter_datetime, + t1.encounter_type, + t1.location_id, + t1.obs, + t1.obs_datetimes, + case + when t1.encounter_type in ',@clinical_encounter_types,' then 1 + else null + end as is_clinical_encounter, + + case + when t1.encounter_type in ',@non_clinical_encounter_types,' then 20 + when t1.encounter_type in ',@clinical_encounter_types,' then 10 + when t1.encounter_type in', @other_encounter_types, ' then 5 + else 1 + end as encounter_type_sort_index, + t2.orders + from etl.flat_obs t1 + join flat_cdm_build_queue__0 t0 using (person_id) + left join etl.flat_orders t2 using(encounter_id) + where t1.encounter_type in ',@encounter_types,');'); + + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + insert into flat_cdm_0a + (select + t1.person_id, + null, + t1.encounter_id, + t1.test_datetime, + t1.encounter_type, + null, #t1.location_id, + t1.obs, + null, #obs_datetimes + # in any visit, there many be multiple encounters. for this dataset, we want to include only clinical encounters (e.g. not lab or triage visit) + 0 as is_clinical_encounter, + 1 as encounter_type_sort_index, + null + from etl.flat_lab_obs t1 + join flat_cdm_build_queue__0 t0 using (person_id) + ); + + drop temporary table if exists flat_cdm_0; + create temporary table flat_cdm_0(index encounter_id (encounter_id), index person_enc (person_id,encounter_datetime)) + (select * from flat_cdm_0a + order by person_id, date(encounter_datetime), encounter_type_sort_index + ); + + + + set @prev_id = null; + set @cur_id = null; + set @prev_encounter_date = null; + set @cur_encounter_date = null; + set @enrollment_date = null; + set @cur_location = null; + set @cur_rtc_date = null; + set @prev_rtc_date = null; + + set @death_date = null; + + + #TO DO + # screened for cervical ca + # exposed infant + + drop temporary table if exists flat_cdm_1; + create temporary table flat_cdm_1 (index encounter_id (encounter_id)) + (select + obs, + encounter_type_sort_index, + @prev_id := @cur_id as prev_id, + @cur_id := t1.person_id as cur_id, + t1.person_id, + p.uuid, + t1.visit_id, + t1.encounter_id, + @prev_encounter_date := date(@cur_encounter_date) as prev_encounter_date, + @cur_encounter_date := date(encounter_datetime) as cur_encounter_date, + t1.encounter_datetime, + t1.encounter_type, + t1.is_clinical_encounter, + + death_date, + case + when location_id then @cur_location := location_id + when @prev_id = @cur_id then @cur_location + else null + end as location_id, + + case + when @prev_id=@cur_id then @prev_rtc_date := @cur_rtc_date + else @prev_rtc_date := null + end as prev_rtc_date, + + # 5096 = return visit date + case + when obs regexp "!!5096=" then @cur_rtc_date := etl.GetValues(obs,5096) + when @prev_id = @cur_id then if(@cur_rtc_date > encounter_datetime,@cur_rtc_date,null) + else @cur_rtc_date := null + end as cur_rtc_date, + + @lmp := etl.GetValues(obs,1836) as lmp, + + case + when obs regexp "!!5085=" then @sbp := etl.GetValues(obs,5085) + end as sbp, + + @dbp := etl.GetValues(obs,5086) as dbp, + + @pulse := etl.GetValues(obs,5087) as pulse, + + @fbs := etl.GetValues(obs,6252) as fbs, + @rbs := etl.GetValues(obs,887) as rbs, + + case + when obs regexp "!!6126=" then @hb_a1c := etl.GetValues(obs,6126) + when @prev_id = @cur_id then @hb_a1c + else @hb_a1c := null + end as hb_a1c, + + case + when obs regexp "!!6126=" then @hb_a1c_date := ifnull(etl.GetValues(obs_datetimes,6126),encounter_datetime) + when @prev_id=@cur_id then @hb_a1c_date + else @hb_a1c_date:=null + end as hb_a1c_date, + + case + when obs regexp "!!790=" then @creatinine := etl.GetValues(obs,790) + when @prev_id = @cur_id then @creatinine + else @creatinine := null + end as creatinine, + + case + when obs regexp "!!790=" then @creatinine_date := ifnull(etl.GetValues(obs_datetimes,790),encounter_datetime) + when @prev_id=@cur_id then @creatinine_date + else @creatinine_date:=null + end as creatinine_date, + + + case + when obs regexp "!!1006=" then @total_cholesterol := etl.GetValues(obs,1006) + when @prev_id = @cur_id then @total_cholesterol + else @total_cholesterol := null + end as total_cholesterol, + + case + when obs regexp "!!1007=" then @hdl := etl.GetValues(obs,1007) + when @prev_id = @cur_id then @hdl + else @hdl := null + end as hdl, + + case + when obs regexp "!!1008=" then @ldl := etl.GetValues(obs,1008) + when @prev_id = @cur_id then @ldl + else @ldl := null + end as ldl, + + case + when obs regexp "!!1009=" then @triglycerides := etl.GetValues(obs,1009) + when @prev_id = @cur_id then @triglycerides + else @triglycerides := null + end as triglycerides, + + case + when obs regexp "!!1006=" then @lipid_panel_date := ifnull(etl.GetValues(obs_datetimes,1006),encounter_datetime) + when @prev_id=@cur_id then @lipid_panel_date + else @lipid_panel_date:=null + end as lipid_panel_date, + + + @dm_status := etl.GetValues(obs,7287) as dm_status, + @htn_status := etl.GetValues(obs,7288) as htn_status, + @dm_meds := etl.GetValues(obs,7290) as dm_meds, + @htn_meds := etl.GetValues(obs,10241) as htn_meds, + t2.prescriptions as prescriptions, + + @problems := concat(etl.GetValues(obs,6042 ), ' ## ', etl.GetValues(obs,11679)) as problems, + @comorbidities := etl.GetValues(obs,10239 ) as comorbidities, + @rheumatologic_disorder := etl.GetValues(obs,12293) as rheumatologic_disorder + @kidney_disease := etl.GetValues(obs, 6033) as kidney_disease, + @ckd_staging := etl.GetValues(obs,10101) as ckd_staging, + @cardiovascular_disorder := etl.GetValues(obs, 7971) as cardiovascular_disorder, + @neurological_disease := etl.GetValues(obs, 1129) as neurological_disease, + @has_past_mhd_tx := etl.GetValues(obs, 10280) as has_past_mhd_tx, + @eligible_for_depression_care := etl.GetValues(obs, 10293) as eligible_for_depression_care, + @anxiety_condition := etl.GetValues(obs, 11231) as anxiety_condition, + @convulsive_disorder := etl.GetValues(obs, 11791) as convulsive_disorder, + @mood_disorder := etl.GetValues(obs, 11279) as mood_disorder, + @indicated_mhd_tx := etl.GetValues(obs, 7781) as indicated_mhd_tx, + @prev_hbp_findings := etl.GetValues(obs, 9092) as prev_hbp_findings, + @type_of_follow_up := etl.GetValues(obs, 2332) as type_of_follow_up, + @review_of_med_history := etl.GetValues(obs, 6245) as review_of_med_history + + from flat_cdm_0 t1 + join amrs.person p using (person_id) + left outer join prescriptions t2 using (encounter_id) + ); + + + set @prev_id = null; + set @cur_id = null; + set @prev_encounter_datetime = null; + set @cur_encounter_datetime = null; + + set @prev_clinical_datetime = null; + set @cur_clinical_datetime = null; + + set @next_encounter_type = null; + set @cur_encounter_type = null; + + set @prev_clinical_location_id = null; + set @cur_clinical_location_id = null; + + + alter table flat_cdm_1 drop prev_id, drop cur_id; + + drop table if exists flat_cdm_2; + create temporary table flat_cdm_2 + (select *, + @prev_id := @cur_id as prev_id, + @cur_id := person_id as cur_id, + + case + when @prev_id = @cur_id then @prev_encounter_datetime := @cur_encounter_datetime + else @prev_encounter_datetime := null + end as next_encounter_datetime_cdm, + + @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, + + case + when @prev_id=@cur_id then @next_encounter_type := @cur_encounter_type + else @next_encounter_type := null + end as next_encounter_type_cdm, + + @cur_encounter_type := encounter_type as cur_encounter_type, + + case + when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime + else @prev_clinical_datetime := null + end as next_clinical_datetime_cdm, + + case + when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id + else @prev_clinical_location_id := null + end as next_clinical_location_id_cdm, + + case + when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime + when @prev_id = @cur_id then @cur_clinical_datetime + else @cur_clinical_datetime := null + end as cur_clinic_datetime, + + case + when is_clinical_encounter then @cur_clinical_location_id := location_id + when @prev_id = @cur_id then @cur_clinical_location_id + else @cur_clinical_location_id := null + end as cur_clinic_location_id, + + case + when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date + else @prev_clinical_rtc_date := null + end as next_clinical_rtc_date_cdm, + + case + when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date + when @prev_id = @cur_id then @cur_clinical_rtc_date + else @cur_clinical_rtc_date:= null + end as cur_clinical_rtc_date + + from flat_cdm_1 + order by person_id, date(encounter_datetime) desc, encounter_type_sort_index desc + ); + + alter table flat_cdm_2 drop prev_id, drop cur_id, drop cur_encounter_type, drop cur_encounter_datetime, drop cur_clinical_rtc_date; + + + set @prev_id = null; + set @cur_id = null; + set @prev_encounter_type = null; + set @cur_encounter_type = null; + set @prev_encounter_datetime = null; + set @cur_encounter_datetime = null; + set @prev_clinical_datetime = null; + set @cur_clinical_datetime = null; + set @prev_clinical_location_id = null; + set @cur_clinical_location_id = null; + + drop temporary table if exists flat_cdm_3; + create temporary table flat_cdm_3 (prev_encounter_datetime datetime, prev_encounter_type int, index person_enc (person_id, encounter_datetime desc)) + (select + *, + @prev_id := @cur_id as prev_id, + @cur_id := t1.person_id as cur_id, + + case + when @prev_id=@cur_id then @prev_encounter_type := @cur_encounter_type + else @prev_encounter_type:=null + end as prev_encounter_type_cdm, + @cur_encounter_type := encounter_type as cur_encounter_type, + + case + when @prev_id=@cur_id then @prev_encounter_datetime := @cur_encounter_datetime + else @prev_encounter_datetime := null + end as prev_encounter_datetime_cdm, + + @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, + + case + when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime + else @prev_clinical_datetime := null + end as prev_clinical_datetime_cdm, + + case + when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id + else @prev_clinical_location_id := null + end as prev_clinical_location_id_cdm, + + case + when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime + when @prev_id = @cur_id then @cur_clinical_datetime + else @cur_clinical_datetime := null + end as cur_clinical_datetime, + + case + when is_clinical_encounter then @cur_clinical_location_id := location_id + when @prev_id = @cur_id then @cur_clinical_location_id + else @cur_clinical_location_id := null + end as cur_clinical_location_id, + + case + when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date + else @prev_clinical_rtc_date := null + end as prev_clinical_rtc_date_cdm, + + case + when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date + when @prev_id = @cur_id then @cur_clinical_rtc_date + else @cur_clinical_rtc_date:= null + end as cur_clinic_rtc_date + + from flat_cdm_2 t1 + order by person_id, date(encounter_datetime), encounter_type_sort_index + ); + + + + select count(*) into @new_encounter_rows from flat_cdm_3; + + select @new_encounter_rows; + set @total_rows_written = @total_rows_written + @new_encounter_rows; + select @total_rows_written; + + + #add data to table + SET @dyn_sql=CONCAT('replace into ',@write_table, + '(select + null, + person_id, + t1.uuid, + visit_id, + encounter_id, + encounter_datetime, + encounter_type, + is_clinical_encounter, + location_id, + t2.uuid as location_uuid, + death_date, + prev_rtc_date, + cur_rtc_date, + lmp, + sbp, + dbp, + pulse, + fbs, + rbs, + hb_a1c, + hb_a1c_date, + creatinine, + creatinine_date, + total_cholesterol, + hdl, + ldl, + triglycerides, + lipid_panel_date, + dm_status, + htn_status, + dm_meds, + htn_meds, + prescriptions, + problems, + comorbidities, + rheumatologic_disorder, + kidney_disease, + ckd_staging, + cardiovascular_disorder, + neurological_disease, + has_past_mhd_tx, + eligible_for_depression_care, + anxiety_condition, + convulsive_disorder, + mood_disorder, + indicated_mhd_tx, + prev_hbp_findings, + type_of_follow_up, + review_of_med_history, + + prev_encounter_datetime_cdm, + next_encounter_datetime_cdm, + prev_encounter_type_cdm, + next_encounter_type_cdm, + prev_clinical_datetime_cdm, + next_clinical_datetime_cdm, + prev_clinical_location_id_cdm, + next_clinical_location_id_cdm, + prev_clinical_rtc_date_cdm, + next_clinical_rtc_date_cdm + + from flat_cdm_3 t1 + join amrs.location t2 using (location_id))'); + + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + #delete from @queue_table where person_id in (select person_id from flat_cdm_build_queue__0); + + SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join flat_cdm_build_queue__0 t2 using (person_id);'); +# select @dyn_sql; + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + #select @person_ids_count := (select count(*) from flat_cdm_build_queue_2); + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #select @person_ids_count as remaining_in_build_queue; + + set @cycle_length = timestampdiff(second,@loop_start_time,now()); + #select concat('Cycle time: ',@cycle_length,' seconds'); + set @total_time = @total_time + @cycle_length; + set @cycle_number = @cycle_number + 1; + + #select ceil(@person_ids_count / cycle_size) as remaining_cycles; + set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); + #select concat("Estimated time remaining: ", @remaining_time,' minutes'); + + select @person_ids_count as 'persons remaining', @cycle_length as 'Cycle time (s)', ceil(@person_ids_count / cycle_size) as remaining_cycles, @remaining_time as 'Est time remaining (min)'; + + end while; + + if(@query_type="build") then + SET @dyn_sql=CONCAT('drop table ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @total_rows_to_write=0; + SET @dyn_sql=CONCAT("Select count(*) into @total_rows_to_write from ",@write_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @start_write = now(); + select concat(@start_write, " : Writing ",@total_rows_to_write, ' to ',@primary_table); + + SET @dyn_sql=CONCAT('replace into ', @primary_table, + '(select * from ',@write_table,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @finish_write = now(); + set @time_to_write = timestampdiff(second,@start_write,@finish_write); + select concat(@finish_write, ' : Completed writing rows. Time to write to primary table: ', @time_to_write, ' seconds '); + + SET @dyn_sql=CONCAT('drop table ',@write_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + end if; + + + set @ave_cycle_length = ceil(@total_time/@cycle_number); + select CONCAT('Average Cycle Length: ', @ave_cycle_length, ' second(s)'); + + set @end = now(); + insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); + select concat(@table_version," : Time to complete: ",timestampdiff(minute, @start, @end)," minutes"); + + END$$ +DELIMITER ; diff --git a/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql new file mode 100644 index 0000000..eb4b9af --- /dev/null +++ b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql @@ -0,0 +1,455 @@ +DELIMITER $$ +CREATE PROCEDURE `generate_ncd_monthly_report_dataset`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int, IN start_date varchar(50)) +BEGIN + + set @start = now(); + set @table_version = "ncd_monthly_report_dataset_v1.4"; + set @last_date_created = (select max(date_created) from etl.flat_hiv_summary_v15b); + + set @sep = " ## "; + set @lab_encounter_type = 99999; + set @death_encounter_type = 31; + + +create table if not exists ncd_monthly_report_dataset ( + date_created timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP NOT NULL, + elastic_id bigint, + endDate date, + encounter_id int, + person_id int, + person_uuid varchar(100), + birthdate date, + age double, + gender varchar(1), + location_id int, + location_uuid varchar(100), + encounter_date date, + visit_this_month tinyint, + + is_hypertensive tinyint, + htn_state tinyint, + + is_diabetic tinyint, + dm_state tinyint, + + has_mhd tinyint, + is_depressive_mhd tinyint, + is_anxiety_mhd tinyint, + is_bipolar_and_related_mhd tinyint, + is_personality_mhd tinyint, + is_feeding_and_eating_mhd tinyint, + is_ocd_mhd tinyint, + + has_kd tinyint, + is_ckd tinyint, + ckd_stage int, + + has_cvd tinyint, + is_heart_failure_cvd tinyint, + is_myocardinal_infarction tinyint, + + has_neurological_disorder tinyint, + has_stroke tinyint, + is_stroke_haemorrhagic tinyint, + is_stroke_ischaemic tinyint, + has_seizure tinyint, + has_epilepsy tinyint, + has_convulsive_disorder tinyint, + + has_rheumatologic_disorder tinyint, + has_arthritis tinyint, + has_SLE tinyint, + + + primary key elastic_id (elastic_id), + index person_enc_date (person_id, encounter_date), + index person_report_date (person_id, endDate), + index endDate_location_id (endDate, location_id), + index date_created (date_created), + index status_change (location_id, endDate, status, prev_status) + + ); + + #create table if not exists ncd_monthly_report_dataset_build_queue (person_id int primary key); + #replace into ncd_monthly_report_dataset_build_queue + #(select distinct person_id from flat_hiv_summary_v15); + + if (query_type = "build") then + select "BUILDING......................."; + set @queue_table = concat("ncd_monthly_report_dataset_build_queue_",queue_number); +#set @queue_table = concat("ncd_monthly_report_dataset_build_queue_1"); + #create table if not exists @queue_table (person_id int, primary key (person_id)); + #SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from ncd_monthly_report_dataset_build_queue limit 1000);'); + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,'(person_id int primary key) (select * from ncd_monthly_report_dataset_build_queue limit ', queue_size, ');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #delete t1 from ncd_monthly_report_dataset_build_queue t1 join @queue_table t2 using (person_id) + SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset_build_queue t1 join ',@queue_table, ' t2 using (person_id)'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + end if; + + + if (query_type = "sync") then + set @queue_table = "ncd_monthly_report_dataset_sync_queue"; + create table if not exists ncd_monthly_report_dataset_sync_queue (person_id int primary key); + + select @last_update := (select max(date_updated) from etl.flat_log where table_name=@table_version); + + replace into ncd_monthly_report_dataset_sync_queue + (select distinct person_id from flat_hiv_summary_v15b where date_created >= @last_update); + end if; + + + SET @num_ids := 0; + SET @dyn_sql=CONCAT('select count(*) into @num_ids from ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + SET @person_ids_count = 0; + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + +SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_table,' t2 using (person_id);'); +# SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_table,' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @total_time=0; + set @cycle_number = 0; + + while @person_ids_count > 0 do + + set @loop_start_time = now(); + #create temporary table ncd_monthly_report_dataset_build_queue_0 (select * from ncd_monthly_report_dataset_build_queue_2 limit 5000); #TODO - change this when data_fetch_size changes + + drop temporary table if exists ncd_monthly_report_dataset_build_queue__0; + create temporary table ncd_monthly_report_dataset_build_queue__0 (person_id int primary key); + +#SET @dyn_sql=CONCAT('insert into ncd_monthly_report_dataset_build_queue__0 (select * from ncd_monthly_report_dataset_build_queue_1 limit 100);'); + SET @dyn_sql=CONCAT('insert into ncd_monthly_report_dataset_build_queue__0 (select * from ',@queue_table,' limit ',cycle_size,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + set @age =null; + set @status = null; + + drop temporary table if exists ncd_monthly_report_dataset_0; + create temporary table ncd_monthly_report_dataset_0 + (select + concat(date_format(endDate,"%Y%m"),person_id) as elastic_id, + endDate, + encounter_id, + person_id, + t3.uuid as person_uuid, + date(birthdate) as birthdate, + case + when timestampdiff(year,birthdate,endDate) > 0 then @age := round(timestampdiff(year,birthdate,endDate),0) + else @age :=round(timestampdiff(month,birthdate,endDate)/12,2) + end as age, + t3.gender, + date(encounter_datetime) as encounter_date, + + if(encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate,1,0) as visit_this_month, + + date(rtc_date) as rtc_date, + timestampdiff(day,rtc_date, endDate) as days_since_rtc_date, + + if(date(encounter_datetime) = date(prev_clinical_rtc_date_hiv),1,0) as on_schedule, + + case + when encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate + AND date(encounter_datetime) = date(prev_clinical_rtc_date_hiv) + then 1 + else 0 + end as scheduled_this_month, + + case + when encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate + AND date(encounter_datetime) != date(prev_clinical_rtc_date_hiv) + then 1 + else 0 + end as unscheduled_this_month, + + case + when arv_first_regimen_location_id != 9999 + and arv_first_regimen_start_date between date_format(endDate,"%Y-%m-01") and endDate then arv_first_regimen_location_id + else location_id + end as location_id, + + + encounter_type, + + case + when (comorbidities regexp '903') then 1 + when htn_status = 7285 or htn_status = 7286 then 1 + when (htn_meds is not null) then 1 + else null + end as is_hypertensive, + + case + when ((sbp < 130) and (dbp < 80)) then 1 + when ((sbp >= 130) and (dbp >= 80)) then 2 + when ((sbp is null) or (dbp is null)) then 3 + else NULL + end as htn_state, + + case + when (comorbidities regexp '175') then 1 + when dm_status = 7281 or dm_status = 7282 then 1 + when (dm_meds is not null) then 1 + else null + end as is_diabetic, + + case + when (hb_a1c >= 7 and hb_a1c <= 8) then 1 + when (hb_a1c < 7 and hb_a1c > 8) then 2 + when (hb_a1c is null) or (hb_a1c is null) then 3 + else null + end as dm_state, + + case + when (comorbidities regexp '10860') then 1 + else null + end as has_mhd, + + from etl.dates t1 + join etl.flat_hiv_summary_v15b t2 + join amrs.person t3 using (person_id) + join etl.ncd_monthly_report_dataset_build_queue__0 t5 using (person_id) + + + where + #t2.encounter_datetime <= t1.endDate + t2.encounter_datetime < date_add(endDate, interval 1 day) + and (t2.next_clinical_datetime_hiv is null or t2.next_clinical_datetime_hiv >= date_add(t1.endDate, interval 1 day) ) + and t2.is_clinical_encounter=1 + and t1.endDate between start_date and date_add(now(),interval 2 year) + order by person_id, endDate + ); + + + + set @prev_id = null; + set @cur_id = null; + set @cur_status = null; + set @prev_status = null; + set @prev_location_id = null; + set @cur_location_id = null; + + drop temporary table if exists ncd_monthly_report_dataset_1; + create temporary table ncd_monthly_report_dataset_1 + (select + *, + @prev_id := @cur_id as prev_id, + @cur_id := person_id as cur_id, + + case + when @prev_id=@cur_id then @prev_location_id := @cur_location_id + else @prev_location_id := null + end as next_location_id, + + @cur_location_id := location_id as cur_location_id, + + case + when @prev_id=@cur_id then @prev_status := @cur_status + else @prev_status := null + end as next_status, + @cur_status := status as cur_status + + from ncd_monthly_report_dataset_0 + order by person_id, endDate desc + ); + + select now(); + select count(*) as num_rows_to_be_inserted from ncd_monthly_report_dataset_2; + + #add data to table + replace into ncd_monthly_report_dataset + (select + null, #date_created will be automatically set or updated + elastic_id, + endDate, + encounter_id, + person_id, + person_uuid, + birthdate, + age, + gender, + encounter_date, + visit_this_month, + rtc_date, + days_since_rtc_date, + on_schedule, + scheduled_this_month, + unscheduled_this_month, + f_18_and_over_this_month, + prev_location_id, + location_id, + t2.uuid as location_uuid, + next_location_id, + t2.state_province as clinic_county, + t2.name as clinic, + t2.latitude as clinic_latitude, + t2.longitude as clinic_longitude, + encounter_type, + death_date, + enrollment_date, + enrolled_this_month, + transfer_in_this_month, + transfer_in_location_id, + transfer_in_date, + transfer_out_this_month, + transfer_out_location_id, + transfer_out_date, + prev_status, + status, + next_status, + active_in_care_this_month, + is_pre_art_this_month, + arv_first_regimen_location_id, + arv_first_regimen, + arv_first_regimen_names, + arv_first_regimen_start_date, + art_cohort_year, + art_cohort_month, + art_cohort_num, + art_cohort_total_months, + days_since_starting_arvs, + started_art_this_month, + art_revisit_this_month, + arv_start_date, + prev_month_arvs, + prev_month_arvs_names, + cur_arv_meds, + cur_arv_meds_names, + cur_arv_meds_strict, + cur_arv_line, + cur_arv_line_strict, + cur_arv_line_reported, + on_art_this_month, + on_original_first_line_this_month, + on_alt_first_line_this_month, + on_second_line_or_higher_this_month, + eligible_for_vl, + days_since_last_vl, + net_12_month_cohort_this_month, + active_on_art_12_month_cohort_this_month, + has_vl_12_month_cohort, + vl_suppressed_12_month_cohort, + has_vl_this_month, + is_suppressed_this_month, + vl_1, + vl_1_date, + vl_in_past_year, + vl_2, + vl_2_date, + qualifies_for_follow_up_vl, + got_follow_up_vl, + got_follow_up_vl_this_month, + num_days_to_follow_vl, + follow_up_vl_suppressed, + follow_up_vl_suppressed_this_month, + follow_up_vl_unsuppressed, + follow_up_vl_unsuppressed_this_month, + due_for_vl_this_month, + reason_for_needing_vl_this_month, + number_of_months_has_needed_vl, + needs_follow_up_vl, + had_med_change_this_month, + had_med_change_this_month_after_2_unsuppressed_vls, + same_meds_this_month_after_2_unsuppressed_vls, + tb_screen, + tb_screening_datetime, + tb_screening_result, + tb_screened_this_visit_this_month, + tb_screened_active_this_month, + presumed_tb_positive_this_month, + tb_tx_start_date, + started_tb_tx_this_month, + on_tb_tx_this_month, + on_tb_tx_and_started_art_this_month, + pcp_prophylaxis_start_date, + started_pcp_prophylaxis_this_month, + on_pcp_prophylaxis_this_month, + ipt_start_date, + ipt_stop_date, + ipt_completion_date, + started_ipt_this_month, + on_ipt_this_month, + completed_ipt_past_12_months, + pregnant_this_month, + is_pregnant_and_started_art_this_month, + delivered_this_month, + condoms_provided_this_month, + condoms_provided_since_active, + started_modern_contraception_this_month, + modern_contraception_since_active, + on_modern_contraception_this_month, + contraceptive_method, + discordant_status + from ncd_monthly_report_dataset_2 t1 + join amrs.location t2 using (location_id) + ); + + + + #delete from @queue_table where person_id in (select person_id from ncd_monthly_report_dataset_build_queue__0); + SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join ncd_monthly_report_dataset_build_queue__0 t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #select @person_ids_count := (select count(*) from @queue_table); + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #select @person_ids_count as num_remaining; + + set @cycle_length = timestampdiff(second,@loop_start_time,now()); + #select concat('Cycle time: ',@cycle_length,' seconds'); + set @total_time = @total_time + @cycle_length; + set @cycle_number = @cycle_number + 1; + + #select ceil(@person_ids_count / cycle_size) as remaining_cycles; + set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); + #select concat("Estimated time remaining: ", @remaining_time,' minutes'); + +# select count(*) into @num_in_hmrd from ncd_monthly_report_dataset; + + select @num_in_hmrd as num_in_hmrd, + @person_ids_count as num_remaining, + @cycle_length as 'Cycle time (s)', + ceil(@person_ids_count / cycle_size) as remaining_cycles, + @remaining_time as 'Est time remaining (min)'; + + + end while; + + if(query_type = "build") then + SET @dyn_sql=CONCAT('drop table ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + end if; + + set @end = now(); + # not sure why we need last date_created, Ive replaced this with @start + insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); + select concat(@table_version," : Time to complete: ",timestampdiff(minute, @start, @end)," minutes"); + + END$$ +DELIMITER ; From 745d2ff0005cbfd299398eca96d5dba7f42fe9a1 Mon Sep 17 00:00:00 2001 From: henrykorir Date: Mon, 11 Dec 2023 17:01:54 +0300 Subject: [PATCH 3/9] POC-545: Create a Stored Procedure for the NCD Monthly Report --- .../generate_flat_cdm_v1_1.sql | 5 +- .../generate_ncd_monthly_report_dataset.sql | 375 +++++++++++------- 2 files changed, 231 insertions(+), 149 deletions(-) diff --git a/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql b/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql index 08f6629..85cc2c1 100644 --- a/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql +++ b/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql @@ -444,7 +444,7 @@ BEGIN @htn_meds := etl.GetValues(obs,10241) as htn_meds, t2.prescriptions as prescriptions, - @problems := concat(etl.GetValues(obs,6042 ), ' ## ', etl.GetValues(obs,11679)) as problems, + @problems := concat(etl.GetValues(obs,6042 ), ' ## ', etl.GetValues(obs,11679), ' ## ', etl.GetValues(obs,6796)) as problems, @comorbidities := etl.GetValues(obs,10239 ) as comorbidities, @rheumatologic_disorder := etl.GetValues(obs,12293) as rheumatologic_disorder @kidney_disease := etl.GetValues(obs, 6033) as kidney_disease, @@ -459,7 +459,8 @@ BEGIN @indicated_mhd_tx := etl.GetValues(obs, 7781) as indicated_mhd_tx, @prev_hbp_findings := etl.GetValues(obs, 9092) as prev_hbp_findings, @type_of_follow_up := etl.GetValues(obs, 2332) as type_of_follow_up, - @review_of_med_history := etl.GetValues(obs, 6245) as review_of_med_history + @review_of_med_history := etl.GetValues(obs, 6245) as review_of_med_history, + @psychiatric_exam_findings := etl.GetValues(obs, 6245) as review_of_med_history from flat_cdm_0 t1 join amrs.person p using (person_id) diff --git a/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql index eb4b9af..45fddb9 100644 --- a/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql +++ b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql @@ -69,23 +69,16 @@ create table if not exists ncd_monthly_report_dataset ( index status_change (location_id, endDate, status, prev_status) ); - - #create table if not exists ncd_monthly_report_dataset_build_queue (person_id int primary key); - #replace into ncd_monthly_report_dataset_build_queue - #(select distinct person_id from flat_hiv_summary_v15); if (query_type = "build") then select "BUILDING......................."; set @queue_table = concat("ncd_monthly_report_dataset_build_queue_",queue_number); -#set @queue_table = concat("ncd_monthly_report_dataset_build_queue_1"); - #create table if not exists @queue_table (person_id int, primary key (person_id)); - #SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from ncd_monthly_report_dataset_build_queue limit 1000);'); + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,'(person_id int primary key) (select * from ncd_monthly_report_dataset_build_queue limit ', queue_size, ');'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; - #delete t1 from ncd_monthly_report_dataset_build_queue t1 join @queue_table t2 using (person_id) SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset_build_queue t1 join ',@queue_table, ' t2 using (person_id)'); PREPARE s1 from @dyn_sql; EXECUTE s1; @@ -118,8 +111,7 @@ create table if not exists ncd_monthly_report_dataset ( DEALLOCATE PREPARE s1; -SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_table,' t2 using (person_id);'); -# SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_table,' t2 using (person_id);'); + SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_table,' t2 using (person_id);'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; @@ -130,12 +122,10 @@ SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_ while @person_ids_count > 0 do set @loop_start_time = now(); - #create temporary table ncd_monthly_report_dataset_build_queue_0 (select * from ncd_monthly_report_dataset_build_queue_2 limit 5000); #TODO - change this when data_fetch_size changes drop temporary table if exists ncd_monthly_report_dataset_build_queue__0; create temporary table ncd_monthly_report_dataset_build_queue__0 (person_id int primary key); -#SET @dyn_sql=CONCAT('insert into ncd_monthly_report_dataset_build_queue__0 (select * from ncd_monthly_report_dataset_build_queue_1 limit 100);'); SET @dyn_sql=CONCAT('insert into ncd_monthly_report_dataset_build_queue__0 (select * from ',@queue_table,' limit ',cycle_size,');'); PREPARE s1 from @dyn_sql; EXECUTE s1; @@ -192,9 +182,12 @@ SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_ encounter_type, case + when htn_status = 7285 or htn_status = 7286 then 1 when (comorbidities regexp '903') then 1 - when htn_status = 7285 or htn_status = 7286 then 1 + when (prev_hbp_findings regexp '1065') then 1 when (htn_meds is not null) then 1 + when (problems regexp '903') then 1 + when (review_of_med_history regexp '903') then 1 else null end as is_hypertensive, @@ -206,9 +199,12 @@ SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_ end as htn_state, case + when dm_status = 7281 or dm_status = 7282 then 1 when (comorbidities regexp '175') then 1 - when dm_status = 7281 or dm_status = 7282 then 1 when (dm_meds is not null) then 1 + when (problems regexp '9324') or (problems regexp '175') then 1 + when (problems regexp '175') then 1 + when (review_of_med_history regexp '175') then 1 else null end as is_diabetic, @@ -221,26 +217,116 @@ SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_ case when (comorbidities regexp '10860') then 1 + when (indicated_mhd_tx is not null) then 1 + when (has_past_mhd_tx = '1065') then 1 + when (review_of_med_history regexp '(77)|(207)') then 1 + when (eligible_for_depression_care = '1065') then 1 + when (mood_disorder is not null) then 1 + when (anxiety_condition is not null) then 1 else null end as has_mhd, + case + when (eligible_for_depression_care = '1065') then 1 + when (mood_disorder regexp '11278') then 1 + when (indicated_mhd_tx regexp '207') then 1 + when (review_of_med_history regexp '207') then 1 + else null + end as is_depressive_mhd, + + case + when (anxiety_condition is not null) then 1 + when (indicated_mhd_tx regexp '1443') then 1 + when (review_of_med_history regexp '207') then 1 + else null + end as is_anxiety_mhd, + + case + when (mood_disorder regexp '7763') then 1 + when (indicated_mhd_tx regexp '7763') then 1 + else null + end as is_bipolar_and_related_mhd, + + case + when (mood_disorder regexp '7763') then 1 + when (indicated_mhd_tx regexp '11281') then 1 + when (problems regexp '467') then 1 + else null + end as is_personality_mhd, + + null as is_feeding_and_eating_mhd, + + null as is_ocd_mhd, + + case + when (comorbidities regexp '[[:<:]]77[[:>:]]') then 1 + when (kidney_disease = '[[:<:]]1065[[:>:]]') then 1 + when (problems regexp '[[:<:]]8078[[:>:]]|[[:<:]]11684[[:>:]]') then 1 + when (review_of_med_history regexp '(6033)|(8078)') then 1 + else null + end as has_kd, + + case + when (problems regexp '8078') then 1 + when (review_of_med_history regexp '8078') then 1 + when (ckd_staging is not null) then 1 + else null + end as is_ckd, + + ckd_staging as ckd_stage, + + case + when (cardiovascular_disorder is not null) then 1 + when (comorbidities regexp '7971') then 1 + when (review_of_med_history regexp '(7971)|(6237)') then 1 + else null + end as has_cvd, + + case + when (cardiovascular_disorder regexp '1456') then 1 + when (indicated_mhd_tx regexp '1456') then 1 + when (review_of_med_history regexp '7971') then 1 + else null + end as is_heart_failure_cvd, + + case + when (neurological_disease is not null) then 1 + when (indicated_mhd_tx regexp '1456') then 1 + when (review_of_med_history regexp '7971') then 1 + else null + end as has_neurological_disorder, + + case + when (cardiovascular_disorder regexp '1535') then 1 + else null + end as is_myocardinal_infarction, + + case + when (cardiovascular_disorder regexp '1878') then 1 + when (indicated_mhd_tx regexp '1456') then 1 + when (review_of_med_history regexp '7971') then 1 + else null + end as has_stroke, + + null as is_stroke_haemorrhagic + + null as is_stroke_ischaemic, + + null as + from etl.dates t1 - join etl.flat_hiv_summary_v15b t2 + join etl.flat_cdm_v1 t2 join amrs.person t3 using (person_id) join etl.ncd_monthly_report_dataset_build_queue__0 t5 using (person_id) - where - #t2.encounter_datetime <= t1.endDate t2.encounter_datetime < date_add(endDate, interval 1 day) - and (t2.next_clinical_datetime_hiv is null or t2.next_clinical_datetime_hiv >= date_add(t1.endDate, interval 1 day) ) + and (t2.next_clinical_datetime_cdm is null or t2.next_clinical_datetime_cdm >= date_add(t1.endDate, interval 1 day) ) and t2.is_clinical_encounter=1 and t1.endDate between start_date and date_add(now(),interval 2 year) order by person_id, endDate ); - - set @prev_id = null; set @cur_id = null; set @cur_status = null; @@ -279,154 +365,149 @@ SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_ replace into ncd_monthly_report_dataset (select null, #date_created will be automatically set or updated - elastic_id, - endDate, - encounter_id, - person_id, - person_uuid, - birthdate, - age, - gender, - encounter_date, - visit_this_month, - rtc_date, - days_since_rtc_date, - on_schedule, - scheduled_this_month, - unscheduled_this_month, - f_18_and_over_this_month, - prev_location_id, - location_id, - t2.uuid as location_uuid, - next_location_id, - t2.state_province as clinic_county, - t2.name as clinic, - t2.latitude as clinic_latitude, - t2.longitude as clinic_longitude, - encounter_type, - death_date, - enrollment_date, - enrolled_this_month, - transfer_in_this_month, - transfer_in_location_id, - transfer_in_date, - transfer_out_this_month, - transfer_out_location_id, - transfer_out_date, - prev_status, - status, - next_status, - active_in_care_this_month, - is_pre_art_this_month, - arv_first_regimen_location_id, - arv_first_regimen, - arv_first_regimen_names, - arv_first_regimen_start_date, - art_cohort_year, - art_cohort_month, - art_cohort_num, - art_cohort_total_months, - days_since_starting_arvs, - started_art_this_month, - art_revisit_this_month, - arv_start_date, - prev_month_arvs, - prev_month_arvs_names, - cur_arv_meds, - cur_arv_meds_names, - cur_arv_meds_strict, - cur_arv_line, - cur_arv_line_strict, - cur_arv_line_reported, - on_art_this_month, - on_original_first_line_this_month, - on_alt_first_line_this_month, - on_second_line_or_higher_this_month, - eligible_for_vl, - days_since_last_vl, - net_12_month_cohort_this_month, - active_on_art_12_month_cohort_this_month, - has_vl_12_month_cohort, - vl_suppressed_12_month_cohort, - has_vl_this_month, - is_suppressed_this_month, - vl_1, - vl_1_date, - vl_in_past_year, - vl_2, - vl_2_date, - qualifies_for_follow_up_vl, - got_follow_up_vl, - got_follow_up_vl_this_month, - num_days_to_follow_vl, - follow_up_vl_suppressed, - follow_up_vl_suppressed_this_month, - follow_up_vl_unsuppressed, - follow_up_vl_unsuppressed_this_month, - due_for_vl_this_month, - reason_for_needing_vl_this_month, - number_of_months_has_needed_vl, - needs_follow_up_vl, - had_med_change_this_month, - had_med_change_this_month_after_2_unsuppressed_vls, - same_meds_this_month_after_2_unsuppressed_vls, - tb_screen, - tb_screening_datetime, - tb_screening_result, - tb_screened_this_visit_this_month, - tb_screened_active_this_month, - presumed_tb_positive_this_month, - tb_tx_start_date, - started_tb_tx_this_month, - on_tb_tx_this_month, - on_tb_tx_and_started_art_this_month, - pcp_prophylaxis_start_date, - started_pcp_prophylaxis_this_month, - on_pcp_prophylaxis_this_month, - ipt_start_date, - ipt_stop_date, - ipt_completion_date, - started_ipt_this_month, - on_ipt_this_month, - completed_ipt_past_12_months, - pregnant_this_month, - is_pregnant_and_started_art_this_month, - delivered_this_month, - condoms_provided_this_month, - condoms_provided_since_active, - started_modern_contraception_this_month, - modern_contraception_since_active, - on_modern_contraception_this_month, - contraceptive_method, - discordant_status + -- elastic_id, + -- endDate, + -- encounter_id, + -- person_id, + -- person_uuid, + -- birthdate, + -- age, + -- gender, + -- encounter_date, + -- visit_this_month, + -- rtc_date, + -- days_since_rtc_date, + -- on_schedule, + -- scheduled_this_month, + -- unscheduled_this_month, + -- f_18_and_over_this_month, + -- prev_location_id, + -- location_id, + -- t2.uuid as location_uuid, + -- next_location_id, + -- t2.state_province as clinic_county, + -- t2.name as clinic, + -- t2.latitude as clinic_latitude, + -- t2.longitude as clinic_longitude, + -- encounter_type, + -- death_date, + -- enrollment_date, + -- enrolled_this_month, + -- transfer_in_this_month, + -- transfer_in_location_id, + -- transfer_in_date, + -- transfer_out_this_month, + -- transfer_out_location_id, + -- transfer_out_date, + -- prev_status, + -- status, + -- next_status, + -- active_in_care_this_month, + -- is_pre_art_this_month, + -- arv_first_regimen_location_id, + -- arv_first_regimen, + -- arv_first_regimen_names, + -- arv_first_regimen_start_date, + -- art_cohort_year, + -- art_cohort_month, + -- art_cohort_num, + -- art_cohort_total_months, + -- days_since_starting_arvs, + -- started_art_this_month, + -- art_revisit_this_month, + -- arv_start_date, + -- prev_month_arvs, + -- prev_month_arvs_names, + -- cur_arv_meds, + -- cur_arv_meds_names, + -- cur_arv_meds_strict, + -- cur_arv_line, + -- cur_arv_line_strict, + -- cur_arv_line_reported, + -- on_art_this_month, + -- on_original_first_line_this_month, + -- on_alt_first_line_this_month, + -- on_second_line_or_higher_this_month, + -- eligible_for_vl, + -- days_since_last_vl, + -- net_12_month_cohort_this_month, + -- active_on_art_12_month_cohort_this_month, + -- has_vl_12_month_cohort, + -- vl_suppressed_12_month_cohort, + -- has_vl_this_month, + -- is_suppressed_this_month, + -- vl_1, + -- vl_1_date, + -- vl_in_past_year, + -- vl_2, + -- vl_2_date, + -- qualifies_for_follow_up_vl, + -- got_follow_up_vl, + -- got_follow_up_vl_this_month, + -- num_days_to_follow_vl, + -- follow_up_vl_suppressed, + -- follow_up_vl_suppressed_this_month, + -- follow_up_vl_unsuppressed, + -- follow_up_vl_unsuppressed_this_month, + -- due_for_vl_this_month, + -- reason_for_needing_vl_this_month, + -- number_of_months_has_needed_vl, + -- needs_follow_up_vl, + -- had_med_change_this_month, + -- had_med_change_this_month_after_2_unsuppressed_vls, + -- same_meds_this_month_after_2_unsuppressed_vls, + -- tb_screen, + -- tb_screening_datetime, + -- tb_screening_result, + -- tb_screened_this_visit_this_month, + -- tb_screened_active_this_month, + -- presumed_tb_positive_this_month, + -- tb_tx_start_date, + -- started_tb_tx_this_month, + -- on_tb_tx_this_month, + -- on_tb_tx_and_started_art_this_month, + -- pcp_prophylaxis_start_date, + -- started_pcp_prophylaxis_this_month, + -- on_pcp_prophylaxis_this_month, + -- ipt_start_date, + -- ipt_stop_date, + -- ipt_completion_date, + -- started_ipt_this_month, + -- on_ipt_this_month, + -- completed_ipt_past_12_months, + -- pregnant_this_month, + -- is_pregnant_and_started_art_this_month, + -- delivered_this_month, + -- condoms_provided_this_month, + -- condoms_provided_since_active, + -- started_modern_contraception_this_month, + -- modern_contraception_since_active, + -- on_modern_contraception_this_month, + -- contraceptive_method, + -- discordant_status from ncd_monthly_report_dataset_2 t1 join amrs.location t2 using (location_id) ); - #delete from @queue_table where person_id in (select person_id from ncd_monthly_report_dataset_build_queue__0); SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join ncd_monthly_report_dataset_build_queue__0 t2 using (person_id);'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; - - #select @person_ids_count := (select count(*) from @queue_table); + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; - #select @person_ids_count as num_remaining; set @cycle_length = timestampdiff(second,@loop_start_time,now()); - #select concat('Cycle time: ',@cycle_length,' seconds'); + set @total_time = @total_time + @cycle_length; set @cycle_number = @cycle_number + 1; - #select ceil(@person_ids_count / cycle_size) as remaining_cycles; set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); - #select concat("Estimated time remaining: ", @remaining_time,' minutes'); # select count(*) into @num_in_hmrd from ncd_monthly_report_dataset; From 1df298802e467a5f8ed783b66025b779bbe87438 Mon Sep 17 00:00:00 2001 From: henrykorir Date: Wed, 13 Dec 2023 19:43:04 +0300 Subject: [PATCH 4/9] POC-545: Create a Stored Procedure for the NCD Monthly Report --- ...lat_cdm_v1_1.sql => generate_flat_ncd.sql} | 186 ++-- .../generate_ncd_monthly_report_dataset.sql | 359 ++++---- ...erate_plhiv_ncd_monthly_report_dataset.sql | 265 ------ .../generate_plhiv_ncd_summary.sql | 823 ------------------ 4 files changed, 263 insertions(+), 1370 deletions(-) rename etl-scripts/stored-procedures/{generate_flat_cdm_v1_1.sql => generate_flat_ncd.sql} (85%) delete mode 100644 etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql delete mode 100644 etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql diff --git a/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql b/etl-scripts/stored-procedures/generate_flat_ncd.sql similarity index 85% rename from etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql rename to etl-scripts/stored-procedures/generate_flat_ncd.sql index 85cc2c1..7a21750 100644 --- a/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql +++ b/etl-scripts/stored-procedures/generate_flat_ncd.sql @@ -1,10 +1,7 @@ -DELIMITER $$ -CREATE PROCEDURE `generate_flat_cdm_v1_1`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int) +CREATE PROCEDURE `etl`.`generate_flat_ncd_v1_1`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int) BEGIN - set @primary_table := "flat_cdm_v1"; + set @primary_table := "flat_ncd"; set @query_type = query_type; -#set @query_type = "build"; - set @total_rows_written = 0; @@ -14,7 +11,7 @@ BEGIN set @other_encounter_types = "(-1)"; set @start = now(); - set @table_version = "flat_cdm_v1.1"; + set @table_version = "flat_ncd_v1.0"; set session sort_buffer_size=512000000; @@ -22,7 +19,7 @@ BEGIN set @boundary = "!!"; set @last_date_created = (select max(max_date_created) from etl.flat_obs); - create table if not exists flat_cdm_v1 ( + create table if not exists flat_ncd ( date_created TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, person_id int, uuid varchar(100), @@ -80,17 +77,18 @@ BEGIN prev_hbp_findings text, type_of_follow_up text, review_of_med_history text, + psychiatric_exam_findings text, - prev_encounter_datetime_cdm datetime, - next_encounter_datetime_cdm datetime, - prev_encounter_type_cdm mediumint, - next_encounter_type_cdm mediumint, - prev_clinical_datetime_cdm datetime, - next_clinical_datetime_cdm datetime, - prev_clinical_location_id_cdm mediumint, - next_clinical_location_id_cdm mediumint, - prev_clinical_rtc_date_cdm datetime, - next_clinical_rtc_date_cdm datetime, + prev_encounter_datetime_ncd datetime, + next_encounter_datetime_ncd datetime, + prev_encounter_type_ncd mediumint, + next_encounter_type_ncd mediumint, + prev_clinical_datetime_ncd datetime, + next_clinical_datetime_ncd datetime, + prev_clinical_location_id_ncd mediumint, + next_clinical_location_id_ncd mediumint, + prev_clinical_rtc_date_ncd datetime, + next_clinical_rtc_date_ncd datetime, primary key encounter_id (encounter_id), index person_date (person_id, encounter_datetime), @@ -99,7 +97,7 @@ BEGIN index enc_date_location (encounter_datetime, location_uuid), index location_id_rtc_date (location_id,rtc_date), index location_uuid_rtc_date (location_uuid,rtc_date), - index loc_id_enc_date_next_clinical (location_id, encounter_datetime, next_clinical_datetime_cdm), + index loc_id_enc_date_next_clinical (location_id, encounter_datetime, next_clinical_datetime_ncd), index encounter_type (encounter_type), index date_created (date_created) @@ -110,8 +108,8 @@ BEGIN if(@query_type="build") then select 'BUILDING..........................................'; - set @write_table = concat("flat_cdm_temp_",queue_number); - set @queue_table = concat("flat_cdm_build_queue_",queue_number); + set @write_table = concat("flat_ncd_temp_",queue_number); + set @queue_table = concat("flat_ncd_build_queue_",queue_number); SET @dyn_sql=CONCAT('Create table if not exists ',@write_table,' like ',@primary_table); @@ -119,12 +117,12 @@ BEGIN EXECUTE s1; DEALLOCATE PREPARE s1; - SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from flat_cdm_build_queue limit ', queue_size, ');'); + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from flat_ncd_build_queue limit ', queue_size, ');'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; - SET @dyn_sql=CONCAT('delete t1 from flat_cdm_build_queue t1 join ',@queue_table, ' t2 using (person_id);'); + SET @dyn_sql=CONCAT('delete t1 from flat_ncd_build_queue t1 join ',@queue_table, ' t2 using (person_id);'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; @@ -134,9 +132,9 @@ BEGIN if (@query_type="sync") then select 'SYNCING..........................................'; - set @write_table = "flat_cdm_v1"; - set @queue_table = "flat_cdm_sync_queue"; - create table if not exists flat_cdm_sync_queue (person_id int primary key); + set @write_table = "flat_ncd_v1"; + set @queue_table = "flat_ncd_sync_queue"; + create table if not exists flat_ncd_sync_queue (person_id int primary key); @@ -144,37 +142,37 @@ BEGIN select max(date_updated) into @last_update from etl.flat_log where table_name=@table_version; - replace into flat_cdm_sync_queue + replace into flat_ncd_sync_queue (select distinct patient_id from amrs.encounter where date_changed > @last_update ); - replace into flat_cdm_sync_queue + replace into flat_ncd_sync_queue (select distinct person_id from etl.flat_obs where max_date_created > @last_update ); - replace into flat_cdm_sync_queue + replace into flat_ncd_sync_queue (select distinct person_id from etl.flat_lab_obs where max_date_created > @last_update ); - replace into flat_cdm_sync_queue + replace into flat_ncd_sync_queue (select distinct person_id from etl.flat_orders where max_date_created > @last_update ); - replace into flat_cdm_sync_queue + replace into flat_ncd_sync_queue (select person_id from amrs.person where date_voided > @last_update); - replace into flat_cdm_sync_queue + replace into flat_ncd_sync_queue (select person_id from amrs.person where date_changed > @last_update); @@ -246,9 +244,9 @@ BEGIN set @loop_start_time = now(); #create temp table with a set of person ids - drop temporary table if exists flat_cdm_build_queue__0; + drop temporary table if exists flat_ncd_build_queue__0; - SET @dyn_sql=CONCAT('create temporary table flat_cdm_build_queue__0 (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); + SET @dyn_sql=CONCAT('create temporary table flat_ncd_build_queue__0 (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; @@ -257,9 +255,9 @@ BEGIN - drop temporary table if exists flat_cdm_0a; + drop temporary table if exists flat_ncd_0a; SET @dyn_sql = CONCAT( - 'create temporary table flat_cdm_0a + 'create temporary table flat_ncd_0a (select t1.person_id, t1.visit_id, @@ -282,7 +280,7 @@ BEGIN end as encounter_type_sort_index, t2.orders from etl.flat_obs t1 - join flat_cdm_build_queue__0 t0 using (person_id) + join flat_ncd_build_queue__0 t0 using (person_id) left join etl.flat_orders t2 using(encounter_id) where t1.encounter_type in ',@encounter_types,');'); @@ -291,7 +289,7 @@ BEGIN DEALLOCATE PREPARE s1; - insert into flat_cdm_0a + insert into flat_ncd_0a (select t1.person_id, null, @@ -306,12 +304,12 @@ BEGIN 1 as encounter_type_sort_index, null from etl.flat_lab_obs t1 - join flat_cdm_build_queue__0 t0 using (person_id) + join flat_ncd_build_queue__0 t0 using (person_id) ); - drop temporary table if exists flat_cdm_0; - create temporary table flat_cdm_0(index encounter_id (encounter_id), index person_enc (person_id,encounter_datetime)) - (select * from flat_cdm_0a + drop temporary table if exists flat_ncd_0; + create temporary table flat_ncd_0(index encounter_id (encounter_id), index person_enc (person_id,encounter_datetime)) + (select * from flat_ncd_0a order by person_id, date(encounter_datetime), encounter_type_sort_index ); @@ -333,8 +331,8 @@ BEGIN # screened for cervical ca # exposed infant - drop temporary table if exists flat_cdm_1; - create temporary table flat_cdm_1 (index encounter_id (encounter_id)) + drop temporary table if exists flat_ncd_1; + create temporary table flat_ncd_1 (index encounter_id (encounter_id)) (select obs, encounter_type_sort_index, @@ -440,13 +438,28 @@ BEGIN @dm_status := etl.GetValues(obs,7287) as dm_status, @htn_status := etl.GetValues(obs,7288) as htn_status, - @dm_meds := etl.GetValues(obs,7290) as dm_meds, - @htn_meds := etl.GetValues(obs,10241) as htn_meds, - t2.prescriptions as prescriptions, - - @problems := concat(etl.GetValues(obs,6042 ), ' ## ', etl.GetValues(obs,11679), ' ## ', etl.GetValues(obs,6796)) as problems, + @dm_meds := concat_ws(' ## ', + etl.GetValues(obs,7290), + etl.GetValues(obs,7304) + ) as dm_meds, + @htn_meds := concat_ws(' ## ', + etl.GetValues(obs,7291), + etl.GetValues(obs,7332), + etl.GetValues(obs,10241) + ) as htn_meds, + + t2.prescriptions as prescriptions, + + @problems := concat_ws(' ## ', + etl.GetValues(obs,6042 ), + etl.GetValues(obs,11679), + etl.GetValues(obs,6796), + etl.GetValues(obs,2072), + etl.GetValues(obs,6097), + etl.GetValues(obs,6461) + ) as problems, @comorbidities := etl.GetValues(obs,10239 ) as comorbidities, - @rheumatologic_disorder := etl.GetValues(obs,12293) as rheumatologic_disorder + @rheumatologic_disorder := etl.GetValues(obs,12293) as rheumatologic_disorder, @kidney_disease := etl.GetValues(obs, 6033) as kidney_disease, @ckd_staging := etl.GetValues(obs,10101) as ckd_staging, @cardiovascular_disorder := etl.GetValues(obs, 7971) as cardiovascular_disorder, @@ -460,9 +473,9 @@ BEGIN @prev_hbp_findings := etl.GetValues(obs, 9092) as prev_hbp_findings, @type_of_follow_up := etl.GetValues(obs, 2332) as type_of_follow_up, @review_of_med_history := etl.GetValues(obs, 6245) as review_of_med_history, - @psychiatric_exam_findings := etl.GetValues(obs, 6245) as review_of_med_history + @psychiatric_exam_findings := etl.GetValues(obs, 1130) as psychiatric_exam_findings - from flat_cdm_0 t1 + from flat_ncd_0 t1 join amrs.person p using (person_id) left outer join prescriptions t2 using (encounter_id) ); @@ -483,10 +496,10 @@ BEGIN set @cur_clinical_location_id = null; - alter table flat_cdm_1 drop prev_id, drop cur_id; + alter table flat_ncd_1 drop prev_id, drop cur_id; - drop table if exists flat_cdm_2; - create temporary table flat_cdm_2 + drop table if exists flat_ncd_2; + create temporary table flat_ncd_2 (select *, @prev_id := @cur_id as prev_id, @cur_id := person_id as cur_id, @@ -494,26 +507,26 @@ BEGIN case when @prev_id = @cur_id then @prev_encounter_datetime := @cur_encounter_datetime else @prev_encounter_datetime := null - end as next_encounter_datetime_cdm, + end as next_encounter_datetime_ncd, @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, case when @prev_id=@cur_id then @next_encounter_type := @cur_encounter_type else @next_encounter_type := null - end as next_encounter_type_cdm, + end as next_encounter_type_ncd, @cur_encounter_type := encounter_type as cur_encounter_type, case when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime else @prev_clinical_datetime := null - end as next_clinical_datetime_cdm, + end as next_clinical_datetime_ncd, case when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id else @prev_clinical_location_id := null - end as next_clinical_location_id_cdm, + end as next_clinical_location_id_ncd, case when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime @@ -530,7 +543,7 @@ BEGIN case when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date else @prev_clinical_rtc_date := null - end as next_clinical_rtc_date_cdm, + end as next_clinical_rtc_date_ncd, case when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date @@ -538,11 +551,11 @@ BEGIN else @cur_clinical_rtc_date:= null end as cur_clinical_rtc_date - from flat_cdm_1 + from flat_ncd_1 order by person_id, date(encounter_datetime) desc, encounter_type_sort_index desc ); - alter table flat_cdm_2 drop prev_id, drop cur_id, drop cur_encounter_type, drop cur_encounter_datetime, drop cur_clinical_rtc_date; + alter table flat_ncd_2 drop prev_id, drop cur_id, drop cur_encounter_type, drop cur_encounter_datetime, drop cur_clinical_rtc_date; set @prev_id = null; @@ -556,8 +569,8 @@ BEGIN set @prev_clinical_location_id = null; set @cur_clinical_location_id = null; - drop temporary table if exists flat_cdm_3; - create temporary table flat_cdm_3 (prev_encounter_datetime datetime, prev_encounter_type int, index person_enc (person_id, encounter_datetime desc)) + drop temporary table if exists flat_ncd_3; + create temporary table flat_ncd_3 (prev_encounter_datetime datetime, prev_encounter_type int, index person_enc (person_id, encounter_datetime desc)) (select *, @prev_id := @cur_id as prev_id, @@ -566,25 +579,25 @@ BEGIN case when @prev_id=@cur_id then @prev_encounter_type := @cur_encounter_type else @prev_encounter_type:=null - end as prev_encounter_type_cdm, + end as prev_encounter_type_ncd, @cur_encounter_type := encounter_type as cur_encounter_type, case when @prev_id=@cur_id then @prev_encounter_datetime := @cur_encounter_datetime else @prev_encounter_datetime := null - end as prev_encounter_datetime_cdm, + end as prev_encounter_datetime_ncd, @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, case when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime else @prev_clinical_datetime := null - end as prev_clinical_datetime_cdm, + end as prev_clinical_datetime_ncd, case when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id else @prev_clinical_location_id := null - end as prev_clinical_location_id_cdm, + end as prev_clinical_location_id_ncd, case when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime @@ -601,7 +614,7 @@ BEGIN case when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date else @prev_clinical_rtc_date := null - end as prev_clinical_rtc_date_cdm, + end as prev_clinical_rtc_date_ncd, case when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date @@ -609,13 +622,13 @@ BEGIN else @cur_clinical_rtc_date:= null end as cur_clinic_rtc_date - from flat_cdm_2 t1 + from flat_ncd_2 t1 order by person_id, date(encounter_datetime), encounter_type_sort_index ); - select count(*) into @new_encounter_rows from flat_cdm_3; + select count(*) into @new_encounter_rows from flat_ncd_3; select @new_encounter_rows; set @total_rows_written = @total_rows_written + @new_encounter_rows; @@ -674,19 +687,20 @@ BEGIN prev_hbp_findings, type_of_follow_up, review_of_med_history, + psychiatric_exam_findings, - prev_encounter_datetime_cdm, - next_encounter_datetime_cdm, - prev_encounter_type_cdm, - next_encounter_type_cdm, - prev_clinical_datetime_cdm, - next_clinical_datetime_cdm, - prev_clinical_location_id_cdm, - next_clinical_location_id_cdm, - prev_clinical_rtc_date_cdm, - next_clinical_rtc_date_cdm + prev_encounter_datetime_ncd, + next_encounter_datetime_ncd, + prev_encounter_type_ncd, + next_encounter_type_ncd, + prev_clinical_datetime_ncd, + next_clinical_datetime_ncd, + prev_clinical_location_id_ncd, + next_clinical_location_id_ncd, + prev_clinical_rtc_date_ncd, + next_clinical_rtc_date_ncd - from flat_cdm_3 t1 + from flat_ncd_3 t1 join amrs.location t2 using (location_id))'); PREPARE s1 from @dyn_sql; @@ -694,16 +708,15 @@ BEGIN DEALLOCATE PREPARE s1; - #delete from @queue_table where person_id in (select person_id from flat_cdm_build_queue__0); + #delete from @queue_table where person_id in (select person_id from flat_ncd_build_queue__0); - SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join flat_cdm_build_queue__0 t2 using (person_id);'); -# select @dyn_sql; + SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join flat_ncd_build_queue__0 t2 using (person_id);'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; - #select @person_ids_count := (select count(*) from flat_cdm_build_queue_2); + #select @person_ids_count := (select count(*) from flat_ncd_build_queue_2); SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); PREPARE s1 from @dyn_sql; EXECUTE s1; @@ -765,5 +778,4 @@ BEGIN insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); select concat(@table_version," : Time to complete: ",timestampdiff(minute, @start, @end)," minutes"); - END$$ -DELIMITER ; + END \ No newline at end of file diff --git a/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql index 45fddb9..d1eceab 100644 --- a/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql +++ b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql @@ -1,5 +1,5 @@ DELIMITER $$ -CREATE PROCEDURE `generate_ncd_monthly_report_dataset`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int, IN start_date varchar(50)) +CREATE CREATE DEFINER=`hkorir`@`%` PROCEDURE `generate_ncd_monthly_report_dataset`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int, IN start_date varchar(50)) BEGIN set @start = now(); @@ -11,7 +11,7 @@ BEGIN set @death_encounter_type = 31; -create table if not exists ncd_monthly_report_dataset ( + create table if not exists ncd_monthly_report_dataset ( date_created timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP NOT NULL, elastic_id bigint, endDate date, @@ -23,6 +23,7 @@ create table if not exists ncd_monthly_report_dataset ( gender varchar(1), location_id int, location_uuid varchar(100), + clinic varchar(250), encounter_date date, visit_this_month tinyint, @@ -52,6 +53,8 @@ create table if not exists ncd_monthly_report_dataset ( has_stroke tinyint, is_stroke_haemorrhagic tinyint, is_stroke_ischaemic tinyint, + + has_migraine tinyint, has_seizure tinyint, has_epilepsy tinyint, has_convulsive_disorder tinyint, @@ -67,7 +70,6 @@ create table if not exists ncd_monthly_report_dataset ( index endDate_location_id (endDate, location_id), index date_created (date_created), index status_change (location_id, endDate, status, prev_status) - ); if (query_type = "build") then @@ -152,25 +154,6 @@ create table if not exists ncd_monthly_report_dataset ( date(encounter_datetime) as encounter_date, if(encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate,1,0) as visit_this_month, - - date(rtc_date) as rtc_date, - timestampdiff(day,rtc_date, endDate) as days_since_rtc_date, - - if(date(encounter_datetime) = date(prev_clinical_rtc_date_hiv),1,0) as on_schedule, - - case - when encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate - AND date(encounter_datetime) = date(prev_clinical_rtc_date_hiv) - then 1 - else 0 - end as scheduled_this_month, - - case - when encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate - AND date(encounter_datetime) != date(prev_clinical_rtc_date_hiv) - then 1 - else 0 - end as unscheduled_this_month, case when arv_first_regimen_location_id != 9999 @@ -183,11 +166,11 @@ create table if not exists ncd_monthly_report_dataset ( case when htn_status = 7285 or htn_status = 7286 then 1 - when (comorbidities regexp '903') then 1 - when (prev_hbp_findings regexp '1065') then 1 + when (comorbidities regexp '[[:<:]]903[[:>:]]') then 1 + when (prev_hbp_findings regexp '[[:<:]]1065[[:>:]]') then 1 when (htn_meds is not null) then 1 - when (problems regexp '903') then 1 - when (review_of_med_history regexp '903') then 1 + when (problems regexp '[[:<:]]903[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]903[[:>:]]') then 1 else null end as is_hypertensive, @@ -200,11 +183,10 @@ create table if not exists ncd_monthly_report_dataset ( case when dm_status = 7281 or dm_status = 7282 then 1 - when (comorbidities regexp '175') then 1 + when (comorbidities regexp '[[:<:]]175[[:>:]]') then 1 when (dm_meds is not null) then 1 - when (problems regexp '9324') or (problems regexp '175') then 1 - when (problems regexp '175') then 1 - when (review_of_med_history regexp '175') then 1 + when (problems regexp '[[:<:]]9324|175[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]175[[:>:]]') then 1 else null end as is_diabetic, @@ -216,41 +198,44 @@ create table if not exists ncd_monthly_report_dataset ( end as dm_state, case - when (comorbidities regexp '10860') then 1 + when (comorbidities regexp '[[:<:]]10860[[:>:]]') then 1 when (indicated_mhd_tx is not null) then 1 when (has_past_mhd_tx = '1065') then 1 - when (review_of_med_history regexp '(77)|(207)') then 1 + when (review_of_med_history regexp '[[:<:]]77|207[[:>:]]') then 1 when (eligible_for_depression_care = '1065') then 1 when (mood_disorder is not null) then 1 when (anxiety_condition is not null) then 1 + when (psychiatric_exam_findings is not null) then 1 else null end as has_mhd, case when (eligible_for_depression_care = '1065') then 1 - when (mood_disorder regexp '11278') then 1 - when (indicated_mhd_tx regexp '207') then 1 - when (review_of_med_history regexp '207') then 1 + when (mood_disorder regexp '[[:<:]]11278[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]207[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]207[[:>:]]') then 1 + when (psychiatric_exam_findings regexp '[[:<:]]207[[:>:]]') then 1 else null end as is_depressive_mhd, case when (anxiety_condition is not null) then 1 - when (indicated_mhd_tx regexp '1443') then 1 - when (review_of_med_history regexp '207') then 1 + when (indicated_mhd_tx regexp '[[:<:]]1443[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]207[[:>:]]') then 1 + when (psychiatric_exam_findings regexp '[[:<:]]1443[[:>:]]') then 1 else null end as is_anxiety_mhd, case - when (mood_disorder regexp '7763') then 1 - when (indicated_mhd_tx regexp '7763') then 1 + when (mood_disorder regexp '[[:<:]]7763[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]7763[[:>:]]') then 1 else null end as is_bipolar_and_related_mhd, case - when (mood_disorder regexp '7763') then 1 - when (indicated_mhd_tx regexp '11281') then 1 - when (problems regexp '467') then 1 + when (mood_disorder regexp '[[:<:]]7763[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]11281[[:>:]]') then 1 + when (problems regexp '[[:<:]]467[[:>:]]') then 1 else null end as is_personality_mhd, @@ -261,14 +246,14 @@ create table if not exists ncd_monthly_report_dataset ( case when (comorbidities regexp '[[:<:]]77[[:>:]]') then 1 when (kidney_disease = '[[:<:]]1065[[:>:]]') then 1 - when (problems regexp '[[:<:]]8078[[:>:]]|[[:<:]]11684[[:>:]]') then 1 - when (review_of_med_history regexp '(6033)|(8078)') then 1 + when (problems regexp '[[:<:]]8078|11684[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]6033|8078[[:>:]]') then 1 else null end as has_kd, case - when (problems regexp '8078') then 1 - when (review_of_med_history regexp '8078') then 1 + when (problems regexp '[[:<:]]8078[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]8078[[:>:]]') then 1 when (ckd_staging is not null) then 1 else null end as is_ckd, @@ -277,34 +262,34 @@ create table if not exists ncd_monthly_report_dataset ( case when (cardiovascular_disorder is not null) then 1 - when (comorbidities regexp '7971') then 1 - when (review_of_med_history regexp '(7971)|(6237)') then 1 + when (comorbidities regexp '[[:<:]]7971[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]7971|6237[[:>:]]') then 1 else null end as has_cvd, case - when (cardiovascular_disorder regexp '1456') then 1 - when (indicated_mhd_tx regexp '1456') then 1 - when (review_of_med_history regexp '7971') then 1 + when (cardiovascular_disorder regexp '[[:<:]]1456[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]1456[[:>:]]') then 1 + when (review_of_med_history regexp '[[:7971') then 1 else null end as is_heart_failure_cvd, - + case - when (neurological_disease is not null) then 1 - when (indicated_mhd_tx regexp '1456') then 1 - when (review_of_med_history regexp '7971') then 1 + when (cardiovascular_disorder regexp '[[:<:]]1535[[:>:]]') then 1 else null - end as has_neurological_disorder, + end as is_myocardinal_infarction, case - when (cardiovascular_disorder regexp '1535') then 1 + when (neurological_disease is not null) then 1 + when (indicated_mhd_tx regexp '[[:<:]]1456[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]7971[[:>:]]') then 1 else null - end as is_myocardinal_infarction, + end as has_neurological_disorder, case - when (cardiovascular_disorder regexp '1878') then 1 - when (indicated_mhd_tx regexp '1456') then 1 - when (review_of_med_history regexp '7971') then 1 + when (cardiovascular_disorder regexp '[[:<:]]1878[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]1456[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]7971[[:>:]]') then 1 else null end as has_stroke, @@ -312,10 +297,51 @@ create table if not exists ncd_monthly_report_dataset ( null as is_stroke_ischaemic, - null as + case + when (problems regexp '[[:<:]]1477[[:>:]]') then 1 + when (neurological_disease regexp '[[:<:]]1477[[:>:]]') then 1 + else null + end as has_migraine, + + case + when (problems regexp '[[:<:]]206[[:>:]]') then 1 + when (neurological_disease regexp '[[:<:]]206[[:>:]]') then 1 + when (convulsive_disorder regexp '[[:<:]]206[[:>:]]') then 1 + else null + end as has_seizure, + + case + when (problems regexp '[[:<:]]155|11687[[:>:]]') then 1 + when (neurological_disease regexp '[[:<:]]155[[:>:]]') then 1 + when (convulsive_disorder regexp '[[:<:]]155[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]155[[:>:]]') then 1 + else null + end as has_epilepsy, + + case + when (neurological_disease regexp '[[:<:]]10806[[:>:]]') then 1 + when (convulsive_disorder regexp '[[:<:]]155|10806[[:>:]]') then 1 + else null + end as has_convulsive_disorder, + + case + when (rheumatologic_disorder is not null) then 1 + when (comorbidities regexp '[[:<:]]12293[[:>:]]') then 1 + else null + end as has_rheumatologic_disorder, + + case + when (rheumatologic_disorder regexp '[[:<:]]116[[:>:]]') then 1 + else null + end as has_arthritis, + + case + when (rheumatologic_disorder regexp '[[:<:]]12292[[:>:]]') then 1 + else null + end as has_SLE from etl.dates t1 - join etl.flat_cdm_v1 t2 + join etl.flat_ncd t2 join amrs.person t3 using (person_id) join etl.ncd_monthly_report_dataset_build_queue__0 t5 using (person_id) @@ -329,8 +355,6 @@ create table if not exists ncd_monthly_report_dataset ( set @prev_id = null; set @cur_id = null; - set @cur_status = null; - set @prev_status = null; set @prev_location_id = null; set @cur_location_id = null; @@ -348,15 +372,33 @@ create table if not exists ncd_monthly_report_dataset ( @cur_location_id := location_id as cur_location_id, - case - when @prev_id=@cur_id then @prev_status := @cur_status - else @prev_status := null - end as next_status, - @cur_status := status as cur_status - from ncd_monthly_report_dataset_0 order by person_id, endDate desc ); + + alter table ncd_monthly_report_dataset_1 drop prev_id, drop cur_id; + + set @prev_id = null; + set @cur_id = null; + set @cur_location_id = null; + set @prev_location_id = null; + drop temporary table if exists hiv_monthly_report_dataset_2; + create temporary table hiv_monthly_report_dataset_2 + (select + *, + @prev_id := @cur_id as prev_id, + @cur_id := person_id as cur_id, + + case + when @prev_id=@cur_id then @prev_location_id := @cur_location_id + else @prev_location_id := null + end as prev_location_id, + + @cur_location_id := location_id as cur_location_id + + from ncd_monthly_report_dataset_1 + order by person_id, endDate + ); select now(); select count(*) as num_rows_to_be_inserted from ncd_monthly_report_dataset_2; @@ -365,132 +407,61 @@ create table if not exists ncd_monthly_report_dataset ( replace into ncd_monthly_report_dataset (select null, #date_created will be automatically set or updated - -- elastic_id, - -- endDate, - -- encounter_id, - -- person_id, - -- person_uuid, - -- birthdate, - -- age, - -- gender, - -- encounter_date, - -- visit_this_month, - -- rtc_date, - -- days_since_rtc_date, - -- on_schedule, - -- scheduled_this_month, - -- unscheduled_this_month, - -- f_18_and_over_this_month, - -- prev_location_id, - -- location_id, - -- t2.uuid as location_uuid, - -- next_location_id, - -- t2.state_province as clinic_county, - -- t2.name as clinic, - -- t2.latitude as clinic_latitude, - -- t2.longitude as clinic_longitude, - -- encounter_type, - -- death_date, - -- enrollment_date, - -- enrolled_this_month, - -- transfer_in_this_month, - -- transfer_in_location_id, - -- transfer_in_date, - -- transfer_out_this_month, - -- transfer_out_location_id, - -- transfer_out_date, - -- prev_status, - -- status, - -- next_status, - -- active_in_care_this_month, - -- is_pre_art_this_month, - -- arv_first_regimen_location_id, - -- arv_first_regimen, - -- arv_first_regimen_names, - -- arv_first_regimen_start_date, - -- art_cohort_year, - -- art_cohort_month, - -- art_cohort_num, - -- art_cohort_total_months, - -- days_since_starting_arvs, - -- started_art_this_month, - -- art_revisit_this_month, - -- arv_start_date, - -- prev_month_arvs, - -- prev_month_arvs_names, - -- cur_arv_meds, - -- cur_arv_meds_names, - -- cur_arv_meds_strict, - -- cur_arv_line, - -- cur_arv_line_strict, - -- cur_arv_line_reported, - -- on_art_this_month, - -- on_original_first_line_this_month, - -- on_alt_first_line_this_month, - -- on_second_line_or_higher_this_month, - -- eligible_for_vl, - -- days_since_last_vl, - -- net_12_month_cohort_this_month, - -- active_on_art_12_month_cohort_this_month, - -- has_vl_12_month_cohort, - -- vl_suppressed_12_month_cohort, - -- has_vl_this_month, - -- is_suppressed_this_month, - -- vl_1, - -- vl_1_date, - -- vl_in_past_year, - -- vl_2, - -- vl_2_date, - -- qualifies_for_follow_up_vl, - -- got_follow_up_vl, - -- got_follow_up_vl_this_month, - -- num_days_to_follow_vl, - -- follow_up_vl_suppressed, - -- follow_up_vl_suppressed_this_month, - -- follow_up_vl_unsuppressed, - -- follow_up_vl_unsuppressed_this_month, - -- due_for_vl_this_month, - -- reason_for_needing_vl_this_month, - -- number_of_months_has_needed_vl, - -- needs_follow_up_vl, - -- had_med_change_this_month, - -- had_med_change_this_month_after_2_unsuppressed_vls, - -- same_meds_this_month_after_2_unsuppressed_vls, - -- tb_screen, - -- tb_screening_datetime, - -- tb_screening_result, - -- tb_screened_this_visit_this_month, - -- tb_screened_active_this_month, - -- presumed_tb_positive_this_month, - -- tb_tx_start_date, - -- started_tb_tx_this_month, - -- on_tb_tx_this_month, - -- on_tb_tx_and_started_art_this_month, - -- pcp_prophylaxis_start_date, - -- started_pcp_prophylaxis_this_month, - -- on_pcp_prophylaxis_this_month, - -- ipt_start_date, - -- ipt_stop_date, - -- ipt_completion_date, - -- started_ipt_this_month, - -- on_ipt_this_month, - -- completed_ipt_past_12_months, - -- pregnant_this_month, - -- is_pregnant_and_started_art_this_month, - -- delivered_this_month, - -- condoms_provided_this_month, - -- condoms_provided_since_active, - -- started_modern_contraception_this_month, - -- modern_contraception_since_active, - -- on_modern_contraception_this_month, - -- contraceptive_method, - -- discordant_status + elastic_id, + endDate, + encounter_id, + person_id, + person_uuid, + birthdate, + age, + gender, + location_id, + location_uuid, + t2.name as clinic + encounter_date, + visit_this_month, + + is_hypertensive, + htn_state, + + is_diabetic, + dm_state, + + has_mhd, + is_depressive_mhd, + is_anxiety_mhd, + is_bipolar_and_related_mhd, + is_personality_mhd, + is_feeding_and_eating_mhd, + is_ocd_mhd, + + has_kd, + is_ckd, + ckd_stage, + + has_cvd, + is_heart_failure_cvd, + is_myocardinal_infarction, + + has_neurological_disorder, + has_stroke, + is_stroke_haemorrhagic, + is_stroke_ischaemic, + + has_migraine, + has_seizure, + has_epilepsy, + has_convulsive_disorder, + + has_rheumatologic_disorder, + has_arthritis, + has_SLE + from ncd_monthly_report_dataset_2 t1 join amrs.location t2 using (location_id) ); - SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join ncd_monthly_report_dataset_build_queue__0 t2 using (person_id);'); PREPARE s1 from @dyn_sql; EXECUTE s1; @@ -509,9 +480,7 @@ create table if not exists ncd_monthly_report_dataset ( set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); -# select count(*) into @num_in_hmrd from ncd_monthly_report_dataset; - - select @num_in_hmrd as num_in_hmrd, + select @num_in_nmrd as num_in_nmrd, @person_ids_count as num_remaining, @cycle_length as 'Cycle time (s)', ceil(@person_ids_count / cycle_size) as remaining_cycles, diff --git a/etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql b/etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql deleted file mode 100644 index 6266644..0000000 --- a/etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql +++ /dev/null @@ -1,265 +0,0 @@ -DELIMITER $$ -CREATE PROCEDURE `generate_plhiv_ncd_monthly_report_dataset`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int , IN log boolean) -BEGIN - select @start := now(); - select @table_version := "plhiv_ncd_monthly_report_dataset"; - set @primary_table := "plhiv_ncd_monthly_report_dataset"; - set @query_type = query_type; - - set @total_rows_written = 0; - - set session sort_buffer_size=512000000; - - select @sep := " ## "; - select @last_date_created := (select max(max_date_created) from etl.flat_obs); - - CREATE TABLE IF NOT EXISTS `plhiv_ncd_monthly_report_dataset` ( - `elastic_id` varchar(21) NOT NULL DEFAULT '', - `location_id` bigint(60) DEFAULT NULL, - `person_id` int(11) DEFAULT NULL, - `person_uuid` char(38) CHARACTER SET utf8 NOT NULL, - `birthdate` date DEFAULT NULL, - `death_date` longtext CHARACTER SET utf8, - `age` decimal(23,2) DEFAULT NULL, - `gender` varchar(50) CHARACTER SET utf8 DEFAULT '', - `encounter_id` int(11) NOT NULL DEFAULT '0', - `encounter_datetime` datetime DEFAULT NULL, - `encounter_month` int(6) DEFAULT NULL, - `endDate` date DEFAULT NULL, - `prev_rtc_date` longtext, - `prev_rtc_month` int(6) DEFAULT NULL, - `rtc_date` varchar(10) CHARACTER SET utf8 DEFAULT NULL, - `rtc_month` int(6) DEFAULT NULL, - `visit_this_month` int(3) DEFAULT NULL, - `appointment_this_month` int(3) DEFAULT NULL, - `scheduled_visit_this_month` int(1) NOT NULL DEFAULT '0', - `early_appointment_this_month` int(1) NOT NULL DEFAULT '0', - `late_appointment_this_month` int(1) NOT NULL DEFAULT '0', - `missed_appointment_this_month` int(1) NOT NULL DEFAULT '0', - `days_since_rtc_date` varchar(23) CHARACTER SET utf8 DEFAULT NULL, - `has_comorbidity` TINYINT(1), - `has_mental_disorder_comorbidity` TINYINT(1), - `has_diabetic_comorbidity` TINYINT(1), - `has_hypertension_comorbidity` TINYINT(1), - `has_other_comorbidity` TINYINT(1), - PRIMARY KEY (`elastic_id`), - KEY `person_id` (`person_id`), - KEY `person_id_2` (`person_id`,`endDate`), - KEY `endDate` (`endDate`), - KEY `location_id` (`location_id`,`endDate`), - KEY `encounter_datetime` (`encounter_datetime`) - ) ENGINE=InnoDB DEFAULT CHARSET=latin1; - - - if(@query_type="build") then - select 'BUILDING..........................................'; - set @write_table = concat("plhiv_ncd_monthly_report_temp_",queue_number); - set @queue_table = concat("plhiv_ncd_monthly_report_build_queue_",queue_number); - - SET @dyn_sql=CONCAT('Create table if not exists ',@write_table,' like ',@primary_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @dyn_sql=CONCAT('drop table if exists ',@queue_table,';'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select person_id from plhiv_ncd_monthly_report_build_queue limit ', queue_size, ');'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @dyn_sql=CONCAT('delete t1 from plhiv_ncd_monthly_report_build_queue t1 join ',@queue_table, ' t2 on (t1.person_id = t2.person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - end if; - - # Display the important tables names - select @queue_table; - select @primary_table; - select @write_table; - - # Remove test patients - SET @dyn_sql=CONCAT('delete t1 FROM ',@queue_table,' t1 - join amrs.person_attribute t2 using (person_id) - where t2.person_attribute_type_id=28 and value="true" and voided=0'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @dyn_sql=CONCAT('select count(*) as queue_size from ',@queue_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @person_ids_count = 0; - SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - select @person_ids_count as 'num patients to sync'; - - - SET @dyn_sql=CONCAT('delete t1 from ',@primary_table, ' t1 join ',@queue_table,' t2 using (person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - set @total_time=0; - set @cycle_number = 0; - while @person_ids_count > 0 do - - set @loop_start_time = now(); - - drop temporary table if exists plhiv_ncd_monthly_report_temp_queue; - SET @dyn_sql=CONCAT('create temporary table plhiv_ncd_monthly_report_temp_queue (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - drop temporary table if exists plhiv_ncd_summary_in_queue; - create temporary table plhiv_ncd_summary_in_queue - (index (person_id), index(person_id, encounter_datetime), index(encounter_id), index(encounter_datetime), index(rtc_date)) - (select * - from - etl.plhiv_ncd_summary_v1 - where - encounter_datetime >= '2018-01-01' - order by person_id, encounter_datetime - ); - - drop table if exists plhiv_ncd_patient_encounters; - create table plhiv_ncd_patient_encounters - (index (person_id), index(person_id, endDate, encounter_id)) - ( - select - * - from ( - select - * - from etl.dates m - join plhiv_ncd_summary_in_queue h - WHERE h.encounter_datetime < DATE_ADD(endDate, INTERVAL 1 DAY) - and m.endDate BETWEEN '2018-01-01' AND DATE_ADD(now(), INTERVAL 2 YEAR) - ORDER BY h.person_id , month(endDate), h.encounter_datetime desc , rtc_date - ) p - group by person_id, month(endDate) - ); - - - drop temporary table if exists stage_1; - create temporary table stage_1 - ( - primary key elastic_id (elastic_id), - index (person_id), - index (person_id, endDate), - index(endDate), - index(location_id, endDate), - index(encounter_datetime)) - (SELECT - concat(month(endDate), t1.person_id) as elastic_id, - location_id, - t1.person_id, - t1.uuid AS person_uuid, - DATE(t1.birthdate) AS birthdate, - t1.death_date, - CASE - WHEN - TIMESTAMPDIFF(YEAR, t1.birthdate, endDate) > 0 - THEN - @age:=ROUND(TIMESTAMPDIFF(YEAR, t1.birthdate, endDate), - 0) - ELSE @age:=ROUND(TIMESTAMPDIFF(MONTH, - t1.birthdate, - endDate) / 12, - 2) - END AS age, - t1.gender, - encounter_id, - encounter_datetime, - @encounter_month := month(encounter_datetime) as encounter_month, - endDate, - prev_rtc_date, - @prev_rtc_month := month(prev_rtc_date) as prev_rtc_month, - rtc_date, - @rtc_month := month(rtc_date) as rtc_month, - - CASE - WHEN encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate THEN @visit_this_month := 1 - ELSE @visit_this_month := 0 - END AS visit_this_month, - - CASE - WHEN prev_rtc_date between date_format(endDate,"%Y-%m-01") and endDate THEN @appointment_this_month := 1 - WHEN rtc_date between date_format(endDate,"%Y-%m-01") and endDate THEN @appointment_this_month := 1 - ELSE @appointment_this_month := 0 - END AS appointment_this_month, - - IF(@visit_this_month = 1 AND @appointment_this_month = 1, 1, 0) AS scheduled_visit_this_month, - - IF(@visit_this_month = 1 AND @appointment_this_month <> 1 AND @encounter_month < @prev_rtc_month - ,1,0) AS early_appointment_this_month, - - IF(@visit_this_month = 1 AND @appointment_this_month <> 1 AND @encounter_month > @prev_rtc_month - ,1,0) AS late_appointment_this_month, - - IF(@visit_this_month = 0 AND @appointment_this_month = 1,1,0) AS missed_appointment_this_month, - - timestampdiff(day,rtc_date, endDate) as days_since_rtc_date, - t1.has_comorbidity, - t1.has_mental_disorder_comorbidity, - t1.has_diabetic_comorbidity, - t1.has_hypertension_comorbidity, - t1.has_other_comorbidity - from - plhiv_ncd_patient_encounters t1 - inner join amrs.person t2 on (t1.person_id = t2.person_id and t2.voided = 0) - ); - - replace into plhiv_ncd_monthly_report_dataset - ( - select - * - from stage_1 - ); - - SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join plhiv_ncd_monthly_report_temp_queue t2 using (person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - - - set @cycle_length = timestampdiff(second,@loop_start_time,now()); - - set @total_time = @total_time + @cycle_length; - set @cycle_number = @cycle_number + 1; - - - set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); - - - SELECT - @person_ids_count AS 'persons remaining', - @cycle_length AS 'Cycle time (s)', - CEIL(@person_ids_count / cycle_size) AS remaining_cycles, - @remaining_time AS 'Est time remaining (min)'; - - end while; - - select @end := now(); - insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); - select concat(@table_version," : Time to complete: ",timestampdiff(minute, @start, @end)," minutes"); - - END$$ -DELIMITER ; \ No newline at end of file diff --git a/etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql b/etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql deleted file mode 100644 index 1677c5f..0000000 --- a/etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql +++ /dev/null @@ -1,823 +0,0 @@ - -DELIMITER $$ - -CREATE PROCEDURE `etl`.`generate_plhiv_ncd_summary`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int) -BEGIN - set @primary_table := "plhiv_ncd_summary_v1"; - set @query_type = query_type; - - set @total_rows_written = 0; - - set @encounter_types = "(54,55,75,76,77,78,79,83,96,99,100,104,107,108,109,131,171,172)"; - set @clinical_encounter_types = "(54,55,75,76,77,78,79,83,96,104,107,108,109,171,172)"; - set @non_clinical_encounter_types = "(131)"; - set @other_encounter_types = "(-1)"; - - set @start = now(); - set @table_version = "plhiv_ncd_summary_v1.0"; - - set session sort_buffer_size=512000000; - - set @sep = " ## "; - set @boundary = "!!"; - set @last_date_created = (select max(max_date_created) from etl.flat_obs); - - CREATE TABLE IF NOT EXISTS plhiv_ncd_summary_v1 ( - date_created TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, - person_id INT, - uuid VARCHAR(100), - visit_id INT, - encounter_id INT, - encounter_datetime DATETIME, - encounter_type INT, - is_clinical_encounter INT, - location_id INT, - location_uuid VARCHAR(100), - death_date DATETIME, - prev_rtc_date DATETIME, - rtc_date DATETIME, - lmp DATE, - sbp SMALLINT, - dbp SMALLINT, - pulse SMALLINT, - fbs DECIMAL, - rbs DECIMAL, - hb_a1c DECIMAL, - hb_a1c_date DATETIME, - creatinine DECIMAL, - creatinine_date DATETIME, - total_cholesterol DECIMAL, - hdl DECIMAL, - ldl DECIMAL, - triglycerides DECIMAL, - lipid_panel_date DATETIME, - dm_status MEDIUMINT, - htn_status MEDIUMINT, - dm_meds VARCHAR(500), - htn_meds VARCHAR(500), - prescriptions TEXT, - problems TEXT, - has_comorbidity TINYINT(1), - has_mental_disorder_comorbidity TINYINT(1), - has_diabetic_comorbidity TINYINT(1), - has_hypertension_comorbidity TINYINT(1), - has_other_comorbidity TINYINT(1), - prev_encounter_datetime_plhiv_ncd DATETIME, - next_encounter_datetime_plhiv_ncd DATETIME, - prev_encounter_type_plhiv_ncd MEDIUMINT, - next_encounter_type_plhiv_ncd MEDIUMINT, - prev_clinical_datetime_plhiv_ncd DATETIME, - next_clinical_datetime_plhiv_ncd DATETIME, - prev_clinical_location_id_plhiv_ncd MEDIUMINT, - next_clinical_location_id_plhiv_ncd MEDIUMINT, - prev_clinical_rtc_date_plhiv_ncd DATETIME, - next_clinical_rtc_date_plhiv_ncd DATETIME, - PRIMARY KEY encounter_id (encounter_id), - INDEX person_date (person_id , encounter_datetime), - INDEX person_uuid (uuid), - INDEX location_enc_date (location_uuid , encounter_datetime), - INDEX enc_date_location (encounter_datetime , location_uuid), - INDEX location_id_rtc_date (location_id , rtc_date), - INDEX location_uuid_rtc_date (location_uuid , rtc_date), - INDEX loc_id_enc_date_next_clinical (location_id , encounter_datetime , next_clinical_datetime_plhiv_ncd), - INDEX encounter_type (encounter_type), - INDEX date_created (date_created) - ); - - if(@query_type="build") then - select 'BUILDING..........................................'; - - set @write_table = concat("plhiv_ncd_summary_temp_",queue_number); - set @queue_table = concat("plhiv_ncd_summary_build_queue_",queue_number); - - select @queue_table; - SET @dyn_sql=CONCAT('Create table if not exists ',@write_table,' like ',@primary_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - #create table if not exists @queue_table (person_id int, primary key (person_id)); - SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from plhiv_ncd_summary_build_queue limit ', queue_size, ');'); - #SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from plhiv_ncd_summary_build_queue limit 500);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - #delete t1 from plhiv_ncd_summary_build_queue t1 join @queue_table t2 using (person_id) - SET @dyn_sql=CONCAT('delete t1 from plhiv_ncd_summary_build_queue t1 join ',@queue_table, ' t2 using (person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - end if; - - if(@query_type="sync") then - select 'SYNCING..........................................'; - set @write_table = "plhiv_ncd_summary_v1"; - set @queue_table = "plhiv_ncd_summary_sync_queue"; - CREATE TABLE IF NOT EXISTS plhiv_ncd_summary_sync_queue ( - person_id INT PRIMARY KEY - ); - - set @last_update = null; - - SELECT - MAX(date_updated) - INTO @last_update FROM - etl.flat_log - WHERE - table_name = @table_version; - - replace into plhiv_ncd_summary_sync_queue - (select distinct patient_id - from amrs.encounter - where date_changed > @last_update - ); - - replace into plhiv_ncd_summary_sync_queue - (select distinct person_id - from etl.flat_obs - where max_date_created > @last_update - ); - - replace into plhiv_ncd_summary_sync_queue - (select distinct person_id - from etl.flat_lab_obs - where max_date_created > @last_update - ); - - replace into plhiv_ncd_summary_sync_queue - (select distinct person_id - from etl.flat_orders - where max_date_created > @last_update - ); - - replace into plhiv_ncd_summary_sync_queue - (select person_id from - amrs.person - where date_voided > @last_update); - - - replace into plhiv_ncd_summary_sync_queue - (select person_id from - amrs.person - where date_changed > @last_update); - end if; - - - # Remove test patients - SET @dyn_sql=CONCAT('delete t1 FROM ',@queue_table,' t1 - join amrs.person_attribute t2 using (person_id) - where t2.person_attribute_type_id=28 and value="true" and voided=0'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @person_ids_count = 0; - - SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SELECT @person_ids_count AS 'num patients to update'; - - - #delete t1 from plhiv_ncd_summary_v1.0 t1 join @queue_table t2 using (person_id); - SET @dyn_sql=CONCAT('delete t1 from ',@primary_table, ' t1 join ',@queue_table,' t2 using (person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - -- drop temporary table if exists prescriptions; - -- create temporary table prescriptions (encounter_id int primary key, prescriptions text) - -- ( - -- select - -- encounter_id, - -- group_concat(obs separator ' $ ') as prescriptions - -- from - -- ( - -- select - -- t2.encounter_id, - -- obs_group_id, - -- group_concat( - -- case - -- when value_coded is not null then concat(@boundary,o.concept_id,'=',value_coded,@boundary) - -- when value_numeric is not null then concat(@boundary,o.concept_id,'=',value_numeric,@boundary) - -- when value_datetime is not null then concat(@boundary,o.concept_id,'=',date(value_datetime),@boundary) - -- when value_text is not null then concat(@boundary,o.concept_id,'=',value_text,@boundary) - -- when value_drug is not null then concat(@boundary,o.concept_id,'=',value_drug,@boundary) - -- when value_modifier is not null then concat(@boundary,o.concept_id,'=',value_modifier,@boundary) - -- end - -- order by o.concept_id,value_coded - -- separator ' ## ' - -- ) as obs - - -- from amrs.obs o - -- join (select encounter_id, obs_id, concept_id as grouping_concept from amrs.obs where concept_id in (7307,7334)) t2 on o.obs_group_id = t2.obs_id - -- group by obs_group_id - -- ) t - -- group by encounter_id - -- ); - - set @total_time=0; - set @cycle_number = 0; - - while @person_ids_count > 0 do - - set @loop_start_time = now(); - - drop temporary table if exists plhiv_ncd_summary_build_queue__0; - - SET @dyn_sql=CONCAT('create temporary table plhiv_ncd_summary_build_queue__0 (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - - - drop temporary table if exists plhiv_ncd_summary_0a; - SET @dyn_sql = CONCAT( - 'create temporary table plhiv_ncd_summary_0a - (select - t1.person_id, - t1.visit_id, - t1.encounter_id, - t1.encounter_datetime, - t1.encounter_type, - t1.location_id, - t1.obs, - t1.obs_datetimes, - case - when t1.encounter_type in ',@clinical_encounter_types,' then 1 - else null - end as is_clinical_encounter, - - case - when t1.encounter_type in ',@non_clinical_encounter_types,' then 20 - when t1.encounter_type in ',@clinical_encounter_types,' then 10 - when t1.encounter_type in', @other_encounter_types, ' then 5 - else 1 - end as encounter_type_sort_index, - t2.orders - from etl.flat_obs t1 - join plhiv_ncd_summary_build_queue__0 t0 using (person_id) - left join etl.flat_orders t2 using(encounter_id) - where t1.encounter_type in ',@encounter_types,');' - ); - - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - insert into plhiv_ncd_summary_0a - ( - select - t1.person_id, - null, - t1.encounter_id, - t1.test_datetime, - t1.encounter_type, - null, #t1.location_id, - t1.obs, - null, #obs_datetimes - # in any visit, there many be multiple encounters. for this dataset, we want to include only clinical encounters (e.g. not lab or triage visit) - 0 as is_clinical_encounter, - 1 as encounter_type_sort_index, - null - from etl.flat_lab_obs t1 - join plhiv_ncd_summary_build_queue__0 t0 using (person_id) - ); - - drop temporary table if exists plhiv_ncd_summary_0; - create temporary table plhiv_ncd_summary_0(index encounter_id (encounter_id), index person_enc (person_id,encounter_datetime)) - ( - select - * - from plhiv_ncd_summary_0a - order by person_id, date(encounter_datetime), encounter_type_sort_index - ); - - set @prev_id = null; - set @cur_id = null; - set @prev_encounter_date = null; - set @cur_encounter_date = null; - set @enrollment_date = null; - set @cur_location = null; - set @cur_rtc_date = null; - set @prev_rtc_date = null; - - set @death_date = null; - - #TO DO - # screened for cervical ca - # exposed infant - - drop temporary table if exists plhiv_ncd_summary_1; - CREATE temporary TABLE plhiv_ncd_summary_1 (INDEX encounter_id (encounter_id)) - ( - SELECT - obs, - encounter_type_sort_index, - @prev_id:=@cur_id AS prev_id, - @cur_id:=t1.person_id AS cur_id, - t1.person_id, - p.uuid, - t1.visit_id, - t1.encounter_id, - @prev_encounter_date:=DATE(@cur_encounter_date) AS prev_encounter_date, - @cur_encounter_date:=DATE(encounter_datetime) AS cur_encounter_date, - t1.encounter_datetime, - t1.encounter_type, - t1.is_clinical_encounter, - death_date, - CASE - WHEN location_id THEN @cur_location:=location_id - WHEN @prev_id = @cur_id THEN @cur_location - ELSE NULL - END AS location_id, - CASE - WHEN @prev_id = @cur_id THEN @prev_rtc_date:=@cur_rtc_date - ELSE @prev_rtc_date:=NULL - END AS prev_rtc_date, - CASE - WHEN obs REGEXP '!!5096=' THEN @cur_rtc_date:=GETVALUES(obs, 5096) - WHEN - @prev_id = @cur_id - THEN - IF(@cur_rtc_date > encounter_datetime, - @cur_rtc_date, - NULL) - ELSE @cur_rtc_date:=NULL - END AS cur_rtc_date, - @lmp:=GETVALUES(obs, 1836) AS lmp, - CASE - WHEN obs REGEXP '!!5085=' THEN @sbp:=GETVALUES(obs, 5085) - END AS sbp, - @dbp:=GETVALUES(obs, 5086) AS dbp, - @pulse:=GETVALUES(obs, 5087) AS pulse, - @fbs:=GETVALUES(obs, 6252) AS fbs, - @rbs:=GETVALUES(obs, 887) AS rbs, - CASE - WHEN obs REGEXP '!!6126=' THEN @hb_a1c:=GETVALUES(obs, 6126) - WHEN @prev_id = @cur_id THEN @hb_a1c - ELSE @hb_a1c:=NULL - END AS hb_a1c, - CASE - WHEN - obs REGEXP '!!6126=' - THEN - @hb_a1c_date:=IFNULL(GETVALUES(obs_datetimes, 6126), - encounter_datetime) - WHEN @prev_id = @cur_id THEN @hb_a1c_date - ELSE @hb_a1c_date:=NULL - END AS hb_a1c_date, - CASE - WHEN obs REGEXP '!!790=' THEN @creatinine:=GETVALUES(obs, 790) - WHEN @prev_id = @cur_id THEN @creatinine - ELSE @creatinine:=NULL - END AS creatinine, - CASE - WHEN - obs REGEXP '!!790=' - THEN - @creatinine_date:=IFNULL(GETVALUES(obs_datetimes, 790), - encounter_datetime) - WHEN @prev_id = @cur_id THEN @creatinine_date - ELSE @creatinine_date:=NULL - END AS creatinine_date, - CASE - WHEN obs REGEXP '!!1006=' THEN @total_cholesterol:=GETVALUES(obs, 1006) - WHEN @prev_id = @cur_id THEN @total_cholesterol - ELSE @total_cholesterol:=NULL - END AS total_cholesterol, - CASE - WHEN obs REGEXP '!!1007=' THEN @hdl:=GETVALUES(obs, 1007) - WHEN @prev_id = @cur_id THEN @hdl - ELSE @hdl:=NULL - END AS hdl, - CASE - WHEN obs REGEXP '!!1008=' THEN @ldl:=GETVALUES(obs, 1008) - WHEN @prev_id = @cur_id THEN @ldl - ELSE @ldl:=NULL - END AS ldl, - CASE - WHEN obs REGEXP '!!1009=' THEN @triglycerides:=GETVALUES(obs, 1009) - WHEN @prev_id = @cur_id THEN @triglycerides - ELSE @triglycerides:=NULL - END AS triglycerides, - CASE - WHEN - obs REGEXP '!!1006=' - THEN - @lipid_panel_date:=IFNULL(GETVALUES(obs_datetimes, 1006), - encounter_datetime) - WHEN @prev_id = @cur_id THEN @lipid_panel_date - ELSE @lipid_panel_date:=NULL - END AS lipid_panel_date, - @dm_status:=GETVALUES(obs, 7287) AS dm_status, - @htn_status:=GETVALUES(obs, 7288) AS htn_status, - @dm_meds:=GETVALUES(obs, 7290) AS dm_meds, - @htn_meds:=GETVALUES(obs, 10241) AS htn_meds, - -- t2.prescriptions AS prescriptions, - NULL AS prescriptions, - @problems:=GETVALUES(obs, 6042) AS problems, - case - when obs regexp '!!11200=10239!!' then 1 - when (obs regexp '!!10239=') = 1 and (obs not regexp '!!10239=1066!!') = 1 then 1 - when obs regexp '!!10239=7281!!' then 1 - when obs regexp '!!10239=7282!!' then 1 - when obs regexp '!!10239=1066!!' then 0 - else NULL - end as has_comorbidity, - case - when obs regexp '!!10239=175!!' then 1 - else NULL - end as has_diabetic_comorbidity, - case - when obs regexp '!!10239=7971!!' then 1 - when obs regexp '!!10239=903!!' then 1 - when obs regexp '!!9328=903!!' then 1 - when obs regexp '!!9328=7971!!' then 1 - else NULL - end as has_hypertension_comorbidity, - case - when obs regexp '!!10239=10860!!' then 1 - when obs regexp '!!10239=77!!' then 1 - else NULL - end as has_mental_disorder_comorbidity, - case - when obs regexp '!!10239=5622!!' then 1 - when (obs regexp '!!10239=')= 1 and (obs not regexp '!!10239=(77|175|903|7281|7282|7971|10860)!!')=1 then 1 - else NULL - end as has_other_comorbidity, - FROM plhiv_ncd_summary_0 t1 - JOIN amrs.person p USING (person_id) - ); - -- LEFT OUTER JOIN - -- prescriptions t2 USING (encounter_id) - -- ); - - set @prev_id = null; - set @cur_id = null; - set @prev_encounter_datetime = null; - set @cur_encounter_datetime = null; - - set @prev_clinical_datetime = null; - set @cur_clinical_datetime = null; - - set @next_encounter_type = null; - set @cur_encounter_type = null; - - set @prev_clinical_location_id = null; - set @cur_clinical_location_id = null; - - - alter table plhiv_ncd_summary_1 drop prev_id, drop cur_id; - - drop table if exists plhiv_ncd_summary_2; - create temporary table plhiv_ncd_summary_2 - ( - select - *, - @prev_id := @cur_id as prev_id, - @cur_id := person_id as cur_id, - - case - when @prev_id = @cur_id then @prev_encounter_datetime := @cur_encounter_datetime - else @prev_encounter_datetime := null - end as next_encounter_datetime_plhiv_ncd, - - @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, - - case - when @prev_id=@cur_id then @next_encounter_type := @cur_encounter_type - else @next_encounter_type := null - end as next_encounter_type_plhiv_ncd, - - @cur_encounter_type := encounter_type as cur_encounter_type, - - case - when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime - else @prev_clinical_datetime := null - end as next_clinical_datetime_plhiv_ncd, - - case - when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id - else @prev_clinical_location_id := null - end as next_clinical_location_id_plhiv_ncd, - - case - when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime - when @prev_id = @cur_id then @cur_clinical_datetime - else @cur_clinical_datetime := null - end as cur_clinic_datetime, - - case - when is_clinical_encounter then @cur_clinical_location_id := location_id - when @prev_id = @cur_id then @cur_clinical_location_id - else @cur_clinical_location_id := null - end as cur_clinic_location_id, - - case - when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date - else @prev_clinical_rtc_date := null - end as next_clinical_rtc_date_plhiv_ncd, - - case - when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date - when @prev_id = @cur_id then @cur_clinical_rtc_date - else @cur_clinical_rtc_date:= null - end as cur_clinical_rtc_date - - from plhiv_ncd_summary_1 - order by person_id, date(encounter_datetime) desc, encounter_type_sort_index desc - ); - - alter table plhiv_ncd_summary_2 drop prev_id, drop cur_id, drop cur_encounter_type, drop cur_encounter_datetime, drop cur_clinical_rtc_date; - - - set @prev_id = null; - set @cur_id = null; - set @prev_encounter_type = null; - set @cur_encounter_type = null; - set @prev_encounter_datetime = null; - set @cur_encounter_datetime = null; - set @prev_clinical_datetime = null; - set @cur_clinical_datetime = null; - set @prev_clinical_location_id = null; - set @cur_clinical_location_id = null; - - drop temporary table if exists plhiv_ncd_summary_3; - create temporary table plhiv_ncd_summary_3 (prev_encounter_datetime datetime, prev_encounter_type int, index person_enc (person_id, encounter_datetime desc)) - ( - select - *, - @prev_id := @cur_id as prev_id, - @cur_id := t1.person_id as cur_id, - - -- if same person then cur enc type is same as prev encounter type else null - case - when @prev_id=@cur_id then @prev_encounter_type := @cur_encounter_type - else @prev_encounter_type:=null - end as prev_encounter_type_plhiv_ncd, - @cur_encounter_type := encounter_type as cur_encounter_type, - - -- if same person then cur enc dt is same as prev enc dt else null - case - when @prev_id=@cur_id then @prev_encounter_datetime := @cur_encounter_datetime - else @prev_encounter_datetime := null - end as prev_encounter_datetime_plhiv_ncd, - - @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, - - -- if same person then cur clc dt is same as prev clc dt else null - case - when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime - else @prev_clinical_datetime := null - end as prev_clinical_datetime_plhiv_ncd, - - -- if same person then cur clc locid is same as prev clc locid else null - case - when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id - else @prev_clinical_location_id := null - end as prev_clinical_location_id_plhiv_ncd, - - -- if clc enc or same person then cur clc dt is enc_dt else null - case - when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime - when @prev_id = @cur_id then @cur_clinical_datetime - else @cur_clinical_datetime := null - end as cur_clinical_datetime, - - -- if clc enc or same person then cur clc loc is loc_id else null - case - when is_clinical_encounter then @cur_clinical_location_id := location_id - when @prev_id = @cur_id then @cur_clinical_location_id - else @cur_clinical_location_id := null - end as cur_clinical_location_id, - - -- if same person then prev clc rtc is cur rtc else null - case - when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date - else @prev_clinical_rtc_date := null - end as prev_clinical_rtc_date_plhiv_ncd, - - -- if clc enc or same person then cur clc rtc is cur rtc else null - case - when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date - when @prev_id = @cur_id then @cur_clinical_rtc_date - else @cur_clinical_rtc_date:= null - end as cur_clinic_rtc_date - - from plhiv_ncd_summary_2 t1 - order by person_id, date(encounter_datetime), encounter_type_sort_index - ); - - SELECT COUNT(*) INTO @new_encounter_rows FROM plhiv_ncd_summary_3; - - SELECT @new_encounter_rows; - set @total_rows_written = @total_rows_written + @new_encounter_rows; - SELECT @total_rows_written; - - select - null, - person_id, - t1.uuid, - visit_id, - encounter_id, - encounter_datetime, - encounter_type, - is_clinical_encounter, - location_id, - t2.uuid as location_uuid, - death_date, - prev_rtc_date, - cur_rtc_date, - lmp, - sbp, - dbp, - pulse, - fbs, - rbs, - hb_a1c, - hb_a1c_date, - creatinine, - creatinine_date, - total_cholesterol, - hdl, - ldl, - triglycerides, - lipid_panel_date, - dm_status, - htn_status, - dm_meds, - htn_meds, - prescriptions, - problems, - has_comorbidity, - has_mental_disorder_comorbidity, - has_diabetic_comorbidity, - has_hypertension_comorbidity, - has_other_comorbidity, - prev_encounter_datetime_plhiv_ncd, - next_encounter_datetime_plhiv_ncd, - prev_encounter_type_plhiv_ncd, - next_encounter_type_plhiv_ncd, - prev_clinical_datetime_plhiv_ncd, - next_clinical_datetime_plhiv_ncd, - prev_clinical_location_id_plhiv_ncd, - next_clinical_location_id_plhiv_ncd, - prev_clinical_rtc_date_plhiv_ncd, - next_clinical_rtc_date_plhiv_ncd - from plhiv_ncd_summary_3 t1 - join amrs.location t2 using (location_id); - - #add data to table - SET @dyn_sql=CONCAT('replace into ',@write_table, - '(select - null, - person_id, - t1.uuid, - visit_id, - encounter_id, - encounter_datetime, - encounter_type, - is_clinical_encounter, - location_id, - t2.uuid as location_uuid, - death_date, - prev_rtc_date, - cur_rtc_date, - lmp, - sbp, - dbp, - pulse, - fbs, - rbs, - hb_a1c, - hb_a1c_date, - creatinine, - creatinine_date, - total_cholesterol, - hdl, - ldl, - triglycerides, - lipid_panel_date, - dm_status, - htn_status, - dm_meds, - htn_meds, - prescriptions, - problems, - has_comorbidity, - has_mental_disorder_comorbidity, - has_diabetic_comorbidity, - has_hypertension_comorbidity, - has_other_comorbidity, - prev_encounter_datetime_plhiv_ncd, - next_encounter_datetime_plhiv_ncd, - prev_encounter_type_plhiv_ncd, - next_encounter_type_plhiv_ncd, - prev_clinical_datetime_plhiv_ncd, - next_clinical_datetime_plhiv_ncd, - prev_clinical_location_id_plhiv_ncd, - next_clinical_location_id_plhiv_ncd, - prev_clinical_rtc_date_plhiv_ncd, - next_clinical_rtc_date_plhiv_ncd - - from plhiv_ncd_summary_3 t1 - join amrs.location t2 using (location_id))'); - - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - - #delete from @queue_table where person_id in (select person_id from plhiv_ncd_summary_build_queue__0); - - SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join plhiv_ncd_summary_build_queue__0 t2 using (person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - - #select @person_ids_count := (select count(*) from plhiv_ncd_summary_build_queue_2); - SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - #select @person_ids_count as remaining_in_build_queue; - - set @cycle_length = timestampdiff(second,@loop_start_time,now()); - #select concat('Cycle time: ',@cycle_length,' seconds'); - set @total_time = @total_time + @cycle_length; - set @cycle_number = @cycle_number + 1; - - #select ceil(@person_ids_count / cycle_size) as remaining_cycles; - set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); - - SELECT - @person_ids_count AS 'persons remaining', - @cycle_length AS 'Cycle time (s)', - CEIL(@person_ids_count / cycle_size) AS remaining_cycles, - @remaining_time AS 'Est time remaining (min)'; - end while; - - if(@query_type="build") then - SET @dyn_sql=CONCAT('drop table ',@queue_table,';'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @total_rows_to_write=0; - SET @dyn_sql=CONCAT("Select count(*) into @total_rows_to_write from ",@write_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - set @start_write = now(); - - SELECT - CONCAT(@start_write, - ' : Writing ', - @total_rows_to_write, - ' to ', - @primary_table); - - SET @dyn_sql=CONCAT('replace into ', @primary_table, - '(select * from ',@write_table,');'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - set @finish_write = now(); - set @time_to_write = timestampdiff(second,@start_write,@finish_write); - - SELECT - CONCAT(@finish_write, - ' : Completed writing rows. Time to write to primary table: ', - @time_to_write, - ' seconds '); - - SET @dyn_sql=CONCAT('drop table ',@write_table,';'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - end if; - - set @ave_cycle_length = ceil(@total_time/@cycle_number); - SELECT - CONCAT('Average Cycle Length: ', - @ave_cycle_length, - ' second(s)'); - - set @end = now(); - insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); - SELECT - CONCAT(@table_version, - ' : Time to complete: ', - TIMESTAMPDIFF(MINUTE, @start, @end), - ' minutes'); -END$$ -DELIMITER ; \ No newline at end of file From 4bc668b45cba3291fb84bf8ec0bb7fdca1dfabe6 Mon Sep 17 00:00:00 2001 From: henrykorir Date: Fri, 27 Oct 2023 12:04:05 +0300 Subject: [PATCH 5/9] POC-545: Create a Stored Procedure for the NCD Monthly Report --- ...erate_plhiv_ncd_monthly_report_dataset.sql | 265 ++++++ .../generate_plhiv_ncd_summary.sql | 823 ++++++++++++++++++ 2 files changed, 1088 insertions(+) create mode 100644 etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql create mode 100644 etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql diff --git a/etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql b/etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql new file mode 100644 index 0000000..6266644 --- /dev/null +++ b/etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql @@ -0,0 +1,265 @@ +DELIMITER $$ +CREATE PROCEDURE `generate_plhiv_ncd_monthly_report_dataset`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int , IN log boolean) +BEGIN + select @start := now(); + select @table_version := "plhiv_ncd_monthly_report_dataset"; + set @primary_table := "plhiv_ncd_monthly_report_dataset"; + set @query_type = query_type; + + set @total_rows_written = 0; + + set session sort_buffer_size=512000000; + + select @sep := " ## "; + select @last_date_created := (select max(max_date_created) from etl.flat_obs); + + CREATE TABLE IF NOT EXISTS `plhiv_ncd_monthly_report_dataset` ( + `elastic_id` varchar(21) NOT NULL DEFAULT '', + `location_id` bigint(60) DEFAULT NULL, + `person_id` int(11) DEFAULT NULL, + `person_uuid` char(38) CHARACTER SET utf8 NOT NULL, + `birthdate` date DEFAULT NULL, + `death_date` longtext CHARACTER SET utf8, + `age` decimal(23,2) DEFAULT NULL, + `gender` varchar(50) CHARACTER SET utf8 DEFAULT '', + `encounter_id` int(11) NOT NULL DEFAULT '0', + `encounter_datetime` datetime DEFAULT NULL, + `encounter_month` int(6) DEFAULT NULL, + `endDate` date DEFAULT NULL, + `prev_rtc_date` longtext, + `prev_rtc_month` int(6) DEFAULT NULL, + `rtc_date` varchar(10) CHARACTER SET utf8 DEFAULT NULL, + `rtc_month` int(6) DEFAULT NULL, + `visit_this_month` int(3) DEFAULT NULL, + `appointment_this_month` int(3) DEFAULT NULL, + `scheduled_visit_this_month` int(1) NOT NULL DEFAULT '0', + `early_appointment_this_month` int(1) NOT NULL DEFAULT '0', + `late_appointment_this_month` int(1) NOT NULL DEFAULT '0', + `missed_appointment_this_month` int(1) NOT NULL DEFAULT '0', + `days_since_rtc_date` varchar(23) CHARACTER SET utf8 DEFAULT NULL, + `has_comorbidity` TINYINT(1), + `has_mental_disorder_comorbidity` TINYINT(1), + `has_diabetic_comorbidity` TINYINT(1), + `has_hypertension_comorbidity` TINYINT(1), + `has_other_comorbidity` TINYINT(1), + PRIMARY KEY (`elastic_id`), + KEY `person_id` (`person_id`), + KEY `person_id_2` (`person_id`,`endDate`), + KEY `endDate` (`endDate`), + KEY `location_id` (`location_id`,`endDate`), + KEY `encounter_datetime` (`encounter_datetime`) + ) ENGINE=InnoDB DEFAULT CHARSET=latin1; + + + if(@query_type="build") then + select 'BUILDING..........................................'; + set @write_table = concat("plhiv_ncd_monthly_report_temp_",queue_number); + set @queue_table = concat("plhiv_ncd_monthly_report_build_queue_",queue_number); + + SET @dyn_sql=CONCAT('Create table if not exists ',@write_table,' like ',@primary_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('drop table if exists ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select person_id from plhiv_ncd_monthly_report_build_queue limit ', queue_size, ');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('delete t1 from plhiv_ncd_monthly_report_build_queue t1 join ',@queue_table, ' t2 on (t1.person_id = t2.person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + end if; + + # Display the important tables names + select @queue_table; + select @primary_table; + select @write_table; + + # Remove test patients + SET @dyn_sql=CONCAT('delete t1 FROM ',@queue_table,' t1 + join amrs.person_attribute t2 using (person_id) + where t2.person_attribute_type_id=28 and value="true" and voided=0'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('select count(*) as queue_size from ',@queue_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @person_ids_count = 0; + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + select @person_ids_count as 'num patients to sync'; + + + SET @dyn_sql=CONCAT('delete t1 from ',@primary_table, ' t1 join ',@queue_table,' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @total_time=0; + set @cycle_number = 0; + while @person_ids_count > 0 do + + set @loop_start_time = now(); + + drop temporary table if exists plhiv_ncd_monthly_report_temp_queue; + SET @dyn_sql=CONCAT('create temporary table plhiv_ncd_monthly_report_temp_queue (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + drop temporary table if exists plhiv_ncd_summary_in_queue; + create temporary table plhiv_ncd_summary_in_queue + (index (person_id), index(person_id, encounter_datetime), index(encounter_id), index(encounter_datetime), index(rtc_date)) + (select * + from + etl.plhiv_ncd_summary_v1 + where + encounter_datetime >= '2018-01-01' + order by person_id, encounter_datetime + ); + + drop table if exists plhiv_ncd_patient_encounters; + create table plhiv_ncd_patient_encounters + (index (person_id), index(person_id, endDate, encounter_id)) + ( + select + * + from ( + select + * + from etl.dates m + join plhiv_ncd_summary_in_queue h + WHERE h.encounter_datetime < DATE_ADD(endDate, INTERVAL 1 DAY) + and m.endDate BETWEEN '2018-01-01' AND DATE_ADD(now(), INTERVAL 2 YEAR) + ORDER BY h.person_id , month(endDate), h.encounter_datetime desc , rtc_date + ) p + group by person_id, month(endDate) + ); + + + drop temporary table if exists stage_1; + create temporary table stage_1 + ( + primary key elastic_id (elastic_id), + index (person_id), + index (person_id, endDate), + index(endDate), + index(location_id, endDate), + index(encounter_datetime)) + (SELECT + concat(month(endDate), t1.person_id) as elastic_id, + location_id, + t1.person_id, + t1.uuid AS person_uuid, + DATE(t1.birthdate) AS birthdate, + t1.death_date, + CASE + WHEN + TIMESTAMPDIFF(YEAR, t1.birthdate, endDate) > 0 + THEN + @age:=ROUND(TIMESTAMPDIFF(YEAR, t1.birthdate, endDate), + 0) + ELSE @age:=ROUND(TIMESTAMPDIFF(MONTH, + t1.birthdate, + endDate) / 12, + 2) + END AS age, + t1.gender, + encounter_id, + encounter_datetime, + @encounter_month := month(encounter_datetime) as encounter_month, + endDate, + prev_rtc_date, + @prev_rtc_month := month(prev_rtc_date) as prev_rtc_month, + rtc_date, + @rtc_month := month(rtc_date) as rtc_month, + + CASE + WHEN encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate THEN @visit_this_month := 1 + ELSE @visit_this_month := 0 + END AS visit_this_month, + + CASE + WHEN prev_rtc_date between date_format(endDate,"%Y-%m-01") and endDate THEN @appointment_this_month := 1 + WHEN rtc_date between date_format(endDate,"%Y-%m-01") and endDate THEN @appointment_this_month := 1 + ELSE @appointment_this_month := 0 + END AS appointment_this_month, + + IF(@visit_this_month = 1 AND @appointment_this_month = 1, 1, 0) AS scheduled_visit_this_month, + + IF(@visit_this_month = 1 AND @appointment_this_month <> 1 AND @encounter_month < @prev_rtc_month + ,1,0) AS early_appointment_this_month, + + IF(@visit_this_month = 1 AND @appointment_this_month <> 1 AND @encounter_month > @prev_rtc_month + ,1,0) AS late_appointment_this_month, + + IF(@visit_this_month = 0 AND @appointment_this_month = 1,1,0) AS missed_appointment_this_month, + + timestampdiff(day,rtc_date, endDate) as days_since_rtc_date, + t1.has_comorbidity, + t1.has_mental_disorder_comorbidity, + t1.has_diabetic_comorbidity, + t1.has_hypertension_comorbidity, + t1.has_other_comorbidity + from + plhiv_ncd_patient_encounters t1 + inner join amrs.person t2 on (t1.person_id = t2.person_id and t2.voided = 0) + ); + + replace into plhiv_ncd_monthly_report_dataset + ( + select + * + from stage_1 + ); + + SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join plhiv_ncd_monthly_report_temp_queue t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + + set @cycle_length = timestampdiff(second,@loop_start_time,now()); + + set @total_time = @total_time + @cycle_length; + set @cycle_number = @cycle_number + 1; + + + set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); + + + SELECT + @person_ids_count AS 'persons remaining', + @cycle_length AS 'Cycle time (s)', + CEIL(@person_ids_count / cycle_size) AS remaining_cycles, + @remaining_time AS 'Est time remaining (min)'; + + end while; + + select @end := now(); + insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); + select concat(@table_version," : Time to complete: ",timestampdiff(minute, @start, @end)," minutes"); + + END$$ +DELIMITER ; \ No newline at end of file diff --git a/etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql b/etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql new file mode 100644 index 0000000..1677c5f --- /dev/null +++ b/etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql @@ -0,0 +1,823 @@ + +DELIMITER $$ + +CREATE PROCEDURE `etl`.`generate_plhiv_ncd_summary`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int) +BEGIN + set @primary_table := "plhiv_ncd_summary_v1"; + set @query_type = query_type; + + set @total_rows_written = 0; + + set @encounter_types = "(54,55,75,76,77,78,79,83,96,99,100,104,107,108,109,131,171,172)"; + set @clinical_encounter_types = "(54,55,75,76,77,78,79,83,96,104,107,108,109,171,172)"; + set @non_clinical_encounter_types = "(131)"; + set @other_encounter_types = "(-1)"; + + set @start = now(); + set @table_version = "plhiv_ncd_summary_v1.0"; + + set session sort_buffer_size=512000000; + + set @sep = " ## "; + set @boundary = "!!"; + set @last_date_created = (select max(max_date_created) from etl.flat_obs); + + CREATE TABLE IF NOT EXISTS plhiv_ncd_summary_v1 ( + date_created TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + person_id INT, + uuid VARCHAR(100), + visit_id INT, + encounter_id INT, + encounter_datetime DATETIME, + encounter_type INT, + is_clinical_encounter INT, + location_id INT, + location_uuid VARCHAR(100), + death_date DATETIME, + prev_rtc_date DATETIME, + rtc_date DATETIME, + lmp DATE, + sbp SMALLINT, + dbp SMALLINT, + pulse SMALLINT, + fbs DECIMAL, + rbs DECIMAL, + hb_a1c DECIMAL, + hb_a1c_date DATETIME, + creatinine DECIMAL, + creatinine_date DATETIME, + total_cholesterol DECIMAL, + hdl DECIMAL, + ldl DECIMAL, + triglycerides DECIMAL, + lipid_panel_date DATETIME, + dm_status MEDIUMINT, + htn_status MEDIUMINT, + dm_meds VARCHAR(500), + htn_meds VARCHAR(500), + prescriptions TEXT, + problems TEXT, + has_comorbidity TINYINT(1), + has_mental_disorder_comorbidity TINYINT(1), + has_diabetic_comorbidity TINYINT(1), + has_hypertension_comorbidity TINYINT(1), + has_other_comorbidity TINYINT(1), + prev_encounter_datetime_plhiv_ncd DATETIME, + next_encounter_datetime_plhiv_ncd DATETIME, + prev_encounter_type_plhiv_ncd MEDIUMINT, + next_encounter_type_plhiv_ncd MEDIUMINT, + prev_clinical_datetime_plhiv_ncd DATETIME, + next_clinical_datetime_plhiv_ncd DATETIME, + prev_clinical_location_id_plhiv_ncd MEDIUMINT, + next_clinical_location_id_plhiv_ncd MEDIUMINT, + prev_clinical_rtc_date_plhiv_ncd DATETIME, + next_clinical_rtc_date_plhiv_ncd DATETIME, + PRIMARY KEY encounter_id (encounter_id), + INDEX person_date (person_id , encounter_datetime), + INDEX person_uuid (uuid), + INDEX location_enc_date (location_uuid , encounter_datetime), + INDEX enc_date_location (encounter_datetime , location_uuid), + INDEX location_id_rtc_date (location_id , rtc_date), + INDEX location_uuid_rtc_date (location_uuid , rtc_date), + INDEX loc_id_enc_date_next_clinical (location_id , encounter_datetime , next_clinical_datetime_plhiv_ncd), + INDEX encounter_type (encounter_type), + INDEX date_created (date_created) + ); + + if(@query_type="build") then + select 'BUILDING..........................................'; + + set @write_table = concat("plhiv_ncd_summary_temp_",queue_number); + set @queue_table = concat("plhiv_ncd_summary_build_queue_",queue_number); + + select @queue_table; + SET @dyn_sql=CONCAT('Create table if not exists ',@write_table,' like ',@primary_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #create table if not exists @queue_table (person_id int, primary key (person_id)); + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from plhiv_ncd_summary_build_queue limit ', queue_size, ');'); + #SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from plhiv_ncd_summary_build_queue limit 500);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #delete t1 from plhiv_ncd_summary_build_queue t1 join @queue_table t2 using (person_id) + SET @dyn_sql=CONCAT('delete t1 from plhiv_ncd_summary_build_queue t1 join ',@queue_table, ' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + end if; + + if(@query_type="sync") then + select 'SYNCING..........................................'; + set @write_table = "plhiv_ncd_summary_v1"; + set @queue_table = "plhiv_ncd_summary_sync_queue"; + CREATE TABLE IF NOT EXISTS plhiv_ncd_summary_sync_queue ( + person_id INT PRIMARY KEY + ); + + set @last_update = null; + + SELECT + MAX(date_updated) + INTO @last_update FROM + etl.flat_log + WHERE + table_name = @table_version; + + replace into plhiv_ncd_summary_sync_queue + (select distinct patient_id + from amrs.encounter + where date_changed > @last_update + ); + + replace into plhiv_ncd_summary_sync_queue + (select distinct person_id + from etl.flat_obs + where max_date_created > @last_update + ); + + replace into plhiv_ncd_summary_sync_queue + (select distinct person_id + from etl.flat_lab_obs + where max_date_created > @last_update + ); + + replace into plhiv_ncd_summary_sync_queue + (select distinct person_id + from etl.flat_orders + where max_date_created > @last_update + ); + + replace into plhiv_ncd_summary_sync_queue + (select person_id from + amrs.person + where date_voided > @last_update); + + + replace into plhiv_ncd_summary_sync_queue + (select person_id from + amrs.person + where date_changed > @last_update); + end if; + + + # Remove test patients + SET @dyn_sql=CONCAT('delete t1 FROM ',@queue_table,' t1 + join amrs.person_attribute t2 using (person_id) + where t2.person_attribute_type_id=28 and value="true" and voided=0'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @person_ids_count = 0; + + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SELECT @person_ids_count AS 'num patients to update'; + + + #delete t1 from plhiv_ncd_summary_v1.0 t1 join @queue_table t2 using (person_id); + SET @dyn_sql=CONCAT('delete t1 from ',@primary_table, ' t1 join ',@queue_table,' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + -- drop temporary table if exists prescriptions; + -- create temporary table prescriptions (encounter_id int primary key, prescriptions text) + -- ( + -- select + -- encounter_id, + -- group_concat(obs separator ' $ ') as prescriptions + -- from + -- ( + -- select + -- t2.encounter_id, + -- obs_group_id, + -- group_concat( + -- case + -- when value_coded is not null then concat(@boundary,o.concept_id,'=',value_coded,@boundary) + -- when value_numeric is not null then concat(@boundary,o.concept_id,'=',value_numeric,@boundary) + -- when value_datetime is not null then concat(@boundary,o.concept_id,'=',date(value_datetime),@boundary) + -- when value_text is not null then concat(@boundary,o.concept_id,'=',value_text,@boundary) + -- when value_drug is not null then concat(@boundary,o.concept_id,'=',value_drug,@boundary) + -- when value_modifier is not null then concat(@boundary,o.concept_id,'=',value_modifier,@boundary) + -- end + -- order by o.concept_id,value_coded + -- separator ' ## ' + -- ) as obs + + -- from amrs.obs o + -- join (select encounter_id, obs_id, concept_id as grouping_concept from amrs.obs where concept_id in (7307,7334)) t2 on o.obs_group_id = t2.obs_id + -- group by obs_group_id + -- ) t + -- group by encounter_id + -- ); + + set @total_time=0; + set @cycle_number = 0; + + while @person_ids_count > 0 do + + set @loop_start_time = now(); + + drop temporary table if exists plhiv_ncd_summary_build_queue__0; + + SET @dyn_sql=CONCAT('create temporary table plhiv_ncd_summary_build_queue__0 (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + + drop temporary table if exists plhiv_ncd_summary_0a; + SET @dyn_sql = CONCAT( + 'create temporary table plhiv_ncd_summary_0a + (select + t1.person_id, + t1.visit_id, + t1.encounter_id, + t1.encounter_datetime, + t1.encounter_type, + t1.location_id, + t1.obs, + t1.obs_datetimes, + case + when t1.encounter_type in ',@clinical_encounter_types,' then 1 + else null + end as is_clinical_encounter, + + case + when t1.encounter_type in ',@non_clinical_encounter_types,' then 20 + when t1.encounter_type in ',@clinical_encounter_types,' then 10 + when t1.encounter_type in', @other_encounter_types, ' then 5 + else 1 + end as encounter_type_sort_index, + t2.orders + from etl.flat_obs t1 + join plhiv_ncd_summary_build_queue__0 t0 using (person_id) + left join etl.flat_orders t2 using(encounter_id) + where t1.encounter_type in ',@encounter_types,');' + ); + + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + insert into plhiv_ncd_summary_0a + ( + select + t1.person_id, + null, + t1.encounter_id, + t1.test_datetime, + t1.encounter_type, + null, #t1.location_id, + t1.obs, + null, #obs_datetimes + # in any visit, there many be multiple encounters. for this dataset, we want to include only clinical encounters (e.g. not lab or triage visit) + 0 as is_clinical_encounter, + 1 as encounter_type_sort_index, + null + from etl.flat_lab_obs t1 + join plhiv_ncd_summary_build_queue__0 t0 using (person_id) + ); + + drop temporary table if exists plhiv_ncd_summary_0; + create temporary table plhiv_ncd_summary_0(index encounter_id (encounter_id), index person_enc (person_id,encounter_datetime)) + ( + select + * + from plhiv_ncd_summary_0a + order by person_id, date(encounter_datetime), encounter_type_sort_index + ); + + set @prev_id = null; + set @cur_id = null; + set @prev_encounter_date = null; + set @cur_encounter_date = null; + set @enrollment_date = null; + set @cur_location = null; + set @cur_rtc_date = null; + set @prev_rtc_date = null; + + set @death_date = null; + + #TO DO + # screened for cervical ca + # exposed infant + + drop temporary table if exists plhiv_ncd_summary_1; + CREATE temporary TABLE plhiv_ncd_summary_1 (INDEX encounter_id (encounter_id)) + ( + SELECT + obs, + encounter_type_sort_index, + @prev_id:=@cur_id AS prev_id, + @cur_id:=t1.person_id AS cur_id, + t1.person_id, + p.uuid, + t1.visit_id, + t1.encounter_id, + @prev_encounter_date:=DATE(@cur_encounter_date) AS prev_encounter_date, + @cur_encounter_date:=DATE(encounter_datetime) AS cur_encounter_date, + t1.encounter_datetime, + t1.encounter_type, + t1.is_clinical_encounter, + death_date, + CASE + WHEN location_id THEN @cur_location:=location_id + WHEN @prev_id = @cur_id THEN @cur_location + ELSE NULL + END AS location_id, + CASE + WHEN @prev_id = @cur_id THEN @prev_rtc_date:=@cur_rtc_date + ELSE @prev_rtc_date:=NULL + END AS prev_rtc_date, + CASE + WHEN obs REGEXP '!!5096=' THEN @cur_rtc_date:=GETVALUES(obs, 5096) + WHEN + @prev_id = @cur_id + THEN + IF(@cur_rtc_date > encounter_datetime, + @cur_rtc_date, + NULL) + ELSE @cur_rtc_date:=NULL + END AS cur_rtc_date, + @lmp:=GETVALUES(obs, 1836) AS lmp, + CASE + WHEN obs REGEXP '!!5085=' THEN @sbp:=GETVALUES(obs, 5085) + END AS sbp, + @dbp:=GETVALUES(obs, 5086) AS dbp, + @pulse:=GETVALUES(obs, 5087) AS pulse, + @fbs:=GETVALUES(obs, 6252) AS fbs, + @rbs:=GETVALUES(obs, 887) AS rbs, + CASE + WHEN obs REGEXP '!!6126=' THEN @hb_a1c:=GETVALUES(obs, 6126) + WHEN @prev_id = @cur_id THEN @hb_a1c + ELSE @hb_a1c:=NULL + END AS hb_a1c, + CASE + WHEN + obs REGEXP '!!6126=' + THEN + @hb_a1c_date:=IFNULL(GETVALUES(obs_datetimes, 6126), + encounter_datetime) + WHEN @prev_id = @cur_id THEN @hb_a1c_date + ELSE @hb_a1c_date:=NULL + END AS hb_a1c_date, + CASE + WHEN obs REGEXP '!!790=' THEN @creatinine:=GETVALUES(obs, 790) + WHEN @prev_id = @cur_id THEN @creatinine + ELSE @creatinine:=NULL + END AS creatinine, + CASE + WHEN + obs REGEXP '!!790=' + THEN + @creatinine_date:=IFNULL(GETVALUES(obs_datetimes, 790), + encounter_datetime) + WHEN @prev_id = @cur_id THEN @creatinine_date + ELSE @creatinine_date:=NULL + END AS creatinine_date, + CASE + WHEN obs REGEXP '!!1006=' THEN @total_cholesterol:=GETVALUES(obs, 1006) + WHEN @prev_id = @cur_id THEN @total_cholesterol + ELSE @total_cholesterol:=NULL + END AS total_cholesterol, + CASE + WHEN obs REGEXP '!!1007=' THEN @hdl:=GETVALUES(obs, 1007) + WHEN @prev_id = @cur_id THEN @hdl + ELSE @hdl:=NULL + END AS hdl, + CASE + WHEN obs REGEXP '!!1008=' THEN @ldl:=GETVALUES(obs, 1008) + WHEN @prev_id = @cur_id THEN @ldl + ELSE @ldl:=NULL + END AS ldl, + CASE + WHEN obs REGEXP '!!1009=' THEN @triglycerides:=GETVALUES(obs, 1009) + WHEN @prev_id = @cur_id THEN @triglycerides + ELSE @triglycerides:=NULL + END AS triglycerides, + CASE + WHEN + obs REGEXP '!!1006=' + THEN + @lipid_panel_date:=IFNULL(GETVALUES(obs_datetimes, 1006), + encounter_datetime) + WHEN @prev_id = @cur_id THEN @lipid_panel_date + ELSE @lipid_panel_date:=NULL + END AS lipid_panel_date, + @dm_status:=GETVALUES(obs, 7287) AS dm_status, + @htn_status:=GETVALUES(obs, 7288) AS htn_status, + @dm_meds:=GETVALUES(obs, 7290) AS dm_meds, + @htn_meds:=GETVALUES(obs, 10241) AS htn_meds, + -- t2.prescriptions AS prescriptions, + NULL AS prescriptions, + @problems:=GETVALUES(obs, 6042) AS problems, + case + when obs regexp '!!11200=10239!!' then 1 + when (obs regexp '!!10239=') = 1 and (obs not regexp '!!10239=1066!!') = 1 then 1 + when obs regexp '!!10239=7281!!' then 1 + when obs regexp '!!10239=7282!!' then 1 + when obs regexp '!!10239=1066!!' then 0 + else NULL + end as has_comorbidity, + case + when obs regexp '!!10239=175!!' then 1 + else NULL + end as has_diabetic_comorbidity, + case + when obs regexp '!!10239=7971!!' then 1 + when obs regexp '!!10239=903!!' then 1 + when obs regexp '!!9328=903!!' then 1 + when obs regexp '!!9328=7971!!' then 1 + else NULL + end as has_hypertension_comorbidity, + case + when obs regexp '!!10239=10860!!' then 1 + when obs regexp '!!10239=77!!' then 1 + else NULL + end as has_mental_disorder_comorbidity, + case + when obs regexp '!!10239=5622!!' then 1 + when (obs regexp '!!10239=')= 1 and (obs not regexp '!!10239=(77|175|903|7281|7282|7971|10860)!!')=1 then 1 + else NULL + end as has_other_comorbidity, + FROM plhiv_ncd_summary_0 t1 + JOIN amrs.person p USING (person_id) + ); + -- LEFT OUTER JOIN + -- prescriptions t2 USING (encounter_id) + -- ); + + set @prev_id = null; + set @cur_id = null; + set @prev_encounter_datetime = null; + set @cur_encounter_datetime = null; + + set @prev_clinical_datetime = null; + set @cur_clinical_datetime = null; + + set @next_encounter_type = null; + set @cur_encounter_type = null; + + set @prev_clinical_location_id = null; + set @cur_clinical_location_id = null; + + + alter table plhiv_ncd_summary_1 drop prev_id, drop cur_id; + + drop table if exists plhiv_ncd_summary_2; + create temporary table plhiv_ncd_summary_2 + ( + select + *, + @prev_id := @cur_id as prev_id, + @cur_id := person_id as cur_id, + + case + when @prev_id = @cur_id then @prev_encounter_datetime := @cur_encounter_datetime + else @prev_encounter_datetime := null + end as next_encounter_datetime_plhiv_ncd, + + @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, + + case + when @prev_id=@cur_id then @next_encounter_type := @cur_encounter_type + else @next_encounter_type := null + end as next_encounter_type_plhiv_ncd, + + @cur_encounter_type := encounter_type as cur_encounter_type, + + case + when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime + else @prev_clinical_datetime := null + end as next_clinical_datetime_plhiv_ncd, + + case + when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id + else @prev_clinical_location_id := null + end as next_clinical_location_id_plhiv_ncd, + + case + when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime + when @prev_id = @cur_id then @cur_clinical_datetime + else @cur_clinical_datetime := null + end as cur_clinic_datetime, + + case + when is_clinical_encounter then @cur_clinical_location_id := location_id + when @prev_id = @cur_id then @cur_clinical_location_id + else @cur_clinical_location_id := null + end as cur_clinic_location_id, + + case + when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date + else @prev_clinical_rtc_date := null + end as next_clinical_rtc_date_plhiv_ncd, + + case + when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date + when @prev_id = @cur_id then @cur_clinical_rtc_date + else @cur_clinical_rtc_date:= null + end as cur_clinical_rtc_date + + from plhiv_ncd_summary_1 + order by person_id, date(encounter_datetime) desc, encounter_type_sort_index desc + ); + + alter table plhiv_ncd_summary_2 drop prev_id, drop cur_id, drop cur_encounter_type, drop cur_encounter_datetime, drop cur_clinical_rtc_date; + + + set @prev_id = null; + set @cur_id = null; + set @prev_encounter_type = null; + set @cur_encounter_type = null; + set @prev_encounter_datetime = null; + set @cur_encounter_datetime = null; + set @prev_clinical_datetime = null; + set @cur_clinical_datetime = null; + set @prev_clinical_location_id = null; + set @cur_clinical_location_id = null; + + drop temporary table if exists plhiv_ncd_summary_3; + create temporary table plhiv_ncd_summary_3 (prev_encounter_datetime datetime, prev_encounter_type int, index person_enc (person_id, encounter_datetime desc)) + ( + select + *, + @prev_id := @cur_id as prev_id, + @cur_id := t1.person_id as cur_id, + + -- if same person then cur enc type is same as prev encounter type else null + case + when @prev_id=@cur_id then @prev_encounter_type := @cur_encounter_type + else @prev_encounter_type:=null + end as prev_encounter_type_plhiv_ncd, + @cur_encounter_type := encounter_type as cur_encounter_type, + + -- if same person then cur enc dt is same as prev enc dt else null + case + when @prev_id=@cur_id then @prev_encounter_datetime := @cur_encounter_datetime + else @prev_encounter_datetime := null + end as prev_encounter_datetime_plhiv_ncd, + + @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, + + -- if same person then cur clc dt is same as prev clc dt else null + case + when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime + else @prev_clinical_datetime := null + end as prev_clinical_datetime_plhiv_ncd, + + -- if same person then cur clc locid is same as prev clc locid else null + case + when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id + else @prev_clinical_location_id := null + end as prev_clinical_location_id_plhiv_ncd, + + -- if clc enc or same person then cur clc dt is enc_dt else null + case + when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime + when @prev_id = @cur_id then @cur_clinical_datetime + else @cur_clinical_datetime := null + end as cur_clinical_datetime, + + -- if clc enc or same person then cur clc loc is loc_id else null + case + when is_clinical_encounter then @cur_clinical_location_id := location_id + when @prev_id = @cur_id then @cur_clinical_location_id + else @cur_clinical_location_id := null + end as cur_clinical_location_id, + + -- if same person then prev clc rtc is cur rtc else null + case + when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date + else @prev_clinical_rtc_date := null + end as prev_clinical_rtc_date_plhiv_ncd, + + -- if clc enc or same person then cur clc rtc is cur rtc else null + case + when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date + when @prev_id = @cur_id then @cur_clinical_rtc_date + else @cur_clinical_rtc_date:= null + end as cur_clinic_rtc_date + + from plhiv_ncd_summary_2 t1 + order by person_id, date(encounter_datetime), encounter_type_sort_index + ); + + SELECT COUNT(*) INTO @new_encounter_rows FROM plhiv_ncd_summary_3; + + SELECT @new_encounter_rows; + set @total_rows_written = @total_rows_written + @new_encounter_rows; + SELECT @total_rows_written; + + select + null, + person_id, + t1.uuid, + visit_id, + encounter_id, + encounter_datetime, + encounter_type, + is_clinical_encounter, + location_id, + t2.uuid as location_uuid, + death_date, + prev_rtc_date, + cur_rtc_date, + lmp, + sbp, + dbp, + pulse, + fbs, + rbs, + hb_a1c, + hb_a1c_date, + creatinine, + creatinine_date, + total_cholesterol, + hdl, + ldl, + triglycerides, + lipid_panel_date, + dm_status, + htn_status, + dm_meds, + htn_meds, + prescriptions, + problems, + has_comorbidity, + has_mental_disorder_comorbidity, + has_diabetic_comorbidity, + has_hypertension_comorbidity, + has_other_comorbidity, + prev_encounter_datetime_plhiv_ncd, + next_encounter_datetime_plhiv_ncd, + prev_encounter_type_plhiv_ncd, + next_encounter_type_plhiv_ncd, + prev_clinical_datetime_plhiv_ncd, + next_clinical_datetime_plhiv_ncd, + prev_clinical_location_id_plhiv_ncd, + next_clinical_location_id_plhiv_ncd, + prev_clinical_rtc_date_plhiv_ncd, + next_clinical_rtc_date_plhiv_ncd + from plhiv_ncd_summary_3 t1 + join amrs.location t2 using (location_id); + + #add data to table + SET @dyn_sql=CONCAT('replace into ',@write_table, + '(select + null, + person_id, + t1.uuid, + visit_id, + encounter_id, + encounter_datetime, + encounter_type, + is_clinical_encounter, + location_id, + t2.uuid as location_uuid, + death_date, + prev_rtc_date, + cur_rtc_date, + lmp, + sbp, + dbp, + pulse, + fbs, + rbs, + hb_a1c, + hb_a1c_date, + creatinine, + creatinine_date, + total_cholesterol, + hdl, + ldl, + triglycerides, + lipid_panel_date, + dm_status, + htn_status, + dm_meds, + htn_meds, + prescriptions, + problems, + has_comorbidity, + has_mental_disorder_comorbidity, + has_diabetic_comorbidity, + has_hypertension_comorbidity, + has_other_comorbidity, + prev_encounter_datetime_plhiv_ncd, + next_encounter_datetime_plhiv_ncd, + prev_encounter_type_plhiv_ncd, + next_encounter_type_plhiv_ncd, + prev_clinical_datetime_plhiv_ncd, + next_clinical_datetime_plhiv_ncd, + prev_clinical_location_id_plhiv_ncd, + next_clinical_location_id_plhiv_ncd, + prev_clinical_rtc_date_plhiv_ncd, + next_clinical_rtc_date_plhiv_ncd + + from plhiv_ncd_summary_3 t1 + join amrs.location t2 using (location_id))'); + + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + #delete from @queue_table where person_id in (select person_id from plhiv_ncd_summary_build_queue__0); + + SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join plhiv_ncd_summary_build_queue__0 t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + #select @person_ids_count := (select count(*) from plhiv_ncd_summary_build_queue_2); + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #select @person_ids_count as remaining_in_build_queue; + + set @cycle_length = timestampdiff(second,@loop_start_time,now()); + #select concat('Cycle time: ',@cycle_length,' seconds'); + set @total_time = @total_time + @cycle_length; + set @cycle_number = @cycle_number + 1; + + #select ceil(@person_ids_count / cycle_size) as remaining_cycles; + set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); + + SELECT + @person_ids_count AS 'persons remaining', + @cycle_length AS 'Cycle time (s)', + CEIL(@person_ids_count / cycle_size) AS remaining_cycles, + @remaining_time AS 'Est time remaining (min)'; + end while; + + if(@query_type="build") then + SET @dyn_sql=CONCAT('drop table ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @total_rows_to_write=0; + SET @dyn_sql=CONCAT("Select count(*) into @total_rows_to_write from ",@write_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @start_write = now(); + + SELECT + CONCAT(@start_write, + ' : Writing ', + @total_rows_to_write, + ' to ', + @primary_table); + + SET @dyn_sql=CONCAT('replace into ', @primary_table, + '(select * from ',@write_table,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @finish_write = now(); + set @time_to_write = timestampdiff(second,@start_write,@finish_write); + + SELECT + CONCAT(@finish_write, + ' : Completed writing rows. Time to write to primary table: ', + @time_to_write, + ' seconds '); + + SET @dyn_sql=CONCAT('drop table ',@write_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + end if; + + set @ave_cycle_length = ceil(@total_time/@cycle_number); + SELECT + CONCAT('Average Cycle Length: ', + @ave_cycle_length, + ' second(s)'); + + set @end = now(); + insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); + SELECT + CONCAT(@table_version, + ' : Time to complete: ', + TIMESTAMPDIFF(MINUTE, @start, @end), + ' minutes'); +END$$ +DELIMITER ; \ No newline at end of file From b7c8a81cc277f81c2eb24c903b1192bccf1bf35b Mon Sep 17 00:00:00 2001 From: henrykorir Date: Sun, 10 Dec 2023 23:35:27 +0300 Subject: [PATCH 6/9] POC-545: Create a Stored Procedure for the NCD Monthly Report --- .../generate_flat_cdm_v1_1.sql | 768 ++++++++++++++++++ .../generate_ncd_monthly_report_dataset.sql | 455 +++++++++++ 2 files changed, 1223 insertions(+) create mode 100644 etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql create mode 100644 etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql diff --git a/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql b/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql new file mode 100644 index 0000000..08f6629 --- /dev/null +++ b/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql @@ -0,0 +1,768 @@ +DELIMITER $$ +CREATE PROCEDURE `generate_flat_cdm_v1_1`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int) +BEGIN + set @primary_table := "flat_cdm_v1"; + set @query_type = query_type; +#set @query_type = "build"; + + + set @total_rows_written = 0; + + set @encounter_types = "(54,55,75,76,77,78,79,83,96,99,100,104,107,108,109,131,171,172)"; + set @clinical_encounter_types = "(54,55,75,76,77,78,79,83,96,104,107,108,109,171,172)"; + set @non_clinical_encounter_types = "(131)"; + set @other_encounter_types = "(-1)"; + + set @start = now(); + set @table_version = "flat_cdm_v1.1"; + + set session sort_buffer_size=512000000; + + set @sep = " ## "; + set @boundary = "!!"; + set @last_date_created = (select max(max_date_created) from etl.flat_obs); + + create table if not exists flat_cdm_v1 ( + date_created TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + person_id int, + uuid varchar(100), + visit_id int, + encounter_id int, + encounter_datetime datetime, + encounter_type int, + is_clinical_encounter int, + location_id int, + location_uuid varchar(100), + death_date datetime, + prev_rtc_date datetime, + rtc_date datetime, + + lmp date, + + sbp smallint, + dbp smallint, + pulse smallint, + + fbs decimal, + rbs decimal, + hb_a1c decimal, + hb_a1c_date datetime, + + creatinine decimal, + creatinine_date datetime, + + total_cholesterol decimal, + hdl decimal, + ldl decimal, + triglycerides decimal, + lipid_panel_date datetime, + + dm_status mediumint, + htn_status mediumint, + dm_meds varchar(500), + htn_meds varchar(500), + prescriptions text, + + problems text, + + comorbidities text, + rheumatologic_disorder text, + kidney_disease text, + ckd_staging text, + cardiovascular_disorder text, + neurological_disease text, + has_past_mhd_tx text, + eligible_for_depression_care text, + anxiety_condition text, + convulsive_disorder text, + mood_disorder text, + indicated_mhd_tx text, + prev_hbp_findings text, + type_of_follow_up text, + review_of_med_history text, + + prev_encounter_datetime_cdm datetime, + next_encounter_datetime_cdm datetime, + prev_encounter_type_cdm mediumint, + next_encounter_type_cdm mediumint, + prev_clinical_datetime_cdm datetime, + next_clinical_datetime_cdm datetime, + prev_clinical_location_id_cdm mediumint, + next_clinical_location_id_cdm mediumint, + prev_clinical_rtc_date_cdm datetime, + next_clinical_rtc_date_cdm datetime, + + primary key encounter_id (encounter_id), + index person_date (person_id, encounter_datetime), + index person_uuid (uuid), + index location_enc_date (location_uuid,encounter_datetime), + index enc_date_location (encounter_datetime, location_uuid), + index location_id_rtc_date (location_id,rtc_date), + index location_uuid_rtc_date (location_uuid,rtc_date), + index loc_id_enc_date_next_clinical (location_id, encounter_datetime, next_clinical_datetime_cdm), + index encounter_type (encounter_type), + index date_created (date_created) + + ); + + + + if(@query_type="build") then + select 'BUILDING..........................................'; + + set @write_table = concat("flat_cdm_temp_",queue_number); + set @queue_table = concat("flat_cdm_build_queue_",queue_number); + + + SET @dyn_sql=CONCAT('Create table if not exists ',@write_table,' like ',@primary_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from flat_cdm_build_queue limit ', queue_size, ');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('delete t1 from flat_cdm_build_queue t1 join ',@queue_table, ' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + end if; + + + if (@query_type="sync") then + select 'SYNCING..........................................'; + set @write_table = "flat_cdm_v1"; + set @queue_table = "flat_cdm_sync_queue"; + create table if not exists flat_cdm_sync_queue (person_id int primary key); + + + + set @last_update = null; + + select max(date_updated) into @last_update from etl.flat_log where table_name=@table_version; + + replace into flat_cdm_sync_queue + (select distinct patient_id + from amrs.encounter + where date_changed > @last_update + ); + + replace into flat_cdm_sync_queue + (select distinct person_id + from etl.flat_obs + where max_date_created > @last_update + ); + + replace into flat_cdm_sync_queue + (select distinct person_id + from etl.flat_lab_obs + where max_date_created > @last_update + ); + + replace into flat_cdm_sync_queue + (select distinct person_id + from etl.flat_orders + where max_date_created > @last_update + ); + + replace into flat_cdm_sync_queue + (select person_id from + amrs.person + where date_voided > @last_update); + + + replace into flat_cdm_sync_queue + (select person_id from + amrs.person + where date_changed > @last_update); + + + end if; + + + # Remove test patients + SET @dyn_sql=CONCAT('delete t1 FROM ',@queue_table,' t1 + join amrs.person_attribute t2 using (person_id) + where t2.person_attribute_type_id=28 and value="true" and voided=0'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @person_ids_count = 0; + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + select @person_ids_count as 'num patients to update'; + + SET @dyn_sql=CONCAT('delete t1 from ',@primary_table, ' t1 join ',@queue_table,' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + drop temporary table if exists prescriptions; + create temporary table prescriptions (encounter_id int primary key, prescriptions text) + ( + select + encounter_id, + group_concat(obs separator ' $ ') as prescriptions + from + ( + select + t2.encounter_id, + obs_group_id, + group_concat( + case + when value_coded is not null then concat(@boundary,o.concept_id,'=',value_coded,@boundary) + when value_numeric is not null then concat(@boundary,o.concept_id,'=',value_numeric,@boundary) + when value_datetime is not null then concat(@boundary,o.concept_id,'=',date(value_datetime),@boundary) + when value_text is not null then concat(@boundary,o.concept_id,'=',value_text,@boundary) + when value_drug is not null then concat(@boundary,o.concept_id,'=',value_drug,@boundary) + when value_modifier is not null then concat(@boundary,o.concept_id,'=',value_modifier,@boundary) + end + order by o.concept_id,value_coded + separator ' ## ' + ) as obs + + from amrs.obs o + join (select encounter_id, obs_id, concept_id as grouping_concept from amrs.obs where concept_id in (7307,7334)) t2 on o.obs_group_id = t2.obs_id + group by obs_group_id + ) t + group by encounter_id + ); + + + set @total_time=0; + set @cycle_number = 0; + + + while @person_ids_count > 0 do + + set @loop_start_time = now(); + + #create temp table with a set of person ids + drop temporary table if exists flat_cdm_build_queue__0; + + SET @dyn_sql=CONCAT('create temporary table flat_cdm_build_queue__0 (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + + + + drop temporary table if exists flat_cdm_0a; + SET @dyn_sql = CONCAT( + 'create temporary table flat_cdm_0a + (select + t1.person_id, + t1.visit_id, + t1.encounter_id, + t1.encounter_datetime, + t1.encounter_type, + t1.location_id, + t1.obs, + t1.obs_datetimes, + case + when t1.encounter_type in ',@clinical_encounter_types,' then 1 + else null + end as is_clinical_encounter, + + case + when t1.encounter_type in ',@non_clinical_encounter_types,' then 20 + when t1.encounter_type in ',@clinical_encounter_types,' then 10 + when t1.encounter_type in', @other_encounter_types, ' then 5 + else 1 + end as encounter_type_sort_index, + t2.orders + from etl.flat_obs t1 + join flat_cdm_build_queue__0 t0 using (person_id) + left join etl.flat_orders t2 using(encounter_id) + where t1.encounter_type in ',@encounter_types,');'); + + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + insert into flat_cdm_0a + (select + t1.person_id, + null, + t1.encounter_id, + t1.test_datetime, + t1.encounter_type, + null, #t1.location_id, + t1.obs, + null, #obs_datetimes + # in any visit, there many be multiple encounters. for this dataset, we want to include only clinical encounters (e.g. not lab or triage visit) + 0 as is_clinical_encounter, + 1 as encounter_type_sort_index, + null + from etl.flat_lab_obs t1 + join flat_cdm_build_queue__0 t0 using (person_id) + ); + + drop temporary table if exists flat_cdm_0; + create temporary table flat_cdm_0(index encounter_id (encounter_id), index person_enc (person_id,encounter_datetime)) + (select * from flat_cdm_0a + order by person_id, date(encounter_datetime), encounter_type_sort_index + ); + + + + set @prev_id = null; + set @cur_id = null; + set @prev_encounter_date = null; + set @cur_encounter_date = null; + set @enrollment_date = null; + set @cur_location = null; + set @cur_rtc_date = null; + set @prev_rtc_date = null; + + set @death_date = null; + + + #TO DO + # screened for cervical ca + # exposed infant + + drop temporary table if exists flat_cdm_1; + create temporary table flat_cdm_1 (index encounter_id (encounter_id)) + (select + obs, + encounter_type_sort_index, + @prev_id := @cur_id as prev_id, + @cur_id := t1.person_id as cur_id, + t1.person_id, + p.uuid, + t1.visit_id, + t1.encounter_id, + @prev_encounter_date := date(@cur_encounter_date) as prev_encounter_date, + @cur_encounter_date := date(encounter_datetime) as cur_encounter_date, + t1.encounter_datetime, + t1.encounter_type, + t1.is_clinical_encounter, + + death_date, + case + when location_id then @cur_location := location_id + when @prev_id = @cur_id then @cur_location + else null + end as location_id, + + case + when @prev_id=@cur_id then @prev_rtc_date := @cur_rtc_date + else @prev_rtc_date := null + end as prev_rtc_date, + + # 5096 = return visit date + case + when obs regexp "!!5096=" then @cur_rtc_date := etl.GetValues(obs,5096) + when @prev_id = @cur_id then if(@cur_rtc_date > encounter_datetime,@cur_rtc_date,null) + else @cur_rtc_date := null + end as cur_rtc_date, + + @lmp := etl.GetValues(obs,1836) as lmp, + + case + when obs regexp "!!5085=" then @sbp := etl.GetValues(obs,5085) + end as sbp, + + @dbp := etl.GetValues(obs,5086) as dbp, + + @pulse := etl.GetValues(obs,5087) as pulse, + + @fbs := etl.GetValues(obs,6252) as fbs, + @rbs := etl.GetValues(obs,887) as rbs, + + case + when obs regexp "!!6126=" then @hb_a1c := etl.GetValues(obs,6126) + when @prev_id = @cur_id then @hb_a1c + else @hb_a1c := null + end as hb_a1c, + + case + when obs regexp "!!6126=" then @hb_a1c_date := ifnull(etl.GetValues(obs_datetimes,6126),encounter_datetime) + when @prev_id=@cur_id then @hb_a1c_date + else @hb_a1c_date:=null + end as hb_a1c_date, + + case + when obs regexp "!!790=" then @creatinine := etl.GetValues(obs,790) + when @prev_id = @cur_id then @creatinine + else @creatinine := null + end as creatinine, + + case + when obs regexp "!!790=" then @creatinine_date := ifnull(etl.GetValues(obs_datetimes,790),encounter_datetime) + when @prev_id=@cur_id then @creatinine_date + else @creatinine_date:=null + end as creatinine_date, + + + case + when obs regexp "!!1006=" then @total_cholesterol := etl.GetValues(obs,1006) + when @prev_id = @cur_id then @total_cholesterol + else @total_cholesterol := null + end as total_cholesterol, + + case + when obs regexp "!!1007=" then @hdl := etl.GetValues(obs,1007) + when @prev_id = @cur_id then @hdl + else @hdl := null + end as hdl, + + case + when obs regexp "!!1008=" then @ldl := etl.GetValues(obs,1008) + when @prev_id = @cur_id then @ldl + else @ldl := null + end as ldl, + + case + when obs regexp "!!1009=" then @triglycerides := etl.GetValues(obs,1009) + when @prev_id = @cur_id then @triglycerides + else @triglycerides := null + end as triglycerides, + + case + when obs regexp "!!1006=" then @lipid_panel_date := ifnull(etl.GetValues(obs_datetimes,1006),encounter_datetime) + when @prev_id=@cur_id then @lipid_panel_date + else @lipid_panel_date:=null + end as lipid_panel_date, + + + @dm_status := etl.GetValues(obs,7287) as dm_status, + @htn_status := etl.GetValues(obs,7288) as htn_status, + @dm_meds := etl.GetValues(obs,7290) as dm_meds, + @htn_meds := etl.GetValues(obs,10241) as htn_meds, + t2.prescriptions as prescriptions, + + @problems := concat(etl.GetValues(obs,6042 ), ' ## ', etl.GetValues(obs,11679)) as problems, + @comorbidities := etl.GetValues(obs,10239 ) as comorbidities, + @rheumatologic_disorder := etl.GetValues(obs,12293) as rheumatologic_disorder + @kidney_disease := etl.GetValues(obs, 6033) as kidney_disease, + @ckd_staging := etl.GetValues(obs,10101) as ckd_staging, + @cardiovascular_disorder := etl.GetValues(obs, 7971) as cardiovascular_disorder, + @neurological_disease := etl.GetValues(obs, 1129) as neurological_disease, + @has_past_mhd_tx := etl.GetValues(obs, 10280) as has_past_mhd_tx, + @eligible_for_depression_care := etl.GetValues(obs, 10293) as eligible_for_depression_care, + @anxiety_condition := etl.GetValues(obs, 11231) as anxiety_condition, + @convulsive_disorder := etl.GetValues(obs, 11791) as convulsive_disorder, + @mood_disorder := etl.GetValues(obs, 11279) as mood_disorder, + @indicated_mhd_tx := etl.GetValues(obs, 7781) as indicated_mhd_tx, + @prev_hbp_findings := etl.GetValues(obs, 9092) as prev_hbp_findings, + @type_of_follow_up := etl.GetValues(obs, 2332) as type_of_follow_up, + @review_of_med_history := etl.GetValues(obs, 6245) as review_of_med_history + + from flat_cdm_0 t1 + join amrs.person p using (person_id) + left outer join prescriptions t2 using (encounter_id) + ); + + + set @prev_id = null; + set @cur_id = null; + set @prev_encounter_datetime = null; + set @cur_encounter_datetime = null; + + set @prev_clinical_datetime = null; + set @cur_clinical_datetime = null; + + set @next_encounter_type = null; + set @cur_encounter_type = null; + + set @prev_clinical_location_id = null; + set @cur_clinical_location_id = null; + + + alter table flat_cdm_1 drop prev_id, drop cur_id; + + drop table if exists flat_cdm_2; + create temporary table flat_cdm_2 + (select *, + @prev_id := @cur_id as prev_id, + @cur_id := person_id as cur_id, + + case + when @prev_id = @cur_id then @prev_encounter_datetime := @cur_encounter_datetime + else @prev_encounter_datetime := null + end as next_encounter_datetime_cdm, + + @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, + + case + when @prev_id=@cur_id then @next_encounter_type := @cur_encounter_type + else @next_encounter_type := null + end as next_encounter_type_cdm, + + @cur_encounter_type := encounter_type as cur_encounter_type, + + case + when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime + else @prev_clinical_datetime := null + end as next_clinical_datetime_cdm, + + case + when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id + else @prev_clinical_location_id := null + end as next_clinical_location_id_cdm, + + case + when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime + when @prev_id = @cur_id then @cur_clinical_datetime + else @cur_clinical_datetime := null + end as cur_clinic_datetime, + + case + when is_clinical_encounter then @cur_clinical_location_id := location_id + when @prev_id = @cur_id then @cur_clinical_location_id + else @cur_clinical_location_id := null + end as cur_clinic_location_id, + + case + when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date + else @prev_clinical_rtc_date := null + end as next_clinical_rtc_date_cdm, + + case + when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date + when @prev_id = @cur_id then @cur_clinical_rtc_date + else @cur_clinical_rtc_date:= null + end as cur_clinical_rtc_date + + from flat_cdm_1 + order by person_id, date(encounter_datetime) desc, encounter_type_sort_index desc + ); + + alter table flat_cdm_2 drop prev_id, drop cur_id, drop cur_encounter_type, drop cur_encounter_datetime, drop cur_clinical_rtc_date; + + + set @prev_id = null; + set @cur_id = null; + set @prev_encounter_type = null; + set @cur_encounter_type = null; + set @prev_encounter_datetime = null; + set @cur_encounter_datetime = null; + set @prev_clinical_datetime = null; + set @cur_clinical_datetime = null; + set @prev_clinical_location_id = null; + set @cur_clinical_location_id = null; + + drop temporary table if exists flat_cdm_3; + create temporary table flat_cdm_3 (prev_encounter_datetime datetime, prev_encounter_type int, index person_enc (person_id, encounter_datetime desc)) + (select + *, + @prev_id := @cur_id as prev_id, + @cur_id := t1.person_id as cur_id, + + case + when @prev_id=@cur_id then @prev_encounter_type := @cur_encounter_type + else @prev_encounter_type:=null + end as prev_encounter_type_cdm, + @cur_encounter_type := encounter_type as cur_encounter_type, + + case + when @prev_id=@cur_id then @prev_encounter_datetime := @cur_encounter_datetime + else @prev_encounter_datetime := null + end as prev_encounter_datetime_cdm, + + @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, + + case + when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime + else @prev_clinical_datetime := null + end as prev_clinical_datetime_cdm, + + case + when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id + else @prev_clinical_location_id := null + end as prev_clinical_location_id_cdm, + + case + when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime + when @prev_id = @cur_id then @cur_clinical_datetime + else @cur_clinical_datetime := null + end as cur_clinical_datetime, + + case + when is_clinical_encounter then @cur_clinical_location_id := location_id + when @prev_id = @cur_id then @cur_clinical_location_id + else @cur_clinical_location_id := null + end as cur_clinical_location_id, + + case + when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date + else @prev_clinical_rtc_date := null + end as prev_clinical_rtc_date_cdm, + + case + when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date + when @prev_id = @cur_id then @cur_clinical_rtc_date + else @cur_clinical_rtc_date:= null + end as cur_clinic_rtc_date + + from flat_cdm_2 t1 + order by person_id, date(encounter_datetime), encounter_type_sort_index + ); + + + + select count(*) into @new_encounter_rows from flat_cdm_3; + + select @new_encounter_rows; + set @total_rows_written = @total_rows_written + @new_encounter_rows; + select @total_rows_written; + + + #add data to table + SET @dyn_sql=CONCAT('replace into ',@write_table, + '(select + null, + person_id, + t1.uuid, + visit_id, + encounter_id, + encounter_datetime, + encounter_type, + is_clinical_encounter, + location_id, + t2.uuid as location_uuid, + death_date, + prev_rtc_date, + cur_rtc_date, + lmp, + sbp, + dbp, + pulse, + fbs, + rbs, + hb_a1c, + hb_a1c_date, + creatinine, + creatinine_date, + total_cholesterol, + hdl, + ldl, + triglycerides, + lipid_panel_date, + dm_status, + htn_status, + dm_meds, + htn_meds, + prescriptions, + problems, + comorbidities, + rheumatologic_disorder, + kidney_disease, + ckd_staging, + cardiovascular_disorder, + neurological_disease, + has_past_mhd_tx, + eligible_for_depression_care, + anxiety_condition, + convulsive_disorder, + mood_disorder, + indicated_mhd_tx, + prev_hbp_findings, + type_of_follow_up, + review_of_med_history, + + prev_encounter_datetime_cdm, + next_encounter_datetime_cdm, + prev_encounter_type_cdm, + next_encounter_type_cdm, + prev_clinical_datetime_cdm, + next_clinical_datetime_cdm, + prev_clinical_location_id_cdm, + next_clinical_location_id_cdm, + prev_clinical_rtc_date_cdm, + next_clinical_rtc_date_cdm + + from flat_cdm_3 t1 + join amrs.location t2 using (location_id))'); + + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + #delete from @queue_table where person_id in (select person_id from flat_cdm_build_queue__0); + + SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join flat_cdm_build_queue__0 t2 using (person_id);'); +# select @dyn_sql; + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + #select @person_ids_count := (select count(*) from flat_cdm_build_queue_2); + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #select @person_ids_count as remaining_in_build_queue; + + set @cycle_length = timestampdiff(second,@loop_start_time,now()); + #select concat('Cycle time: ',@cycle_length,' seconds'); + set @total_time = @total_time + @cycle_length; + set @cycle_number = @cycle_number + 1; + + #select ceil(@person_ids_count / cycle_size) as remaining_cycles; + set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); + #select concat("Estimated time remaining: ", @remaining_time,' minutes'); + + select @person_ids_count as 'persons remaining', @cycle_length as 'Cycle time (s)', ceil(@person_ids_count / cycle_size) as remaining_cycles, @remaining_time as 'Est time remaining (min)'; + + end while; + + if(@query_type="build") then + SET @dyn_sql=CONCAT('drop table ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @total_rows_to_write=0; + SET @dyn_sql=CONCAT("Select count(*) into @total_rows_to_write from ",@write_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @start_write = now(); + select concat(@start_write, " : Writing ",@total_rows_to_write, ' to ',@primary_table); + + SET @dyn_sql=CONCAT('replace into ', @primary_table, + '(select * from ',@write_table,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @finish_write = now(); + set @time_to_write = timestampdiff(second,@start_write,@finish_write); + select concat(@finish_write, ' : Completed writing rows. Time to write to primary table: ', @time_to_write, ' seconds '); + + SET @dyn_sql=CONCAT('drop table ',@write_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + end if; + + + set @ave_cycle_length = ceil(@total_time/@cycle_number); + select CONCAT('Average Cycle Length: ', @ave_cycle_length, ' second(s)'); + + set @end = now(); + insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); + select concat(@table_version," : Time to complete: ",timestampdiff(minute, @start, @end)," minutes"); + + END$$ +DELIMITER ; diff --git a/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql new file mode 100644 index 0000000..eb4b9af --- /dev/null +++ b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql @@ -0,0 +1,455 @@ +DELIMITER $$ +CREATE PROCEDURE `generate_ncd_monthly_report_dataset`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int, IN start_date varchar(50)) +BEGIN + + set @start = now(); + set @table_version = "ncd_monthly_report_dataset_v1.4"; + set @last_date_created = (select max(date_created) from etl.flat_hiv_summary_v15b); + + set @sep = " ## "; + set @lab_encounter_type = 99999; + set @death_encounter_type = 31; + + +create table if not exists ncd_monthly_report_dataset ( + date_created timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP NOT NULL, + elastic_id bigint, + endDate date, + encounter_id int, + person_id int, + person_uuid varchar(100), + birthdate date, + age double, + gender varchar(1), + location_id int, + location_uuid varchar(100), + encounter_date date, + visit_this_month tinyint, + + is_hypertensive tinyint, + htn_state tinyint, + + is_diabetic tinyint, + dm_state tinyint, + + has_mhd tinyint, + is_depressive_mhd tinyint, + is_anxiety_mhd tinyint, + is_bipolar_and_related_mhd tinyint, + is_personality_mhd tinyint, + is_feeding_and_eating_mhd tinyint, + is_ocd_mhd tinyint, + + has_kd tinyint, + is_ckd tinyint, + ckd_stage int, + + has_cvd tinyint, + is_heart_failure_cvd tinyint, + is_myocardinal_infarction tinyint, + + has_neurological_disorder tinyint, + has_stroke tinyint, + is_stroke_haemorrhagic tinyint, + is_stroke_ischaemic tinyint, + has_seizure tinyint, + has_epilepsy tinyint, + has_convulsive_disorder tinyint, + + has_rheumatologic_disorder tinyint, + has_arthritis tinyint, + has_SLE tinyint, + + + primary key elastic_id (elastic_id), + index person_enc_date (person_id, encounter_date), + index person_report_date (person_id, endDate), + index endDate_location_id (endDate, location_id), + index date_created (date_created), + index status_change (location_id, endDate, status, prev_status) + + ); + + #create table if not exists ncd_monthly_report_dataset_build_queue (person_id int primary key); + #replace into ncd_monthly_report_dataset_build_queue + #(select distinct person_id from flat_hiv_summary_v15); + + if (query_type = "build") then + select "BUILDING......................."; + set @queue_table = concat("ncd_monthly_report_dataset_build_queue_",queue_number); +#set @queue_table = concat("ncd_monthly_report_dataset_build_queue_1"); + #create table if not exists @queue_table (person_id int, primary key (person_id)); + #SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from ncd_monthly_report_dataset_build_queue limit 1000);'); + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,'(person_id int primary key) (select * from ncd_monthly_report_dataset_build_queue limit ', queue_size, ');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #delete t1 from ncd_monthly_report_dataset_build_queue t1 join @queue_table t2 using (person_id) + SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset_build_queue t1 join ',@queue_table, ' t2 using (person_id)'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + end if; + + + if (query_type = "sync") then + set @queue_table = "ncd_monthly_report_dataset_sync_queue"; + create table if not exists ncd_monthly_report_dataset_sync_queue (person_id int primary key); + + select @last_update := (select max(date_updated) from etl.flat_log where table_name=@table_version); + + replace into ncd_monthly_report_dataset_sync_queue + (select distinct person_id from flat_hiv_summary_v15b where date_created >= @last_update); + end if; + + + SET @num_ids := 0; + SET @dyn_sql=CONCAT('select count(*) into @num_ids from ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + SET @person_ids_count = 0; + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + +SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_table,' t2 using (person_id);'); +# SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_table,' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @total_time=0; + set @cycle_number = 0; + + while @person_ids_count > 0 do + + set @loop_start_time = now(); + #create temporary table ncd_monthly_report_dataset_build_queue_0 (select * from ncd_monthly_report_dataset_build_queue_2 limit 5000); #TODO - change this when data_fetch_size changes + + drop temporary table if exists ncd_monthly_report_dataset_build_queue__0; + create temporary table ncd_monthly_report_dataset_build_queue__0 (person_id int primary key); + +#SET @dyn_sql=CONCAT('insert into ncd_monthly_report_dataset_build_queue__0 (select * from ncd_monthly_report_dataset_build_queue_1 limit 100);'); + SET @dyn_sql=CONCAT('insert into ncd_monthly_report_dataset_build_queue__0 (select * from ',@queue_table,' limit ',cycle_size,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + set @age =null; + set @status = null; + + drop temporary table if exists ncd_monthly_report_dataset_0; + create temporary table ncd_monthly_report_dataset_0 + (select + concat(date_format(endDate,"%Y%m"),person_id) as elastic_id, + endDate, + encounter_id, + person_id, + t3.uuid as person_uuid, + date(birthdate) as birthdate, + case + when timestampdiff(year,birthdate,endDate) > 0 then @age := round(timestampdiff(year,birthdate,endDate),0) + else @age :=round(timestampdiff(month,birthdate,endDate)/12,2) + end as age, + t3.gender, + date(encounter_datetime) as encounter_date, + + if(encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate,1,0) as visit_this_month, + + date(rtc_date) as rtc_date, + timestampdiff(day,rtc_date, endDate) as days_since_rtc_date, + + if(date(encounter_datetime) = date(prev_clinical_rtc_date_hiv),1,0) as on_schedule, + + case + when encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate + AND date(encounter_datetime) = date(prev_clinical_rtc_date_hiv) + then 1 + else 0 + end as scheduled_this_month, + + case + when encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate + AND date(encounter_datetime) != date(prev_clinical_rtc_date_hiv) + then 1 + else 0 + end as unscheduled_this_month, + + case + when arv_first_regimen_location_id != 9999 + and arv_first_regimen_start_date between date_format(endDate,"%Y-%m-01") and endDate then arv_first_regimen_location_id + else location_id + end as location_id, + + + encounter_type, + + case + when (comorbidities regexp '903') then 1 + when htn_status = 7285 or htn_status = 7286 then 1 + when (htn_meds is not null) then 1 + else null + end as is_hypertensive, + + case + when ((sbp < 130) and (dbp < 80)) then 1 + when ((sbp >= 130) and (dbp >= 80)) then 2 + when ((sbp is null) or (dbp is null)) then 3 + else NULL + end as htn_state, + + case + when (comorbidities regexp '175') then 1 + when dm_status = 7281 or dm_status = 7282 then 1 + when (dm_meds is not null) then 1 + else null + end as is_diabetic, + + case + when (hb_a1c >= 7 and hb_a1c <= 8) then 1 + when (hb_a1c < 7 and hb_a1c > 8) then 2 + when (hb_a1c is null) or (hb_a1c is null) then 3 + else null + end as dm_state, + + case + when (comorbidities regexp '10860') then 1 + else null + end as has_mhd, + + from etl.dates t1 + join etl.flat_hiv_summary_v15b t2 + join amrs.person t3 using (person_id) + join etl.ncd_monthly_report_dataset_build_queue__0 t5 using (person_id) + + + where + #t2.encounter_datetime <= t1.endDate + t2.encounter_datetime < date_add(endDate, interval 1 day) + and (t2.next_clinical_datetime_hiv is null or t2.next_clinical_datetime_hiv >= date_add(t1.endDate, interval 1 day) ) + and t2.is_clinical_encounter=1 + and t1.endDate between start_date and date_add(now(),interval 2 year) + order by person_id, endDate + ); + + + + set @prev_id = null; + set @cur_id = null; + set @cur_status = null; + set @prev_status = null; + set @prev_location_id = null; + set @cur_location_id = null; + + drop temporary table if exists ncd_monthly_report_dataset_1; + create temporary table ncd_monthly_report_dataset_1 + (select + *, + @prev_id := @cur_id as prev_id, + @cur_id := person_id as cur_id, + + case + when @prev_id=@cur_id then @prev_location_id := @cur_location_id + else @prev_location_id := null + end as next_location_id, + + @cur_location_id := location_id as cur_location_id, + + case + when @prev_id=@cur_id then @prev_status := @cur_status + else @prev_status := null + end as next_status, + @cur_status := status as cur_status + + from ncd_monthly_report_dataset_0 + order by person_id, endDate desc + ); + + select now(); + select count(*) as num_rows_to_be_inserted from ncd_monthly_report_dataset_2; + + #add data to table + replace into ncd_monthly_report_dataset + (select + null, #date_created will be automatically set or updated + elastic_id, + endDate, + encounter_id, + person_id, + person_uuid, + birthdate, + age, + gender, + encounter_date, + visit_this_month, + rtc_date, + days_since_rtc_date, + on_schedule, + scheduled_this_month, + unscheduled_this_month, + f_18_and_over_this_month, + prev_location_id, + location_id, + t2.uuid as location_uuid, + next_location_id, + t2.state_province as clinic_county, + t2.name as clinic, + t2.latitude as clinic_latitude, + t2.longitude as clinic_longitude, + encounter_type, + death_date, + enrollment_date, + enrolled_this_month, + transfer_in_this_month, + transfer_in_location_id, + transfer_in_date, + transfer_out_this_month, + transfer_out_location_id, + transfer_out_date, + prev_status, + status, + next_status, + active_in_care_this_month, + is_pre_art_this_month, + arv_first_regimen_location_id, + arv_first_regimen, + arv_first_regimen_names, + arv_first_regimen_start_date, + art_cohort_year, + art_cohort_month, + art_cohort_num, + art_cohort_total_months, + days_since_starting_arvs, + started_art_this_month, + art_revisit_this_month, + arv_start_date, + prev_month_arvs, + prev_month_arvs_names, + cur_arv_meds, + cur_arv_meds_names, + cur_arv_meds_strict, + cur_arv_line, + cur_arv_line_strict, + cur_arv_line_reported, + on_art_this_month, + on_original_first_line_this_month, + on_alt_first_line_this_month, + on_second_line_or_higher_this_month, + eligible_for_vl, + days_since_last_vl, + net_12_month_cohort_this_month, + active_on_art_12_month_cohort_this_month, + has_vl_12_month_cohort, + vl_suppressed_12_month_cohort, + has_vl_this_month, + is_suppressed_this_month, + vl_1, + vl_1_date, + vl_in_past_year, + vl_2, + vl_2_date, + qualifies_for_follow_up_vl, + got_follow_up_vl, + got_follow_up_vl_this_month, + num_days_to_follow_vl, + follow_up_vl_suppressed, + follow_up_vl_suppressed_this_month, + follow_up_vl_unsuppressed, + follow_up_vl_unsuppressed_this_month, + due_for_vl_this_month, + reason_for_needing_vl_this_month, + number_of_months_has_needed_vl, + needs_follow_up_vl, + had_med_change_this_month, + had_med_change_this_month_after_2_unsuppressed_vls, + same_meds_this_month_after_2_unsuppressed_vls, + tb_screen, + tb_screening_datetime, + tb_screening_result, + tb_screened_this_visit_this_month, + tb_screened_active_this_month, + presumed_tb_positive_this_month, + tb_tx_start_date, + started_tb_tx_this_month, + on_tb_tx_this_month, + on_tb_tx_and_started_art_this_month, + pcp_prophylaxis_start_date, + started_pcp_prophylaxis_this_month, + on_pcp_prophylaxis_this_month, + ipt_start_date, + ipt_stop_date, + ipt_completion_date, + started_ipt_this_month, + on_ipt_this_month, + completed_ipt_past_12_months, + pregnant_this_month, + is_pregnant_and_started_art_this_month, + delivered_this_month, + condoms_provided_this_month, + condoms_provided_since_active, + started_modern_contraception_this_month, + modern_contraception_since_active, + on_modern_contraception_this_month, + contraceptive_method, + discordant_status + from ncd_monthly_report_dataset_2 t1 + join amrs.location t2 using (location_id) + ); + + + + #delete from @queue_table where person_id in (select person_id from ncd_monthly_report_dataset_build_queue__0); + SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join ncd_monthly_report_dataset_build_queue__0 t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #select @person_ids_count := (select count(*) from @queue_table); + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + #select @person_ids_count as num_remaining; + + set @cycle_length = timestampdiff(second,@loop_start_time,now()); + #select concat('Cycle time: ',@cycle_length,' seconds'); + set @total_time = @total_time + @cycle_length; + set @cycle_number = @cycle_number + 1; + + #select ceil(@person_ids_count / cycle_size) as remaining_cycles; + set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); + #select concat("Estimated time remaining: ", @remaining_time,' minutes'); + +# select count(*) into @num_in_hmrd from ncd_monthly_report_dataset; + + select @num_in_hmrd as num_in_hmrd, + @person_ids_count as num_remaining, + @cycle_length as 'Cycle time (s)', + ceil(@person_ids_count / cycle_size) as remaining_cycles, + @remaining_time as 'Est time remaining (min)'; + + + end while; + + if(query_type = "build") then + SET @dyn_sql=CONCAT('drop table ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + end if; + + set @end = now(); + # not sure why we need last date_created, Ive replaced this with @start + insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); + select concat(@table_version," : Time to complete: ",timestampdiff(minute, @start, @end)," minutes"); + + END$$ +DELIMITER ; From 43daec37c5238c33af96341da82629154fdef599 Mon Sep 17 00:00:00 2001 From: henrykorir Date: Mon, 11 Dec 2023 17:01:54 +0300 Subject: [PATCH 7/9] POC-545: Create a Stored Procedure for the NCD Monthly Report --- .../generate_flat_cdm_v1_1.sql | 5 +- .../generate_ncd_monthly_report_dataset.sql | 375 +++++++++++------- 2 files changed, 231 insertions(+), 149 deletions(-) diff --git a/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql b/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql index 08f6629..85cc2c1 100644 --- a/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql +++ b/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql @@ -444,7 +444,7 @@ BEGIN @htn_meds := etl.GetValues(obs,10241) as htn_meds, t2.prescriptions as prescriptions, - @problems := concat(etl.GetValues(obs,6042 ), ' ## ', etl.GetValues(obs,11679)) as problems, + @problems := concat(etl.GetValues(obs,6042 ), ' ## ', etl.GetValues(obs,11679), ' ## ', etl.GetValues(obs,6796)) as problems, @comorbidities := etl.GetValues(obs,10239 ) as comorbidities, @rheumatologic_disorder := etl.GetValues(obs,12293) as rheumatologic_disorder @kidney_disease := etl.GetValues(obs, 6033) as kidney_disease, @@ -459,7 +459,8 @@ BEGIN @indicated_mhd_tx := etl.GetValues(obs, 7781) as indicated_mhd_tx, @prev_hbp_findings := etl.GetValues(obs, 9092) as prev_hbp_findings, @type_of_follow_up := etl.GetValues(obs, 2332) as type_of_follow_up, - @review_of_med_history := etl.GetValues(obs, 6245) as review_of_med_history + @review_of_med_history := etl.GetValues(obs, 6245) as review_of_med_history, + @psychiatric_exam_findings := etl.GetValues(obs, 6245) as review_of_med_history from flat_cdm_0 t1 join amrs.person p using (person_id) diff --git a/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql index eb4b9af..45fddb9 100644 --- a/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql +++ b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql @@ -69,23 +69,16 @@ create table if not exists ncd_monthly_report_dataset ( index status_change (location_id, endDate, status, prev_status) ); - - #create table if not exists ncd_monthly_report_dataset_build_queue (person_id int primary key); - #replace into ncd_monthly_report_dataset_build_queue - #(select distinct person_id from flat_hiv_summary_v15); if (query_type = "build") then select "BUILDING......................."; set @queue_table = concat("ncd_monthly_report_dataset_build_queue_",queue_number); -#set @queue_table = concat("ncd_monthly_report_dataset_build_queue_1"); - #create table if not exists @queue_table (person_id int, primary key (person_id)); - #SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from ncd_monthly_report_dataset_build_queue limit 1000);'); + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,'(person_id int primary key) (select * from ncd_monthly_report_dataset_build_queue limit ', queue_size, ');'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; - #delete t1 from ncd_monthly_report_dataset_build_queue t1 join @queue_table t2 using (person_id) SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset_build_queue t1 join ',@queue_table, ' t2 using (person_id)'); PREPARE s1 from @dyn_sql; EXECUTE s1; @@ -118,8 +111,7 @@ create table if not exists ncd_monthly_report_dataset ( DEALLOCATE PREPARE s1; -SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_table,' t2 using (person_id);'); -# SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_table,' t2 using (person_id);'); + SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_table,' t2 using (person_id);'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; @@ -130,12 +122,10 @@ SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_ while @person_ids_count > 0 do set @loop_start_time = now(); - #create temporary table ncd_monthly_report_dataset_build_queue_0 (select * from ncd_monthly_report_dataset_build_queue_2 limit 5000); #TODO - change this when data_fetch_size changes drop temporary table if exists ncd_monthly_report_dataset_build_queue__0; create temporary table ncd_monthly_report_dataset_build_queue__0 (person_id int primary key); -#SET @dyn_sql=CONCAT('insert into ncd_monthly_report_dataset_build_queue__0 (select * from ncd_monthly_report_dataset_build_queue_1 limit 100);'); SET @dyn_sql=CONCAT('insert into ncd_monthly_report_dataset_build_queue__0 (select * from ',@queue_table,' limit ',cycle_size,');'); PREPARE s1 from @dyn_sql; EXECUTE s1; @@ -192,9 +182,12 @@ SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_ encounter_type, case + when htn_status = 7285 or htn_status = 7286 then 1 when (comorbidities regexp '903') then 1 - when htn_status = 7285 or htn_status = 7286 then 1 + when (prev_hbp_findings regexp '1065') then 1 when (htn_meds is not null) then 1 + when (problems regexp '903') then 1 + when (review_of_med_history regexp '903') then 1 else null end as is_hypertensive, @@ -206,9 +199,12 @@ SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_ end as htn_state, case + when dm_status = 7281 or dm_status = 7282 then 1 when (comorbidities regexp '175') then 1 - when dm_status = 7281 or dm_status = 7282 then 1 when (dm_meds is not null) then 1 + when (problems regexp '9324') or (problems regexp '175') then 1 + when (problems regexp '175') then 1 + when (review_of_med_history regexp '175') then 1 else null end as is_diabetic, @@ -221,26 +217,116 @@ SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_ case when (comorbidities regexp '10860') then 1 + when (indicated_mhd_tx is not null) then 1 + when (has_past_mhd_tx = '1065') then 1 + when (review_of_med_history regexp '(77)|(207)') then 1 + when (eligible_for_depression_care = '1065') then 1 + when (mood_disorder is not null) then 1 + when (anxiety_condition is not null) then 1 else null end as has_mhd, + case + when (eligible_for_depression_care = '1065') then 1 + when (mood_disorder regexp '11278') then 1 + when (indicated_mhd_tx regexp '207') then 1 + when (review_of_med_history regexp '207') then 1 + else null + end as is_depressive_mhd, + + case + when (anxiety_condition is not null) then 1 + when (indicated_mhd_tx regexp '1443') then 1 + when (review_of_med_history regexp '207') then 1 + else null + end as is_anxiety_mhd, + + case + when (mood_disorder regexp '7763') then 1 + when (indicated_mhd_tx regexp '7763') then 1 + else null + end as is_bipolar_and_related_mhd, + + case + when (mood_disorder regexp '7763') then 1 + when (indicated_mhd_tx regexp '11281') then 1 + when (problems regexp '467') then 1 + else null + end as is_personality_mhd, + + null as is_feeding_and_eating_mhd, + + null as is_ocd_mhd, + + case + when (comorbidities regexp '[[:<:]]77[[:>:]]') then 1 + when (kidney_disease = '[[:<:]]1065[[:>:]]') then 1 + when (problems regexp '[[:<:]]8078[[:>:]]|[[:<:]]11684[[:>:]]') then 1 + when (review_of_med_history regexp '(6033)|(8078)') then 1 + else null + end as has_kd, + + case + when (problems regexp '8078') then 1 + when (review_of_med_history regexp '8078') then 1 + when (ckd_staging is not null) then 1 + else null + end as is_ckd, + + ckd_staging as ckd_stage, + + case + when (cardiovascular_disorder is not null) then 1 + when (comorbidities regexp '7971') then 1 + when (review_of_med_history regexp '(7971)|(6237)') then 1 + else null + end as has_cvd, + + case + when (cardiovascular_disorder regexp '1456') then 1 + when (indicated_mhd_tx regexp '1456') then 1 + when (review_of_med_history regexp '7971') then 1 + else null + end as is_heart_failure_cvd, + + case + when (neurological_disease is not null) then 1 + when (indicated_mhd_tx regexp '1456') then 1 + when (review_of_med_history regexp '7971') then 1 + else null + end as has_neurological_disorder, + + case + when (cardiovascular_disorder regexp '1535') then 1 + else null + end as is_myocardinal_infarction, + + case + when (cardiovascular_disorder regexp '1878') then 1 + when (indicated_mhd_tx regexp '1456') then 1 + when (review_of_med_history regexp '7971') then 1 + else null + end as has_stroke, + + null as is_stroke_haemorrhagic + + null as is_stroke_ischaemic, + + null as + from etl.dates t1 - join etl.flat_hiv_summary_v15b t2 + join etl.flat_cdm_v1 t2 join amrs.person t3 using (person_id) join etl.ncd_monthly_report_dataset_build_queue__0 t5 using (person_id) - where - #t2.encounter_datetime <= t1.endDate t2.encounter_datetime < date_add(endDate, interval 1 day) - and (t2.next_clinical_datetime_hiv is null or t2.next_clinical_datetime_hiv >= date_add(t1.endDate, interval 1 day) ) + and (t2.next_clinical_datetime_cdm is null or t2.next_clinical_datetime_cdm >= date_add(t1.endDate, interval 1 day) ) and t2.is_clinical_encounter=1 and t1.endDate between start_date and date_add(now(),interval 2 year) order by person_id, endDate ); - - set @prev_id = null; set @cur_id = null; set @cur_status = null; @@ -279,154 +365,149 @@ SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_ replace into ncd_monthly_report_dataset (select null, #date_created will be automatically set or updated - elastic_id, - endDate, - encounter_id, - person_id, - person_uuid, - birthdate, - age, - gender, - encounter_date, - visit_this_month, - rtc_date, - days_since_rtc_date, - on_schedule, - scheduled_this_month, - unscheduled_this_month, - f_18_and_over_this_month, - prev_location_id, - location_id, - t2.uuid as location_uuid, - next_location_id, - t2.state_province as clinic_county, - t2.name as clinic, - t2.latitude as clinic_latitude, - t2.longitude as clinic_longitude, - encounter_type, - death_date, - enrollment_date, - enrolled_this_month, - transfer_in_this_month, - transfer_in_location_id, - transfer_in_date, - transfer_out_this_month, - transfer_out_location_id, - transfer_out_date, - prev_status, - status, - next_status, - active_in_care_this_month, - is_pre_art_this_month, - arv_first_regimen_location_id, - arv_first_regimen, - arv_first_regimen_names, - arv_first_regimen_start_date, - art_cohort_year, - art_cohort_month, - art_cohort_num, - art_cohort_total_months, - days_since_starting_arvs, - started_art_this_month, - art_revisit_this_month, - arv_start_date, - prev_month_arvs, - prev_month_arvs_names, - cur_arv_meds, - cur_arv_meds_names, - cur_arv_meds_strict, - cur_arv_line, - cur_arv_line_strict, - cur_arv_line_reported, - on_art_this_month, - on_original_first_line_this_month, - on_alt_first_line_this_month, - on_second_line_or_higher_this_month, - eligible_for_vl, - days_since_last_vl, - net_12_month_cohort_this_month, - active_on_art_12_month_cohort_this_month, - has_vl_12_month_cohort, - vl_suppressed_12_month_cohort, - has_vl_this_month, - is_suppressed_this_month, - vl_1, - vl_1_date, - vl_in_past_year, - vl_2, - vl_2_date, - qualifies_for_follow_up_vl, - got_follow_up_vl, - got_follow_up_vl_this_month, - num_days_to_follow_vl, - follow_up_vl_suppressed, - follow_up_vl_suppressed_this_month, - follow_up_vl_unsuppressed, - follow_up_vl_unsuppressed_this_month, - due_for_vl_this_month, - reason_for_needing_vl_this_month, - number_of_months_has_needed_vl, - needs_follow_up_vl, - had_med_change_this_month, - had_med_change_this_month_after_2_unsuppressed_vls, - same_meds_this_month_after_2_unsuppressed_vls, - tb_screen, - tb_screening_datetime, - tb_screening_result, - tb_screened_this_visit_this_month, - tb_screened_active_this_month, - presumed_tb_positive_this_month, - tb_tx_start_date, - started_tb_tx_this_month, - on_tb_tx_this_month, - on_tb_tx_and_started_art_this_month, - pcp_prophylaxis_start_date, - started_pcp_prophylaxis_this_month, - on_pcp_prophylaxis_this_month, - ipt_start_date, - ipt_stop_date, - ipt_completion_date, - started_ipt_this_month, - on_ipt_this_month, - completed_ipt_past_12_months, - pregnant_this_month, - is_pregnant_and_started_art_this_month, - delivered_this_month, - condoms_provided_this_month, - condoms_provided_since_active, - started_modern_contraception_this_month, - modern_contraception_since_active, - on_modern_contraception_this_month, - contraceptive_method, - discordant_status + -- elastic_id, + -- endDate, + -- encounter_id, + -- person_id, + -- person_uuid, + -- birthdate, + -- age, + -- gender, + -- encounter_date, + -- visit_this_month, + -- rtc_date, + -- days_since_rtc_date, + -- on_schedule, + -- scheduled_this_month, + -- unscheduled_this_month, + -- f_18_and_over_this_month, + -- prev_location_id, + -- location_id, + -- t2.uuid as location_uuid, + -- next_location_id, + -- t2.state_province as clinic_county, + -- t2.name as clinic, + -- t2.latitude as clinic_latitude, + -- t2.longitude as clinic_longitude, + -- encounter_type, + -- death_date, + -- enrollment_date, + -- enrolled_this_month, + -- transfer_in_this_month, + -- transfer_in_location_id, + -- transfer_in_date, + -- transfer_out_this_month, + -- transfer_out_location_id, + -- transfer_out_date, + -- prev_status, + -- status, + -- next_status, + -- active_in_care_this_month, + -- is_pre_art_this_month, + -- arv_first_regimen_location_id, + -- arv_first_regimen, + -- arv_first_regimen_names, + -- arv_first_regimen_start_date, + -- art_cohort_year, + -- art_cohort_month, + -- art_cohort_num, + -- art_cohort_total_months, + -- days_since_starting_arvs, + -- started_art_this_month, + -- art_revisit_this_month, + -- arv_start_date, + -- prev_month_arvs, + -- prev_month_arvs_names, + -- cur_arv_meds, + -- cur_arv_meds_names, + -- cur_arv_meds_strict, + -- cur_arv_line, + -- cur_arv_line_strict, + -- cur_arv_line_reported, + -- on_art_this_month, + -- on_original_first_line_this_month, + -- on_alt_first_line_this_month, + -- on_second_line_or_higher_this_month, + -- eligible_for_vl, + -- days_since_last_vl, + -- net_12_month_cohort_this_month, + -- active_on_art_12_month_cohort_this_month, + -- has_vl_12_month_cohort, + -- vl_suppressed_12_month_cohort, + -- has_vl_this_month, + -- is_suppressed_this_month, + -- vl_1, + -- vl_1_date, + -- vl_in_past_year, + -- vl_2, + -- vl_2_date, + -- qualifies_for_follow_up_vl, + -- got_follow_up_vl, + -- got_follow_up_vl_this_month, + -- num_days_to_follow_vl, + -- follow_up_vl_suppressed, + -- follow_up_vl_suppressed_this_month, + -- follow_up_vl_unsuppressed, + -- follow_up_vl_unsuppressed_this_month, + -- due_for_vl_this_month, + -- reason_for_needing_vl_this_month, + -- number_of_months_has_needed_vl, + -- needs_follow_up_vl, + -- had_med_change_this_month, + -- had_med_change_this_month_after_2_unsuppressed_vls, + -- same_meds_this_month_after_2_unsuppressed_vls, + -- tb_screen, + -- tb_screening_datetime, + -- tb_screening_result, + -- tb_screened_this_visit_this_month, + -- tb_screened_active_this_month, + -- presumed_tb_positive_this_month, + -- tb_tx_start_date, + -- started_tb_tx_this_month, + -- on_tb_tx_this_month, + -- on_tb_tx_and_started_art_this_month, + -- pcp_prophylaxis_start_date, + -- started_pcp_prophylaxis_this_month, + -- on_pcp_prophylaxis_this_month, + -- ipt_start_date, + -- ipt_stop_date, + -- ipt_completion_date, + -- started_ipt_this_month, + -- on_ipt_this_month, + -- completed_ipt_past_12_months, + -- pregnant_this_month, + -- is_pregnant_and_started_art_this_month, + -- delivered_this_month, + -- condoms_provided_this_month, + -- condoms_provided_since_active, + -- started_modern_contraception_this_month, + -- modern_contraception_since_active, + -- on_modern_contraception_this_month, + -- contraceptive_method, + -- discordant_status from ncd_monthly_report_dataset_2 t1 join amrs.location t2 using (location_id) ); - #delete from @queue_table where person_id in (select person_id from ncd_monthly_report_dataset_build_queue__0); SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join ncd_monthly_report_dataset_build_queue__0 t2 using (person_id);'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; - - #select @person_ids_count := (select count(*) from @queue_table); + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; - #select @person_ids_count as num_remaining; set @cycle_length = timestampdiff(second,@loop_start_time,now()); - #select concat('Cycle time: ',@cycle_length,' seconds'); + set @total_time = @total_time + @cycle_length; set @cycle_number = @cycle_number + 1; - #select ceil(@person_ids_count / cycle_size) as remaining_cycles; set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); - #select concat("Estimated time remaining: ", @remaining_time,' minutes'); # select count(*) into @num_in_hmrd from ncd_monthly_report_dataset; From bbe70a740efedecfd7c2cb67b6e95b294a2db2b6 Mon Sep 17 00:00:00 2001 From: henrykorir Date: Wed, 13 Dec 2023 19:43:04 +0300 Subject: [PATCH 8/9] POC-545: Create a Stored Procedure for the NCD Monthly Report --- ...lat_cdm_v1_1.sql => generate_flat_ncd.sql} | 186 ++-- .../generate_ncd_monthly_report_dataset.sql | 359 ++++---- ...erate_plhiv_ncd_monthly_report_dataset.sql | 265 ------ .../generate_plhiv_ncd_summary.sql | 823 ------------------ 4 files changed, 263 insertions(+), 1370 deletions(-) rename etl-scripts/stored-procedures/{generate_flat_cdm_v1_1.sql => generate_flat_ncd.sql} (85%) delete mode 100644 etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql delete mode 100644 etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql diff --git a/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql b/etl-scripts/stored-procedures/generate_flat_ncd.sql similarity index 85% rename from etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql rename to etl-scripts/stored-procedures/generate_flat_ncd.sql index 85cc2c1..7a21750 100644 --- a/etl-scripts/stored-procedures/generate_flat_cdm_v1_1.sql +++ b/etl-scripts/stored-procedures/generate_flat_ncd.sql @@ -1,10 +1,7 @@ -DELIMITER $$ -CREATE PROCEDURE `generate_flat_cdm_v1_1`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int) +CREATE PROCEDURE `etl`.`generate_flat_ncd_v1_1`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int) BEGIN - set @primary_table := "flat_cdm_v1"; + set @primary_table := "flat_ncd"; set @query_type = query_type; -#set @query_type = "build"; - set @total_rows_written = 0; @@ -14,7 +11,7 @@ BEGIN set @other_encounter_types = "(-1)"; set @start = now(); - set @table_version = "flat_cdm_v1.1"; + set @table_version = "flat_ncd_v1.0"; set session sort_buffer_size=512000000; @@ -22,7 +19,7 @@ BEGIN set @boundary = "!!"; set @last_date_created = (select max(max_date_created) from etl.flat_obs); - create table if not exists flat_cdm_v1 ( + create table if not exists flat_ncd ( date_created TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, person_id int, uuid varchar(100), @@ -80,17 +77,18 @@ BEGIN prev_hbp_findings text, type_of_follow_up text, review_of_med_history text, + psychiatric_exam_findings text, - prev_encounter_datetime_cdm datetime, - next_encounter_datetime_cdm datetime, - prev_encounter_type_cdm mediumint, - next_encounter_type_cdm mediumint, - prev_clinical_datetime_cdm datetime, - next_clinical_datetime_cdm datetime, - prev_clinical_location_id_cdm mediumint, - next_clinical_location_id_cdm mediumint, - prev_clinical_rtc_date_cdm datetime, - next_clinical_rtc_date_cdm datetime, + prev_encounter_datetime_ncd datetime, + next_encounter_datetime_ncd datetime, + prev_encounter_type_ncd mediumint, + next_encounter_type_ncd mediumint, + prev_clinical_datetime_ncd datetime, + next_clinical_datetime_ncd datetime, + prev_clinical_location_id_ncd mediumint, + next_clinical_location_id_ncd mediumint, + prev_clinical_rtc_date_ncd datetime, + next_clinical_rtc_date_ncd datetime, primary key encounter_id (encounter_id), index person_date (person_id, encounter_datetime), @@ -99,7 +97,7 @@ BEGIN index enc_date_location (encounter_datetime, location_uuid), index location_id_rtc_date (location_id,rtc_date), index location_uuid_rtc_date (location_uuid,rtc_date), - index loc_id_enc_date_next_clinical (location_id, encounter_datetime, next_clinical_datetime_cdm), + index loc_id_enc_date_next_clinical (location_id, encounter_datetime, next_clinical_datetime_ncd), index encounter_type (encounter_type), index date_created (date_created) @@ -110,8 +108,8 @@ BEGIN if(@query_type="build") then select 'BUILDING..........................................'; - set @write_table = concat("flat_cdm_temp_",queue_number); - set @queue_table = concat("flat_cdm_build_queue_",queue_number); + set @write_table = concat("flat_ncd_temp_",queue_number); + set @queue_table = concat("flat_ncd_build_queue_",queue_number); SET @dyn_sql=CONCAT('Create table if not exists ',@write_table,' like ',@primary_table); @@ -119,12 +117,12 @@ BEGIN EXECUTE s1; DEALLOCATE PREPARE s1; - SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from flat_cdm_build_queue limit ', queue_size, ');'); + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from flat_ncd_build_queue limit ', queue_size, ');'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; - SET @dyn_sql=CONCAT('delete t1 from flat_cdm_build_queue t1 join ',@queue_table, ' t2 using (person_id);'); + SET @dyn_sql=CONCAT('delete t1 from flat_ncd_build_queue t1 join ',@queue_table, ' t2 using (person_id);'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; @@ -134,9 +132,9 @@ BEGIN if (@query_type="sync") then select 'SYNCING..........................................'; - set @write_table = "flat_cdm_v1"; - set @queue_table = "flat_cdm_sync_queue"; - create table if not exists flat_cdm_sync_queue (person_id int primary key); + set @write_table = "flat_ncd_v1"; + set @queue_table = "flat_ncd_sync_queue"; + create table if not exists flat_ncd_sync_queue (person_id int primary key); @@ -144,37 +142,37 @@ BEGIN select max(date_updated) into @last_update from etl.flat_log where table_name=@table_version; - replace into flat_cdm_sync_queue + replace into flat_ncd_sync_queue (select distinct patient_id from amrs.encounter where date_changed > @last_update ); - replace into flat_cdm_sync_queue + replace into flat_ncd_sync_queue (select distinct person_id from etl.flat_obs where max_date_created > @last_update ); - replace into flat_cdm_sync_queue + replace into flat_ncd_sync_queue (select distinct person_id from etl.flat_lab_obs where max_date_created > @last_update ); - replace into flat_cdm_sync_queue + replace into flat_ncd_sync_queue (select distinct person_id from etl.flat_orders where max_date_created > @last_update ); - replace into flat_cdm_sync_queue + replace into flat_ncd_sync_queue (select person_id from amrs.person where date_voided > @last_update); - replace into flat_cdm_sync_queue + replace into flat_ncd_sync_queue (select person_id from amrs.person where date_changed > @last_update); @@ -246,9 +244,9 @@ BEGIN set @loop_start_time = now(); #create temp table with a set of person ids - drop temporary table if exists flat_cdm_build_queue__0; + drop temporary table if exists flat_ncd_build_queue__0; - SET @dyn_sql=CONCAT('create temporary table flat_cdm_build_queue__0 (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); + SET @dyn_sql=CONCAT('create temporary table flat_ncd_build_queue__0 (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; @@ -257,9 +255,9 @@ BEGIN - drop temporary table if exists flat_cdm_0a; + drop temporary table if exists flat_ncd_0a; SET @dyn_sql = CONCAT( - 'create temporary table flat_cdm_0a + 'create temporary table flat_ncd_0a (select t1.person_id, t1.visit_id, @@ -282,7 +280,7 @@ BEGIN end as encounter_type_sort_index, t2.orders from etl.flat_obs t1 - join flat_cdm_build_queue__0 t0 using (person_id) + join flat_ncd_build_queue__0 t0 using (person_id) left join etl.flat_orders t2 using(encounter_id) where t1.encounter_type in ',@encounter_types,');'); @@ -291,7 +289,7 @@ BEGIN DEALLOCATE PREPARE s1; - insert into flat_cdm_0a + insert into flat_ncd_0a (select t1.person_id, null, @@ -306,12 +304,12 @@ BEGIN 1 as encounter_type_sort_index, null from etl.flat_lab_obs t1 - join flat_cdm_build_queue__0 t0 using (person_id) + join flat_ncd_build_queue__0 t0 using (person_id) ); - drop temporary table if exists flat_cdm_0; - create temporary table flat_cdm_0(index encounter_id (encounter_id), index person_enc (person_id,encounter_datetime)) - (select * from flat_cdm_0a + drop temporary table if exists flat_ncd_0; + create temporary table flat_ncd_0(index encounter_id (encounter_id), index person_enc (person_id,encounter_datetime)) + (select * from flat_ncd_0a order by person_id, date(encounter_datetime), encounter_type_sort_index ); @@ -333,8 +331,8 @@ BEGIN # screened for cervical ca # exposed infant - drop temporary table if exists flat_cdm_1; - create temporary table flat_cdm_1 (index encounter_id (encounter_id)) + drop temporary table if exists flat_ncd_1; + create temporary table flat_ncd_1 (index encounter_id (encounter_id)) (select obs, encounter_type_sort_index, @@ -440,13 +438,28 @@ BEGIN @dm_status := etl.GetValues(obs,7287) as dm_status, @htn_status := etl.GetValues(obs,7288) as htn_status, - @dm_meds := etl.GetValues(obs,7290) as dm_meds, - @htn_meds := etl.GetValues(obs,10241) as htn_meds, - t2.prescriptions as prescriptions, - - @problems := concat(etl.GetValues(obs,6042 ), ' ## ', etl.GetValues(obs,11679), ' ## ', etl.GetValues(obs,6796)) as problems, + @dm_meds := concat_ws(' ## ', + etl.GetValues(obs,7290), + etl.GetValues(obs,7304) + ) as dm_meds, + @htn_meds := concat_ws(' ## ', + etl.GetValues(obs,7291), + etl.GetValues(obs,7332), + etl.GetValues(obs,10241) + ) as htn_meds, + + t2.prescriptions as prescriptions, + + @problems := concat_ws(' ## ', + etl.GetValues(obs,6042 ), + etl.GetValues(obs,11679), + etl.GetValues(obs,6796), + etl.GetValues(obs,2072), + etl.GetValues(obs,6097), + etl.GetValues(obs,6461) + ) as problems, @comorbidities := etl.GetValues(obs,10239 ) as comorbidities, - @rheumatologic_disorder := etl.GetValues(obs,12293) as rheumatologic_disorder + @rheumatologic_disorder := etl.GetValues(obs,12293) as rheumatologic_disorder, @kidney_disease := etl.GetValues(obs, 6033) as kidney_disease, @ckd_staging := etl.GetValues(obs,10101) as ckd_staging, @cardiovascular_disorder := etl.GetValues(obs, 7971) as cardiovascular_disorder, @@ -460,9 +473,9 @@ BEGIN @prev_hbp_findings := etl.GetValues(obs, 9092) as prev_hbp_findings, @type_of_follow_up := etl.GetValues(obs, 2332) as type_of_follow_up, @review_of_med_history := etl.GetValues(obs, 6245) as review_of_med_history, - @psychiatric_exam_findings := etl.GetValues(obs, 6245) as review_of_med_history + @psychiatric_exam_findings := etl.GetValues(obs, 1130) as psychiatric_exam_findings - from flat_cdm_0 t1 + from flat_ncd_0 t1 join amrs.person p using (person_id) left outer join prescriptions t2 using (encounter_id) ); @@ -483,10 +496,10 @@ BEGIN set @cur_clinical_location_id = null; - alter table flat_cdm_1 drop prev_id, drop cur_id; + alter table flat_ncd_1 drop prev_id, drop cur_id; - drop table if exists flat_cdm_2; - create temporary table flat_cdm_2 + drop table if exists flat_ncd_2; + create temporary table flat_ncd_2 (select *, @prev_id := @cur_id as prev_id, @cur_id := person_id as cur_id, @@ -494,26 +507,26 @@ BEGIN case when @prev_id = @cur_id then @prev_encounter_datetime := @cur_encounter_datetime else @prev_encounter_datetime := null - end as next_encounter_datetime_cdm, + end as next_encounter_datetime_ncd, @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, case when @prev_id=@cur_id then @next_encounter_type := @cur_encounter_type else @next_encounter_type := null - end as next_encounter_type_cdm, + end as next_encounter_type_ncd, @cur_encounter_type := encounter_type as cur_encounter_type, case when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime else @prev_clinical_datetime := null - end as next_clinical_datetime_cdm, + end as next_clinical_datetime_ncd, case when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id else @prev_clinical_location_id := null - end as next_clinical_location_id_cdm, + end as next_clinical_location_id_ncd, case when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime @@ -530,7 +543,7 @@ BEGIN case when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date else @prev_clinical_rtc_date := null - end as next_clinical_rtc_date_cdm, + end as next_clinical_rtc_date_ncd, case when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date @@ -538,11 +551,11 @@ BEGIN else @cur_clinical_rtc_date:= null end as cur_clinical_rtc_date - from flat_cdm_1 + from flat_ncd_1 order by person_id, date(encounter_datetime) desc, encounter_type_sort_index desc ); - alter table flat_cdm_2 drop prev_id, drop cur_id, drop cur_encounter_type, drop cur_encounter_datetime, drop cur_clinical_rtc_date; + alter table flat_ncd_2 drop prev_id, drop cur_id, drop cur_encounter_type, drop cur_encounter_datetime, drop cur_clinical_rtc_date; set @prev_id = null; @@ -556,8 +569,8 @@ BEGIN set @prev_clinical_location_id = null; set @cur_clinical_location_id = null; - drop temporary table if exists flat_cdm_3; - create temporary table flat_cdm_3 (prev_encounter_datetime datetime, prev_encounter_type int, index person_enc (person_id, encounter_datetime desc)) + drop temporary table if exists flat_ncd_3; + create temporary table flat_ncd_3 (prev_encounter_datetime datetime, prev_encounter_type int, index person_enc (person_id, encounter_datetime desc)) (select *, @prev_id := @cur_id as prev_id, @@ -566,25 +579,25 @@ BEGIN case when @prev_id=@cur_id then @prev_encounter_type := @cur_encounter_type else @prev_encounter_type:=null - end as prev_encounter_type_cdm, + end as prev_encounter_type_ncd, @cur_encounter_type := encounter_type as cur_encounter_type, case when @prev_id=@cur_id then @prev_encounter_datetime := @cur_encounter_datetime else @prev_encounter_datetime := null - end as prev_encounter_datetime_cdm, + end as prev_encounter_datetime_ncd, @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, case when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime else @prev_clinical_datetime := null - end as prev_clinical_datetime_cdm, + end as prev_clinical_datetime_ncd, case when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id else @prev_clinical_location_id := null - end as prev_clinical_location_id_cdm, + end as prev_clinical_location_id_ncd, case when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime @@ -601,7 +614,7 @@ BEGIN case when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date else @prev_clinical_rtc_date := null - end as prev_clinical_rtc_date_cdm, + end as prev_clinical_rtc_date_ncd, case when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date @@ -609,13 +622,13 @@ BEGIN else @cur_clinical_rtc_date:= null end as cur_clinic_rtc_date - from flat_cdm_2 t1 + from flat_ncd_2 t1 order by person_id, date(encounter_datetime), encounter_type_sort_index ); - select count(*) into @new_encounter_rows from flat_cdm_3; + select count(*) into @new_encounter_rows from flat_ncd_3; select @new_encounter_rows; set @total_rows_written = @total_rows_written + @new_encounter_rows; @@ -674,19 +687,20 @@ BEGIN prev_hbp_findings, type_of_follow_up, review_of_med_history, + psychiatric_exam_findings, - prev_encounter_datetime_cdm, - next_encounter_datetime_cdm, - prev_encounter_type_cdm, - next_encounter_type_cdm, - prev_clinical_datetime_cdm, - next_clinical_datetime_cdm, - prev_clinical_location_id_cdm, - next_clinical_location_id_cdm, - prev_clinical_rtc_date_cdm, - next_clinical_rtc_date_cdm + prev_encounter_datetime_ncd, + next_encounter_datetime_ncd, + prev_encounter_type_ncd, + next_encounter_type_ncd, + prev_clinical_datetime_ncd, + next_clinical_datetime_ncd, + prev_clinical_location_id_ncd, + next_clinical_location_id_ncd, + prev_clinical_rtc_date_ncd, + next_clinical_rtc_date_ncd - from flat_cdm_3 t1 + from flat_ncd_3 t1 join amrs.location t2 using (location_id))'); PREPARE s1 from @dyn_sql; @@ -694,16 +708,15 @@ BEGIN DEALLOCATE PREPARE s1; - #delete from @queue_table where person_id in (select person_id from flat_cdm_build_queue__0); + #delete from @queue_table where person_id in (select person_id from flat_ncd_build_queue__0); - SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join flat_cdm_build_queue__0 t2 using (person_id);'); -# select @dyn_sql; + SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join flat_ncd_build_queue__0 t2 using (person_id);'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; - #select @person_ids_count := (select count(*) from flat_cdm_build_queue_2); + #select @person_ids_count := (select count(*) from flat_ncd_build_queue_2); SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); PREPARE s1 from @dyn_sql; EXECUTE s1; @@ -765,5 +778,4 @@ BEGIN insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); select concat(@table_version," : Time to complete: ",timestampdiff(minute, @start, @end)," minutes"); - END$$ -DELIMITER ; + END \ No newline at end of file diff --git a/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql index 45fddb9..d1eceab 100644 --- a/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql +++ b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql @@ -1,5 +1,5 @@ DELIMITER $$ -CREATE PROCEDURE `generate_ncd_monthly_report_dataset`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int, IN start_date varchar(50)) +CREATE CREATE DEFINER=`hkorir`@`%` PROCEDURE `generate_ncd_monthly_report_dataset`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int, IN start_date varchar(50)) BEGIN set @start = now(); @@ -11,7 +11,7 @@ BEGIN set @death_encounter_type = 31; -create table if not exists ncd_monthly_report_dataset ( + create table if not exists ncd_monthly_report_dataset ( date_created timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP NOT NULL, elastic_id bigint, endDate date, @@ -23,6 +23,7 @@ create table if not exists ncd_monthly_report_dataset ( gender varchar(1), location_id int, location_uuid varchar(100), + clinic varchar(250), encounter_date date, visit_this_month tinyint, @@ -52,6 +53,8 @@ create table if not exists ncd_monthly_report_dataset ( has_stroke tinyint, is_stroke_haemorrhagic tinyint, is_stroke_ischaemic tinyint, + + has_migraine tinyint, has_seizure tinyint, has_epilepsy tinyint, has_convulsive_disorder tinyint, @@ -67,7 +70,6 @@ create table if not exists ncd_monthly_report_dataset ( index endDate_location_id (endDate, location_id), index date_created (date_created), index status_change (location_id, endDate, status, prev_status) - ); if (query_type = "build") then @@ -152,25 +154,6 @@ create table if not exists ncd_monthly_report_dataset ( date(encounter_datetime) as encounter_date, if(encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate,1,0) as visit_this_month, - - date(rtc_date) as rtc_date, - timestampdiff(day,rtc_date, endDate) as days_since_rtc_date, - - if(date(encounter_datetime) = date(prev_clinical_rtc_date_hiv),1,0) as on_schedule, - - case - when encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate - AND date(encounter_datetime) = date(prev_clinical_rtc_date_hiv) - then 1 - else 0 - end as scheduled_this_month, - - case - when encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate - AND date(encounter_datetime) != date(prev_clinical_rtc_date_hiv) - then 1 - else 0 - end as unscheduled_this_month, case when arv_first_regimen_location_id != 9999 @@ -183,11 +166,11 @@ create table if not exists ncd_monthly_report_dataset ( case when htn_status = 7285 or htn_status = 7286 then 1 - when (comorbidities regexp '903') then 1 - when (prev_hbp_findings regexp '1065') then 1 + when (comorbidities regexp '[[:<:]]903[[:>:]]') then 1 + when (prev_hbp_findings regexp '[[:<:]]1065[[:>:]]') then 1 when (htn_meds is not null) then 1 - when (problems regexp '903') then 1 - when (review_of_med_history regexp '903') then 1 + when (problems regexp '[[:<:]]903[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]903[[:>:]]') then 1 else null end as is_hypertensive, @@ -200,11 +183,10 @@ create table if not exists ncd_monthly_report_dataset ( case when dm_status = 7281 or dm_status = 7282 then 1 - when (comorbidities regexp '175') then 1 + when (comorbidities regexp '[[:<:]]175[[:>:]]') then 1 when (dm_meds is not null) then 1 - when (problems regexp '9324') or (problems regexp '175') then 1 - when (problems regexp '175') then 1 - when (review_of_med_history regexp '175') then 1 + when (problems regexp '[[:<:]]9324|175[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]175[[:>:]]') then 1 else null end as is_diabetic, @@ -216,41 +198,44 @@ create table if not exists ncd_monthly_report_dataset ( end as dm_state, case - when (comorbidities regexp '10860') then 1 + when (comorbidities regexp '[[:<:]]10860[[:>:]]') then 1 when (indicated_mhd_tx is not null) then 1 when (has_past_mhd_tx = '1065') then 1 - when (review_of_med_history regexp '(77)|(207)') then 1 + when (review_of_med_history regexp '[[:<:]]77|207[[:>:]]') then 1 when (eligible_for_depression_care = '1065') then 1 when (mood_disorder is not null) then 1 when (anxiety_condition is not null) then 1 + when (psychiatric_exam_findings is not null) then 1 else null end as has_mhd, case when (eligible_for_depression_care = '1065') then 1 - when (mood_disorder regexp '11278') then 1 - when (indicated_mhd_tx regexp '207') then 1 - when (review_of_med_history regexp '207') then 1 + when (mood_disorder regexp '[[:<:]]11278[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]207[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]207[[:>:]]') then 1 + when (psychiatric_exam_findings regexp '[[:<:]]207[[:>:]]') then 1 else null end as is_depressive_mhd, case when (anxiety_condition is not null) then 1 - when (indicated_mhd_tx regexp '1443') then 1 - when (review_of_med_history regexp '207') then 1 + when (indicated_mhd_tx regexp '[[:<:]]1443[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]207[[:>:]]') then 1 + when (psychiatric_exam_findings regexp '[[:<:]]1443[[:>:]]') then 1 else null end as is_anxiety_mhd, case - when (mood_disorder regexp '7763') then 1 - when (indicated_mhd_tx regexp '7763') then 1 + when (mood_disorder regexp '[[:<:]]7763[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]7763[[:>:]]') then 1 else null end as is_bipolar_and_related_mhd, case - when (mood_disorder regexp '7763') then 1 - when (indicated_mhd_tx regexp '11281') then 1 - when (problems regexp '467') then 1 + when (mood_disorder regexp '[[:<:]]7763[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]11281[[:>:]]') then 1 + when (problems regexp '[[:<:]]467[[:>:]]') then 1 else null end as is_personality_mhd, @@ -261,14 +246,14 @@ create table if not exists ncd_monthly_report_dataset ( case when (comorbidities regexp '[[:<:]]77[[:>:]]') then 1 when (kidney_disease = '[[:<:]]1065[[:>:]]') then 1 - when (problems regexp '[[:<:]]8078[[:>:]]|[[:<:]]11684[[:>:]]') then 1 - when (review_of_med_history regexp '(6033)|(8078)') then 1 + when (problems regexp '[[:<:]]8078|11684[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]6033|8078[[:>:]]') then 1 else null end as has_kd, case - when (problems regexp '8078') then 1 - when (review_of_med_history regexp '8078') then 1 + when (problems regexp '[[:<:]]8078[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]8078[[:>:]]') then 1 when (ckd_staging is not null) then 1 else null end as is_ckd, @@ -277,34 +262,34 @@ create table if not exists ncd_monthly_report_dataset ( case when (cardiovascular_disorder is not null) then 1 - when (comorbidities regexp '7971') then 1 - when (review_of_med_history regexp '(7971)|(6237)') then 1 + when (comorbidities regexp '[[:<:]]7971[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]7971|6237[[:>:]]') then 1 else null end as has_cvd, case - when (cardiovascular_disorder regexp '1456') then 1 - when (indicated_mhd_tx regexp '1456') then 1 - when (review_of_med_history regexp '7971') then 1 + when (cardiovascular_disorder regexp '[[:<:]]1456[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]1456[[:>:]]') then 1 + when (review_of_med_history regexp '[[:7971') then 1 else null end as is_heart_failure_cvd, - + case - when (neurological_disease is not null) then 1 - when (indicated_mhd_tx regexp '1456') then 1 - when (review_of_med_history regexp '7971') then 1 + when (cardiovascular_disorder regexp '[[:<:]]1535[[:>:]]') then 1 else null - end as has_neurological_disorder, + end as is_myocardinal_infarction, case - when (cardiovascular_disorder regexp '1535') then 1 + when (neurological_disease is not null) then 1 + when (indicated_mhd_tx regexp '[[:<:]]1456[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]7971[[:>:]]') then 1 else null - end as is_myocardinal_infarction, + end as has_neurological_disorder, case - when (cardiovascular_disorder regexp '1878') then 1 - when (indicated_mhd_tx regexp '1456') then 1 - when (review_of_med_history regexp '7971') then 1 + when (cardiovascular_disorder regexp '[[:<:]]1878[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]1456[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]7971[[:>:]]') then 1 else null end as has_stroke, @@ -312,10 +297,51 @@ create table if not exists ncd_monthly_report_dataset ( null as is_stroke_ischaemic, - null as + case + when (problems regexp '[[:<:]]1477[[:>:]]') then 1 + when (neurological_disease regexp '[[:<:]]1477[[:>:]]') then 1 + else null + end as has_migraine, + + case + when (problems regexp '[[:<:]]206[[:>:]]') then 1 + when (neurological_disease regexp '[[:<:]]206[[:>:]]') then 1 + when (convulsive_disorder regexp '[[:<:]]206[[:>:]]') then 1 + else null + end as has_seizure, + + case + when (problems regexp '[[:<:]]155|11687[[:>:]]') then 1 + when (neurological_disease regexp '[[:<:]]155[[:>:]]') then 1 + when (convulsive_disorder regexp '[[:<:]]155[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]155[[:>:]]') then 1 + else null + end as has_epilepsy, + + case + when (neurological_disease regexp '[[:<:]]10806[[:>:]]') then 1 + when (convulsive_disorder regexp '[[:<:]]155|10806[[:>:]]') then 1 + else null + end as has_convulsive_disorder, + + case + when (rheumatologic_disorder is not null) then 1 + when (comorbidities regexp '[[:<:]]12293[[:>:]]') then 1 + else null + end as has_rheumatologic_disorder, + + case + when (rheumatologic_disorder regexp '[[:<:]]116[[:>:]]') then 1 + else null + end as has_arthritis, + + case + when (rheumatologic_disorder regexp '[[:<:]]12292[[:>:]]') then 1 + else null + end as has_SLE from etl.dates t1 - join etl.flat_cdm_v1 t2 + join etl.flat_ncd t2 join amrs.person t3 using (person_id) join etl.ncd_monthly_report_dataset_build_queue__0 t5 using (person_id) @@ -329,8 +355,6 @@ create table if not exists ncd_monthly_report_dataset ( set @prev_id = null; set @cur_id = null; - set @cur_status = null; - set @prev_status = null; set @prev_location_id = null; set @cur_location_id = null; @@ -348,15 +372,33 @@ create table if not exists ncd_monthly_report_dataset ( @cur_location_id := location_id as cur_location_id, - case - when @prev_id=@cur_id then @prev_status := @cur_status - else @prev_status := null - end as next_status, - @cur_status := status as cur_status - from ncd_monthly_report_dataset_0 order by person_id, endDate desc ); + + alter table ncd_monthly_report_dataset_1 drop prev_id, drop cur_id; + + set @prev_id = null; + set @cur_id = null; + set @cur_location_id = null; + set @prev_location_id = null; + drop temporary table if exists hiv_monthly_report_dataset_2; + create temporary table hiv_monthly_report_dataset_2 + (select + *, + @prev_id := @cur_id as prev_id, + @cur_id := person_id as cur_id, + + case + when @prev_id=@cur_id then @prev_location_id := @cur_location_id + else @prev_location_id := null + end as prev_location_id, + + @cur_location_id := location_id as cur_location_id + + from ncd_monthly_report_dataset_1 + order by person_id, endDate + ); select now(); select count(*) as num_rows_to_be_inserted from ncd_monthly_report_dataset_2; @@ -365,132 +407,61 @@ create table if not exists ncd_monthly_report_dataset ( replace into ncd_monthly_report_dataset (select null, #date_created will be automatically set or updated - -- elastic_id, - -- endDate, - -- encounter_id, - -- person_id, - -- person_uuid, - -- birthdate, - -- age, - -- gender, - -- encounter_date, - -- visit_this_month, - -- rtc_date, - -- days_since_rtc_date, - -- on_schedule, - -- scheduled_this_month, - -- unscheduled_this_month, - -- f_18_and_over_this_month, - -- prev_location_id, - -- location_id, - -- t2.uuid as location_uuid, - -- next_location_id, - -- t2.state_province as clinic_county, - -- t2.name as clinic, - -- t2.latitude as clinic_latitude, - -- t2.longitude as clinic_longitude, - -- encounter_type, - -- death_date, - -- enrollment_date, - -- enrolled_this_month, - -- transfer_in_this_month, - -- transfer_in_location_id, - -- transfer_in_date, - -- transfer_out_this_month, - -- transfer_out_location_id, - -- transfer_out_date, - -- prev_status, - -- status, - -- next_status, - -- active_in_care_this_month, - -- is_pre_art_this_month, - -- arv_first_regimen_location_id, - -- arv_first_regimen, - -- arv_first_regimen_names, - -- arv_first_regimen_start_date, - -- art_cohort_year, - -- art_cohort_month, - -- art_cohort_num, - -- art_cohort_total_months, - -- days_since_starting_arvs, - -- started_art_this_month, - -- art_revisit_this_month, - -- arv_start_date, - -- prev_month_arvs, - -- prev_month_arvs_names, - -- cur_arv_meds, - -- cur_arv_meds_names, - -- cur_arv_meds_strict, - -- cur_arv_line, - -- cur_arv_line_strict, - -- cur_arv_line_reported, - -- on_art_this_month, - -- on_original_first_line_this_month, - -- on_alt_first_line_this_month, - -- on_second_line_or_higher_this_month, - -- eligible_for_vl, - -- days_since_last_vl, - -- net_12_month_cohort_this_month, - -- active_on_art_12_month_cohort_this_month, - -- has_vl_12_month_cohort, - -- vl_suppressed_12_month_cohort, - -- has_vl_this_month, - -- is_suppressed_this_month, - -- vl_1, - -- vl_1_date, - -- vl_in_past_year, - -- vl_2, - -- vl_2_date, - -- qualifies_for_follow_up_vl, - -- got_follow_up_vl, - -- got_follow_up_vl_this_month, - -- num_days_to_follow_vl, - -- follow_up_vl_suppressed, - -- follow_up_vl_suppressed_this_month, - -- follow_up_vl_unsuppressed, - -- follow_up_vl_unsuppressed_this_month, - -- due_for_vl_this_month, - -- reason_for_needing_vl_this_month, - -- number_of_months_has_needed_vl, - -- needs_follow_up_vl, - -- had_med_change_this_month, - -- had_med_change_this_month_after_2_unsuppressed_vls, - -- same_meds_this_month_after_2_unsuppressed_vls, - -- tb_screen, - -- tb_screening_datetime, - -- tb_screening_result, - -- tb_screened_this_visit_this_month, - -- tb_screened_active_this_month, - -- presumed_tb_positive_this_month, - -- tb_tx_start_date, - -- started_tb_tx_this_month, - -- on_tb_tx_this_month, - -- on_tb_tx_and_started_art_this_month, - -- pcp_prophylaxis_start_date, - -- started_pcp_prophylaxis_this_month, - -- on_pcp_prophylaxis_this_month, - -- ipt_start_date, - -- ipt_stop_date, - -- ipt_completion_date, - -- started_ipt_this_month, - -- on_ipt_this_month, - -- completed_ipt_past_12_months, - -- pregnant_this_month, - -- is_pregnant_and_started_art_this_month, - -- delivered_this_month, - -- condoms_provided_this_month, - -- condoms_provided_since_active, - -- started_modern_contraception_this_month, - -- modern_contraception_since_active, - -- on_modern_contraception_this_month, - -- contraceptive_method, - -- discordant_status + elastic_id, + endDate, + encounter_id, + person_id, + person_uuid, + birthdate, + age, + gender, + location_id, + location_uuid, + t2.name as clinic + encounter_date, + visit_this_month, + + is_hypertensive, + htn_state, + + is_diabetic, + dm_state, + + has_mhd, + is_depressive_mhd, + is_anxiety_mhd, + is_bipolar_and_related_mhd, + is_personality_mhd, + is_feeding_and_eating_mhd, + is_ocd_mhd, + + has_kd, + is_ckd, + ckd_stage, + + has_cvd, + is_heart_failure_cvd, + is_myocardinal_infarction, + + has_neurological_disorder, + has_stroke, + is_stroke_haemorrhagic, + is_stroke_ischaemic, + + has_migraine, + has_seizure, + has_epilepsy, + has_convulsive_disorder, + + has_rheumatologic_disorder, + has_arthritis, + has_SLE + from ncd_monthly_report_dataset_2 t1 join amrs.location t2 using (location_id) ); - SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join ncd_monthly_report_dataset_build_queue__0 t2 using (person_id);'); PREPARE s1 from @dyn_sql; EXECUTE s1; @@ -509,9 +480,7 @@ create table if not exists ncd_monthly_report_dataset ( set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); -# select count(*) into @num_in_hmrd from ncd_monthly_report_dataset; - - select @num_in_hmrd as num_in_hmrd, + select @num_in_nmrd as num_in_nmrd, @person_ids_count as num_remaining, @cycle_length as 'Cycle time (s)', ceil(@person_ids_count / cycle_size) as remaining_cycles, diff --git a/etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql b/etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql deleted file mode 100644 index 6266644..0000000 --- a/etl-scripts/stored-procedures/generate_plhiv_ncd_monthly_report_dataset.sql +++ /dev/null @@ -1,265 +0,0 @@ -DELIMITER $$ -CREATE PROCEDURE `generate_plhiv_ncd_monthly_report_dataset`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int , IN log boolean) -BEGIN - select @start := now(); - select @table_version := "plhiv_ncd_monthly_report_dataset"; - set @primary_table := "plhiv_ncd_monthly_report_dataset"; - set @query_type = query_type; - - set @total_rows_written = 0; - - set session sort_buffer_size=512000000; - - select @sep := " ## "; - select @last_date_created := (select max(max_date_created) from etl.flat_obs); - - CREATE TABLE IF NOT EXISTS `plhiv_ncd_monthly_report_dataset` ( - `elastic_id` varchar(21) NOT NULL DEFAULT '', - `location_id` bigint(60) DEFAULT NULL, - `person_id` int(11) DEFAULT NULL, - `person_uuid` char(38) CHARACTER SET utf8 NOT NULL, - `birthdate` date DEFAULT NULL, - `death_date` longtext CHARACTER SET utf8, - `age` decimal(23,2) DEFAULT NULL, - `gender` varchar(50) CHARACTER SET utf8 DEFAULT '', - `encounter_id` int(11) NOT NULL DEFAULT '0', - `encounter_datetime` datetime DEFAULT NULL, - `encounter_month` int(6) DEFAULT NULL, - `endDate` date DEFAULT NULL, - `prev_rtc_date` longtext, - `prev_rtc_month` int(6) DEFAULT NULL, - `rtc_date` varchar(10) CHARACTER SET utf8 DEFAULT NULL, - `rtc_month` int(6) DEFAULT NULL, - `visit_this_month` int(3) DEFAULT NULL, - `appointment_this_month` int(3) DEFAULT NULL, - `scheduled_visit_this_month` int(1) NOT NULL DEFAULT '0', - `early_appointment_this_month` int(1) NOT NULL DEFAULT '0', - `late_appointment_this_month` int(1) NOT NULL DEFAULT '0', - `missed_appointment_this_month` int(1) NOT NULL DEFAULT '0', - `days_since_rtc_date` varchar(23) CHARACTER SET utf8 DEFAULT NULL, - `has_comorbidity` TINYINT(1), - `has_mental_disorder_comorbidity` TINYINT(1), - `has_diabetic_comorbidity` TINYINT(1), - `has_hypertension_comorbidity` TINYINT(1), - `has_other_comorbidity` TINYINT(1), - PRIMARY KEY (`elastic_id`), - KEY `person_id` (`person_id`), - KEY `person_id_2` (`person_id`,`endDate`), - KEY `endDate` (`endDate`), - KEY `location_id` (`location_id`,`endDate`), - KEY `encounter_datetime` (`encounter_datetime`) - ) ENGINE=InnoDB DEFAULT CHARSET=latin1; - - - if(@query_type="build") then - select 'BUILDING..........................................'; - set @write_table = concat("plhiv_ncd_monthly_report_temp_",queue_number); - set @queue_table = concat("plhiv_ncd_monthly_report_build_queue_",queue_number); - - SET @dyn_sql=CONCAT('Create table if not exists ',@write_table,' like ',@primary_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @dyn_sql=CONCAT('drop table if exists ',@queue_table,';'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select person_id from plhiv_ncd_monthly_report_build_queue limit ', queue_size, ');'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @dyn_sql=CONCAT('delete t1 from plhiv_ncd_monthly_report_build_queue t1 join ',@queue_table, ' t2 on (t1.person_id = t2.person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - end if; - - # Display the important tables names - select @queue_table; - select @primary_table; - select @write_table; - - # Remove test patients - SET @dyn_sql=CONCAT('delete t1 FROM ',@queue_table,' t1 - join amrs.person_attribute t2 using (person_id) - where t2.person_attribute_type_id=28 and value="true" and voided=0'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @dyn_sql=CONCAT('select count(*) as queue_size from ',@queue_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @person_ids_count = 0; - SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - select @person_ids_count as 'num patients to sync'; - - - SET @dyn_sql=CONCAT('delete t1 from ',@primary_table, ' t1 join ',@queue_table,' t2 using (person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - set @total_time=0; - set @cycle_number = 0; - while @person_ids_count > 0 do - - set @loop_start_time = now(); - - drop temporary table if exists plhiv_ncd_monthly_report_temp_queue; - SET @dyn_sql=CONCAT('create temporary table plhiv_ncd_monthly_report_temp_queue (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - drop temporary table if exists plhiv_ncd_summary_in_queue; - create temporary table plhiv_ncd_summary_in_queue - (index (person_id), index(person_id, encounter_datetime), index(encounter_id), index(encounter_datetime), index(rtc_date)) - (select * - from - etl.plhiv_ncd_summary_v1 - where - encounter_datetime >= '2018-01-01' - order by person_id, encounter_datetime - ); - - drop table if exists plhiv_ncd_patient_encounters; - create table plhiv_ncd_patient_encounters - (index (person_id), index(person_id, endDate, encounter_id)) - ( - select - * - from ( - select - * - from etl.dates m - join plhiv_ncd_summary_in_queue h - WHERE h.encounter_datetime < DATE_ADD(endDate, INTERVAL 1 DAY) - and m.endDate BETWEEN '2018-01-01' AND DATE_ADD(now(), INTERVAL 2 YEAR) - ORDER BY h.person_id , month(endDate), h.encounter_datetime desc , rtc_date - ) p - group by person_id, month(endDate) - ); - - - drop temporary table if exists stage_1; - create temporary table stage_1 - ( - primary key elastic_id (elastic_id), - index (person_id), - index (person_id, endDate), - index(endDate), - index(location_id, endDate), - index(encounter_datetime)) - (SELECT - concat(month(endDate), t1.person_id) as elastic_id, - location_id, - t1.person_id, - t1.uuid AS person_uuid, - DATE(t1.birthdate) AS birthdate, - t1.death_date, - CASE - WHEN - TIMESTAMPDIFF(YEAR, t1.birthdate, endDate) > 0 - THEN - @age:=ROUND(TIMESTAMPDIFF(YEAR, t1.birthdate, endDate), - 0) - ELSE @age:=ROUND(TIMESTAMPDIFF(MONTH, - t1.birthdate, - endDate) / 12, - 2) - END AS age, - t1.gender, - encounter_id, - encounter_datetime, - @encounter_month := month(encounter_datetime) as encounter_month, - endDate, - prev_rtc_date, - @prev_rtc_month := month(prev_rtc_date) as prev_rtc_month, - rtc_date, - @rtc_month := month(rtc_date) as rtc_month, - - CASE - WHEN encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate THEN @visit_this_month := 1 - ELSE @visit_this_month := 0 - END AS visit_this_month, - - CASE - WHEN prev_rtc_date between date_format(endDate,"%Y-%m-01") and endDate THEN @appointment_this_month := 1 - WHEN rtc_date between date_format(endDate,"%Y-%m-01") and endDate THEN @appointment_this_month := 1 - ELSE @appointment_this_month := 0 - END AS appointment_this_month, - - IF(@visit_this_month = 1 AND @appointment_this_month = 1, 1, 0) AS scheduled_visit_this_month, - - IF(@visit_this_month = 1 AND @appointment_this_month <> 1 AND @encounter_month < @prev_rtc_month - ,1,0) AS early_appointment_this_month, - - IF(@visit_this_month = 1 AND @appointment_this_month <> 1 AND @encounter_month > @prev_rtc_month - ,1,0) AS late_appointment_this_month, - - IF(@visit_this_month = 0 AND @appointment_this_month = 1,1,0) AS missed_appointment_this_month, - - timestampdiff(day,rtc_date, endDate) as days_since_rtc_date, - t1.has_comorbidity, - t1.has_mental_disorder_comorbidity, - t1.has_diabetic_comorbidity, - t1.has_hypertension_comorbidity, - t1.has_other_comorbidity - from - plhiv_ncd_patient_encounters t1 - inner join amrs.person t2 on (t1.person_id = t2.person_id and t2.voided = 0) - ); - - replace into plhiv_ncd_monthly_report_dataset - ( - select - * - from stage_1 - ); - - SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join plhiv_ncd_monthly_report_temp_queue t2 using (person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - - - set @cycle_length = timestampdiff(second,@loop_start_time,now()); - - set @total_time = @total_time + @cycle_length; - set @cycle_number = @cycle_number + 1; - - - set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); - - - SELECT - @person_ids_count AS 'persons remaining', - @cycle_length AS 'Cycle time (s)', - CEIL(@person_ids_count / cycle_size) AS remaining_cycles, - @remaining_time AS 'Est time remaining (min)'; - - end while; - - select @end := now(); - insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); - select concat(@table_version," : Time to complete: ",timestampdiff(minute, @start, @end)," minutes"); - - END$$ -DELIMITER ; \ No newline at end of file diff --git a/etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql b/etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql deleted file mode 100644 index 1677c5f..0000000 --- a/etl-scripts/stored-procedures/generate_plhiv_ncd_summary.sql +++ /dev/null @@ -1,823 +0,0 @@ - -DELIMITER $$ - -CREATE PROCEDURE `etl`.`generate_plhiv_ncd_summary`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int) -BEGIN - set @primary_table := "plhiv_ncd_summary_v1"; - set @query_type = query_type; - - set @total_rows_written = 0; - - set @encounter_types = "(54,55,75,76,77,78,79,83,96,99,100,104,107,108,109,131,171,172)"; - set @clinical_encounter_types = "(54,55,75,76,77,78,79,83,96,104,107,108,109,171,172)"; - set @non_clinical_encounter_types = "(131)"; - set @other_encounter_types = "(-1)"; - - set @start = now(); - set @table_version = "plhiv_ncd_summary_v1.0"; - - set session sort_buffer_size=512000000; - - set @sep = " ## "; - set @boundary = "!!"; - set @last_date_created = (select max(max_date_created) from etl.flat_obs); - - CREATE TABLE IF NOT EXISTS plhiv_ncd_summary_v1 ( - date_created TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, - person_id INT, - uuid VARCHAR(100), - visit_id INT, - encounter_id INT, - encounter_datetime DATETIME, - encounter_type INT, - is_clinical_encounter INT, - location_id INT, - location_uuid VARCHAR(100), - death_date DATETIME, - prev_rtc_date DATETIME, - rtc_date DATETIME, - lmp DATE, - sbp SMALLINT, - dbp SMALLINT, - pulse SMALLINT, - fbs DECIMAL, - rbs DECIMAL, - hb_a1c DECIMAL, - hb_a1c_date DATETIME, - creatinine DECIMAL, - creatinine_date DATETIME, - total_cholesterol DECIMAL, - hdl DECIMAL, - ldl DECIMAL, - triglycerides DECIMAL, - lipid_panel_date DATETIME, - dm_status MEDIUMINT, - htn_status MEDIUMINT, - dm_meds VARCHAR(500), - htn_meds VARCHAR(500), - prescriptions TEXT, - problems TEXT, - has_comorbidity TINYINT(1), - has_mental_disorder_comorbidity TINYINT(1), - has_diabetic_comorbidity TINYINT(1), - has_hypertension_comorbidity TINYINT(1), - has_other_comorbidity TINYINT(1), - prev_encounter_datetime_plhiv_ncd DATETIME, - next_encounter_datetime_plhiv_ncd DATETIME, - prev_encounter_type_plhiv_ncd MEDIUMINT, - next_encounter_type_plhiv_ncd MEDIUMINT, - prev_clinical_datetime_plhiv_ncd DATETIME, - next_clinical_datetime_plhiv_ncd DATETIME, - prev_clinical_location_id_plhiv_ncd MEDIUMINT, - next_clinical_location_id_plhiv_ncd MEDIUMINT, - prev_clinical_rtc_date_plhiv_ncd DATETIME, - next_clinical_rtc_date_plhiv_ncd DATETIME, - PRIMARY KEY encounter_id (encounter_id), - INDEX person_date (person_id , encounter_datetime), - INDEX person_uuid (uuid), - INDEX location_enc_date (location_uuid , encounter_datetime), - INDEX enc_date_location (encounter_datetime , location_uuid), - INDEX location_id_rtc_date (location_id , rtc_date), - INDEX location_uuid_rtc_date (location_uuid , rtc_date), - INDEX loc_id_enc_date_next_clinical (location_id , encounter_datetime , next_clinical_datetime_plhiv_ncd), - INDEX encounter_type (encounter_type), - INDEX date_created (date_created) - ); - - if(@query_type="build") then - select 'BUILDING..........................................'; - - set @write_table = concat("plhiv_ncd_summary_temp_",queue_number); - set @queue_table = concat("plhiv_ncd_summary_build_queue_",queue_number); - - select @queue_table; - SET @dyn_sql=CONCAT('Create table if not exists ',@write_table,' like ',@primary_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - #create table if not exists @queue_table (person_id int, primary key (person_id)); - SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from plhiv_ncd_summary_build_queue limit ', queue_size, ');'); - #SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,' (select * from plhiv_ncd_summary_build_queue limit 500);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - #delete t1 from plhiv_ncd_summary_build_queue t1 join @queue_table t2 using (person_id) - SET @dyn_sql=CONCAT('delete t1 from plhiv_ncd_summary_build_queue t1 join ',@queue_table, ' t2 using (person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - end if; - - if(@query_type="sync") then - select 'SYNCING..........................................'; - set @write_table = "plhiv_ncd_summary_v1"; - set @queue_table = "plhiv_ncd_summary_sync_queue"; - CREATE TABLE IF NOT EXISTS plhiv_ncd_summary_sync_queue ( - person_id INT PRIMARY KEY - ); - - set @last_update = null; - - SELECT - MAX(date_updated) - INTO @last_update FROM - etl.flat_log - WHERE - table_name = @table_version; - - replace into plhiv_ncd_summary_sync_queue - (select distinct patient_id - from amrs.encounter - where date_changed > @last_update - ); - - replace into plhiv_ncd_summary_sync_queue - (select distinct person_id - from etl.flat_obs - where max_date_created > @last_update - ); - - replace into plhiv_ncd_summary_sync_queue - (select distinct person_id - from etl.flat_lab_obs - where max_date_created > @last_update - ); - - replace into plhiv_ncd_summary_sync_queue - (select distinct person_id - from etl.flat_orders - where max_date_created > @last_update - ); - - replace into plhiv_ncd_summary_sync_queue - (select person_id from - amrs.person - where date_voided > @last_update); - - - replace into plhiv_ncd_summary_sync_queue - (select person_id from - amrs.person - where date_changed > @last_update); - end if; - - - # Remove test patients - SET @dyn_sql=CONCAT('delete t1 FROM ',@queue_table,' t1 - join amrs.person_attribute t2 using (person_id) - where t2.person_attribute_type_id=28 and value="true" and voided=0'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @person_ids_count = 0; - - SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SELECT @person_ids_count AS 'num patients to update'; - - - #delete t1 from plhiv_ncd_summary_v1.0 t1 join @queue_table t2 using (person_id); - SET @dyn_sql=CONCAT('delete t1 from ',@primary_table, ' t1 join ',@queue_table,' t2 using (person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - -- drop temporary table if exists prescriptions; - -- create temporary table prescriptions (encounter_id int primary key, prescriptions text) - -- ( - -- select - -- encounter_id, - -- group_concat(obs separator ' $ ') as prescriptions - -- from - -- ( - -- select - -- t2.encounter_id, - -- obs_group_id, - -- group_concat( - -- case - -- when value_coded is not null then concat(@boundary,o.concept_id,'=',value_coded,@boundary) - -- when value_numeric is not null then concat(@boundary,o.concept_id,'=',value_numeric,@boundary) - -- when value_datetime is not null then concat(@boundary,o.concept_id,'=',date(value_datetime),@boundary) - -- when value_text is not null then concat(@boundary,o.concept_id,'=',value_text,@boundary) - -- when value_drug is not null then concat(@boundary,o.concept_id,'=',value_drug,@boundary) - -- when value_modifier is not null then concat(@boundary,o.concept_id,'=',value_modifier,@boundary) - -- end - -- order by o.concept_id,value_coded - -- separator ' ## ' - -- ) as obs - - -- from amrs.obs o - -- join (select encounter_id, obs_id, concept_id as grouping_concept from amrs.obs where concept_id in (7307,7334)) t2 on o.obs_group_id = t2.obs_id - -- group by obs_group_id - -- ) t - -- group by encounter_id - -- ); - - set @total_time=0; - set @cycle_number = 0; - - while @person_ids_count > 0 do - - set @loop_start_time = now(); - - drop temporary table if exists plhiv_ncd_summary_build_queue__0; - - SET @dyn_sql=CONCAT('create temporary table plhiv_ncd_summary_build_queue__0 (person_id int primary key) (select * from ',@queue_table,' limit ',cycle_size,');'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - - - drop temporary table if exists plhiv_ncd_summary_0a; - SET @dyn_sql = CONCAT( - 'create temporary table plhiv_ncd_summary_0a - (select - t1.person_id, - t1.visit_id, - t1.encounter_id, - t1.encounter_datetime, - t1.encounter_type, - t1.location_id, - t1.obs, - t1.obs_datetimes, - case - when t1.encounter_type in ',@clinical_encounter_types,' then 1 - else null - end as is_clinical_encounter, - - case - when t1.encounter_type in ',@non_clinical_encounter_types,' then 20 - when t1.encounter_type in ',@clinical_encounter_types,' then 10 - when t1.encounter_type in', @other_encounter_types, ' then 5 - else 1 - end as encounter_type_sort_index, - t2.orders - from etl.flat_obs t1 - join plhiv_ncd_summary_build_queue__0 t0 using (person_id) - left join etl.flat_orders t2 using(encounter_id) - where t1.encounter_type in ',@encounter_types,');' - ); - - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - insert into plhiv_ncd_summary_0a - ( - select - t1.person_id, - null, - t1.encounter_id, - t1.test_datetime, - t1.encounter_type, - null, #t1.location_id, - t1.obs, - null, #obs_datetimes - # in any visit, there many be multiple encounters. for this dataset, we want to include only clinical encounters (e.g. not lab or triage visit) - 0 as is_clinical_encounter, - 1 as encounter_type_sort_index, - null - from etl.flat_lab_obs t1 - join plhiv_ncd_summary_build_queue__0 t0 using (person_id) - ); - - drop temporary table if exists plhiv_ncd_summary_0; - create temporary table plhiv_ncd_summary_0(index encounter_id (encounter_id), index person_enc (person_id,encounter_datetime)) - ( - select - * - from plhiv_ncd_summary_0a - order by person_id, date(encounter_datetime), encounter_type_sort_index - ); - - set @prev_id = null; - set @cur_id = null; - set @prev_encounter_date = null; - set @cur_encounter_date = null; - set @enrollment_date = null; - set @cur_location = null; - set @cur_rtc_date = null; - set @prev_rtc_date = null; - - set @death_date = null; - - #TO DO - # screened for cervical ca - # exposed infant - - drop temporary table if exists plhiv_ncd_summary_1; - CREATE temporary TABLE plhiv_ncd_summary_1 (INDEX encounter_id (encounter_id)) - ( - SELECT - obs, - encounter_type_sort_index, - @prev_id:=@cur_id AS prev_id, - @cur_id:=t1.person_id AS cur_id, - t1.person_id, - p.uuid, - t1.visit_id, - t1.encounter_id, - @prev_encounter_date:=DATE(@cur_encounter_date) AS prev_encounter_date, - @cur_encounter_date:=DATE(encounter_datetime) AS cur_encounter_date, - t1.encounter_datetime, - t1.encounter_type, - t1.is_clinical_encounter, - death_date, - CASE - WHEN location_id THEN @cur_location:=location_id - WHEN @prev_id = @cur_id THEN @cur_location - ELSE NULL - END AS location_id, - CASE - WHEN @prev_id = @cur_id THEN @prev_rtc_date:=@cur_rtc_date - ELSE @prev_rtc_date:=NULL - END AS prev_rtc_date, - CASE - WHEN obs REGEXP '!!5096=' THEN @cur_rtc_date:=GETVALUES(obs, 5096) - WHEN - @prev_id = @cur_id - THEN - IF(@cur_rtc_date > encounter_datetime, - @cur_rtc_date, - NULL) - ELSE @cur_rtc_date:=NULL - END AS cur_rtc_date, - @lmp:=GETVALUES(obs, 1836) AS lmp, - CASE - WHEN obs REGEXP '!!5085=' THEN @sbp:=GETVALUES(obs, 5085) - END AS sbp, - @dbp:=GETVALUES(obs, 5086) AS dbp, - @pulse:=GETVALUES(obs, 5087) AS pulse, - @fbs:=GETVALUES(obs, 6252) AS fbs, - @rbs:=GETVALUES(obs, 887) AS rbs, - CASE - WHEN obs REGEXP '!!6126=' THEN @hb_a1c:=GETVALUES(obs, 6126) - WHEN @prev_id = @cur_id THEN @hb_a1c - ELSE @hb_a1c:=NULL - END AS hb_a1c, - CASE - WHEN - obs REGEXP '!!6126=' - THEN - @hb_a1c_date:=IFNULL(GETVALUES(obs_datetimes, 6126), - encounter_datetime) - WHEN @prev_id = @cur_id THEN @hb_a1c_date - ELSE @hb_a1c_date:=NULL - END AS hb_a1c_date, - CASE - WHEN obs REGEXP '!!790=' THEN @creatinine:=GETVALUES(obs, 790) - WHEN @prev_id = @cur_id THEN @creatinine - ELSE @creatinine:=NULL - END AS creatinine, - CASE - WHEN - obs REGEXP '!!790=' - THEN - @creatinine_date:=IFNULL(GETVALUES(obs_datetimes, 790), - encounter_datetime) - WHEN @prev_id = @cur_id THEN @creatinine_date - ELSE @creatinine_date:=NULL - END AS creatinine_date, - CASE - WHEN obs REGEXP '!!1006=' THEN @total_cholesterol:=GETVALUES(obs, 1006) - WHEN @prev_id = @cur_id THEN @total_cholesterol - ELSE @total_cholesterol:=NULL - END AS total_cholesterol, - CASE - WHEN obs REGEXP '!!1007=' THEN @hdl:=GETVALUES(obs, 1007) - WHEN @prev_id = @cur_id THEN @hdl - ELSE @hdl:=NULL - END AS hdl, - CASE - WHEN obs REGEXP '!!1008=' THEN @ldl:=GETVALUES(obs, 1008) - WHEN @prev_id = @cur_id THEN @ldl - ELSE @ldl:=NULL - END AS ldl, - CASE - WHEN obs REGEXP '!!1009=' THEN @triglycerides:=GETVALUES(obs, 1009) - WHEN @prev_id = @cur_id THEN @triglycerides - ELSE @triglycerides:=NULL - END AS triglycerides, - CASE - WHEN - obs REGEXP '!!1006=' - THEN - @lipid_panel_date:=IFNULL(GETVALUES(obs_datetimes, 1006), - encounter_datetime) - WHEN @prev_id = @cur_id THEN @lipid_panel_date - ELSE @lipid_panel_date:=NULL - END AS lipid_panel_date, - @dm_status:=GETVALUES(obs, 7287) AS dm_status, - @htn_status:=GETVALUES(obs, 7288) AS htn_status, - @dm_meds:=GETVALUES(obs, 7290) AS dm_meds, - @htn_meds:=GETVALUES(obs, 10241) AS htn_meds, - -- t2.prescriptions AS prescriptions, - NULL AS prescriptions, - @problems:=GETVALUES(obs, 6042) AS problems, - case - when obs regexp '!!11200=10239!!' then 1 - when (obs regexp '!!10239=') = 1 and (obs not regexp '!!10239=1066!!') = 1 then 1 - when obs regexp '!!10239=7281!!' then 1 - when obs regexp '!!10239=7282!!' then 1 - when obs regexp '!!10239=1066!!' then 0 - else NULL - end as has_comorbidity, - case - when obs regexp '!!10239=175!!' then 1 - else NULL - end as has_diabetic_comorbidity, - case - when obs regexp '!!10239=7971!!' then 1 - when obs regexp '!!10239=903!!' then 1 - when obs regexp '!!9328=903!!' then 1 - when obs regexp '!!9328=7971!!' then 1 - else NULL - end as has_hypertension_comorbidity, - case - when obs regexp '!!10239=10860!!' then 1 - when obs regexp '!!10239=77!!' then 1 - else NULL - end as has_mental_disorder_comorbidity, - case - when obs regexp '!!10239=5622!!' then 1 - when (obs regexp '!!10239=')= 1 and (obs not regexp '!!10239=(77|175|903|7281|7282|7971|10860)!!')=1 then 1 - else NULL - end as has_other_comorbidity, - FROM plhiv_ncd_summary_0 t1 - JOIN amrs.person p USING (person_id) - ); - -- LEFT OUTER JOIN - -- prescriptions t2 USING (encounter_id) - -- ); - - set @prev_id = null; - set @cur_id = null; - set @prev_encounter_datetime = null; - set @cur_encounter_datetime = null; - - set @prev_clinical_datetime = null; - set @cur_clinical_datetime = null; - - set @next_encounter_type = null; - set @cur_encounter_type = null; - - set @prev_clinical_location_id = null; - set @cur_clinical_location_id = null; - - - alter table plhiv_ncd_summary_1 drop prev_id, drop cur_id; - - drop table if exists plhiv_ncd_summary_2; - create temporary table plhiv_ncd_summary_2 - ( - select - *, - @prev_id := @cur_id as prev_id, - @cur_id := person_id as cur_id, - - case - when @prev_id = @cur_id then @prev_encounter_datetime := @cur_encounter_datetime - else @prev_encounter_datetime := null - end as next_encounter_datetime_plhiv_ncd, - - @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, - - case - when @prev_id=@cur_id then @next_encounter_type := @cur_encounter_type - else @next_encounter_type := null - end as next_encounter_type_plhiv_ncd, - - @cur_encounter_type := encounter_type as cur_encounter_type, - - case - when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime - else @prev_clinical_datetime := null - end as next_clinical_datetime_plhiv_ncd, - - case - when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id - else @prev_clinical_location_id := null - end as next_clinical_location_id_plhiv_ncd, - - case - when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime - when @prev_id = @cur_id then @cur_clinical_datetime - else @cur_clinical_datetime := null - end as cur_clinic_datetime, - - case - when is_clinical_encounter then @cur_clinical_location_id := location_id - when @prev_id = @cur_id then @cur_clinical_location_id - else @cur_clinical_location_id := null - end as cur_clinic_location_id, - - case - when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date - else @prev_clinical_rtc_date := null - end as next_clinical_rtc_date_plhiv_ncd, - - case - when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date - when @prev_id = @cur_id then @cur_clinical_rtc_date - else @cur_clinical_rtc_date:= null - end as cur_clinical_rtc_date - - from plhiv_ncd_summary_1 - order by person_id, date(encounter_datetime) desc, encounter_type_sort_index desc - ); - - alter table plhiv_ncd_summary_2 drop prev_id, drop cur_id, drop cur_encounter_type, drop cur_encounter_datetime, drop cur_clinical_rtc_date; - - - set @prev_id = null; - set @cur_id = null; - set @prev_encounter_type = null; - set @cur_encounter_type = null; - set @prev_encounter_datetime = null; - set @cur_encounter_datetime = null; - set @prev_clinical_datetime = null; - set @cur_clinical_datetime = null; - set @prev_clinical_location_id = null; - set @cur_clinical_location_id = null; - - drop temporary table if exists plhiv_ncd_summary_3; - create temporary table plhiv_ncd_summary_3 (prev_encounter_datetime datetime, prev_encounter_type int, index person_enc (person_id, encounter_datetime desc)) - ( - select - *, - @prev_id := @cur_id as prev_id, - @cur_id := t1.person_id as cur_id, - - -- if same person then cur enc type is same as prev encounter type else null - case - when @prev_id=@cur_id then @prev_encounter_type := @cur_encounter_type - else @prev_encounter_type:=null - end as prev_encounter_type_plhiv_ncd, - @cur_encounter_type := encounter_type as cur_encounter_type, - - -- if same person then cur enc dt is same as prev enc dt else null - case - when @prev_id=@cur_id then @prev_encounter_datetime := @cur_encounter_datetime - else @prev_encounter_datetime := null - end as prev_encounter_datetime_plhiv_ncd, - - @cur_encounter_datetime := encounter_datetime as cur_encounter_datetime, - - -- if same person then cur clc dt is same as prev clc dt else null - case - when @prev_id = @cur_id then @prev_clinical_datetime := @cur_clinical_datetime - else @prev_clinical_datetime := null - end as prev_clinical_datetime_plhiv_ncd, - - -- if same person then cur clc locid is same as prev clc locid else null - case - when @prev_id = @cur_id then @prev_clinical_location_id := @cur_clinical_location_id - else @prev_clinical_location_id := null - end as prev_clinical_location_id_plhiv_ncd, - - -- if clc enc or same person then cur clc dt is enc_dt else null - case - when is_clinical_encounter then @cur_clinical_datetime := encounter_datetime - when @prev_id = @cur_id then @cur_clinical_datetime - else @cur_clinical_datetime := null - end as cur_clinical_datetime, - - -- if clc enc or same person then cur clc loc is loc_id else null - case - when is_clinical_encounter then @cur_clinical_location_id := location_id - when @prev_id = @cur_id then @cur_clinical_location_id - else @cur_clinical_location_id := null - end as cur_clinical_location_id, - - -- if same person then prev clc rtc is cur rtc else null - case - when @prev_id = @cur_id then @prev_clinical_rtc_date := @cur_clinical_rtc_date - else @prev_clinical_rtc_date := null - end as prev_clinical_rtc_date_plhiv_ncd, - - -- if clc enc or same person then cur clc rtc is cur rtc else null - case - when is_clinical_encounter then @cur_clinical_rtc_date := cur_rtc_date - when @prev_id = @cur_id then @cur_clinical_rtc_date - else @cur_clinical_rtc_date:= null - end as cur_clinic_rtc_date - - from plhiv_ncd_summary_2 t1 - order by person_id, date(encounter_datetime), encounter_type_sort_index - ); - - SELECT COUNT(*) INTO @new_encounter_rows FROM plhiv_ncd_summary_3; - - SELECT @new_encounter_rows; - set @total_rows_written = @total_rows_written + @new_encounter_rows; - SELECT @total_rows_written; - - select - null, - person_id, - t1.uuid, - visit_id, - encounter_id, - encounter_datetime, - encounter_type, - is_clinical_encounter, - location_id, - t2.uuid as location_uuid, - death_date, - prev_rtc_date, - cur_rtc_date, - lmp, - sbp, - dbp, - pulse, - fbs, - rbs, - hb_a1c, - hb_a1c_date, - creatinine, - creatinine_date, - total_cholesterol, - hdl, - ldl, - triglycerides, - lipid_panel_date, - dm_status, - htn_status, - dm_meds, - htn_meds, - prescriptions, - problems, - has_comorbidity, - has_mental_disorder_comorbidity, - has_diabetic_comorbidity, - has_hypertension_comorbidity, - has_other_comorbidity, - prev_encounter_datetime_plhiv_ncd, - next_encounter_datetime_plhiv_ncd, - prev_encounter_type_plhiv_ncd, - next_encounter_type_plhiv_ncd, - prev_clinical_datetime_plhiv_ncd, - next_clinical_datetime_plhiv_ncd, - prev_clinical_location_id_plhiv_ncd, - next_clinical_location_id_plhiv_ncd, - prev_clinical_rtc_date_plhiv_ncd, - next_clinical_rtc_date_plhiv_ncd - from plhiv_ncd_summary_3 t1 - join amrs.location t2 using (location_id); - - #add data to table - SET @dyn_sql=CONCAT('replace into ',@write_table, - '(select - null, - person_id, - t1.uuid, - visit_id, - encounter_id, - encounter_datetime, - encounter_type, - is_clinical_encounter, - location_id, - t2.uuid as location_uuid, - death_date, - prev_rtc_date, - cur_rtc_date, - lmp, - sbp, - dbp, - pulse, - fbs, - rbs, - hb_a1c, - hb_a1c_date, - creatinine, - creatinine_date, - total_cholesterol, - hdl, - ldl, - triglycerides, - lipid_panel_date, - dm_status, - htn_status, - dm_meds, - htn_meds, - prescriptions, - problems, - has_comorbidity, - has_mental_disorder_comorbidity, - has_diabetic_comorbidity, - has_hypertension_comorbidity, - has_other_comorbidity, - prev_encounter_datetime_plhiv_ncd, - next_encounter_datetime_plhiv_ncd, - prev_encounter_type_plhiv_ncd, - next_encounter_type_plhiv_ncd, - prev_clinical_datetime_plhiv_ncd, - next_clinical_datetime_plhiv_ncd, - prev_clinical_location_id_plhiv_ncd, - next_clinical_location_id_plhiv_ncd, - prev_clinical_rtc_date_plhiv_ncd, - next_clinical_rtc_date_plhiv_ncd - - from plhiv_ncd_summary_3 t1 - join amrs.location t2 using (location_id))'); - - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - - #delete from @queue_table where person_id in (select person_id from plhiv_ncd_summary_build_queue__0); - - SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join plhiv_ncd_summary_build_queue__0 t2 using (person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - - #select @person_ids_count := (select count(*) from plhiv_ncd_summary_build_queue_2); - SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - #select @person_ids_count as remaining_in_build_queue; - - set @cycle_length = timestampdiff(second,@loop_start_time,now()); - #select concat('Cycle time: ',@cycle_length,' seconds'); - set @total_time = @total_time + @cycle_length; - set @cycle_number = @cycle_number + 1; - - #select ceil(@person_ids_count / cycle_size) as remaining_cycles; - set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); - - SELECT - @person_ids_count AS 'persons remaining', - @cycle_length AS 'Cycle time (s)', - CEIL(@person_ids_count / cycle_size) AS remaining_cycles, - @remaining_time AS 'Est time remaining (min)'; - end while; - - if(@query_type="build") then - SET @dyn_sql=CONCAT('drop table ',@queue_table,';'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @total_rows_to_write=0; - SET @dyn_sql=CONCAT("Select count(*) into @total_rows_to_write from ",@write_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - set @start_write = now(); - - SELECT - CONCAT(@start_write, - ' : Writing ', - @total_rows_to_write, - ' to ', - @primary_table); - - SET @dyn_sql=CONCAT('replace into ', @primary_table, - '(select * from ',@write_table,');'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - set @finish_write = now(); - set @time_to_write = timestampdiff(second,@start_write,@finish_write); - - SELECT - CONCAT(@finish_write, - ' : Completed writing rows. Time to write to primary table: ', - @time_to_write, - ' seconds '); - - SET @dyn_sql=CONCAT('drop table ',@write_table,';'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - end if; - - set @ave_cycle_length = ceil(@total_time/@cycle_number); - SELECT - CONCAT('Average Cycle Length: ', - @ave_cycle_length, - ' second(s)'); - - set @end = now(); - insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); - SELECT - CONCAT(@table_version, - ' : Time to complete: ', - TIMESTAMPDIFF(MINUTE, @start, @end), - ' minutes'); -END$$ -DELIMITER ; \ No newline at end of file From 60ebecb0df9cea599eec7793855498d177246b28 Mon Sep 17 00:00:00 2001 From: henrykorir Date: Sat, 23 Dec 2023 17:20:27 +0300 Subject: [PATCH 9/9] POC-545: Updated the SP to persist an NCD since the time of discovery to enddate POC-545: Persist NCD throughout PLHIV record since the first time a NCD diagonised POC-545: Updated ncd report stored procedure to exclude normal findings POC-545: Updated ncd summaries stored procedure and ncd monthly report stored procedure POC-545: added logic to exclude normal findings POC-545: fixed the htn and dm state logical error POC-545: updated ncd stored procedures POC-545: Modified report logic to persist NCD in the liftime a of a record POC-545: Updated dataset stored procedure POC-545: Updated the SP to persist an NCD since the time of discovery to enddate --- .../stored-procedures/generate_flat_ncd.sql | 29 +- .../generate_ncd_monthly_report_dataset.sql | 1024 ++++++++++------- 2 files changed, 603 insertions(+), 450 deletions(-) diff --git a/etl-scripts/stored-procedures/generate_flat_ncd.sql b/etl-scripts/stored-procedures/generate_flat_ncd.sql index 7a21750..6da0d1c 100644 --- a/etl-scripts/stored-procedures/generate_flat_ncd.sql +++ b/etl-scripts/stored-procedures/generate_flat_ncd.sql @@ -1,4 +1,4 @@ -CREATE PROCEDURE `etl`.`generate_flat_ncd_v1_1`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int) +CREATE DEFINER=`hkorir`@`%` PROCEDURE `generate_flat_ncd`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int) BEGIN set @primary_table := "flat_ncd"; set @query_type = query_type; @@ -132,7 +132,7 @@ BEGIN if (@query_type="sync") then select 'SYNCING..........................................'; - set @write_table = "flat_ncd_v1"; + set @write_table = "flat_ncd"; set @queue_table = "flat_ncd_sync_queue"; create table if not exists flat_ncd_sync_queue (person_id int primary key); @@ -140,7 +140,8 @@ BEGIN set @last_update = null; - select max(date_updated) into @last_update from etl.flat_log where table_name=@table_version; + select max(date_updated) into @last_update from etl.flat_log where table_name=@table_version; + select @last_update := if(@last_update,@last_update,'1900-01-01'); replace into flat_ncd_sync_queue (select distinct patient_id @@ -251,10 +252,6 @@ BEGIN EXECUTE s1; DEALLOCATE PREPARE s1; - - - - drop temporary table if exists flat_ncd_0a; SET @dyn_sql = CONCAT( 'create temporary table flat_ncd_0a @@ -282,7 +279,7 @@ BEGIN from etl.flat_obs t1 join flat_ncd_build_queue__0 t0 using (person_id) left join etl.flat_orders t2 using(encounter_id) - where t1.encounter_type in ',@encounter_types,');'); + );'); PREPARE s1 from @dyn_sql; EXECUTE s1; @@ -369,9 +366,7 @@ BEGIN @lmp := etl.GetValues(obs,1836) as lmp, - case - when obs regexp "!!5085=" then @sbp := etl.GetValues(obs,5085) - end as sbp, + @sbp := etl.GetValues(obs,5085) as sbp, @dbp := etl.GetValues(obs,5086) as dbp, @@ -438,26 +433,26 @@ BEGIN @dm_status := etl.GetValues(obs,7287) as dm_status, @htn_status := etl.GetValues(obs,7288) as htn_status, - @dm_meds := concat_ws(' ## ', + @dm_meds := nullif(concat_ws(' ## ', etl.GetValues(obs,7290), etl.GetValues(obs,7304) - ) as dm_meds, - @htn_meds := concat_ws(' ## ', + ),'') as dm_meds, + @htn_meds := nullif(concat_ws(' ## ', etl.GetValues(obs,7291), etl.GetValues(obs,7332), etl.GetValues(obs,10241) - ) as htn_meds, + ),'') as htn_meds, t2.prescriptions as prescriptions, - @problems := concat_ws(' ## ', + @problems := nullif(concat_ws(' ## ', etl.GetValues(obs,6042 ), etl.GetValues(obs,11679), etl.GetValues(obs,6796), etl.GetValues(obs,2072), etl.GetValues(obs,6097), etl.GetValues(obs,6461) - ) as problems, + ), '') as problems, @comorbidities := etl.GetValues(obs,10239 ) as comorbidities, @rheumatologic_disorder := etl.GetValues(obs,12293) as rheumatologic_disorder, @kidney_disease := etl.GetValues(obs, 6033) as kidney_disease, diff --git a/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql index d1eceab..8abb393 100644 --- a/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql +++ b/etl-scripts/stored-procedures/generate_ncd_monthly_report_dataset.sql @@ -1,425 +1,582 @@ -DELIMITER $$ -CREATE CREATE DEFINER=`hkorir`@`%` PROCEDURE `generate_ncd_monthly_report_dataset`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int, IN start_date varchar(50)) +CREATE DEFINER=`hkorir`@`%` PROCEDURE `generate_ncd_monthly_report_dataset`(IN query_type varchar(50), IN queue_number int, IN queue_size int, IN cycle_size int, IN start_date varchar(50)) BEGIN - set @start = now(); - set @table_version = "ncd_monthly_report_dataset_v1.4"; - set @last_date_created = (select max(date_created) from etl.flat_hiv_summary_v15b); - - set @sep = " ## "; - set @lab_encounter_type = 99999; - set @death_encounter_type = 31; - - - create table if not exists ncd_monthly_report_dataset ( - date_created timestamp DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP NOT NULL, - elastic_id bigint, - endDate date, - encounter_id int, - person_id int, - person_uuid varchar(100), - birthdate date, - age double, - gender varchar(1), - location_id int, - location_uuid varchar(100), - clinic varchar(250), - encounter_date date, - visit_this_month tinyint, - - is_hypertensive tinyint, - htn_state tinyint, - - is_diabetic tinyint, - dm_state tinyint, - - has_mhd tinyint, - is_depressive_mhd tinyint, - is_anxiety_mhd tinyint, - is_bipolar_and_related_mhd tinyint, - is_personality_mhd tinyint, - is_feeding_and_eating_mhd tinyint, - is_ocd_mhd tinyint, - - has_kd tinyint, - is_ckd tinyint, - ckd_stage int, - - has_cvd tinyint, - is_heart_failure_cvd tinyint, - is_myocardinal_infarction tinyint, - - has_neurological_disorder tinyint, - has_stroke tinyint, - is_stroke_haemorrhagic tinyint, - is_stroke_ischaemic tinyint, - - has_migraine tinyint, - has_seizure tinyint, - has_epilepsy tinyint, - has_convulsive_disorder tinyint, - - has_rheumatologic_disorder tinyint, - has_arthritis tinyint, - has_SLE tinyint, - - - primary key elastic_id (elastic_id), - index person_enc_date (person_id, encounter_date), - index person_report_date (person_id, endDate), - index endDate_location_id (endDate, location_id), - index date_created (date_created), - index status_change (location_id, endDate, status, prev_status) - ); - - if (query_type = "build") then - select "BUILDING......................."; - set @queue_table = concat("ncd_monthly_report_dataset_build_queue_",queue_number); - - SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,'(person_id int primary key) (select * from ncd_monthly_report_dataset_build_queue limit ', queue_size, ');'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset_build_queue t1 join ',@queue_table, ' t2 using (person_id)'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - end if; + set @start = now(); + set @table_version = "ncd_monthly_report_dataset_v1.0"; + set @last_date_created = (select max(date_created) from etl.flat_ncd); + set @sep = " ## "; + set @lab_encounter_type = 99999; + set @death_encounter_type = 31; - if (query_type = "sync") then - set @queue_table = "ncd_monthly_report_dataset_sync_queue"; - create table if not exists ncd_monthly_report_dataset_sync_queue (person_id int primary key); - - select @last_update := (select max(date_updated) from etl.flat_log where table_name=@table_version); - - replace into ncd_monthly_report_dataset_sync_queue - (select distinct person_id from flat_hiv_summary_v15b where date_created >= @last_update); - end if; - - - SET @num_ids := 0; - SET @dyn_sql=CONCAT('select count(*) into @num_ids from ',@queue_table,';'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - - SET @person_ids_count = 0; - SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - - SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_table,' t2 using (person_id);'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - set @total_time=0; - set @cycle_number = 0; - - while @person_ids_count > 0 do - - set @loop_start_time = now(); - - drop temporary table if exists ncd_monthly_report_dataset_build_queue__0; - create temporary table ncd_monthly_report_dataset_build_queue__0 (person_id int primary key); + CREATE TABLE IF NOT EXISTS ncd_monthly_report_dataset ( + `date_created` TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP NOT NULL, + `elastic_id` BIGINT, + `endDate` DATE, + `encounter_id` INT, + `person_id` INT, + `person_uuid` VARCHAR(100), + `birthdate` DATE, + `age` DOUBLE, + `gender` VARCHAR(1), + `location_id` INT, + `location_uuid` VARCHAR(100), + `clinic` VARCHAR(250), + `encounter_datetime` DATETIME, + `visit_this_month` TINYINT, + `is_hypertensive` TINYINT, + `htn_state` TINYINT, + `is_diabetic` TINYINT, + `dm_state` TINYINT, + `has_mhd` TINYINT, + `is_depressive_mhd` TINYINT, + `is_anxiety_mhd` TINYINT, + `is_bipolar_and_related_mhd` TINYINT, + `is_personality_mhd` TINYINT, + `is_feeding_and_eating_mhd` TINYINT, + `is_ocd_mhd` TINYINT, + `has_kd` TINYINT, + `is_ckd` TINYINT, + `ckd_stage` INT, + `has_cvd` TINYINT, + `is_heart_failure_cvd` TINYINT, + `is_myocardinal_infarction` TINYINT, + `has_neurological_disorder` TINYINT, + `has_stroke` TINYINT, + `is_stroke_haemorrhagic` TINYINT, + `is_stroke_ischaemic` TINYINT, + `has_migraine` TINYINT, + `has_seizure` TINYINT, + `has_epilepsy` TINYINT, + `has_convulsive_disorder` TINYINT, + `has_rheumatologic_disorder` TINYINT, + `has_arthritis` TINYINT, + `has_SLE` TINYINT, + PRIMARY KEY elastic_id (elastic_id), + INDEX person_enc_date (person_id , encounter_datetime), + INDEX person_report_date (person_id , endDate), + INDEX endDate_location_id (endDate , location_id), + INDEX date_created (date_created), + INDEX status_change (location_id , endDate) + ); + + if (query_type = "build") then + select "BUILDING......................."; + set @queue_table = concat("ncd_monthly_report_dataset_build_queue_",queue_number); + + SET @dyn_sql=CONCAT('Create table if not exists ',@queue_table,'(person_id int primary key) (select * from ncd_monthly_report_dataset_build_queue limit ', queue_size, ');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset_build_queue t1 join ',@queue_table, ' t2 using (person_id)'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + end if; + + + if (query_type = "sync") then + set @queue_table = "ncd_monthly_report_dataset_sync_queue"; + CREATE TABLE IF NOT EXISTS ncd_monthly_report_dataset_sync_queue ( + person_id INT PRIMARY KEY + ); + + SELECT @last_update:=(SELECT MAX(date_updated) FROM etl.flat_log WHERE table_name = @table_version); + SELECT @last_update := IF(@last_update,@last_update,'1900-01-01'); - SET @dyn_sql=CONCAT('insert into ncd_monthly_report_dataset_build_queue__0 (select * from ',@queue_table,' limit ',cycle_size,');'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - - - set @age =null; - set @status = null; - - drop temporary table if exists ncd_monthly_report_dataset_0; - create temporary table ncd_monthly_report_dataset_0 - (select - concat(date_format(endDate,"%Y%m"),person_id) as elastic_id, - endDate, - encounter_id, - person_id, - t3.uuid as person_uuid, - date(birthdate) as birthdate, - case - when timestampdiff(year,birthdate,endDate) > 0 then @age := round(timestampdiff(year,birthdate,endDate),0) - else @age :=round(timestampdiff(month,birthdate,endDate)/12,2) - end as age, - t3.gender, - date(encounter_datetime) as encounter_date, - - if(encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate,1,0) as visit_this_month, - - case - when arv_first_regimen_location_id != 9999 - and arv_first_regimen_start_date between date_format(endDate,"%Y-%m-01") and endDate then arv_first_regimen_location_id - else location_id - end as location_id, - - - encounter_type, + replace into ncd_monthly_report_dataset_sync_queue + (select distinct person_id from flat_ncd where date_created >= @last_update); + end if; - case - when htn_status = 7285 or htn_status = 7286 then 1 - when (comorbidities regexp '[[:<:]]903[[:>:]]') then 1 - when (prev_hbp_findings regexp '[[:<:]]1065[[:>:]]') then 1 - when (htn_meds is not null) then 1 - when (problems regexp '[[:<:]]903[[:>:]]') then 1 - when (review_of_med_history regexp '[[:<:]]903[[:>:]]') then 1 - else null - end as is_hypertensive, - - case - when ((sbp < 130) and (dbp < 80)) then 1 - when ((sbp >= 130) and (dbp >= 80)) then 2 - when ((sbp is null) or (dbp is null)) then 3 - else NULL - end as htn_state, - - case - when dm_status = 7281 or dm_status = 7282 then 1 - when (comorbidities regexp '[[:<:]]175[[:>:]]') then 1 - when (dm_meds is not null) then 1 - when (problems regexp '[[:<:]]9324|175[[:>:]]') then 1 - when (review_of_med_history regexp '[[:<:]]175[[:>:]]') then 1 - else null - end as is_diabetic, - - case - when (hb_a1c >= 7 and hb_a1c <= 8) then 1 - when (hb_a1c < 7 and hb_a1c > 8) then 2 - when (hb_a1c is null) or (hb_a1c is null) then 3 - else null - end as dm_state, - - case - when (comorbidities regexp '[[:<:]]10860[[:>:]]') then 1 - when (indicated_mhd_tx is not null) then 1 - when (has_past_mhd_tx = '1065') then 1 - when (review_of_med_history regexp '[[:<:]]77|207[[:>:]]') then 1 - when (eligible_for_depression_care = '1065') then 1 - when (mood_disorder is not null) then 1 - when (anxiety_condition is not null) then 1 - when (psychiatric_exam_findings is not null) then 1 - else null - end as has_mhd, - - case - when (eligible_for_depression_care = '1065') then 1 - when (mood_disorder regexp '[[:<:]]11278[[:>:]]') then 1 - when (indicated_mhd_tx regexp '[[:<:]]207[[:>:]]') then 1 - when (review_of_med_history regexp '[[:<:]]207[[:>:]]') then 1 - when (psychiatric_exam_findings regexp '[[:<:]]207[[:>:]]') then 1 - else null - end as is_depressive_mhd, - - case - when (anxiety_condition is not null) then 1 - when (indicated_mhd_tx regexp '[[:<:]]1443[[:>:]]') then 1 - when (review_of_med_history regexp '[[:<:]]207[[:>:]]') then 1 - when (psychiatric_exam_findings regexp '[[:<:]]1443[[:>:]]') then 1 - else null - end as is_anxiety_mhd, - - case - when (mood_disorder regexp '[[:<:]]7763[[:>:]]') then 1 - when (indicated_mhd_tx regexp '[[:<:]]7763[[:>:]]') then 1 - else null - end as is_bipolar_and_related_mhd, - - case - when (mood_disorder regexp '[[:<:]]7763[[:>:]]') then 1 - when (indicated_mhd_tx regexp '[[:<:]]11281[[:>:]]') then 1 - when (problems regexp '[[:<:]]467[[:>:]]') then 1 - else null - end as is_personality_mhd, - - null as is_feeding_and_eating_mhd, - - null as is_ocd_mhd, - - case - when (comorbidities regexp '[[:<:]]77[[:>:]]') then 1 - when (kidney_disease = '[[:<:]]1065[[:>:]]') then 1 - when (problems regexp '[[:<:]]8078|11684[[:>:]]') then 1 - when (review_of_med_history regexp '[[:<:]]6033|8078[[:>:]]') then 1 - else null - end as has_kd, - - case - when (problems regexp '[[:<:]]8078[[:>:]]') then 1 - when (review_of_med_history regexp '[[:<:]]8078[[:>:]]') then 1 - when (ckd_staging is not null) then 1 - else null - end as is_ckd, - - ckd_staging as ckd_stage, - - case - when (cardiovascular_disorder is not null) then 1 - when (comorbidities regexp '[[:<:]]7971[[:>:]]') then 1 - when (review_of_med_history regexp '[[:<:]]7971|6237[[:>:]]') then 1 - else null - end as has_cvd, - - case - when (cardiovascular_disorder regexp '[[:<:]]1456[[:>:]]') then 1 - when (indicated_mhd_tx regexp '[[:<:]]1456[[:>:]]') then 1 - when (review_of_med_history regexp '[[:7971') then 1 - else null - end as is_heart_failure_cvd, - - case - when (cardiovascular_disorder regexp '[[:<:]]1535[[:>:]]') then 1 - else null - end as is_myocardinal_infarction, - - case - when (neurological_disease is not null) then 1 - when (indicated_mhd_tx regexp '[[:<:]]1456[[:>:]]') then 1 - when (review_of_med_history regexp '[[:<:]]7971[[:>:]]') then 1 - else null - end as has_neurological_disorder, - - case - when (cardiovascular_disorder regexp '[[:<:]]1878[[:>:]]') then 1 - when (indicated_mhd_tx regexp '[[:<:]]1456[[:>:]]') then 1 - when (review_of_med_history regexp '[[:<:]]7971[[:>:]]') then 1 - else null - end as has_stroke, - - null as is_stroke_haemorrhagic - - null as is_stroke_ischaemic, - - case - when (problems regexp '[[:<:]]1477[[:>:]]') then 1 - when (neurological_disease regexp '[[:<:]]1477[[:>:]]') then 1 - else null - end as has_migraine, - - case - when (problems regexp '[[:<:]]206[[:>:]]') then 1 - when (neurological_disease regexp '[[:<:]]206[[:>:]]') then 1 - when (convulsive_disorder regexp '[[:<:]]206[[:>:]]') then 1 - else null - end as has_seizure, - - case - when (problems regexp '[[:<:]]155|11687[[:>:]]') then 1 - when (neurological_disease regexp '[[:<:]]155[[:>:]]') then 1 - when (convulsive_disorder regexp '[[:<:]]155[[:>:]]') then 1 - when (indicated_mhd_tx regexp '[[:<:]]155[[:>:]]') then 1 - else null - end as has_epilepsy, - - case - when (neurological_disease regexp '[[:<:]]10806[[:>:]]') then 1 - when (convulsive_disorder regexp '[[:<:]]155|10806[[:>:]]') then 1 - else null - end as has_convulsive_disorder, - - case - when (rheumatologic_disorder is not null) then 1 - when (comorbidities regexp '[[:<:]]12293[[:>:]]') then 1 - else null - end as has_rheumatologic_disorder, - - case - when (rheumatologic_disorder regexp '[[:<:]]116[[:>:]]') then 1 - else null - end as has_arthritis, - - case - when (rheumatologic_disorder regexp '[[:<:]]12292[[:>:]]') then 1 - else null - end as has_SLE - - from etl.dates t1 - join etl.flat_ncd t2 - join amrs.person t3 using (person_id) - join etl.ncd_monthly_report_dataset_build_queue__0 t5 using (person_id) - - where - t2.encounter_datetime < date_add(endDate, interval 1 day) - and (t2.next_clinical_datetime_cdm is null or t2.next_clinical_datetime_cdm >= date_add(t1.endDate, interval 1 day) ) - and t2.is_clinical_encounter=1 - and t1.endDate between start_date and date_add(now(),interval 2 year) - order by person_id, endDate - ); - - set @prev_id = null; - set @cur_id = null; - set @prev_location_id = null; - set @cur_location_id = null; - - drop temporary table if exists ncd_monthly_report_dataset_1; - create temporary table ncd_monthly_report_dataset_1 - (select - *, - @prev_id := @cur_id as prev_id, - @cur_id := person_id as cur_id, - - case - when @prev_id=@cur_id then @prev_location_id := @cur_location_id - else @prev_location_id := null - end as next_location_id, - - @cur_location_id := location_id as cur_location_id, - - from ncd_monthly_report_dataset_0 - order by person_id, endDate desc - ); - alter table ncd_monthly_report_dataset_1 drop prev_id, drop cur_id; + SET @num_ids := 0; + SET @dyn_sql=CONCAT('select count(*) into @num_ids from ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + SET @person_ids_count = 0; + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + SET @dyn_sql=CONCAT('delete t1 from ncd_monthly_report_dataset t1 join ',@queue_table,' t2 using (person_id);'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + set @total_time=0; + set @cycle_number = 0; + + while @person_ids_count > 0 do + + set @loop_start_time = now(); + + drop temporary table if exists ncd_monthly_report_dataset_build_queue__0; + create temporary table ncd_monthly_report_dataset_build_queue__0 (person_id int primary key); + + SET @dyn_sql=CONCAT('insert into ncd_monthly_report_dataset_build_queue__0 (select * from ',@queue_table,' limit ',cycle_size,');'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + + + set @age =null; + set @status = null; + drop temporary table if exists ncd_monthly_report_dataset_0; + create temporary table ncd_monthly_report_dataset_0 + ( + select + concat(date_format(endDate,"%Y%m"),person_id) as elastic_id, + endDate, + encounter_id, + person_id, + t3.uuid as person_uuid, + date(birthdate) as birthdate, + case + when timestampdiff(year,birthdate,endDate) > 0 then @age := round(timestampdiff(year,birthdate,endDate),0) + else @age :=round(timestampdiff(month,birthdate,endDate)/12,2) + end as age, + t3.gender, + t2.location_id, + t2.location_uuid, + encounter_datetime, + + if(encounter_datetime between date_format(endDate,"%Y-%m-01") and endDate,1,0) as visit_this_month, + + encounter_type, + + case + when htn_status = 7285 or htn_status = 7286 then 1 + when (comorbidities regexp '[[:<:]]903[[:>:]]') then 1 + when (prev_hbp_findings regexp '[[:<:]]1065[[:>:]]') then 1 + when (htn_meds is not null) then 1 + when (problems regexp '[[:<:]]903[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]903[[:>:]]') then 1 + else 0 + end as is_hypertensive, + + case + when ((sbp < 130) and (dbp < 80)) then 1 + when ((sbp >= 130) and (dbp >= 80)) then 2 + else 3 + end as htn_state, + + case + when dm_status = 7281 or dm_status = 7282 then 1 + when (comorbidities regexp '[[:<:]]175[[:>:]]') then 1 + when (dm_meds is not null) then 1 + when (problems regexp '[[:<:]]9324|175[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]175[[:>:]]') then 1 + else 0 + end as is_diabetic, + + case + when (hb_a1c <= 7) then 1 + when (hb_a1c > 7) then 2 + else 3 + end as dm_state, + + case + when (comorbidities regexp '[[:<:]]10860[[:>:]]') then 1 + when (indicated_mhd_tx is not null) then 1 + when (has_past_mhd_tx regexp '[[:<:]]1065[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]77|207[[:>:]]') then 1 + when (eligible_for_depression_care regexp '[[:<:]]1065[[:>:]]') then 1 + when (mood_disorder is not null) AND (mood_disorder not regexp '[[:<:]]1115[[:>:]]') then 1 + when (anxiety_condition is not null) AND (anxiety_condition not regexp '[[:<:]]1115[[:>:]]')then 1 + when (psychiatric_exam_findings is not null) AND (psychiatric_exam_findings not regexp '[[:<:]]1115[[:>:]]') then 1 + else 0 + end as has_mhd, + + case + when (eligible_for_depression_care regexp '[[:<:]]1065[[:>:]]') then 1 + when (mood_disorder regexp '[[:<:]]11278[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]207[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]207[[:>:]]') then 1 + when (psychiatric_exam_findings regexp '[[:<:]]207[[:>:]]') then 1 + else 0 + end as is_depressive_mhd, + + case + when (anxiety_condition is not null) AND (anxiety_condition not regexp '[[:<:]]1115[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]1443[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]207[[:>:]]') then 1 + when (psychiatric_exam_findings regexp '[[:<:]]1443[[:>:]]') then 1 + else 0 + end as is_anxiety_mhd, + + case + when (mood_disorder regexp '[[:<:]]7763[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]7763[[:>:]]') then 1 + else 0 + end as is_bipolar_and_related_mhd, + + case + when (mood_disorder regexp '[[:<:]]7763[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]11281[[:>:]]') then 1 + when (problems regexp '[[:<:]]467[[:>:]]') then 1 + else 0 + end as is_personality_mhd, + + null as is_feeding_and_eating_mhd, + + null as is_ocd_mhd, + + case + when (comorbidities regexp '[[:<:]]77[[:>:]]') then 1 + when (kidney_disease regexp '[[:<:]]1065[[:>:]]') then 1 + when (problems regexp '[[:<:]]8078|11684[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]6033|8078[[:>:]]') then 1 + else 0 + end as has_kd, + + case + when (problems regexp '[[:<:]]8078[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]8078[[:>:]]') then 1 + when (ckd_staging is not null) then 1 + else 0 + end as is_ckd, + + ckd_staging as ckd_stage, + + case + when (cardiovascular_disorder is not null) AND (cardiovascular_disorder not regexp '[[:<:]]1115[[:>:]]') then 1 + when (comorbidities regexp '[[:<:]]7971[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]7971|6237[[:>:]]') then 1 + else 0 + end as has_cvd, + + case + when (cardiovascular_disorder regexp '[[:<:]]1456[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]1456[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]7971[[:>:]]') then 1 + else 0 + end as is_heart_failure_cvd, + + case + when (cardiovascular_disorder regexp '[[:<:]]1535[[:>:]]') then 1 + else 0 + end as is_myocardinal_infarction, + + case + when (neurological_disease is not null) AND (neurological_disease not regexp '[[:<:]]1115[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]1456[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]7971[[:>:]]') then 1 + else 0 + end as has_neurological_disorder, + + case + when (cardiovascular_disorder regexp '[[:<:]]1878[[:>:]]') AND (cardiovascular_disorder not regexp '[[:<:]]1115[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]1456[[:>:]]') then 1 + when (review_of_med_history regexp '[[:<:]]7971[[:>:]]') then 1 + else 0 + end as has_stroke, + + null as is_stroke_haemorrhagic, + + null as is_stroke_ischaemic, + + case + when (problems regexp '[[:<:]]1477[[:>:]]') then 1 + when (neurological_disease regexp '[[:<:]]1477[[:>:]]') then 1 + else 0 + end as has_migraine, + + case + when (problems regexp '[[:<:]]206[[:>:]]') then 1 + when (neurological_disease regexp '[[:<:]]206[[:>:]]') then 1 + when (convulsive_disorder regexp '[[:<:]]206[[:>:]]') then 1 + else 0 + end as has_seizure, + + case + when (problems regexp '[[:<:]]155|11687[[:>:]]') then 1 + when (neurological_disease regexp '[[:<:]]155[[:>:]]') then 1 + when (convulsive_disorder regexp '[[:<:]]155[[:>:]]') then 1 + when (indicated_mhd_tx regexp '[[:<:]]155[[:>:]]') then 1 + else 0 + end as has_epilepsy, + + case + when (neurological_disease regexp '[[:<:]]10806[[:>:]]') then 1 + when (convulsive_disorder regexp '[[:<:]]155|10806[[:>:]]') then 1 + else 0 + end as has_convulsive_disorder, + + case + when (rheumatologic_disorder is not null) AND (rheumatologic_disorder not regexp '[[:<:]]1115[[:>:]]') then 1 + when (comorbidities regexp '[[:<:]]12293[[:>:]]') then 1 + else 0 + end as has_rheumatologic_disorder, + + case + when (rheumatologic_disorder regexp '[[:<:]]116[[:>:]]') then 1 + else 0 + end as has_arthritis, + + case + when (rheumatologic_disorder regexp '[[:<:]]12292[[:>:]]') then 1 + else 0 + end as has_SLE + + from etl.dates t1 + join etl.flat_ncd t2 + join amrs.person t3 using (person_id) + join etl.ncd_monthly_report_dataset_build_queue__0 t5 using (person_id) + + where + t2.encounter_datetime < date_add(endDate, interval 1 day) + -- and (t2.next_clinical_datetime_ncd is null or t2.next_clinical_datetime_ncd >= date_add(t1.endDate, interval 1 day) ) + -- and t2.is_clinical_encounter=1 + and t1.endDate between start_date and date_add(now(),interval 2 year) + order by person_id, endDate, sbp desc, dbp desc, hb_a1c desc + ); + + + set @prev_id = null; + set @cur_id = null; + + set @is_hypertensive = null; + set @has_mhd = null; + set @is_depressive_mhd = null; + set @is_anxiety_mhd = null; + set @is_bipolar_and_related_mhd = null; + set @is_personality_mhd = null; + set @is_feeding_and_eating_mhd = null; + set @is_ocd_mhd = null; + set @has_kd = null; + set @is_ckd = null; + set @ckd_stage = null; + set @has_cvd = null; + set @is_heart_failure_cvd = null; + set @is_myocardinal_infarction = null; + set @has_neurological_disorder = null; + set @has_stroke = null; + set @is_stroke_haemorrhagic = null; + set @is_stroke_ischaemic = null; + set @has_migraine = null; + set @has_seizure = null; + set @has_epilepsy = null; + set @has_convulsive_disorder = null; + set @has_rheumatologic_disorder = null; + set @has_arthritis = null; + set @has_SLE = null; + + drop temporary table if exists ncd_monthly_report_dataset_1; + create temporary table ncd_monthly_report_dataset_1 + ( + select + @prev_id := @cur_id as prev_id, + @cur_id := person_id as cur_id, + elastic_id, + endDate, + encounter_id, + person_id, + person_uuid, + birthdate, + age, + gender, + location_id, + location_uuid, + encounter_datetime, + + visit_this_month, + + encounter_type, + case + when (@prev_id = @cur_id AND (is_hypertensive = 1 OR @is_hypertensive = 1)) then @is_hypertensive := 1 + else @is_hypertensive := is_hypertensive + end as is_hypertensive, + htn_state, + case + when (@prev_id = @cur_id AND (is_diabetic = 1 OR @is_diabetic = 1)) then @is_diabetic := 1 + else @is_diabetic := is_diabetic + end as is_diabetic, + dm_state, + case + when (@prev_id = @cur_id AND (has_mhd = 1 OR @has_mhd = 1)) then @has_mhd := 1 + else @has_mhd := has_mhd + end as has_mhd, + case + when (@prev_id = @cur_id AND (is_depressive_mhd = 1 OR @is_depressive_mhd = 1)) then @is_depressive_mhd := 1 + else @is_depressive_mhd := is_depressive_mhd + end as is_depressive_mhd, + case + when (@prev_id = @cur_id AND (is_anxiety_mhd = 1 OR @is_anxiety_mhd = 1)) then @is_anxiety_mhd := 1 + else @is_anxiety_mhd := is_anxiety_mhd + end as is_anxiety_mhd, + + case + when (@prev_id = @cur_id AND (is_bipolar_and_related_mhd = 1 OR @is_bipolar_and_related_mhd = 1)) then @is_bipolar_and_related_mhd := 1 + else @is_bipolar_and_related_mhd := is_bipolar_and_related_mhd + end as is_bipolar_and_related_mhd, + + case + when (@prev_id = @cur_id AND (is_personality_mhd = 1 OR @is_personality_mhd = 1)) then @is_personality_mhd := 1 + else @is_personality_mhd := is_personality_mhd + end as is_personality_mhd, + + null as is_feeding_and_eating_mhd, + + null as is_ocd_mhd, + + case + when (@prev_id = @cur_id AND (has_kd = 1 OR @has_kd = 1)) then @has_kd := 1 + else @has_kd := has_kd + end as has_kd, + + case + when (@prev_id = @cur_id AND (is_ckd = 1 OR @is_ckd = 1)) then @is_ckd := 1 + else @is_ckd := is_ckd + end as is_ckd, + + case + when (@prev_id = @cur_id AND (@ckd_stage is null) AND (ckd_stage is not null)) then @ckd_stage := ckd_stage + when (@prev_id = @cur_id AND (@ckd_stage is not null) AND (ckd_stage is null)) then @ckd_stage + else @ckd_stage := ckd_stage + end as ckd_stage, + + case + when (@prev_id = @cur_id AND (has_cvd = 1 OR @has_cvd = 1)) then @has_cvd := 1 + else @has_cvd := has_cvd + end as has_cvd, + + case + when (@prev_id = @cur_id AND (is_heart_failure_cvd = 1 OR @is_heart_failure_cvd = 1)) then @is_heart_failure_cvd := 1 + else @is_heart_failure_cvd := is_heart_failure_cvd + end as is_heart_failure_cvd, + + case + when (@prev_id = @cur_id AND (is_myocardinal_infarction = 1 OR @is_myocardinal_infarction = 1)) then @is_myocardinal_infarction := 1 + else @is_myocardinal_infarction := is_myocardinal_infarction + end as is_myocardinal_infarction, + + case + when (@prev_id = @cur_id AND (has_neurological_disorder = 1 OR @has_neurological_disorder = 1)) then @has_neurological_disorder := 1 + else @has_neurological_disorder := has_neurological_disorder + end as has_neurological_disorder, + + case + when (@prev_id = @cur_id AND (has_stroke = 1 OR @has_stroke = 1)) then @has_stroke := 1 + else @has_stroke := has_stroke + end as has_stroke, - set @prev_id = null; - set @cur_id = null; - set @cur_location_id = null; - set @prev_location_id = null; - drop temporary table if exists hiv_monthly_report_dataset_2; - create temporary table hiv_monthly_report_dataset_2 - (select - *, - @prev_id := @cur_id as prev_id, - @cur_id := person_id as cur_id, - - case - when @prev_id=@cur_id then @prev_location_id := @cur_location_id - else @prev_location_id := null - end as prev_location_id, - - @cur_location_id := location_id as cur_location_id - - from ncd_monthly_report_dataset_1 - order by person_id, endDate - ); - - select now(); - select count(*) as num_rows_to_be_inserted from ncd_monthly_report_dataset_2; + is_stroke_haemorrhagic, + + is_stroke_ischaemic, + + case + when (@prev_id = @cur_id AND (has_migraine = 1 OR @has_migraine = 1)) then @has_migraine := 1 + else @has_migraine := has_migraine + end as has_migraine, + + case + when (@prev_id = @cur_id AND (has_seizure = 1 OR @has_seizure = 1)) then @has_seizure := 1 + else @has_seizure := has_seizure + end as has_seizure, + + case + when (@prev_id = @cur_id AND (has_epilepsy = 1 OR @has_epilepsy = 1)) then @has_epilepsy := 1 + else @has_epilepsy := has_epilepsy + end as has_epilepsy, + + case + when (@prev_id = @cur_id AND (has_convulsive_disorder = 1 OR @has_convulsive_disorder = 1)) then @has_convulsive_disorder := 1 + else @has_convulsive_disorder := has_convulsive_disorder + end as has_convulsive_disorder, + + case + when (@prev_id = @cur_id AND (has_rheumatologic_disorder = 1 OR @has_rheumatologic_disorder = 1)) then @has_rheumatologic_disorder := 1 + else @has_rheumatologic_disorder := has_rheumatologic_disorder + end as has_rheumatologic_disorder, + + case + when (@prev_id = @cur_id AND (has_arthritis = 1 OR @has_arthritis = 1)) then @has_arthritis := 1 + else @has_arthritis := has_arthritis + end as has_arthritis, + + case + when (@prev_id = @cur_id AND (has_SLE = 1 OR @has_SLE = 1)) then @has_SLE := 1 + else @has_SLE := has_SLE + end as has_SLE + + from ncd_monthly_report_dataset_0 + order by person_id, encounter_datetime, endDate + ); + + alter table ncd_monthly_report_dataset_1 drop prev_id, drop cur_id; + + set @prev_id = null; + set @cur_id = null; + set @prev_location_id = null; + set @cur_location_id = null; + drop temporary table if exists ncd_monthly_report_dataset_2; + create temporary table ncd_monthly_report_dataset_2 + (select + *, + @prev_id := @cur_id as prev_id, + @cur_id := person_id as cur_id, + + case + when @prev_id=@cur_id then @prev_location_id := @cur_location_id + else @prev_location_id := null + end as next_location_id, + + @cur_location_id := location_id as cur_location_id + + from ncd_monthly_report_dataset_1 + order by person_id, endDate desc + ); + + alter table ncd_monthly_report_dataset_2 drop prev_id, drop cur_id, drop cur_location_id; + + set @prev_id = null; + set @cur_id = null; + set @cur_location_id = null; + set @prev_location_id = null; + drop temporary table if exists ncd_monthly_report_dataset_3; + create temporary table ncd_monthly_report_dataset_3 + (select + *, + @prev_id := @cur_id as prev_id, + @cur_id := person_id as cur_id, + + case + when @prev_id=@cur_id then @prev_location_id := @cur_location_id + else @prev_location_id := null + end as prev_location_id, + + @cur_location_id := location_id as cur_location_id + + from ncd_monthly_report_dataset_2 + order by person_id, endDate + ); + + SELECT NOW(); + SELECT COUNT(*) AS num_rows_to_be_inserted FROM ncd_monthly_report_dataset_3; #add data to table replace into ncd_monthly_report_dataset (select - null, #date_created will be automatically set or updated + null, elastic_id, endDate, - encounter_id, + encounter_id, person_id, - person_uuid, + person_uuid, birthdate, age, gender, location_id, location_uuid, - t2.name as clinic - encounter_date, - visit_this_month, + t2.name as clinic, + encounter_datetime, + visit_this_month, is_hypertensive, htn_state, @@ -457,49 +614,50 @@ BEGIN has_arthritis, has_SLE - from ncd_monthly_report_dataset_2 t1 - join amrs.location t2 using (location_id) + from ncd_monthly_report_dataset_3 t1 + join amrs.location t2 using (location_id) ); - + SET @dyn_sql=CONCAT('delete t1 from ',@queue_table,' t1 join ncd_monthly_report_dataset_build_queue__0 t2 using (person_id);'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; - + SET @dyn_sql=CONCAT('select count(*) into @person_ids_count from ',@queue_table,';'); PREPARE s1 from @dyn_sql; EXECUTE s1; DEALLOCATE PREPARE s1; - - + + set @cycle_length = timestampdiff(second,@loop_start_time,now()); - + set @total_time = @total_time + @cycle_length; set @cycle_number = @cycle_number + 1; set @remaining_time = ceil((@total_time / @cycle_number) * ceil(@person_ids_count / cycle_size) / 60); - - select @num_in_nmrd as num_in_nmrd, - @person_ids_count as num_remaining, - @cycle_length as 'Cycle time (s)', - ceil(@person_ids_count / cycle_size) as remaining_cycles, - @remaining_time as 'Est time remaining (min)'; - - - end while; - - if(query_type = "build") then - SET @dyn_sql=CONCAT('drop table ',@queue_table,';'); - PREPARE s1 from @dyn_sql; - EXECUTE s1; - DEALLOCATE PREPARE s1; - end if; - - set @end = now(); - # not sure why we need last date_created, Ive replaced this with @start - insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); - select concat(@table_version," : Time to complete: ",timestampdiff(minute, @start, @end)," minutes"); - - END$$ -DELIMITER ; + set @num_in_nmrd := (select count(*) from ncd_monthly_report_dataset); + + SELECT + @num_in_nmrd AS num_in_nmrd, + @person_ids_count AS num_remaining, + @cycle_length AS 'Cycle time (s)', + CEIL(@person_ids_count / cycle_size) AS remaining_cycles, + @remaining_time AS 'Est time remaining (min)'; + end while; + + if(query_type = "build") then + SET @dyn_sql=CONCAT('drop table ',@queue_table,';'); + PREPARE s1 from @dyn_sql; + EXECUTE s1; + DEALLOCATE PREPARE s1; + end if; + + set @end = now(); + + #log the operation for next starting point + insert into etl.flat_log values (@start,@last_date_created,@table_version,timestampdiff(second,@start,@end)); + + SELECT CONCAT(@table_version, ' : Time to complete: ',TIMESTAMPDIFF(MINUTE, @start, @end),' minutes'); + +END \ No newline at end of file