This commit is contained in:
Dona Maria Absi
2025-03-19 09:20:59 +03:00
parent 8213218500
commit acc2a1c65c

View File

@ -39,20 +39,33 @@ WITH start_date AS (
WHERE prev_none_flag = 1
)
, overlaping_none_presence AS ( --assuming only 2 devices
SELECT
a.space_id,
GREATEST(a.start_time, b.start_time) AS overlap_start,
LEAST(a.end_time, b.end_time) AS overlap_end,
EXTRACT(EPOCH FROM (LEAST(a.end_time, b.end_time) - GREATEST(a.start_time, b.start_time))) AS overlap_duration_seconds
FROM time_intervals a
JOIN time_intervals b
ON a.space_id = b.space_id
AND a.device_id <> b.device_id
AND a.start_time < b.end_time
AND b.start_time < a.end_time
)
, overlapping_none_presence AS (
SELECT -- spaces with 2 devices
a.space_id,
GREATEST(a.start_time, b.start_time) AS overlap_start,
LEAST(a.end_time, b.end_time) AS overlap_end,
EXTRACT(EPOCH FROM (LEAST(a.end_time, b.end_time) - GREATEST(a.start_time, b.start_time))) AS overlap_duration_seconds
FROM time_intervals a
LEFT JOIN time_intervals b
ON a.space_id = b.space_id
AND a.device_id <> b.device_id
AND a.start_time < b.end_time
AND b.start_time < a.end_time
UNION
select --spaces with 1 device
a.space_id,
a.start_time AS overlap_start,
a.end_time AS overlap_end,
EXTRACT(EPOCH FROM (a.end_time - a.start_time)) AS overlap_duration_seconds
FROM time_intervals a
WHERE NOT EXISTS (
SELECT 1
FROM time_intervals b
WHERE a.space_id = b.space_id
AND a.device_id <> b.device_id
)
)
, expanded_overlapping_none_presence AS (
SELECT distinct
@ -62,11 +75,10 @@ WITH start_date AS (
WHEN DATE(o.overlap_start) <> DATE(o.overlap_end) THEN 86400
ELSE EXTRACT(EPOCH FROM (LEAST(o.overlap_end, gs.date + INTERVAL '1 day') - GREATEST(o.overlap_start, gs.date)))
END AS missing_seconds
FROM overlaping_none_presence o
FROM overlapping_none_presence o
CROSS JOIN LATERAL generate_series(DATE(o.overlap_start), DATE(o.overlap_end) - INTERVAL '1 day', '1 day') AS gs(date)
)
, daily_total_occupancy AS (
SELECT
t.space_id,
@ -79,8 +91,7 @@ WITH start_date AS (
LEFT JOIN expanded_overlapping_none_presence e
ON t.space_id = e.space_id
AND DATE(t.start_time) = e.missing_date
GROUP BY t.space_id, DATE(t.start_time)
order by 1,2
GROUP BY 1,2
)
SELECT * FROM daily_total_occupancy;