diff --git a/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_insert_all_daily_spacy_occupancy_duration.sql b/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_insert_all_daily_spacy_occupancy_duration.sql index 96beac1..7b6fdff 100644 --- a/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_insert_all_daily_spacy_occupancy_duration.sql +++ b/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_insert_all_daily_spacy_occupancy_duration.sql @@ -13,81 +13,142 @@ WITH presence_logs AS ( AND p.cat_name = 'hps' ), --- Intervals when device was in 'presence' (between prev_time and event_time when value='none') -presence_intervals AS ( +raw_absence_intervals AS ( SELECT space_id, + device_id, prev_time AS start_time, event_time AS end_time FROM presence_logs - WHERE value <> 'none' - AND prev_value = 'none' - AND prev_time IS NOT NULL + WHERE prev_value = 'none' AND prev_time IS NOT NULL ), --- Split intervals across days -split_intervals AS ( +absence_intervals AS ( + SELECT + r.space_id, + r.device_id, + gs.day, + GREATEST(r.start_time, gs.day) AS start_time, + LEAST(r.end_time, gs.day + INTERVAL '1 day') AS end_time + FROM raw_absence_intervals r + CROSS JOIN LATERAL ( + SELECT generate_series( + date_trunc('day', r.start_time), + date_trunc('day', r.end_time), + INTERVAL '1 day' + ) AS day + ) gs + WHERE GREATEST(r.start_time, gs.day) < LEAST(r.end_time, gs.day + INTERVAL '1 day') +), + +device_counts AS ( + SELECT space_id, day, COUNT(DISTINCT device_id) AS device_count + FROM absence_intervals + GROUP BY 1, 2 +), + +timeline AS ( + SELECT + a.space_id, + a.day, + a.device_id, + a.start_time AS ts, + 1 AS is_start + FROM absence_intervals a + UNION ALL + SELECT + a.space_id, + a.day, + a.device_id, + a.end_time AS ts, + 0 AS is_start + FROM absence_intervals a +), + +ordered_events AS ( SELECT space_id, - generate_series( - date_trunc('day', start_time), - date_trunc('day', end_time), - interval '1 day' - )::date AS event_date, - GREATEST(start_time, date_trunc('day', start_time)) AS interval_start, - LEAST(end_time, date_trunc('day', end_time) + interval '1 day') AS interval_end - FROM presence_intervals + day, + ts, + is_start, + device_id, + SUM(CASE WHEN is_start = 1 THEN 1 ELSE -1 END) + OVER (PARTITION BY space_id, day, device_id ORDER BY ts) AS device_active + FROM timeline ), --- Mark and group overlapping intervals per space per day -ordered_intervals AS ( - SELECT - space_id, - event_date, - interval_start, - interval_end, - LAG(interval_end) OVER (PARTITION BY space_id, event_date ORDER BY interval_start) AS prev_end - FROM split_intervals -), - -grouped_intervals AS ( - SELECT *, - SUM(CASE - WHEN prev_end IS NULL OR interval_start > prev_end THEN 1 - ELSE 0 - END) OVER (PARTITION BY space_id, event_date ORDER BY interval_start) AS grp - FROM ordered_intervals -), - --- Merge overlapping intervals per group -merged_intervals AS ( - SELECT - space_id, - event_date, - MIN(interval_start) AS merged_start, - MAX(interval_end) AS merged_end - FROM grouped_intervals - GROUP BY space_id, event_date, grp -), - --- Sum durations of merged intervals -summed_intervals AS ( +device_state_changes AS ( SELECT space_id, - event_date, - SUM(EXTRACT(EPOCH FROM (merged_end - merged_start))) AS raw_occupied_seconds - FROM merged_intervals - GROUP BY space_id, event_date - ), + day, + ts, + SUM(CASE WHEN is_start = 1 THEN 1 ELSE -1 END) + OVER (PARTITION BY space_id, day ORDER BY ts) AS net_active_devices + FROM ( + SELECT DISTINCT space_id, day, ts, is_start + FROM timeline + ) t +), -final_data AS ( +absence_windows AS ( + SELECT + dc.space_id, + dc.day, + ts AS start_time, + LEAD(ts) OVER (PARTITION BY dc.space_id, dc.day ORDER BY ts) AS end_time + FROM device_state_changes dsc + JOIN device_counts dc ON dc.space_id = dsc.space_id AND dc.day = dsc.day + WHERE net_active_devices = 0 +), + +empty_periods AS ( + SELECT + space_id, + day, + EXTRACT(EPOCH FROM (end_time - start_time)) AS unoccupied_seconds + FROM absence_windows + WHERE end_time IS NOT NULL +), + +unoccupied_summary AS ( + SELECT + space_id, + day, + SUM(unoccupied_seconds) AS total_unoccupied_seconds + FROM empty_periods + GROUP BY space_id, day +), + +-- Include device count even for days with 0 unoccupied time +all_days_with_devices AS ( + SELECT + space_id, + DATE(event_time) AS day, + COUNT(DISTINCT device_id) AS device_count + FROM presence_logs + GROUP BY 1, 2 +), + +final_occupancy AS ( + SELECT + d.space_id, + d.day, + d.device_count, + COALESCE(u.total_unoccupied_seconds, 0) AS unoccupied_seconds, + 86400 - COALESCE(u.total_unoccupied_seconds, 0) AS occupied_seconds + FROM all_days_with_devices d + LEFT JOIN unoccupied_summary u + ON d.space_id = u.space_id AND d.day = u.day +) +, final_data as ( SELECT space_id, - event_date, - LEAST(raw_occupied_seconds, 86400) AS occupied_seconds, - ROUND(LEAST(raw_occupied_seconds, 86400) / 86400.0 * 100, 2) AS occupancy_percentage -FROM summed_intervals -ORDER BY space_id, event_date) + day, + device_count, + occupied_seconds, + ROUND(occupied_seconds / 86400.0 * 100, 2) AS occupancy_percentage +FROM final_occupancy +ORDER BY space_id, day) INSERT INTO public."space-daily-occupancy-duration" ( diff --git a/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_update_daily_space_occupancy_duration.sql b/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_update_daily_space_occupancy_duration.sql index df1bd55..86b373f 100644 --- a/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_update_daily_space_occupancy_duration.sql +++ b/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_update_daily_space_occupancy_duration.sql @@ -10,7 +10,8 @@ presence_logs AS ( l.device_id, l.event_time, l.value, - LAG(l.event_time) OVER (PARTITION BY l.device_id ORDER BY l.event_time) AS prev_time + LAG(l.event_time) OVER (PARTITION BY l.device_id ORDER BY l.event_time) AS prev_time, + LAG(l.value) OVER (PARTITION BY l.device_id ORDER BY l.event_time) AS prev_value FROM device d JOIN "device-status-log" l ON d.uuid = l.device_id JOIN product p ON p.uuid = d.product_device_uuid @@ -18,79 +19,147 @@ presence_logs AS ( AND p.cat_name = 'hps' ), -presence_intervals AS ( +raw_absence_intervals AS ( SELECT space_id, + device_id, prev_time AS start_time, event_time AS end_time FROM presence_logs - WHERE value = 'none' - and prev_value <>'none' - AND prev_time IS NOT NULL + WHERE prev_value = 'none' AND prev_time IS NOT NULL ), -split_intervals AS ( +absence_intervals AS ( + SELECT + r.space_id, + r.device_id, + gs.day, + GREATEST(r.start_time, gs.day) AS start_time, + LEAST(r.end_time, gs.day + INTERVAL '1 day') AS end_time + FROM raw_absence_intervals r + CROSS JOIN LATERAL ( + SELECT generate_series( + date_trunc('day', r.start_time), + date_trunc('day', r.end_time), + INTERVAL '1 day' + ) AS day + ) gs + WHERE GREATEST(r.start_time, gs.day) < LEAST(r.end_time, gs.day + INTERVAL '1 day') +), + +device_counts AS ( + SELECT space_id, day, COUNT(DISTINCT device_id) AS device_count + FROM absence_intervals + GROUP BY 1, 2 +), + +timeline AS ( + SELECT + a.space_id, + a.day, + a.device_id, + a.start_time AS ts, + 1 AS is_start + FROM absence_intervals a + UNION ALL + SELECT + a.space_id, + a.day, + a.device_id, + a.end_time AS ts, + 0 AS is_start + FROM absence_intervals a +), + +ordered_events AS ( SELECT space_id, - generate_series( - date_trunc('day', start_time), - date_trunc('day', end_time), - interval '1 day' - )::date AS event_date, - GREATEST(start_time, date_trunc('day', start_time)) AS interval_start, - LEAST(end_time, date_trunc('day', end_time) + INTERVAL '1 day') AS interval_end - FROM presence_intervals + day, + ts, + is_start, + device_id, + SUM(CASE WHEN is_start = 1 THEN 1 ELSE -1 END) + OVER (PARTITION BY space_id, day, device_id ORDER BY ts) AS device_active + FROM timeline ), -ordered_intervals AS ( - SELECT - space_id, - event_date, - interval_start, - interval_end, - LAG(interval_end) OVER (PARTITION BY space_id, event_date ORDER BY interval_start) AS prev_end - FROM split_intervals -), - -grouped_intervals AS ( - SELECT *, - SUM(CASE - WHEN prev_end IS NULL OR interval_start > prev_end THEN 1 - ELSE 0 - END) OVER (PARTITION BY space_id, event_date ORDER BY interval_start) AS grp - FROM ordered_intervals -), - -merged_intervals AS ( - SELECT - space_id, - event_date, - MIN(interval_start) AS merged_start, - MAX(interval_end) AS merged_end - FROM grouped_intervals - GROUP BY space_id, event_date, grp -), - -summed_intervals AS ( +device_state_changes AS ( SELECT space_id, - event_date, - SUM(EXTRACT(EPOCH FROM (merged_end - merged_start))) AS raw_occupied_seconds - FROM merged_intervals - GROUP BY space_id, event_date + day, + ts, + SUM(CASE WHEN is_start = 1 THEN 1 ELSE -1 END) + OVER (PARTITION BY space_id, day ORDER BY ts) AS net_active_devices + FROM ( + SELECT DISTINCT space_id, day, ts, is_start + FROM timeline + ) t ), -final_data AS ( +absence_windows AS ( SELECT - s.space_id, - s.event_date, - LEAST(raw_occupied_seconds, 86400) AS occupied_seconds, - ROUND(LEAST(raw_occupied_seconds, 86400) / 86400.0 * 100, 2) AS occupancy_percentage - FROM summed_intervals s - JOIN params p + dc.space_id, + dc.day, + ts AS start_time, + LEAD(ts) OVER (PARTITION BY dc.space_id, dc.day ORDER BY ts) AS end_time + FROM device_state_changes dsc + JOIN device_counts dc ON dc.space_id = dsc.space_id AND dc.day = dsc.day + WHERE net_active_devices = 0 +), + +empty_periods AS ( + SELECT + space_id, + day, + EXTRACT(EPOCH FROM (end_time - start_time)) AS unoccupied_seconds + FROM absence_windows + WHERE end_time IS NOT NULL +), + +unoccupied_summary AS ( + SELECT + space_id, + day, + SUM(unoccupied_seconds) AS total_unoccupied_seconds + FROM empty_periods + GROUP BY space_id, day +), + +-- Include device count even for days with 0 unoccupied time +all_days_with_devices AS ( + SELECT + space_id, + DATE(event_time) AS day, + COUNT(DISTINCT device_id) AS device_count + FROM presence_logs + GROUP BY 1, 2 +), + +final_occupancy AS ( + SELECT + d.space_id, + d.day, + d.device_count, + COALESCE(u.total_unoccupied_seconds, 0) AS unoccupied_seconds, + 86400 - COALESCE(u.total_unoccupied_seconds, 0) AS occupied_seconds + FROM all_days_with_devices d + LEFT JOIN unoccupied_summary u + ON d.space_id = u.space_id AND d.day = u.day +), + +final_data as( +SELECT + space_id, + day, + device_count, + occupied_seconds, + ROUND(occupied_seconds / 86400.0 * 100, 2) AS occupancy_percentage +FROM final_occupancy s +JOIN params p ON p.space_id = s.space_id AND p.event_date = s.event_date -) +ORDER BY space_id, DAY) + INSERT INTO public."space-daily-occupancy-duration" ( space_uuid, diff --git a/libs/common/src/sql/procedures/fact_space_occupancy_count/proceduce_select_fact_space_occupancy.sql b/libs/common/src/sql/procedures/fact_space_occupancy_count/proceduce_select_fact_space_occupancy.sql index 113eb07..139466a 100644 --- a/libs/common/src/sql/procedures/fact_space_occupancy_count/proceduce_select_fact_space_occupancy.sql +++ b/libs/common/src/sql/procedures/fact_space_occupancy_count/proceduce_select_fact_space_occupancy.sql @@ -12,4 +12,8 @@ AND ( P.event_year IS NULL OR TO_CHAR(psdsd.event_date, 'YYYY') = TO_CHAR(P.event_year, 'YYYY') ) -ORDER BY space_uuid, event_date \ No newline at end of file +ORDER BY space_uuid, event_date + + + + diff --git a/libs/common/src/sql/queries/fact_daily_space_presence_duration/fact_daily_space_presence_duration.sql b/libs/common/src/sql/queries/fact_daily_space_presence_duration/fact_daily_space_presence_duration.sql index b8a696b..156ee28 100644 --- a/libs/common/src/sql/queries/fact_daily_space_presence_duration/fact_daily_space_presence_duration.sql +++ b/libs/common/src/sql/queries/fact_daily_space_presence_duration/fact_daily_space_presence_duration.sql @@ -2,7 +2,7 @@ WITH presence_logs AS ( SELECT d.space_device_uuid AS space_id, l.device_id, - l.event_time as start_time, + l.event_time, l.value, LAG(l.event_time) OVER (PARTITION BY l.device_id ORDER BY l.event_time) AS prev_time, LAG(l.value) OVER (PARTITION BY l.device_id ORDER BY l.event_time) AS prev_value @@ -13,9 +13,8 @@ WITH presence_logs AS ( AND p.cat_name = 'hps' ), - --- Intervals when device was in 'presence' (between prev_time and event_time when value='none') -presence_intervals AS ( +-- Intervals when device was in 'absence' (between prev_time and event_time when value='none') +raw_absence_intervals AS ( SELECT space_id, device_id, @@ -27,66 +26,143 @@ presence_intervals AS ( AND prev_time IS NOT NULL ), --- Split intervals across days -split_intervals AS ( +-- Split intervals that span multiple days into day-specific chunks +absence_intervals AS ( + SELECT + r.space_id, + r.device_id, + GREATEST(r.start_time, gs.day::timestamp) AS start_time, + LEAST(r.end_time, (gs.day + INTERVAL '1 day' - INTERVAL '1 second')::timestamp) AS end_time + FROM raw_absence_intervals r + CROSS JOIN LATERAL ( + SELECT generate_series( + date_trunc('day', r.start_time), + date_trunc('day', r.end_time), + INTERVAL '1 day' + ) AS day + ) gs + WHERE GREATEST(r.start_time, gs.day::timestamp) < LEAST(r.end_time, (gs.day + INTERVAL '1 day')::timestamp) +), + +-- FIXED: Count devices based on presence_logs OR absence_intervals +devices_per_day AS ( SELECT space_id, - generate_series( - date_trunc('day', start_time), - date_trunc('day', end_time), - interval '1 day' - )::date AS event_date, - GREATEST(start_time, date_trunc('day', start_time)) AS interval_start, - LEAST(end_time, date_trunc('day', end_time) + interval '1 day') AS interval_end - FROM presence_intervals + day, + COUNT(DISTINCT device_id) AS device_count + FROM ( + -- Devices that logged events on that day + SELECT space_id, DATE(event_time) AS day, device_id + FROM presence_logs + + UNION + + -- Devices that had absence intervals on that day + SELECT space_id, DATE(start_time) AS day, device_id + FROM absence_intervals + ) combined + GROUP BY space_id, day ), --- Mark and group overlapping intervals per space per day -ordered_intervals AS ( - SELECT - space_id, - event_date, - interval_start, - interval_end, - LAG(interval_end) OVER (PARTITION BY space_id, event_date ORDER BY interval_start) AS prev_end - FROM split_intervals -), -grouped_intervals AS ( - SELECT *, - SUM(CASE - WHEN prev_end IS NULL OR interval_start > prev_end THEN 1 - ELSE 0 - END) OVER (PARTITION BY space_id, event_date ORDER BY interval_start) AS grp - FROM ordered_intervals -), - --- Merge overlapping intervals per group -merged_intervals AS ( - SELECT - space_id, - event_date, - MIN(interval_start) AS merged_start, - MAX(interval_end) AS merged_end - FROM grouped_intervals - GROUP BY space_id, event_date, grp -), - --- Sum durations of merged intervals -summed_intervals AS ( +-- For multi-device spaces, find all time periods when ALL devices were absent +multi_device_unoccupied AS ( + WITH device_absence_per_day AS ( + SELECT + a.space_id, + DATE(a.start_time) AS day, + a.device_id, + a.start_time, + a.end_time, + d.device_count + FROM absence_intervals a + JOIN devices_per_day d ON a.space_id = d.space_id AND DATE(a.start_time) = d.day + WHERE d.device_count > 1 + ), + -- Generate time slots for each day with multiple devices + time_ranges AS ( + SELECT + space_id, + day, + day::timestamp AS range_start, + (day + INTERVAL '1 day')::timestamp AS range_end, + device_count + FROM devices_per_day + WHERE device_count > 1 + ), + + -- Find all time periods when all devices were absent + all_devices_absent AS ( + SELECT + t.space_id, + t.day, + t.range_start, + t.range_end, + t.device_count, + -- Find the latest start time of all devices' absence intervals + MAX(a.start_time) OVER (PARTITION BY t.space_id, t.day) AS max_start_time, + -- Find the earliest end time of all devices' absence intervals + MIN(a.end_time) OVER (PARTITION BY t.space_id, t.day) AS min_end_time + FROM time_ranges t + LEFT JOIN device_absence_per_day a ON + t.space_id = a.space_id AND + t.day = a.day + GROUP BY t.space_id, t.day, t.range_start, t.range_end, t.device_count, a.start_time, a.end_time + ) + + -- Calculate total unoccupied seconds when all devices were absent SELECT space_id, - event_date, - SUM(EXTRACT(EPOCH FROM (merged_end - merged_start))) AS raw_occupied_seconds - FROM merged_intervals - GROUP BY space_id, event_date + day, + CASE + WHEN max_start_time IS NULL OR min_end_time IS NULL THEN 0 + WHEN max_start_time >= min_end_time THEN 0 + ELSE EXTRACT(EPOCH FROM (LEAST(min_end_time, range_end) - GREATEST(max_start_time, range_start))) + END AS unoccupied_seconds + FROM all_devices_absent + GROUP BY space_id, day, range_start, range_end, device_count, max_start_time, min_end_time + HAVING COUNT(*) = device_count -- Only include periods when all devices were absent +) +, + +-- Calculate unoccupied time for spaces with single device reporting +single_device_unoccupied AS ( + SELECT + a.space_id, + DATE(a.start_time) AS day, + SUM(EXTRACT(EPOCH FROM (a.end_time - a.start_time))) AS unoccupied_seconds + FROM absence_intervals a + JOIN devices_per_day d ON a.space_id = d.space_id AND DATE(a.start_time) = d.day + WHERE d.device_count = 1 + GROUP BY a.space_id, DATE(a.start_time) +) +, + +-- Combine results from both single and multi-device cases +combined_unoccupied AS ( + SELECT space_id, day, unoccupied_seconds FROM single_device_unoccupied + UNION ALL + SELECT space_id, day, unoccupied_seconds FROM multi_device_unoccupied +), + +-- Calculate total occupied time per space per day +daily_occupancy AS ( + SELECT + space_id, + day, + -- Total seconds in day (86400) minus unoccupied seconds + 86400 - COALESCE(SUM(unoccupied_seconds), 0) AS occupied_seconds + FROM combined_unoccupied + GROUP BY space_id, day ) --- Final output with capped seconds and percentage +-- Final result SELECT space_id, - event_date, - LEAST(raw_occupied_seconds, 86400) AS occupied_seconds, - ROUND(LEAST(raw_occupied_seconds, 86400) / 86400.0 * 100, 2) AS occupancy_percentage -FROM summed_intervals -ORDER BY space_id, event_date; \ No newline at end of file + day, + occupied_seconds, + -- Also include percentage for convenience + ROUND((occupied_seconds / 86400.0) * 100, 2) AS occupancy_percentage +FROM daily_occupancy +ORDER BY space_id, day; +