diff --git a/fact_daily_space_presence_duration/fact_daily_space_presence_duration.sql b/fact_daily_space_presence_duration/fact_daily_space_presence_duration.sql index 26f4929..5b2b68d 100644 --- a/fact_daily_space_presence_duration/fact_daily_space_presence_duration.sql +++ b/fact_daily_space_presence_duration/fact_daily_space_presence_duration.sql @@ -1,97 +1,91 @@ +-- Step 1: Get device presence events with previous timestamps WITH start_date AS ( SELECT - device.uuid AS device_id, - device.space_device_uuid AS space_id, - "device-status-log".value, - 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 -) + d.uuid AS device_id, + d.space_device_uuid AS space_id, + l.value, + l.event_time::timestamp AS event_time, + LAG(l.event_time::timestamp) OVER (PARTITION BY d.uuid ORDER BY l.event_time) AS prev_timestamp + FROM device d + LEFT JOIN "device-status-log" l + ON d.uuid = l.device_id + LEFT JOIN product p + ON p.uuid = d.product_device_uuid + WHERE p.cat_name = 'hps' + AND l.code = 'presence_state' +), -, 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 -) - -, 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 - o.space_id, - gs.date AS missing_date, - CASE - 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 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 ( +-- Step 2: Identify periods when device reports "none" +device_none_periods AS ( SELECT - t.space_id, - DATE(t.start_time) AS occupancy_date, - GREATEST(0, LEAST(86400, SUM(EXTRACT(EPOCH FROM (t.end_time - t.start_time))) - - COALESCE(SUM(e.missing_seconds), 0))) AS total_presence_seconds, - TO_CHAR(INTERVAL '1 second' * GREATEST(0, LEAST(86400, SUM(EXTRACT(EPOCH FROM (t.end_time - t.start_time))) - - COALESCE(SUM(e.missing_seconds), 0))), 'HH24:MI:SS') AS total_presence_formatted - FROM time_intervals t - LEFT JOIN expanded_overlapping_none_presence e - ON t.space_id = e.space_id - AND DATE(t.start_time) = e.missing_date - GROUP BY 1,2 + space_id, + device_id, + event_time AS empty_from, + LEAD(event_time) OVER (PARTITION BY device_id ORDER BY event_time) AS empty_until + FROM start_date + WHERE value = 'none' +), + +-- Step 3: Clip the "none" periods to the edges of each day +clipped_device_none_periods AS ( + SELECT + space_id, + GREATEST(empty_from, DATE_TRUNC('day', empty_from)) AS clipped_from, + LEAST(empty_until, DATE_TRUNC('day', empty_until) + INTERVAL '1 day') AS clipped_until + FROM device_none_periods + WHERE empty_until IS NOT NULL +), + +-- Step 4: Break multi-day periods into daily intervals +generated_daily_intervals AS ( + SELECT + space_id, + gs::date AS day, + GREATEST(clipped_from, gs) AS interval_start, + LEAST(clipped_until, gs + INTERVAL '1 day') AS interval_end + FROM clipped_device_none_periods, + LATERAL generate_series(DATE_TRUNC('day', clipped_from), DATE_TRUNC('day', clipped_until), INTERVAL '1 day') AS gs +), + +-- Step 5: Merge overlapping or adjacent intervals per day +merged_intervals AS ( + SELECT + space_id, + day, + interval_start, + interval_end + FROM ( + SELECT + space_id, + day, + interval_start, + interval_end, + LAG(interval_end) OVER (PARTITION BY space_id, day ORDER BY interval_start) AS prev_end + FROM generated_daily_intervals + ) sub + WHERE prev_end IS NULL OR interval_start > prev_end +), + +-- Step 6: Sum up total missing seconds (device reported "none") per day +missing_seconds_per_day AS ( + SELECT + space_id, + day AS missing_date, + SUM(EXTRACT(EPOCH FROM (interval_end - interval_start))) AS total_missing_seconds + FROM merged_intervals + GROUP BY space_id, day +), + +-- Step 7: Calculate total occupied time per day (86400 - missing) +occupied_seconds_per_day AS ( + SELECT + space_id, + missing_date, + 86400 - total_missing_seconds AS total_occupied_seconds + FROM missing_seconds_per_day ) -SELECT * FROM daily_total_occupancy \ No newline at end of file +-- Final Output +SELECT * +FROM occupied_seconds_per_day +ORDER BY 1,2;