mirror of
https://github.com/SyncrowIOT/data.git
synced 2025-07-15 17:47:39 +00:00
script adjustment
This commit is contained in:
@ -13,7 +13,7 @@ WITH start_date AS (
|
|||||||
ORDER BY "device-status-log".event_time) AS prev_timestamp,
|
ORDER BY "device-status-log".event_time) AS prev_timestamp,
|
||||||
LAG(
|
LAG(
|
||||||
CASE
|
CASE
|
||||||
WHEN "device-status-log".value = 'none' THEN 1
|
WHEN "device-status-log".value = 'none' THEN 1 -- identifies if there was a 'none' flag detected
|
||||||
ELSE 0
|
ELSE 0
|
||||||
END
|
END
|
||||||
) OVER (PARTITION BY device.uuid
|
) OVER (PARTITION BY device.uuid
|
||||||
@ -39,36 +39,60 @@ time_intervals AS (
|
|||||||
WHERE prev_none_flag = 1 -- Only consider intervals where the previous state was 'none'
|
WHERE prev_none_flag = 1 -- Only consider intervals where the previous state was 'none'
|
||||||
),
|
),
|
||||||
|
|
||||||
simultaneous_none_intervals AS (
|
grouped_none_intervals AS (
|
||||||
SELECT
|
|
||||||
t1.space_id,
|
|
||||||
GREATEST(t1.start_time, t2.start_time) AS overlap_start,
|
|
||||||
LEAST(t1.end_time, t2.end_time) AS overlap_end,
|
|
||||||
COUNT(DISTINCT t1.device_id) AS simultaneous_none_count
|
|
||||||
FROM time_intervals t1
|
|
||||||
JOIN time_intervals t2
|
|
||||||
ON t1.space_id = t2.space_id
|
|
||||||
AND t1.device_id != t2.device_id
|
|
||||||
AND GREATEST(t1.start_time, t2.start_time) < LEAST(t1.end_time, t2.end_time)
|
|
||||||
WHERE t1.none_flag = 1 AND t2.none_flag = 1
|
|
||||||
GROUP BY t1.space_id, GREATEST(t1.start_time, t2.start_time), LEAST(t1.end_time, t2.end_time)
|
|
||||||
),
|
|
||||||
|
|
||||||
daily_occupancy_duration AS (
|
|
||||||
SELECT
|
SELECT
|
||||||
space_id,
|
space_id,
|
||||||
DATE(overlap_start) AS occupancy_date,
|
start_time,
|
||||||
SUM(EXTRACT(EPOCH FROM (overlap_end - overlap_start))) AS total_occupancy_seconds
|
end_time,
|
||||||
FROM simultaneous_none_intervals
|
COUNT(DISTINCT device_id) AS simultaneous_none_count
|
||||||
WHERE simultaneous_none_count = (
|
FROM time_intervals
|
||||||
SELECT COUNT(DISTINCT uuid)
|
GROUP BY space_id, start_time, end_time
|
||||||
FROM device
|
),
|
||||||
WHERE space_device_uuid = simultaneous_none_intervals.space_id
|
|
||||||
) -- Ensure all devices in the space detect 'none' simultaneously
|
space_empty_intervals AS (
|
||||||
GROUP BY space_id, DATE(overlap_start)
|
SELECT
|
||||||
|
space_id,
|
||||||
|
start_time,
|
||||||
|
end_time
|
||||||
|
FROM grouped_none_intervals
|
||||||
|
WHERE simultaneous_none_count = (SELECT COUNT(DISTINCT uuid)
|
||||||
|
FROM device
|
||||||
|
WHERE device.space_device_uuid = grouped_none_intervals.space_id)
|
||||||
|
-- Ensures all devices in the space detected 'none' simultaneously
|
||||||
|
),
|
||||||
|
|
||||||
|
daily_empty_duration AS (
|
||||||
|
SELECT
|
||||||
|
space_id,
|
||||||
|
DATE(start_time) AS occupancy_date,
|
||||||
|
(SUM(EXTRACT(EPOCH FROM (end_time - start_time))) / 60) AS total_empty_minutes
|
||||||
|
FROM space_empty_intervals
|
||||||
|
GROUP BY space_id, DATE(start_time)
|
||||||
|
),
|
||||||
|
|
||||||
|
all_spaces_dates AS (
|
||||||
|
SELECT
|
||||||
|
DISTINCT
|
||||||
|
device.space_device_uuid AS space_id,
|
||||||
|
DATE("device-status-log".event_time) AS occupancy_date
|
||||||
|
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'
|
||||||
)
|
)
|
||||||
|
|
||||||
SELECT *
|
SELECT
|
||||||
FROM daily_occupancy_duration
|
a.space_id,
|
||||||
ORDER BY space_id, occupancy_date;
|
s.space_name,
|
||||||
|
a.occupancy_date,
|
||||||
|
24 * 60 - COALESCE(d.total_empty_minutes, 0) AS total_occupancy_minutes,
|
||||||
|
24 - (COALESCE(d.total_empty_minutes, 0)/60) as total_occupancy_hours
|
||||||
|
FROM all_spaces_dates a
|
||||||
|
LEFT JOIN daily_empty_duration d
|
||||||
|
ON a.space_id = d.space_id
|
||||||
|
AND a.occupancy_date = d.occupancy_date
|
||||||
|
join "space" s
|
||||||
|
on s."uuid" =a.space_id;
|
@ -1,3 +1,4 @@
|
|||||||
|
-- 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,
|
||||||
@ -64,7 +65,7 @@ left join presence_detection_summary as pds
|
|||||||
and pds.event_time = "device-status-log".event_time::date
|
and pds.event_time = "device-status-log".event_time::date
|
||||||
INNER JOIN subspace
|
INNER JOIN subspace
|
||||||
ON subspace.uuid = device.subspace_id
|
ON subspace.uuid = device.subspace_id
|
||||||
INNER JOIN "space"
|
INNER JOIN "space" AS space
|
||||||
ON space.uuid = device.space_device_uuid
|
ON space.uuid = device.space_device_uuid
|
||||||
WHERE "device-status-log".code = 'presence_state'
|
WHERE "device-status-log".code = 'presence_state'
|
||||||
GROUP BY 1, 2, 3, 4, 5,6
|
GROUP BY 1, 2, 3, 4, 5,6
|
||||||
|
Reference in New Issue
Block a user