From a8fcd5849fcd46c53aef5e61ee74bab47b456e50 Mon Sep 17 00:00:00 2001 From: Tresor Mvumbi Date: Fri, 12 Jun 2020 15:42:05 +0200 Subject: [PATCH 1/3] COM-850 Add column "Regimen Switch" to radet Adds the above column to the treatment report --- metadata/reportssql/drug_functions.sql | 42 +++++++++++++++++++- openmrs/apps/reports/RADET/sql/treatment.sql | 2 +- 2 files changed, 42 insertions(+), 2 deletions(-) diff --git a/metadata/reportssql/drug_functions.sql b/metadata/reportssql/drug_functions.sql index 1a5371e6..0fd8716f 100644 --- a/metadata/reportssql/drug_functions.sql +++ b/metadata/reportssql/drug_functions.sql @@ -276,7 +276,47 @@ BEGIN RETURN (result); END$$ -DELIMITER ; +DELIMITER ; + +-- getRegimenSwitch + +DROP FUNCTION IF EXISTS getRegimenSwitch; + +DELIMITER $$ +CREATE FUNCTION getRegimenSwitch( + p_patientId INT(11), + p_startDate DATE, + p_endDate DATE) RETURNS VARCHAR(250) + DETERMINISTIC +BEGIN + DECLARE currentRegimen VARCHAR(250); + DECLARE previousRegimen VARCHAR(250); + + SELECT d.name INTO currentRegimen + FROM orders o + JOIN drug_order do ON do.order_id = o.order_id + JOIN drug d ON d.drug_id = do.drug_inventory_id AND d.retired = 0 + WHERE o.patient_id = p_patientId AND o.voided = 0 + AND o.date_created BETWEEN p_startDate AND p_endDate + AND drugIsARV(d.concept_id) + AND drugOrderIsDispensed(o.patient_id, o.order_id) + ORDER BY o.date_created DESC + LIMIT 1; + + SELECT d.name INTO previousRegimen + FROM orders o + JOIN drug_order do ON do.order_id = o.order_id + JOIN drug d ON d.drug_id = do.drug_inventory_id AND d.retired = 0 + WHERE o.patient_id = p_patientId AND o.voided = 0 + AND o.date_created BETWEEN p_startDate AND p_endDate + AND drugIsARV(d.concept_id) + AND drugOrderIsDispensed(o.patient_id, o.order_id) + ORDER BY o.date_created DESC + LIMIT 1, 1; + + RETURN IF (currentRegimen <> previousRegimen, currentRegimen, NULL); +END$$ +DELIMITER ; -- getInfantARVProphylaxis diff --git a/openmrs/apps/reports/RADET/sql/treatment.sql b/openmrs/apps/reports/RADET/sql/treatment.sql index bdf0b3d2..2e83a232 100644 --- a/openmrs/apps/reports/RADET/sql/treatment.sql +++ b/openmrs/apps/reports/RADET/sql/treatment.sql @@ -18,7 +18,7 @@ SELECT getPatientDateOfEnrolmentInProgram(p.patient_id, "HIV_PROGRAM_KEY") AS "E "N/A" as "Regimen at ART Start/ Régime chez ART Start", getPatientMostRecentProgramAttributeCodedValue(p.patient_id, "397b7bc7-13ca-4e4e-abc3-bf854904dce3", "en") as "Current Regimen Line/ Ligne de régime actuelle", getListOfActiveARVDrugs(p.patient_id, '#startDate#', '#endDate#') as "Current ART Regimen/ Régime d'ART actuel", - "N/A" as "Regimen Switch/ Commutateur de régime", + getRegimenSwitch(p.patient_id, "2010-01-01", "#endDate#") as "Regimen Switch/ Commutateur de régime", "N/A" as "Date of Regimen switch (limit only to the current reporting month)", getPregnancyStatus(p.patient_id) as "Pregnancy Status/ Statut de grossesse", getMostRecentCodedObservation(p.patient_id,"HTC, Risk Group","en") as "KP Status", From a692fbcdccdc619ab5a3806eaf0f5d1a4bfa13df Mon Sep 17 00:00:00 2001 From: Tresor Mvumbi Date: Mon, 15 Jun 2020 12:57:12 +0200 Subject: [PATCH 2/3] COM-851 Add column "Regimen Switch Date" to radet Adds the above column to the treatment report --- metadata/reportssql/drug_functions.sql | 71 +++++++++++++++++--- openmrs/apps/reports/RADET/sql/treatment.sql | 2 +- 2 files changed, 63 insertions(+), 10 deletions(-) diff --git a/metadata/reportssql/drug_functions.sql b/metadata/reportssql/drug_functions.sql index 0fd8716f..9b4ab516 100644 --- a/metadata/reportssql/drug_functions.sql +++ b/metadata/reportssql/drug_functions.sql @@ -278,21 +278,26 @@ END$$ DELIMITER ; --- getRegimenSwitch +-- retrieveRegimenSwitchARVandDate -DROP FUNCTION IF EXISTS getRegimenSwitch; +DROP PROCEDURE IF EXISTS retrieveRegimenSwitchARVandDate; DELIMITER $$ -CREATE FUNCTION getRegimenSwitch( - p_patientId INT(11), - p_startDate DATE, - p_endDate DATE) RETURNS VARCHAR(250) +CREATE PROCEDURE retrieveRegimenSwitchARVandDate( + IN p_patientId INT(11), + IN p_startDate DATE, + IN p_endDate DATE, + OUT p_regimen VARCHAR(250), + OUT p_switchDate DATE + ) DETERMINISTIC -BEGIN + BEGIN -- proc_retrieve_regimen_switch_and_date: + DECLARE currentRegimen VARCHAR(250); DECLARE previousRegimen VARCHAR(250); + DECLARE switchDate DATE; - SELECT d.name INTO currentRegimen + SELECT d.name, o.date_created INTO currentRegimen, switchDate FROM orders o JOIN drug_order do ON do.order_id = o.order_id JOIN drug d ON d.drug_id = do.drug_inventory_id AND d.retired = 0 @@ -314,7 +319,55 @@ BEGIN ORDER BY o.date_created DESC LIMIT 1, 1; - RETURN IF (currentRegimen <> previousRegimen, currentRegimen, NULL); + IF (currentRegimen <> previousRegimen) THEN + SET p_regimen = currentRegimen; + SET p_switchDate = switchDate; + END IF; + +END$$ +DELIMITER ; + +-- getRegimenSwitch + +DROP FUNCTION IF EXISTS getRegimenSwitch; + +DELIMITER $$ +CREATE FUNCTION getRegimenSwitch( + p_patientId INT(11), + p_startDate DATE, + p_endDate DATE) RETURNS VARCHAR(250) + DETERMINISTIC +BEGIN + + DECLARE regimen VARCHAR(250); + DECLARE switchDate DATE; + + CALL retrieveRegimenSwitchARVandDate(p_patientId, p_startDate, p_endDate, regimen, switchDate); + + RETURN regimen; + +END$$ +DELIMITER ; + +-- getRegimenSwitchDate + +DROP FUNCTION IF EXISTS getRegimenSwitchDate; + +DELIMITER $$ +CREATE FUNCTION getRegimenSwitchDate( + p_patientId INT(11), + p_startDate DATE, + p_endDate DATE) RETURNS VARCHAR(250) + DETERMINISTIC +BEGIN + + DECLARE regimen VARCHAR(250); + DECLARE switchDate DATE; + + CALL retrieveRegimenSwitchARVandDate(p_patientId, p_startDate, p_endDate, regimen, switchDate); + + RETURN switchDate; + END$$ DELIMITER ; diff --git a/openmrs/apps/reports/RADET/sql/treatment.sql b/openmrs/apps/reports/RADET/sql/treatment.sql index 2e83a232..e1703d71 100644 --- a/openmrs/apps/reports/RADET/sql/treatment.sql +++ b/openmrs/apps/reports/RADET/sql/treatment.sql @@ -19,7 +19,7 @@ SELECT getPatientDateOfEnrolmentInProgram(p.patient_id, "HIV_PROGRAM_KEY") AS "E getPatientMostRecentProgramAttributeCodedValue(p.patient_id, "397b7bc7-13ca-4e4e-abc3-bf854904dce3", "en") as "Current Regimen Line/ Ligne de régime actuelle", getListOfActiveARVDrugs(p.patient_id, '#startDate#', '#endDate#') as "Current ART Regimen/ Régime d'ART actuel", getRegimenSwitch(p.patient_id, "2010-01-01", "#endDate#") as "Regimen Switch/ Commutateur de régime", - "N/A" as "Date of Regimen switch (limit only to the current reporting month)", + getRegimenSwitchDate(p.patient_id, "2010-01-01", "#endDate#") as "Date of Regimen switch (limit only to the current reporting month)", getPregnancyStatus(p.patient_id) as "Pregnancy Status/ Statut de grossesse", getMostRecentCodedObservation(p.patient_id,"HTC, Risk Group","en") as "KP Status", getViralLoadTestResult(p.patient_id) as "Current Viral Load / Charge virale actuelle (c/ml)", From 58344b949d56cc46af854d1a8f4ff054a47d7fb7 Mon Sep 17 00:00:00 2001 From: Tresor Mvumbi Date: Fri, 19 Jun 2020 10:07:13 +0200 Subject: [PATCH 3/3] COM-851 Fix retrieveRegimenSwitchARVandDate to use drug regim The previous code was comparing single drug orders, instead of regimens --- metadata/reportssql/drug_functions.sql | 43 +++++++++++++++++++++++--- 1 file changed, 39 insertions(+), 4 deletions(-) diff --git a/metadata/reportssql/drug_functions.sql b/metadata/reportssql/drug_functions.sql index 9b4ab516..7c88925d 100644 --- a/metadata/reportssql/drug_functions.sql +++ b/metadata/reportssql/drug_functions.sql @@ -291,13 +291,15 @@ CREATE PROCEDURE retrieveRegimenSwitchARVandDate( OUT p_switchDate DATE ) DETERMINISTIC - BEGIN -- proc_retrieve_regimen_switch_and_date: + proc_retrieve_regimen_switch_and_date:BEGIN + DECLARE currentEncounterId INT(11); + DECLARE previousEncounterId INT(11); DECLARE currentRegimen VARCHAR(250); DECLARE previousRegimen VARCHAR(250); DECLARE switchDate DATE; - SELECT d.name, o.date_created INTO currentRegimen, switchDate + SELECT o.encounter_id INTO currentEncounterId FROM orders o JOIN drug_order do ON do.order_id = o.order_id JOIN drug d ON d.drug_id = do.drug_inventory_id AND d.retired = 0 @@ -308,7 +310,11 @@ CREATE PROCEDURE retrieveRegimenSwitchARVandDate( ORDER BY o.date_created DESC LIMIT 1; - SELECT d.name INTO previousRegimen + IF (currentEncounterId IS NULL) THEN + LEAVE proc_retrieve_regimen_switch_and_date; + END IF; + + SELECT o.encounter_id INTO previousEncounterId FROM orders o JOIN drug_order do ON do.order_id = o.order_id JOIN drug d ON d.drug_id = do.drug_inventory_id AND d.retired = 0 @@ -316,8 +322,37 @@ CREATE PROCEDURE retrieveRegimenSwitchARVandDate( AND o.date_created BETWEEN p_startDate AND p_endDate AND drugIsARV(d.concept_id) AND drugOrderIsDispensed(o.patient_id, o.order_id) + AND o.encounter_id <> currentEncounterId ORDER BY o.date_created DESC - LIMIT 1, 1; + LIMIT 1; + + IF (previousEncounterId IS NULL) THEN + LEAVE proc_retrieve_regimen_switch_and_date; + END IF; + + SELECT GROUP_CONCAT(DISTINCT d.name), o.date_created INTO currentRegimen, switchDate + FROM orders o + JOIN drug_order do ON do.order_id = o.order_id + JOIN drug d ON d.drug_id = do.drug_inventory_id AND d.retired = 0 + WHERE o.voided = 0 + AND o.encounter_id = currentEncounterId + AND o.date_created BETWEEN p_startDate AND p_endDate + AND drugIsARV(d.concept_id) + AND drugOrderIsDispensed(o.patient_id, o.order_id) + ORDER BY d.name DESC -- 2 regimens with the same drugs but not in the same order should be considered the same + LIMIT 1; + + SELECT GROUP_CONCAT(DISTINCT d.name) INTO previousRegimen + FROM orders o + JOIN drug_order do ON do.order_id = o.order_id + JOIN drug d ON d.drug_id = do.drug_inventory_id AND d.retired = 0 + WHERE o.voided = 0 + AND o.encounter_id = previousEncounterId + AND o.date_created BETWEEN p_startDate AND p_endDate + AND drugIsARV(d.concept_id) + AND drugOrderIsDispensed(o.patient_id, o.order_id) + ORDER BY d.name DESC + LIMIT 1; IF (currentRegimen <> previousRegimen) THEN SET p_regimen = currentRegimen;