From 22436af903804361c78db32a5f7be6eb74ae3895 Mon Sep 17 00:00:00 2001 From: Dona Maria Absi <49731027+DonaAbsi@users.noreply.github.com> Date: Fri, 2 May 2025 12:37:29 +0300 Subject: [PATCH] daily occupancy procedure --- .../procedures/fact_space_occupancy/.Rhistory | 0 .../procedure_fact_daily_space_occupancy.sql | 80 +++++++++++++++++++ 2 files changed, 80 insertions(+) create mode 100644 libs/common/src/sql/procedures/fact_space_occupancy/.Rhistory create mode 100644 libs/common/src/sql/procedures/fact_space_occupancy/procedure_fact_daily_space_occupancy.sql diff --git a/libs/common/src/sql/procedures/fact_space_occupancy/.Rhistory b/libs/common/src/sql/procedures/fact_space_occupancy/.Rhistory new file mode 100644 index 0000000..e69de29 diff --git a/libs/common/src/sql/procedures/fact_space_occupancy/procedure_fact_daily_space_occupancy.sql b/libs/common/src/sql/procedures/fact_space_occupancy/procedure_fact_daily_space_occupancy.sql new file mode 100644 index 0000000..a7f230f --- /dev/null +++ b/libs/common/src/sql/procedures/fact_space_occupancy/procedure_fact_daily_space_occupancy.sql @@ -0,0 +1,80 @@ +WITH params AS ( + SELECT + $1::uuid AS device_id, + $2::text::date AS event_date +), + +device_logs AS ( + SELECT + device.uuid AS device_id, + device.created_at, + device.device_tuya_uuid, + device.space_device_uuid AS space_id, + "device-status-log".event_id, + "device-status-log".event_time::timestamp, + "device-status-log".code, + "device-status-log".value, + "device-status-log".log, + LAG("device-status-log".event_time::timestamp) + OVER (PARTITION BY device.uuid + ORDER BY "device-status-log".event_time) AS prev_timestamp, + LAG("device-status-log".value) + OVER (PARTITION BY device.uuid + ORDER BY "device-status-log".event_time) AS prev_value + FROM device + LEFT JOIN "device-status-log" + ON device.uuid = "device-status-log".device_id + LEFT JOIN product + ON product.uuid = device.product_device_uuid + JOIN params ON params.device_id = device.uuid::text + WHERE product.cat_name = 'hps' + AND "device-status-log".code = 'presence_state' + AND "device-status-log".event_time::date = params.event_date +), + +presence_detection AS ( + SELECT *, + CASE + WHEN value = 'motion' AND prev_value = 'none' THEN 1 ELSE 0 + END AS motion_detected, + CASE + WHEN value = 'presence' AND prev_value = 'none' THEN 1 ELSE 0 + END AS presence_detected + FROM device_logs +), + +presence_detection_summary AS ( + SELECT + pd.device_id, + d.subspace_id, + pd.space_id, + pd.event_time::date AS event_date, + EXTRACT(HOUR FROM date_trunc('hour', pd.event_time)) AS event_hour, + SUM(motion_detected) AS count_motion_detected, + SUM(presence_detected) AS count_presence_detected, + SUM(motion_detected + presence_detected) AS count_total_presence_detected + FROM presence_detection pd + LEFT JOIN device d ON d.uuid = pd.device_id + GROUP BY 1, 2, 3, 4, 5 +), + +all_dates_and_hours AS ( + SELECT device_id, subspace_id, space_id, event_date, event_hour + FROM ( + SELECT DISTINCT device_id, subspace_id, space_id, event_date + FROM presence_detection_summary + ) d, + generate_series(0, 23) AS event_hour +) + +SELECT + adah.*, + COALESCE(pds.count_motion_detected, 0) AS count_motion_detected, + COALESCE(pds.count_presence_detected, 0) AS count_presence_detected, + COALESCE(pds.count_total_presence_detected, 0) AS count_total_presence_detected +FROM all_dates_and_hours adah +LEFT JOIN presence_detection_summary pds + ON pds.device_id = adah.device_id + AND pds.event_date = adah.event_date + AND pds.event_hour = adah.event_hour +ORDER BY 1, 4, 5; \ No newline at end of file