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

@ -94,4 +94,4 @@ WITH start_date AS (
GROUP BY 1,2 GROUP BY 1,2
) )
SELECT * FROM daily_total_occupancy; SELECT * FROM daily_total_occupancy

View File

@ -1,4 +1,3 @@
-- returns the number of times a presence way detected in a day. For example, if presence was detected 4 times this returns 4
WITH device_logs AS ( WITH device_logs AS (
SELECT SELECT
device.uuid AS device_id, device.uuid AS device_id,
@ -21,7 +20,7 @@ WITH device_logs AS (
ON device.uuid = "device-status-log".device_id ON device.uuid = "device-status-log".device_id
LEFT JOIN product LEFT JOIN product
ON product.uuid = device.product_device_uuid ON product.uuid = device.product_device_uuid
WHERE product.cat_name = 'hps' WHERE product.cat_name = 'hps' -- presence sensors
AND "device-status-log".code = 'presence_state' AND "device-status-log".code = 'presence_state'
ORDER BY device.uuid, "device-status-log".event_time ORDER BY device.uuid, "device-status-log".event_time
) )
@ -29,22 +28,42 @@ WITH device_logs AS (
, presence_detection AS ( , presence_detection AS (
SELECT *, SELECT *,
CASE CASE
WHEN value IN ('presence', 'motion') AND prev_value = 'none' THEN 1 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 ELSE 0
END AS presence_detected END AS presence_detected
FROM device_logs FROM device_logs
) )
, presence_detection_summary AS ( , presence_detection_summary AS (
SELECT device_id, SELECT device_id,
subspace_id, subspace_id,
space_id, space_id,
event_time::date, event_time::date AS event_date,
sum(presence_detected) as count_presence_detected EXTRACT(HOUR FROM date_trunc('hour', event_time)) AS event_hour,
sum(presence_detected) AS count_presence_detected
FROM presence_detection FROM presence_detection
left join device LEFT JOIN device
on device."uuid" =device_id ON device."uuid" = device_id
group by 1,2,3,4 GROUP BY 1, 2, 3, 4, 5
) )
select * from presence_detection_summary; -- 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;