Files
syncrow-data/fact_daily_presence_duration/fact_daily_presence_duration.sql
Dona Maria Absi ca21adfa77 new tables
2024-12-29 17:14:00 +03:00

50 lines
1.7 KiB
SQL

WITH start_date 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 -- Partition only 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::text = "device-status-log".device_id
LEFT JOIN product
ON product.uuid = device.product_device_uuid
WHERE product.cat_name = 'hps'
AND "device-status-log".code = 'presence_state'
ORDER BY device.uuid, "device-status-log".event_time
),
time_differences AS (
SELECT
device_id,
value,
prev_value,
event_time,
prev_timestamp,
event_time::date AS event_date,
EXTRACT(EPOCH FROM (event_time - COALESCE(prev_timestamp, event_time))) AS time_diff_in_seconds
FROM start_date
)
SELECT
device_id,
event_date,
SUM(CASE WHEN prev_value = 'motion' THEN time_diff_in_seconds ELSE 0 END) AS motion_seconds,
SUM(CASE WHEN prev_value = 'presence' THEN time_diff_in_seconds ELSE 0 END) AS presence_seconds,
SUM(CASE WHEN prev_value = 'none' THEN time_diff_in_seconds ELSE 0 END) AS none_seconds
FROM time_differences
GROUP BY device_id, event_date
ORDER BY device_id, event_date