mirror of
https://github.com/SyncrowIOT/backend.git
synced 2025-11-26 21:04:53 +00:00
Merge pull request #355 from SyncrowIOT/DATA-device-presence-sensor-detection
Data device presence sensor detection
This commit is contained in:
@ -0,0 +1,79 @@
|
|||||||
|
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 AS event_time,
|
||||||
|
"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'
|
||||||
|
AND "device-status-log".code = 'presence_state'
|
||||||
|
),
|
||||||
|
|
||||||
|
presence_detection AS (
|
||||||
|
SELECT *,
|
||||||
|
CASE
|
||||||
|
WHEN value IN ('motion', 'presence') AND prev_value = 'none' THEN 1 ELSE 0
|
||||||
|
END AS presence_started
|
||||||
|
FROM device_logs
|
||||||
|
),
|
||||||
|
|
||||||
|
space_level_presence_events AS (
|
||||||
|
SELECT DISTINCT
|
||||||
|
pd.space_id,
|
||||||
|
pd.event_time::date AS event_date,
|
||||||
|
EXTRACT(HOUR FROM pd.event_time) AS event_hour,
|
||||||
|
pd.event_time
|
||||||
|
FROM presence_detection pd
|
||||||
|
WHERE presence_started = 1
|
||||||
|
),
|
||||||
|
|
||||||
|
space_level_presence_summary AS (
|
||||||
|
SELECT
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
event_hour,
|
||||||
|
COUNT(*) AS count_total_presence_detected
|
||||||
|
FROM (
|
||||||
|
SELECT DISTINCT
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
event_hour,
|
||||||
|
event_time
|
||||||
|
FROM space_level_presence_events
|
||||||
|
) deduped
|
||||||
|
GROUP BY space_id, event_date, event_hour
|
||||||
|
),
|
||||||
|
|
||||||
|
all_dates_and_hours AS (
|
||||||
|
SELECT space_id, event_date, event_hour
|
||||||
|
FROM (
|
||||||
|
SELECT DISTINCT space_id, event_date
|
||||||
|
FROM space_level_presence_summary
|
||||||
|
) d
|
||||||
|
CROSS JOIN generate_series(0, 23) AS event_hour
|
||||||
|
)
|
||||||
|
|
||||||
|
SELECT
|
||||||
|
adah.*,
|
||||||
|
COALESCE(pds.count_total_presence_detected, 0) AS count_total_presence_detected
|
||||||
|
FROM all_dates_and_hours adah
|
||||||
|
LEFT JOIN space_level_presence_summary pds
|
||||||
|
ON pds.space_id = adah.space_id
|
||||||
|
AND pds.event_date = adah.event_date
|
||||||
|
AND pds.event_hour = adah.event_hour
|
||||||
|
ORDER BY space_id, event_date, event_hour;
|
||||||
|
|
||||||
|
|
||||||
Reference in New Issue
Block a user