diff --git a/Care/Clinical/latestdiagnosis_kc.md b/Care/Clinical/latestdiagnosis_kc.md new file mode 100644 index 0000000..fa6b4e4 --- /dev/null +++ b/Care/Clinical/latestdiagnosis_kc.md @@ -0,0 +1,77 @@ +# Latest Diagnosis + +> Analyze diagnosis distribution from the latest patient encounters + +## Purpose + +Track and analyze the distribution of diagnoses recorded in the most recent encounter for each patient. Helps monitor current health conditions and treatment patterns across the organization. + +## Parameters + +| Parameter | Type | Description | Example | +|-----------|------|-------------|---------| +| `date` | DATE | Filter by encounter date range (optional) | `2025-12-01 TO 2025-12-31` | +| `facility_id` | TEXT | Filter by facility external ID (optional) | `6909ac5e-37b5-4ff7-8311-65610685ed44` | +| `staff_name` | TEXT | Filter by staff member who recorded diagnosis (optional) | `Jane Smith` | + +--- + +## Query + +```sql +WITH encounters_with_diagnosis AS ( + SELECT + public.emr_encounter.id AS encounter_id, + public.emr_encounter.patient_id, + public.emr_encounter.created_date, + public.emr_encounter.facility_id, + public.emr_condition.created_by_id AS staff_id + FROM public.emr_encounter + JOIN public.emr_condition + ON public.emr_condition.encounter_id = public.emr_encounter.id + WHERE + public.emr_condition.category in ('encounter_diagnosis', 'chronic_condition') + -- [[AND {{date}}]] +), +latest_encounter AS ( + SELECT DISTINCT ON (patient_id) + encounter_id, + patient_id, + created_date AS latest_encounter_date, + facility_id, + staff_id + FROM encounters_with_diagnosis + ORDER BY patient_id, created_date DESC +) +SELECT + public.emr_condition.code #>> ARRAY['display'] AS diagnosis, + COUNT(DISTINCT public.emr_condition.patient_id) AS count +FROM + latest_encounter + JOIN public.emr_condition + ON public.emr_condition.encounter_id = latest_encounter.encounter_id + JOIN public.facility_facility + ON public.facility_facility.id = latest_encounter.facility_id + LEFT JOIN public.users_user + ON public.users_user.id = latest_encounter.staff_id + -- WHERE 1=1 + -- [[AND public.facility_facility.external_id::text = {{facility_id}}]] + -- [[AND (users_user.first_name || ' ' || users_user.last_name) = {{staff_name}}]] +GROUP BY + diagnosis +ORDER BY + count DESC; +``` + + +## Notes + +- Metabase-specific filters (`[[...]]`) allow dynamic filtering in dashboards. +- The query uses two CTEs: `encounters_with_diagnosis` identifies all encounters with diagnoses, and `latest_encounter` selects the most recent encounter per patient. +- Uses `DISTINCT ON (patient_id)` to select the latest encounter per patient, ordered by `created_date DESC`. +- Diagnosis categories are filtered to include only `'encounter_diagnosis'` and `'chronic_condition'` types. +- Facility filter uses `external_id::text` to match facility external identifiers. +- 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/mobilitysplit_kc.md b/Care/Clinical/mobilitysplit_kc.md new file mode 100644 index 0000000..a1b76af --- /dev/null +++ b/Care/Clinical/mobilitysplit_kc.md @@ -0,0 +1,65 @@ +# Mobility Split + +> Analyze patient distribution across all mobility status categories + +## Purpose + +Track and analyze the distribution of patients by mobility status based on the latest assessment. Helps monitor mobility patterns and patient care needs across the organization. + +## Parameters + +| Parameter | Type | Description | Example | +|-----------|------|-------------|---------| +| `facility_id` | TEXT | Filter by facility external ID (optional) | `6909ac5e-37b5-4ff7-8311-65610685ed44` | +| `date` | DATE | Filter by assessment date range (optional) | `2025-12-01 TO 2025-12-31` | +| `staff_name` | TEXT | Filter by staff member who conducted assessment (optional) | `Jane Smith` | + +--- + +## Query + +```sql +SELECT + mobility AS Mobility, + COUNT(*) AS count +FROM ( + SELECT DISTINCT ON (emr_questionnaireresponse.patient_id) + (rs -> 'values' -> 0 ->> 'value') AS mobility + FROM public.emr_questionnaireresponse + JOIN public.emr_questionnaire + ON emr_questionnaireresponse.questionnaire_id = emr_questionnaire.id + LEFT JOIN users_user ON + emr_questionnaireresponse.created_by_id = users_user.id + LEFT JOIN emr_encounter + ON emr_questionnaireresponse.encounter_id = emr_encounter.id + LEFT JOIN facility_facility + ON emr_encounter.facility_id = facility_facility.id + LEFT JOIN public.emr_patient + ON emr_questionnaireresponse.patient_id = emr_patient.id + CROSS JOIN LATERAL jsonb_array_elements(emr_questionnaireresponse.responses) AS rs + WHERE (rs ->> 'question_id') IN ( + 'a9d443eb-a71c-4288-b285-f4b7310a4f69' + ) + AND emr_patient.deceased_datetime IS NULL + -- [[AND facility_facility.external_id::text = {{facility_id}}]] + -- [[AND {{date}}]] + -- [[AND (users_user.first_name || ' ' || users_user.last_name) = {{staff_name}}]] + ORDER BY emr_questionnaireresponse.patient_id, emr_questionnaireresponse.created_date DESC +) AS query +GROUP BY mobility +ORDER BY count DESC; +``` + + +## Notes + +- Metabase-specific filters (`[[...]]`) allow dynamic filtering in dashboards. +- The query uses a subquery with `DISTINCT ON (emr_questionnaireresponse.patient_id)` to select the latest mobility assessment per patient, ordered by `created_date DESC`. +- Filters out deceased patients using `emr_patient.deceased_datetime IS NULL`. +- The question_id `a9d443eb-a71c-4288-b285-f4b7310a4f69` identifies mobility assessment responses and is instance-specific. +- Facility filter uses `external_id::text` to match facility external identifiers. +- Results are grouped by mobility status and ordered by count in descending order (most common status first). +- 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/patientsrequiringcontinuouscare_kc.md b/Care/Clinical/patientsrequiringcontinuouscare_kc.md new file mode 100644 index 0000000..560f95a --- /dev/null +++ b/Care/Clinical/patientsrequiringcontinuouscare_kc.md @@ -0,0 +1,80 @@ +# Patients Requiring Continuous Care + +> Track the count of patients requiring continuous caregiver support + +## Purpose + +Monitor and identify patients who require continuous caregiver support based on the latest care assessment. Helps track care needs and resource planning for patients requiring ongoing support. + +## Parameters + +| Parameter | Type | Description | Example | +|-----------|------|-------------|---------| +| `facility_id` | TEXT | Filter by facility external ID (optional) | `6909ac5e-37b5-4ff7-8311-65610685ed44` | +| `date` | DATE | Filter by assessment date range (optional) | `2025-12-01 TO 2025-12-31` | +| `staff_name` | TEXT | Filter by staff member who recorded assessment (optional) | `Jane Smith` | + +--- + +## Query + +```sql +WITH + all_care_entries AS ( + SELECT + emr_questionnaireresponse.patient_id, + emr_questionnaireresponse.questionnaire_id, + val ->> 'value' AS care, + emr_questionnaireresponse.created_date, + facility_facility.name AS facility_name + FROM + emr_questionnaireresponse + CROSS JOIN LATERAL jsonb_array_elements(emr_questionnaireresponse.responses) AS elem + CROSS JOIN LATERAL jsonb_array_elements(elem -> 'values') AS val + JOIN emr_questionnaire ON emr_questionnaireresponse.questionnaire_id = emr_questionnaire.id + JOIN users_user ON emr_questionnaireresponse.created_by_id = users_user.id + LEFT JOIN emr_encounter ON emr_questionnaireresponse.encounter_id = emr_encounter.id + LEFT JOIN facility_facility ON emr_encounter.facility_id = facility_facility.id + WHERE + emr_questionnaireresponse.questionnaire_id IN (3) + AND elem ->> 'question_id' IN ('8cbd24e7-3d47-43fb-8f69-3632cba1d149') + -- [[AND facility_facility.external_id::text = {{facility_id}}]] + -- [[AND {{date}}]] + -- [[AND (users_user.first_name || ' ' || users_user.last_name) = {{staff_name}}]] + ), + latest_per_patient AS ( + SELECT DISTINCT + ON (patient_id) patient_id, + care, + facility_name, + questionnaire_id, + created_date + FROM + all_care_entries + ORDER BY + patient_id, + created_date DESC + ) +SELECT + COUNT(*) AS current_continuous_caregiver_support +FROM + latest_per_patient +WHERE + REPLACE(UPPER(care), ' ', '_') = 'CONTINUOUS_CAREGIVER_SUPPORT'; +``` + + +## Notes + +- Metabase-specific filters (`[[...]]`) allow dynamic filtering in dashboards. +- The query uses two CTEs: `all_care_entries` extracts all care values from questionnaire responses, and `latest_per_patient` selects the most recent care assessment per patient. +- Uses `DISTINCT ON (patient_id)` to select the latest care assessment per patient, ordered by `created_date DESC`. +- Questionnaire_id = 3 identifies care requirement assessment forms and is instance-specific. +- Question_id `8cbd24e7-3d47-43fb-8f69-3632cba1d149` identifies care support requirement responses and is instance-specific. +- Care values are extracted from nested JSONB arrays using two CROSS JOIN LATERAL operations on `responses` and `values`. +- The final WHERE clause filters for continuous caregiver support using `REPLACE(UPPER(care), ' ', '_') = 'CONTINUOUS_CAREGIVER_SUPPORT'` to normalize spacing and case. +- Facility filter uses `external_id::text` to match facility external identifiers. +- 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/Encounter/totalvisits_kc.md b/Care/Encounter/totalvisits_kc.md new file mode 100644 index 0000000..05ef81d --- /dev/null +++ b/Care/Encounter/totalvisits_kc.md @@ -0,0 +1,49 @@ +# Total Visits + +> Track the total count of encounters/visits recorded in the system + +## Purpose + +Monitor and analyze the total number of encounters/visits across the organization. Helps track visit volume and trends with optional filtering by facility, date, and staff member. + +## Parameters + +| Parameter | Type | Description | Example | +|-----------|------|-------------|---------| +| `facility_id` | TEXT | Filter by facility external ID (optional) | `6909ac5e-37b5-4ff7-8311-65610685ed44` | +| `created_date` | DATE | Filter by visit creation date range (optional) | `2025-12-01 TO 2025-12-31` | +| `staff_name` | TEXT | Filter by staff member who created visit (optional) | `Jane Smith` | + +--- + +## Query + +```sql +SELECT + COUNT(*) AS count +FROM + public.emr_encounter +JOIN + public.emr_patient + ON emr_encounter.patient_id = emr_patient.id +LEFT JOIN facility_facility + ON facility_facility.id = emr_encounter.facility_id +LEFT JOIN users_user + ON users_user.id = emr_encounter.created_by_id + -- WHERE 1 = 1 + -- [[AND facility_facility.external_id::text = {{facility_id}}]] + -- [[AND {{created_date}}]] + -- [[AND (users_user.first_name || ' ' || users_user.last_name) = {{staff_name}}]] +; +``` + + +## Notes + +- Metabase-specific filters (`[[...]]`) allow dynamic filtering in dashboards. +- The query counts all encounters regardless of status or type. +- Facility filter uses `external_id::text` to match facility external identifiers. +- 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/Patient/agewisesplit_kc.md b/Care/Patient/agewisesplit_kc.md new file mode 100644 index 0000000..6f68d05 --- /dev/null +++ b/Care/Patient/agewisesplit_kc.md @@ -0,0 +1,80 @@ +# Age Wise Split + +> Analyze patient distribution across age groups + +## Purpose + +Track and analyze the distribution of patients by age groups. Helps monitor patient demographics and identify age-based trends in the patient population. + +## Parameters + +| Parameter | Type | Description | Example | +|-----------|------|-------------|---------| +| `facility_id` | TEXT | Filter by facility external ID (optional) | `6909ac5e-37b5-4ff7-8311-65610685ed44` | +| `date` | DATE | Filter by patient creation date range (optional) | `2025-12-01 TO 2025-12-31` | +| `staff_name` | TEXT | Filter by staff member who registered patient (optional) | `Jane Smith` | + +--- + +## Query + +```sql +SELECT + CASE + WHEN source.age BETWEEN 0 AND 18 THEN '0-18' + WHEN source.age BETWEEN 19 AND 30 THEN '19-30' + WHEN source.age BETWEEN 31 AND 40 THEN '31-40' + WHEN source.age BETWEEN 41 AND 50 THEN '41-50' + WHEN source.age BETWEEN 51 AND 60 THEN '51-60' + WHEN source.age BETWEEN 61 AND 70 THEN '61-70' + WHEN source.age BETWEEN 71 AND 80 THEN '71-80' + WHEN source.age BETWEEN 81 AND 90 THEN '81-90' + ELSE '91+' + END AS age, + COUNT(*) AS count +FROM ( + SELECT + emr_patient.year_of_birth, + date_part('year', CURRENT_DATE) - emr_patient.year_of_birth AS age, + emr_patient.created_date::date + FROM public.emr_patient + LEFT JOIN emr_encounter + ON emr_encounter.patient_id = emr_patient.id + LEFT JOIN facility_facility + ON facility_facility.id = emr_encounter.facility_id + LEFT JOIN users_user + ON users_user.id = emr_patient.created_by_id + WHERE + emr_patient.deceased_datetime IS NULL + -- [[AND facility_facility.external_id::text = {{facility_id}}]] + -- [[AND {{date}}]] + -- [[AND (users_user.first_name || ' ' || users_user.last_name) = {{staff_name}}]] +) AS source +GROUP BY 1, source.age +ORDER BY + CASE + WHEN source.age BETWEEN 0 AND 18 THEN 1 + WHEN source.age BETWEEN 19 AND 30 THEN 2 + WHEN source.age BETWEEN 31 AND 40 THEN 3 + WHEN source.age BETWEEN 41 AND 50 THEN 4 + WHEN source.age BETWEEN 51 AND 60 THEN 5 + WHEN source.age BETWEEN 61 AND 70 THEN 6 + WHEN source.age BETWEEN 71 AND 80 THEN 7 + WHEN source.age BETWEEN 81 AND 90 THEN 8 + ELSE 9 + END; +``` + + +## Notes + +- Metabase-specific filters (`[[...]]`) allow dynamic filtering in dashboards. +- Age is calculated from `year_of_birth` using `date_part('year', CURRENT_DATE) - year_of_birth`. +- Filters out deceased patients using `emr_patient.deceased_datetime IS NULL`. +- The subquery calculates age, and the outer query groups by age ranges using CASE statements. +- Two CASE statements are used: one for grouping/display (`age` column), and another for ordering results numerically. +- Facility filter uses `external_id::text` to match facility external identifiers. +- 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*