new tables

This commit is contained in:
Dona Maria Absi
2025-01-28 21:15:28 +03:00
parent f26656de94
commit 99002f10dc
3 changed files with 84 additions and 4 deletions

5
dim_date/dim_date.sql Normal file
View File

@ -0,0 +1,5 @@
SELECT generate_series(
DATE '2024-01-01', -- Start date
DATE '2065-12-31', -- End date
INTERVAL '1 day' -- Step size
)::DATE AS daily_date;

View File

@ -17,7 +17,7 @@ WITH start_date AS (
ORDER BY "device-status-log".event_time) AS prev_value ORDER BY "device-status-log".event_time) AS prev_value
FROM device FROM device
LEFT JOIN "device-status-log" LEFT JOIN "device-status-log"
ON device.uuid::text = "device-status-log".device_id ON device.uuid = "device-status-log".device_id
LEFT JOIN product LEFT JOIN product
ON product.uuid = device.product_device_uuid ON product.uuid = device.product_device_uuid
WHERE product.cat_name = 'hps' WHERE product.cat_name = 'hps'
@ -35,7 +35,7 @@ time_differences AS (
event_time::date AS event_date, event_time::date AS event_date,
EXTRACT(EPOCH FROM (event_time - COALESCE(prev_timestamp, event_time))) AS time_diff_in_seconds EXTRACT(EPOCH FROM (event_time - COALESCE(prev_timestamp, event_time))) AS time_diff_in_seconds
FROM start_date FROM start_date
), )
duration as ( duration as (
@ -51,7 +51,7 @@ GROUP BY device_id, event_date
ORDER BY device_id, event_date) ORDER BY device_id, event_date)
, data_final AS(
select device_id, select device_id,
event_date, event_date,
motion_seconds, motion_seconds,
@ -61,5 +61,6 @@ select device_id,
none_seconds, none_seconds,
CONCAT(FLOOR(none_seconds / 3600), ':',LPAD(FLOOR((none_seconds % 3600) / 60)::TEXT, 2, '0'), ':',LPAD(FLOOR(none_seconds % 60)::TEXT, 2, '0')) AS none_formatted_duration CONCAT(FLOOR(none_seconds / 3600), ':',LPAD(FLOOR((none_seconds % 3600) / 60)::TEXT, 2, '0'), ':',LPAD(FLOOR(none_seconds % 60)::TEXT, 2, '0')) AS none_formatted_duration
from duration from duration
order by 1,2 order by 1,2)
SELECT * FROM data_final

View File

@ -0,0 +1,74 @@
WITH start_date AS (
SELECT
device.uuid AS device_id,
device.space_device_uuid AS space_id,
-- Mark none_flag if value is 'none'
CASE
WHEN "device-status-log".value = 'none' THEN 1
ELSE 0
END AS none_flag,
"device-status-log".event_time::timestamp AS event_time,
LAG("device-status-log".event_time::timestamp)
OVER (PARTITION BY device.uuid
ORDER BY "device-status-log".event_time) AS prev_timestamp,
LAG(
CASE
WHEN "device-status-log".value = 'none' THEN 1
ELSE 0
END
) OVER (PARTITION BY device.uuid
ORDER BY "device-status-log".event_time) AS prev_none_flag
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'
ORDER BY device.uuid, "device-status-log".event_time
),
time_intervals AS (
SELECT
device_id,
space_id,
prev_none_flag AS none_flag,
prev_timestamp AS start_time,
event_time AS end_time
FROM start_date
WHERE prev_none_flag = 1 -- Only consider intervals where the previous state was 'none'
),
simultaneous_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
space_id,
DATE(overlap_start) AS occupancy_date,
SUM(EXTRACT(EPOCH FROM (overlap_end - overlap_start))) AS total_occupancy_seconds
FROM simultaneous_none_intervals
WHERE simultaneous_none_count = (
SELECT COUNT(DISTINCT uuid)
FROM device
WHERE space_device_uuid = simultaneous_none_intervals.space_id
) -- Ensure all devices in the space detect 'none' simultaneously
GROUP BY space_id, DATE(overlap_start)
)
SELECT *
FROM daily_occupancy_duration
ORDER BY space_id, occupancy_date;