diff --git a/Care/Clinical/physicalaiddelivery_pallium.md b/Care/Clinical/physicalaiddelivery_pallium.md new file mode 100644 index 0000000..96f0691 --- /dev/null +++ b/Care/Clinical/physicalaiddelivery_pallium.md @@ -0,0 +1,105 @@ +# Physical Aid Delivery + +> Analyze the distribution of physical aids delivered to patients across the organization + +## Purpose + +Track and analyze the types of physical aids delivered to patients, including count of patients receiving each aid type. + +## Parameters + +| Parameter | Type | Description | Example | +|-----------|------|-------------|---------| +| `date` | DATE | Filter by delivery date range | `2025-12-01 TO 2025-12-31` | +| `patient_name` | TEXT | Filter by specific patient | `John Doe` | +| `staff_name` | TEXT | Filter by staff member who delivered aid | `Jane Smith` | + +--- + +## Query + +```sql +SELECT + aid.physical_aid, + COUNT(DISTINCT qr.patient_id) AS patient_count +FROM emr_questionnaireresponse qr +JOIN emr_patient p ON qr.patient_id = p.id +JOIN users_user u ON qr.created_by_id = u.id +JOIN LATERAL ( + SELECT + UPPER(TRIM(REPLACE(val ->> 'value', '_', ' '))) AS physical_aid + FROM jsonb_array_elements(qr.responses) resp + JOIN LATERAL jsonb_array_elements(resp -> 'values') val ON TRUE + WHERE resp ->> 'question_id' = 'd78cee94-461d-46a8-98ac-f57b36584b1d' +) aid ON TRUE +WHERE qr.questionnaire_id = 18 +-- [[AND {{date}}]] +-- [[AND p.name = {{patient_name}}]] +-- [[AND TRIM(u.first_name || ' ' || COALESCE(u.last_name, '')) = {{staff_name}}]] +GROUP BY aid.physical_aid +ORDER BY patient_count DESC, aid.physical_aid; +``` + + +--- + +## Drill-Down Query + +> Returns detailed patient information for each physical aid delivered, including staff, and delivery details. + +### Purpose + +To provide a detailed list of patients for each physical aid type, supporting patient-level review and aid delivery tracking. + +### Parameters + +| Parameter | Type | Description | Example | +|-----------|------|-------------|---------| +| `date` | DATE | Filter by delivery date (optional) | `2025-12-01 TO 2025-12-31` | +| `patient_name` | TEXT | Filter by patient name (optional) | `John Doe` | +| `staff_name` | TEXT | Filter by staff full name (optional) | `Jane Smith` | +| `physical_aid` | TEXT | Filter by physical aid type (optional) | `CRUTCHES` | + +--- + +```sql +SELECT + p.name AS patient_name, + p.gender, + EXTRACT(YEAR FROM CURRENT_DATE) - p.year_of_birth AS age, + p.phone_number, + p.address, + pi.value AS mrnumber, + qr.created_date AS delivery_date, + TRIM(u.first_name || ' ' || COALESCE(u.last_name, '')) AS staff_name, + aid.physical_aid +FROM emr_questionnaireresponse qr +JOIN emr_patient p ON qr.patient_id = p.id +LEFT JOIN emr_patientidentifier pi ON pi.patient_id = p.id AND pi.config_id = 5 +JOIN users_user u ON qr.created_by_id = u.id +JOIN LATERAL ( + SELECT + UPPER(TRIM(REPLACE(val ->> 'value', '_', ' '))) AS physical_aid + FROM jsonb_array_elements(qr.responses) resp + JOIN LATERAL jsonb_array_elements(resp -> 'values') val ON TRUE + WHERE resp ->> 'question_id' = 'd78cee94-461d-46a8-98ac-f57b36584b1d' +) aid ON TRUE +WHERE qr.questionnaire_id = 18 +-- [[AND {{date}}]] +-- [[AND p.name = {{patient_name}}]] +-- [[AND TRIM(u.first_name || ' ' || COALESCE(u.last_name, '')) = {{staff_name}}]] +-- [[AND aid.physical_aid ILIKE '%' || {{physical_aid}} || '%']] +ORDER BY delivery_date DESC, patient_name, aid.physical_aid; +``` + + +## Notes + +- Metabase-specific filters (`[[...]]`) allow dynamic filtering in dashboards. +- The query uses `questionnaire_id = 18` to identify Physical Aid Delivery forms. +- Specific question_id `d78cee94-461d-46a8-98ac-f57b36584b1d` is used to extract physical aid data. +- The `config_id = 5` condition is used to select the correct Medical Record number (mrnumber) for each patient. +- Ensure all referenced tables and fields exist and are mapped correctly. +- All filters are optional and applied dynamically by Metabase. + +*Last updated: 2025-12-16* diff --git a/Care/Clinical/physiotherapyservices_pallium.md b/Care/Clinical/physiotherapyservices_pallium.md new file mode 100644 index 0000000..269d45e --- /dev/null +++ b/Care/Clinical/physiotherapyservices_pallium.md @@ -0,0 +1,201 @@ +# Physiotherapy Services + +> Returns the count of patients by physiotherapy services provided, with optional filters for visit date, patient, and staff. + +## Purpose + +To analyze the distribution of physiotherapy services provided to patients, supporting clinical reporting and rehabilitation service utilization analysis. + +## Parameters + +| Parameter | Type | Description | Example | +|---------------|--------|---------------------------------------------|----------------| +| `visit_date` | DATE | Filter by visit date (optional) | '2025-12-01' | +| `patient_name` | TEXT | Filter by patient name (optional) | 'John Doe' | +| `staff_name` | TEXT | Filter by staff full name (optional) | 'Jane Smith' | + +--- + +## Query + +```sql +WITH responses AS ( + SELECT + emr_questionnaireresponse.patient_id, + emr_questionnaireresponse.created_date, + emr_questionnaireresponse.created_by_id, + emr_questionnaireresponse.questionnaire_id, + resp ->> 'question_id' AS question_id, + UPPER( + TRIM( + REPLACE( + COALESCE(val ->> 'value', val -> 'coding' ->> 'display'), + '_', + ' ' + ) + ) + ) AS response_value + FROM + emr_questionnaireresponse + LEFT JOIN emr_encounter e ON emr_questionnaireresponse.encounter_id = e.id, + jsonb_array_elements(emr_questionnaireresponse.responses) AS resp, + jsonb_array_elements(resp -> 'values') AS val + WHERE + emr_questionnaireresponse.questionnaire_id IN (19,20) + AND resp ->> 'question_id' IN ( + 'dfb3a53f-2200-4331-b395-0509a388b180', + '3a26c703-38b2-4da9-8a62-030efbb53461' + ) + + --The following filters are Metabase-specific and will be replaced by Metabase if parameters are provided: + /* + [[AND {{visit_date}}]] + */ +) +SELECT + r.response_value AS PROCEDURE, + COUNT(DISTINCT (r.patient_id, r.created_date)) AS patient_count +FROM + responses r +JOIN emr_patient p ON r.patient_id = p.id +LEFT JOIN users_user u ON r.created_by_id = u.id +WHERE 1=1 + + -- The following filters are Metabase-specific and will be replaced by Metabase if parameters are provided: + /* + [[AND p.name = {{patient_name}} ]] + [[AND TRIM(u.first_name || ' ' || COALESCE(u.last_name, '')) = {{staff_name}} ]] + */ +GROUP BY + r.response_value +ORDER BY + patient_count DESC; +``` + +## Drill-Down Query + +> Returns detailed patient information for each physiotherapy service provided, including staff, encounter, and link center. + +### Purpose + +To provide a detailed list of patients for each physiotherapy service, supporting patient-level review and service tracking. + +### Parameters + +| Parameter | Type | Description | Example | +|---------------|--------|---------------------------------------------|----------------| +| `visit_date` | DATE | Filter by visit date (optional) | '2025-12-01' | +| `Service` | TEXT | Filter by physiotherapy service (optional) | 'EXERCISE' | +| `patient_name` | TEXT | Filter by patient name (optional) | 'John Doe' | +| `link_center` | TEXT | Filter by link center (optional) | 'CENTER A' | +| `staff_name` | TEXT | Filter by staff full name (optional) | 'Jane Smith' | + +--- + +```sql +-- CTE for latest link center per patient +WITH latest_link_center AS ( + SELECT DISTINCT ON (qr.patient_id) + qr.patient_id, + UPPER( + TRIM( + REPLACE( + COALESCE(val ->> 'value', val -> 'coding' ->> 'display'), + '_', + ' ' + ) + ) + ) AS link_center, + qr.created_date + FROM + emr_questionnaireresponse qr, + jsonb_array_elements(qr.responses) AS resp, + jsonb_array_elements(resp -> 'values') AS val + WHERE + qr.questionnaire_id IN (19,20) + AND resp ->> 'question_id' IN ( '4741c337-b66e-4269-85d5-f7752db6b14d', 'b05fa832-f38a-4b70-8fb9-cb7d59c00a41') + + --The following filters are Metabase-specific and will be replaced by Metabase if parameters are provided: + /* + --[[AND {{visit_date}}]] + */ + ORDER BY + qr.patient_id, qr.created_date DESC +) + +SELECT + r.response_value AS procedure, + p.name AS patient_name, + p.gender, + p.phone_number, + EXTRACT(YEAR FROM CURRENT_DATE) - p.year_of_birth AS age, + p.address, + pi.value AS MRnumber, + TRIM(s.first_name || ' ' || COALESCE(s.last_name, '')) AS staff_name, + r.created_date, + r.questionnaire_id, + e.encounter_class, + llc.link_center AS latest_link_center +FROM ( + SELECT + qr.patient_id, + qr.created_date, + qr.created_by_id, + qr.questionnaire_id, + qr.encounter_id, + resp ->> 'question_id' AS question_id, + UPPER( + TRIM( + REPLACE( + COALESCE(val ->> 'value', val -> 'coding' ->> 'display'), + '_', + ' ' + ) + ) + ) AS response_value + FROM + emr_questionnaireresponse qr, + jsonb_array_elements(qr.responses) AS resp, + jsonb_array_elements(resp -> 'values') AS val + WHERE + qr.questionnaire_id IN (19,20) + AND resp ->> 'question_id' IN ( + 'dfb3a53f-2200-4331-b395-0509a388b180', + '3a26c703-38b2-4da9-8a62-030efbb53461' + ) + + --The following filters are Metabase-specific and will be replaced by Metabase if parameters are provided: + /* + [[AND {{visit_date}}]] + */ +) r +JOIN emr_patient p ON r.patient_id = p.id +LEFT JOIN emr_encounter e ON r.encounter_id = e.id +LEFT JOIN emr_patientidentifier pi ON pi.patient_id = p.id AND pi.config_id = 5 +LEFT JOIN users_user s ON r.created_by_id = s.id +LEFT JOIN latest_link_center llc ON p.id = llc.patient_id +WHERE + p.deleted = FALSE + + --The following filters are Metabase-specific and will be replaced by Metabase if parameters are provided: + /* + [[AND r.response_value = {{Service}} ]] + [[AND p.name ILIKE {{patient_name}} ]] + [[AND llc.link_center ILIKE '%' || {{link_center}} || '%']] + [[AND TRIM(s.first_name || ' ' || COALESCE(s.last_name, '')) = {{staff_name}} ]] + */ +ORDER BY r.created_date DESC, patient_name; +``` + + +## Notes + +- Metabase-specific filters (`[[...]]`) allow dynamic filtering in dashboards. +- The queries use `questionnaire_id IN (19, 20)` to identify physiotherapy services forms. +- Specific question_ids are used to extract services provided data and link center information. +- The drill-down query includes the latest link center per patient using a CTE. +- The `config_id = 5` condition is used to select the correct Medical Record number (MRnumber) for each patient. +- Ensure all referenced tables and fields exist and are mapped correctly. +- All filters are optional and applied dynamically by Metabase. + +*Last updated: 2025-12-16* diff --git a/Care/Clinical/psychologyservices_pallium.md b/Care/Clinical/psychologyservices_pallium.md new file mode 100644 index 0000000..eef3d52 --- /dev/null +++ b/Care/Clinical/psychologyservices_pallium.md @@ -0,0 +1,197 @@ +# Psychology Services (Pallium) + +> Returns the count of patients by psychology services provided, with optional filters for visit date, patient, and staff. + +## Purpose + +To analyze the distribution of psychology services provided to patients, supporting clinical reporting and mental health service utilization analysis. + +## Parameters + +| Parameter | Type | Description | Example | +|---------------|--------|---------------------------------------------|----------------| +| `visit_date` | DATE | Filter by visit date (optional) | '2025-12-01' | +| `patient_name` | TEXT | Filter by patient name (optional) | 'John Doe' | +| `staff_name` | TEXT | Filter by staff full name (optional) | 'Jane Smith' | + +--- + +## Query + +```sql +WITH responses AS ( + SELECT + emr_questionnaireresponse.patient_id, + emr_questionnaireresponse.created_date, + emr_questionnaireresponse.created_by_id, + emr_questionnaireresponse.questionnaire_id, + resp ->> 'question_id' AS question_id, + UPPER( + TRIM( + REPLACE( + COALESCE(val ->> 'value', val -> 'coding' ->> 'display'), + '_', + ' ' + ) + ) + ) AS response_value + FROM + emr_questionnaireresponse + LEFT JOIN emr_encounter e ON emr_questionnaireresponse.encounter_id = e.id, + jsonb_array_elements(emr_questionnaireresponse.responses) AS resp, + jsonb_array_elements(resp -> 'values') AS val + WHERE + emr_questionnaireresponse.questionnaire_id IN (21,22) + AND resp ->> 'question_id' IN ( + '1d13528d-89ea-4057-bf01-aca909d62d9e', + '520d1879-ad9b-4bab-b490-209c10068e71' + ) + /* + --The following filters are Metabase-specific and will be replaced by Metabase if parameters are provided: + [[AND {{visit_date}}]] + */ +) +SELECT + r.response_value AS PROCEDURE, + COUNT(DISTINCT (r.patient_id, r.created_date)) AS patient_count +FROM + responses r +JOIN emr_patient p ON r.patient_id = p.id +LEFT JOIN users_user u ON r.created_by_id = u.id +WHERE 1=1 + /* + --The following filters are Metabase-specific and will be replaced by Metabase if parameters are provided: + [[AND p.name = {{patient_name}} ]] + [[AND TRIM(u.first_name || ' ' || COALESCE(u.last_name, '')) = {{staff_name}} ]] + */ +GROUP BY + r.response_value +ORDER BY + patient_count DESC; +``` + + +## Drill-Down Query + +> Returns detailed patient information for each psychology service provided, staff, encounter, and link center. + +### Purpose + +To provide a detailed list of patients for each psychology service, supporting patient-level review and service tracking. + +### Parameters + +| Parameter | Type | Description | Example | +|---------------|--------|---------------------------------------------|----------------| +| `visit_date` | DATE | Filter by visit date (optional) | '2025-12-01' | +| `Service` | TEXT | Filter by psychology service (optional) | 'COUNSELING' | +| `patient_name` | TEXT | Filter by patient name (optional) | 'John Doe' | +| `link_center` | TEXT | Filter by link center (optional) | 'CENTER A' | +| `staff_name` | TEXT | Filter by staff full name (optional) | 'Jane Smith' | + +--- + +```sql +-- CTE for latest link center per patient +WITH latest_link_center AS ( + SELECT DISTINCT ON (qr.patient_id) + qr.patient_id, + UPPER( + TRIM( + REPLACE( + COALESCE(val ->> 'value', val -> 'coding' ->> 'display'), + '_', + ' ' + ) + ) + ) AS link_center, + qr.created_date + FROM + emr_questionnaireresponse qr, + jsonb_array_elements(qr.responses) AS resp, + jsonb_array_elements(resp -> 'values') AS val + WHERE + qr.questionnaire_id IN (21,22) + AND resp ->> 'question_id' IN( 'dc67f745-8293-4e36-9180-fba655a37b36', '9c9f2d13-c593-4f11-92f7-a513d78379e3') + /* + --The following filters are Metabase-specific and will be replaced by Metabase if parameters are provided: + [[AND {{visit_date}}]] + */ + ORDER BY + qr.patient_id, qr.created_date DESC +) + +SELECT + r.response_value AS procedure, + p.name AS patient_name, + p.gender, + p.phone_number, + EXTRACT(YEAR FROM CURRENT_DATE) - p.year_of_birth AS age, + p.address, + pi.value AS MRnumber, + TRIM(s.first_name || ' ' || COALESCE(s.last_name, '')) AS staff_name, + r.created_date, + r.questionnaire_id, + e.encounter_class, + llc.link_center AS latest_link_center +FROM ( + SELECT + qr.patient_id, + qr.created_date, + qr.created_by_id, + qr.questionnaire_id, + qr.encounter_id, + resp ->> 'question_id' AS question_id, + UPPER( + TRIM( + REPLACE( + COALESCE(val ->> 'value', val -> 'coding' ->> 'display'), + '_', + ' ' + ) + ) + ) AS response_value + FROM + emr_questionnaireresponse qr, + jsonb_array_elements(qr.responses) AS resp, + jsonb_array_elements(resp -> 'values') AS val + WHERE + qr.questionnaire_id IN (21,22) + AND resp ->> 'question_id' IN ( + '1d13528d-89ea-4057-bf01-aca909d62d9e', + '520d1879-ad9b-4bab-b490-209c10068e71' + ) + /* + --The following filters are Metabase-specific and will be replaced by Metabase if parameters are provided: + [[AND {{visit_date}}]] + */ +) r +JOIN emr_patient p ON r.patient_id = p.id +LEFT JOIN emr_encounter e ON r.encounter_id = e.id +LEFT JOIN emr_patientidentifier pi ON pi.patient_id = p.id AND pi.config_id = 5 +LEFT JOIN users_user s ON r.created_by_id = s.id +LEFT JOIN latest_link_center llc ON p.id = llc.patient_id +WHERE + p.deleted = FALSE + /* + --The following filters are Metabase-specific and will be replaced by Metabase if parameters are provided: + [[AND r.response_value = {{Service}} ]] + [[AND p.name ILIKE {{patient_name}} ]] + [[AND llc.link_center ILIKE '%' || {{link_center}} || '%']] + [[AND TRIM(s.first_name || ' ' || COALESCE(s.last_name, '')) = {{staff_name}} ]] + */ +ORDER BY r.created_date DESC, patient_name; +``` + + +## Notes + +- Metabase-specific filters (`[[...]]`) allow dynamic filtering in dashboards. +- The queries use `questionnaire_id IN (21, 22)` to identify psychology services forms. +- Specific question_ids are used to extract services provided data and link center information. +- The drill-down query includes the latest link center per patient using a CTE. +- The `config_id = 5` condition is used to select the correct Medical Record number (MRnumber) for each patient. +- Ensure all referenced tables and fields exist and are mapped correctly. +- All filters are optional and applied dynamically by Metabase. + +*Last updated: 2025-12-16*