adjusted presence detection to hourly

This commit is contained in:
Dona Maria Absi
2025-03-26 15:01:29 +03:00
parent e50231b2ea
commit b893d8c641
2 changed files with 31 additions and 12 deletions

View File

@ -0,0 +1,69 @@
WITH 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
WHERE product.cat_name = 'hps' -- presence sensors
AND "device-status-log".code = 'presence_state'
ORDER BY device.uuid, "device-status-log".event_time
)
, presence_detection AS (
SELECT *,
CASE
WHEN value IN ('presence', 'motion') AND prev_value = 'none' THEN 1 -- detects a change in status from no presence to presence or motion
ELSE 0
END AS presence_detected
FROM device_logs
)
, presence_detection_summary AS (
SELECT device_id,
subspace_id,
space_id,
event_time::date AS event_date,
EXTRACT(HOUR FROM date_trunc('hour', event_time)) AS event_hour,
sum(presence_detected) AS count_presence_detected
FROM presence_detection
LEFT JOIN device
ON device."uuid" = device_id
GROUP BY 1, 2, 3, 4, 5
)
-- Generate all 24 hours for each unique event_date
, 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_presence_detected, 0) AS count_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;