adjusted occupancy calculation

This commit is contained in:
Dona Maria Absi
2025-01-15 15:48:54 +03:00
parent 6ab98869a6
commit 3c6e81d316
2 changed files with 69 additions and 19 deletions

View File

@ -1,19 +0,0 @@
SELECT device.subspace_id AS subspace_id,
device.space_device_uuid as space_id,
space.space_name ,
subspace.subspace_name,
"device-status-log".event_time::date as date,
count(distinct device.uuid) AS count_device,
SUM(case when "device-status-log".value in ('presence','motion') then 1 else 0 END) as count_presence_detected
FROM device
INNER JOIN "device-status-log"
ON device.uuid::text = "device-status-log".device_id
LEFT JOIN product
ON product.uuid = device.product_device_uuid
INNER join subspace
on subspace."uuid" = device.subspace_id
inner join "space"
on space."uuid" = device.space_device_uuid
WHERE "device-status-log".code = 'presence_state'
group by 1,2,3,4,5

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::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
)
, presence_detection AS (
SELECT *,
CASE
WHEN value IN ('presence', 'motion') AND prev_value = 'none' THEN 1
ELSE 0
END AS presence_detected
FROM device_logs
)
, presence_detection_summary AS (
SELECT device_id,
subspace_id,
event_time::date,
sum(presence_detected) as count_presence_detected
FROM presence_detection
left join device
on device."uuid" =device_id
group by 1,2,3
)
SELECT
device.subspace_id AS subspace_id,
device.space_device_uuid AS space_id,
space.space_name,
subspace.subspace_name,
"device-status-log".event_time::date AS date,
pds.count_presence_detected,
COUNT(DISTINCT device.uuid) AS count_device
FROM device
INNER JOIN "device-status-log"
ON device.uuid::text = "device-status-log".device_id::text
LEFT JOIN product
ON product.uuid = device.product_device_uuid
left join presence_detection_summary as pds
ON pds.subspace_id= device.subspace_id
and pds.event_time = "device-status-log".event_time::date
INNER JOIN subspace
ON subspace.uuid = device.subspace_id
INNER JOIN "space"
ON space.uuid = device.space_device_uuid
WHERE "device-status-log".code = 'presence_state'
GROUP BY 1, 2, 3, 4, 5,6