-
Notifications
You must be signed in to change notification settings - Fork 6
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #337 from jembi/dev
Staging deployment 29 Jun 2020
- Loading branch information
Showing
75 changed files
with
31,783 additions
and
2,961 deletions.
There are no files selected for viewing
Binary file not shown.
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 |
---|---|---|
@@ -0,0 +1,152 @@ | ||
-- patientHasScheduledAnARTAppointmentDuringReportingPeriod | ||
|
||
DROP FUNCTION IF EXISTS patientHasScheduledAnARTAppointment; | ||
|
||
DELIMITER $$ | ||
CREATE FUNCTION patientHasScheduledAnARTAppointment( | ||
p_patientId INT(11), | ||
p_startDate DATE, | ||
p_endDate DATE, | ||
p_monthOffset INT(11)) RETURNS TINYINT(1) | ||
DETERMINISTIC | ||
BEGIN | ||
DECLARE result TINYINT(1) DEFAULT 0; | ||
|
||
SELECT TRUE INTO result | ||
FROM patient_appointment pa | ||
JOIN appointment_service aps ON aps.appointment_service_id = pa.appointment_service_id AND aps.voided = 0 | ||
WHERE pa.voided = 0 | ||
AND pa.patient_id = p_patientId | ||
AND pa.start_date_time BETWEEN TIMESTAMPADD(MONTH,p_monthOffset,p_startDate) AND TIMESTAMPADD(MONTH,p_monthOffset,p_endDate) | ||
AND (aps.name = "APPOINTMENT_SERVICE_ART_KEY" OR aps.name = "APPOINTMENT_SERVICE_ART_DISPENSARY_KEY") | ||
GROUP BY pa.patient_id; | ||
|
||
RETURN (result ); | ||
END$$ | ||
DELIMITER ; | ||
|
||
|
||
-- patientHasScheduledAnAppointmentDuringReportingPeriod | ||
|
||
DROP FUNCTION IF EXISTS patientHasScheduledAnAppointmentDuringReportingPeriod; | ||
|
||
DELIMITER $$ | ||
CREATE FUNCTION patientHasScheduledAnAppointmentDuringReportingPeriod( | ||
p_patientId INT(11), | ||
p_startDate DATE, | ||
p_endDate DATE, | ||
p_service VARCHAR(50)) RETURNS VARCHAR(3) | ||
DETERMINISTIC | ||
BEGIN | ||
DECLARE result VARCHAR(3) DEFAULT "No"; | ||
|
||
SELECT "Yes" INTO result | ||
FROM patient_appointment pa | ||
JOIN appointment_service aps ON aps.appointment_service_id = pa.appointment_service_id AND aps.voided = 0 | ||
WHERE pa.voided = 0 | ||
AND pa.patient_id = p_patientId | ||
AND pa.start_date_time BETWEEN p_startDate AND p_endDate | ||
AND (aps.name = p_service) | ||
GROUP BY pa.patient_id; | ||
|
||
RETURN (result); | ||
END$$ | ||
DELIMITER ; | ||
|
||
|
||
-- getNumberOfScheduledAppointmentsDuringReportingPeriod | ||
|
||
DROP FUNCTION IF EXISTS getNumberOfScheduledAppointmentsDuringReportingPeriod; | ||
|
||
DELIMITER $$ | ||
CREATE FUNCTION getNumberOfScheduledAppointmentsDuringReportingPeriod( | ||
p_patientId INT(11), | ||
p_startDate DATE, | ||
p_endDate DATE, | ||
p_service VARCHAR(50)) RETURNS INT(11) | ||
DETERMINISTIC | ||
BEGIN | ||
DECLARE result INT(11) DEFAULT 0; | ||
|
||
SELECT count(DISTINCT pa.patient_appointment_id) INTO result | ||
FROM patient_appointment pa | ||
JOIN appointment_service aps ON aps.appointment_service_id = pa.appointment_service_id AND aps.voided = 0 | ||
WHERE pa.voided = 0 | ||
AND pa.patient_id = p_patientId | ||
AND pa.start_date_time BETWEEN p_startDate AND p_endDate | ||
AND (aps.name = p_service) | ||
GROUP BY pa.patient_id; | ||
|
||
RETURN (result); | ||
END$$ | ||
DELIMITER ; | ||
|
||
-- getDateOfLastScheduledAppointment | ||
|
||
DROP FUNCTION IF EXISTS getDateOfLastScheduledAppointment; | ||
|
||
DELIMITER $$ | ||
CREATE FUNCTION getDateOfLastScheduledAppointment( | ||
p_patientId INT(11), | ||
p_service VARCHAR(50)) RETURNS DATE | ||
DETERMINISTIC | ||
BEGIN | ||
DECLARE result DATE; | ||
|
||
SELECT pa.start_date_time INTO result | ||
FROM patient_appointment pa | ||
JOIN appointment_service aps ON aps.appointment_service_id = pa.appointment_service_id AND aps.voided = 0 | ||
WHERE pa.voided = 0 | ||
AND pa.patient_id = p_patientId | ||
AND aps.name = p_service | ||
ORDER BY pa.start_date_time DESC | ||
LIMIT 1; | ||
|
||
RETURN (result); | ||
END$$ | ||
DELIMITER ; | ||
|
||
-- getDateOfLastScheduledARTOrARTDispensaryAppointment | ||
|
||
DROP FUNCTION IF EXISTS getDateOfLastScheduledARTOrARTDispensaryAppointment; | ||
|
||
DELIMITER $$ | ||
CREATE FUNCTION getDateOfLastScheduledARTOrARTDispensaryAppointment( | ||
p_patientId INT(11)) RETURNS DATE | ||
DETERMINISTIC | ||
BEGIN | ||
DECLARE dateLastARTAppointment DATE DEFAULT getDateOfLastScheduledAppointment(p_patientId, "APPOINTMENT_SERVICE_ART_KEY"); | ||
DECLARE dateLastARTDispensaryAppoint DATE DEFAULT getDateOfLastScheduledAppointment(p_patientId, "APPOINTMENT_SERVICE_ART_DISPENSARY_KEY"); | ||
|
||
RETURN getGreatestDate(dateLastARTAppointment, dateLastARTDispensaryAppoint); | ||
END$$ | ||
DELIMITER ; | ||
|
||
-- getNextARTPickupDate | ||
|
||
DROP FUNCTION IF EXISTS getNextARTPickupDate; | ||
|
||
DELIMITER $$ | ||
CREATE FUNCTION getNextARTPickupDate( | ||
p_patientId INT(11), | ||
p_endDate DATE) RETURNS DATE | ||
DETERMINISTIC | ||
BEGIN | ||
DECLARE lastArvPickupDate DATE DEFAULT getLastArvPickupDate(p_patientId, '2000-01-01', p_endDate); | ||
|
||
IF lastArvPickupDate IS NULL THEN | ||
RETURN NULL; | ||
END IF; | ||
|
||
RETURN( | ||
SELECT pa.start_date_time | ||
FROM patient_appointment pa | ||
JOIN appointment_service aps ON aps.appointment_service_id = pa.appointment_service_id AND aps.voided = 0 | ||
WHERE pa.voided = 0 | ||
AND pa.patient_id = p_patientId | ||
AND (aps.name = "APPOINTMENT_SERVICE_ART_KEY" OR aps.name = "APPOINTMENT_SERVICE_ART_DISPENSARY_KEY") | ||
AND pa.start_date_time > lastArvPickupDate | ||
ORDER BY pa.start_date_time DESC | ||
LIMIT 1); | ||
END$$ | ||
DELIMITER ; |
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 |
---|---|---|
@@ -0,0 +1,149 @@ | ||
|
||
-- patientAgeWhenRegisteredForHivProgramIsBetween | ||
|
||
DROP FUNCTION IF EXISTS patientAgeWhenRegisteredForHivProgramIsBetween; | ||
|
||
DELIMITER $$ | ||
CREATE FUNCTION patientAgeWhenRegisteredForHivProgramIsBetween( | ||
p_patientId INT(11), | ||
p_startAge INT(11), | ||
p_endAge INT(11), | ||
p_includeEndAge TINYINT(1)) RETURNS TINYINT(1) | ||
DETERMINISTIC | ||
BEGIN | ||
DECLARE result TINYINT(1) DEFAULT 0; | ||
SELECT | ||
IF (p_includeEndAge, | ||
timestampdiff(YEAR, p.birthdate, pp.date_enrolled) BETWEEN p_startAge AND p_endAge, | ||
timestampdiff(YEAR, p.birthdate, pp.date_enrolled) >= p_startAge | ||
AND timestampdiff(YEAR, p.birthdate, pp.date_enrolled) < p_endAge | ||
) INTO result | ||
FROM person p | ||
JOIN patient_program pp ON pp.patient_id = p.person_id AND pp.voided = 0 | ||
JOIN program pro ON pp.program_id = pro.program_id AND pro.retired = 0 | ||
WHERE p.person_id = p_patientId AND p.voided = 0 | ||
AND pro.name = "HIV_PROGRAM_KEY" | ||
GROUP BY pro.name; | ||
|
||
RETURN (result ); | ||
END$$ | ||
DELIMITER ; | ||
|
||
-- patientIsPregnant | ||
|
||
DROP FUNCTION IF EXISTS patientIsPregnant; | ||
|
||
DELIMITER $$ | ||
CREATE FUNCTION patientIsPregnant( | ||
p_patientId INT(11)) RETURNS TINYINT(1) | ||
DETERMINISTIC | ||
BEGIN | ||
DECLARE patientPregnant TINYINT(1) DEFAULT 0; | ||
|
||
DECLARE uuidPatientIsPregnant VARCHAR(38) DEFAULT "279583bf-70d4-40b5-82e9-6cb29fbe00b4"; | ||
|
||
SELECT TRUE INTO patientPregnant | ||
FROM obs o | ||
JOIN concept c ON c.concept_id = o.concept_id AND c.retired = 0 | ||
WHERE o.voided = 0 | ||
AND o.person_id = p_patientId | ||
AND c.uuid = uuidPatientIsPregnant | ||
GROUP BY c.uuid; | ||
|
||
RETURN (patientPregnant ); | ||
END$$ | ||
DELIMITER ; | ||
|
||
-- getPregnancyStatus | ||
|
||
DROP FUNCTION IF EXISTS getPregnancyStatus; | ||
|
||
DELIMITER $$ | ||
CREATE FUNCTION getPregnancyStatus( | ||
p_patientId INT(11)) RETURNS VARCHAR(250) | ||
DETERMINISTIC | ||
BEGIN | ||
DECLARE pregrantStatusObsDate1 DATETIME DEFAULT getObsLastModifiedDate(p_patientId, "279583bf-70d4-40b5-82e9-6cb29fbe00b4"); | ||
DECLARE pregrantStatusObsDate2 DATETIME DEFAULT getObsLastModifiedDate(p_patientId, "b2e1ffa5-a6a8-4f3d-b797-25f11a66293b"); | ||
DECLARE pregrancyStatus VARCHAR(250) DEFAULT ""; | ||
|
||
IF pregrantStatusObsDate1 >= pregrantStatusObsDate2 OR pregrantStatusObsDate1 IS NULL THEN | ||
SET pregrancyStatus = getMostRecentCodedObservation(p_patientId,"HTC, Pregnancy Status","en"); | ||
ELSEIF pregrantStatusObsDate1 < pregrantStatusObsDate2 OR pregrantStatusObsDate2 IS NULL THEN | ||
SET pregrancyStatus = getMostRecentCodedObservation(p_patientId,"Pregnancy","en"); | ||
ELSE | ||
RETURN NULL; | ||
END IF; | ||
|
||
RETURN | ||
CASE | ||
WHEN pregrancyStatus = "Yes full name" THEN "Pregnant" | ||
WHEN pregrancyStatus = "No full name" THEN "Not Pregnant" | ||
WHEN pregrancyStatus = "Do not know" THEN "Do not know" | ||
WHEN pregrancyStatus = "Not Applicable" THEN "Not Applicable" | ||
ELSE NULL | ||
END; | ||
|
||
END$$ | ||
DELIMITER ; | ||
|
||
-- calculateTreatmentEndDate | ||
|
||
DROP FUNCTION IF EXISTS calculateTreatmentEndDate; | ||
|
||
DELIMITER $$ | ||
CREATE FUNCTION calculateTreatmentEndDate( | ||
p_startDate DATE, | ||
p_duration INT(11), | ||
p_uuidDurationUnit VARCHAR(38)) RETURNS DATE | ||
DETERMINISTIC | ||
BEGIN | ||
|
||
DECLARE result DATE; | ||
DECLARE uuidMinute VARCHAR(38) DEFAULT '33bc78b1-8a92-11e4-977f-0800271c1b75'; | ||
DECLARE uuidHour VARCHAR(38) DEFAULT 'bb62c684-3f10-11e4-adec-0800271c1b75'; | ||
DECLARE uuidDay VARCHAR(38) DEFAULT '9d7437a9-3f10-11e4-adec-0800271c1b75'; | ||
DECLARE uuidWeek VARCHAR(38) DEFAULT 'bb6436e3-3f10-11e4-adec-0800271c1b75'; | ||
DECLARE uuidMonth VARCHAR(38) DEFAULT 'bb655344-3f10-11e4-adec-0800271c1b75'; | ||
|
||
IF p_uuidDurationUnit = uuidMinute THEN | ||
SET result = timestampadd(MINUTE, p_duration, p_startDate); | ||
ELSEIF p_uuidDurationUnit = uuidHour THEN | ||
SET result = timestampadd(HOUR, p_duration, p_startDate); | ||
ELSEIF p_uuidDurationUnit = uuidDay THEN | ||
SET result = timestampadd(DAY, p_duration, p_startDate); | ||
ELSEIF p_uuidDurationUnit = uuidWeek THEN | ||
SET result = timestampadd(WEEK, p_duration, p_startDate); | ||
ELSEIF p_uuidDurationUnit = uuidMonth THEN | ||
SET result = timestampadd(MONTH, p_duration, p_startDate); | ||
END IF; | ||
|
||
RETURN (result); | ||
END$$ | ||
|
||
DELIMITER ; | ||
|
||
-- getLabTestOrderDate | ||
|
||
DROP FUNCTION IF EXISTS getLabTestOrderDate; | ||
|
||
DELIMITER $$ | ||
CREATE FUNCTION getLabTestOrderDate( | ||
p_patientId INT(11), | ||
p_labTestName VARCHAR(255), | ||
p_startDate DATE, | ||
p_endDate DATE) RETURNS DATE | ||
DETERMINISTIC | ||
BEGIN | ||
RETURN ( | ||
SELECT o.date_activated | ||
FROM orders o | ||
JOIN concept_name cn ON o.concept_id = cn.concept_id | ||
WHERE o.patient_id = p_patientId AND o.voided = 0 | ||
AND o.date_activated BETWEEN p_startDate AND p_endDate | ||
AND cn.locale='en' AND cn.concept_name_type = 'FULLY_SPECIFIED' | ||
AND cn.name = p_labTestName | ||
ORDER BY o.date_activated DESC | ||
LIMIT 1); | ||
END$$ | ||
DELIMITER ; |
Oops, something went wrong.