Merge pull request #368 from SyncrowIOT/DATA-space-occupancy-procedures

DATA-daily-space-occupancy-procedures
This commit is contained in:
faljawhary
2025-05-12 01:02:38 +03:00
committed by GitHub
5 changed files with 225 additions and 0 deletions

View File

@ -0,0 +1,12 @@
WITH params AS (
SELECT
$1::uuid AS space_id,
TO_DATE(NULLIF($2, ''), 'YYYY-MM') AS event_month
)
select psdsd.*
from public."presence-sensor-daily-space-detection" psdsd
JOIN params P ON true
where psdsd.space_uuid = P.space_id
AND (P.event_month IS NULL OR TO_CHAR(psdsd.event_date, 'YYYY-MM') = TO_CHAR(P.event_month, 'YYYY-MM'))
ORDER BY space_uuid, event_date

View File

@ -0,0 +1,100 @@
WITH device_logs AS (
SELECT
device.uuid AS device_id,
device.space_device_uuid AS space_id,
"device-status-log".event_time::timestamp AS event_time,
"device-status-log".value,
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'
),
-- 1. All 'none' → presence or motion
presence_transitions AS (
SELECT
space_id,
event_time,
event_time::date AS event_date,
value
FROM device_logs
WHERE (value = 'motion' OR value = 'presence') AND prev_value = 'none'
),
-- 2. Cluster events per space_id within 30s
clustered_events AS (
SELECT
space_id,
event_time,
event_date,
value,
SUM(new_cluster_flag) OVER (PARTITION BY space_id ORDER BY event_time) AS cluster_id
FROM (
SELECT *,
CASE
WHEN event_time - LAG(event_time) OVER (PARTITION BY space_id ORDER BY event_time) > INTERVAL '30 seconds'
THEN 1 ELSE 0
END AS new_cluster_flag
FROM presence_transitions
) marked
),
-- 3. Determine dominant type (motion vs presence) per cluster
cluster_type AS (
SELECT
space_id,
event_date,
cluster_id,
COUNT(*) FILTER (WHERE value = 'motion') AS motion_count,
COUNT(*) FILTER (WHERE value = 'presence') AS presence_count,
CASE
WHEN COUNT(*) FILTER (WHERE value = 'motion') > COUNT(*) FILTER (WHERE value = 'presence') THEN 'motion'
ELSE 'presence'
END AS dominant_type
FROM clustered_events
GROUP BY space_id, event_date, cluster_id
),
-- 4. Count clusters by dominant type
summary AS (
SELECT
space_id,
event_date,
COUNT(*) FILTER (WHERE dominant_type = 'motion') AS count_motion_detected,
COUNT(*) FILTER (WHERE dominant_type = 'presence') AS count_presence_detected,
COUNT(*) AS count_total_presence_detected
FROM cluster_type
GROUP BY space_id, event_date
)
-- 5. Output
, final_table as (
SELECT *
FROM summary
ORDER BY space_id, event_date)
INSERT INTO public."presence-sensor-daily-space-detection" (
space_uuid,
event_date,
count_motion_detected,
count_presence_detected,
count_total_presence_detected
)
SELECT
space_id,
event_date,
count_motion_detected,
count_presence_detected,
count_total_presence_detected
FROM final_table
ON CONFLICT (space_uuid, event_date) DO UPDATE
SET
count_motion_detected = EXCLUDED.count_motion_detected,
count_presence_detected = EXCLUDED.count_presence_detected,
count_total_presence_detected = EXCLUDED.count_total_presence_detected;

View File

@ -0,0 +1,113 @@
WITH params AS (
SELECT
TO_DATE(NULLIF($2, ''), 'YYYY-MM-DD') AS event_date,
$4::uuid AS space_id
),
device_logs AS (
SELECT
device.uuid AS device_id,
device.space_device_uuid AS space_id,
"device-status-log".event_time::timestamp AS event_time,
"device-status-log".value,
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'
),
-- 1. All 'none' → presence or motion
presence_transitions AS (
SELECT
space_id,
event_time,
event_time::date AS event_date,
value
FROM device_logs
WHERE (value = 'motion' OR value = 'presence') AND prev_value = 'none'
),
-- 2. Cluster events per space_id within 30s
clustered_events AS (
SELECT
space_id,
event_time,
event_date,
value,
SUM(new_cluster_flag) OVER (PARTITION BY space_id ORDER BY event_time) AS cluster_id
FROM (
SELECT *,
CASE
WHEN event_time - LAG(event_time) OVER (PARTITION BY space_id ORDER BY event_time) > INTERVAL '30 seconds'
THEN 1 ELSE 0
END AS new_cluster_flag
FROM presence_transitions
) marked
),
-- 3. Determine dominant type (motion vs presence) per cluster
cluster_type AS (
SELECT
space_id,
event_date,
cluster_id,
COUNT(*) FILTER (WHERE value = 'motion') AS motion_count,
COUNT(*) FILTER (WHERE value = 'presence') AS presence_count,
CASE
WHEN COUNT(*) FILTER (WHERE value = 'motion') > COUNT(*) FILTER (WHERE value = 'presence') THEN 'motion'
ELSE 'presence'
END AS dominant_type
FROM clustered_events
GROUP BY space_id, event_date, cluster_id
),
-- 4. Count clusters by dominant type
summary AS (
SELECT
space_id,
event_date,
COUNT(*) FILTER (WHERE dominant_type = 'motion') AS count_motion_detected,
COUNT(*) FILTER (WHERE dominant_type = 'presence') AS count_presence_detected,
COUNT(*) AS count_total_presence_detected
FROM cluster_type
GROUP BY space_id, event_date
)
-- 5. Output
, final_table as (
SELECT summary.space_id,
summary.event_date,
count_motion_detected,
count_presence_detected,
count_total_presence_detected
FROM summary
JOIN params P ON true
where summary.space_id = P.space_id
and (P.event_date IS NULL or summary.event_date::date = P.event_date)
ORDER BY space_id, event_date)
INSERT INTO public."presence-sensor-daily-space-detection" (
space_uuid,
event_date,
count_motion_detected,
count_presence_detected,
count_total_presence_detected
)
SELECT
space_id,
event_date,
count_motion_detected,
count_presence_detected,
count_total_presence_detected
FROM final_table
ON CONFLICT (space_uuid, event_date) DO UPDATE
SET
count_motion_detected = EXCLUDED.count_motion_detected,
count_presence_detected = EXCLUDED.count_presence_detected,
count_total_presence_detected = EXCLUDED.count_total_presence_detected;