-
Notifications
You must be signed in to change notification settings - Fork 6
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
COM-851 TX_PLVS: Column - Date of Regimen switch (limit only to the current reporting month) #323
Open
tmvumbi2
wants to merge
3
commits into
dev
Choose a base branch
from
COM-851
base: dev
Could not load branches
Branch not found: {{ refName }}
Loading
Could not load tags
Nothing to show
Loading
Are you sure you want to change the base?
Some commits from the old base branch may be removed from the timeline,
and old review comments may become outdated.
Open
Changes from all commits
Commits
Show all changes
3 commits
Select commit
Hold shift + click to select a range
File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -276,7 +276,135 @@ BEGIN | |
RETURN (result); | ||
END$$ | ||
|
||
DELIMITER ; | ||
DELIMITER ; | ||
|
||
-- retrieveRegimenSwitchARVandDate | ||
|
||
DROP PROCEDURE IF EXISTS retrieveRegimenSwitchARVandDate; | ||
|
||
DELIMITER $$ | ||
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 | ||
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 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 | ||
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; | ||
|
||
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 | ||
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) | ||
AND o.encounter_id <> currentEncounterId | ||
ORDER BY o.date_created DESC | ||
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 | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. @tmvumbi2 Why checking date created for this regimen? |
||
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; | ||
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 ; | ||
|
||
-- getInfantARVProphylaxis | ||
|
||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -18,8 +18,8 @@ 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", | ||
"N/A" as "Date of Regimen switch (limit only to the current reporting month)", | ||
getRegimenSwitch(p.patient_id, "2010-01-01", "#endDate#") as "Regimen Switch/ Commutateur de régime", | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. @tmvumbi2 Remember to use 2000 instead of 2010 in case there's data entered for before 2010 |
||
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)", | ||
|
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
@tmvumbi2 Isn't it better to use o.encounter_id < currentEncounterId and not check the date for this one?