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 new file mode 100644 index 0000000..9c3315f --- /dev/null +++ b/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_insert_all_daily_spacy_occupancy_duration.sql @@ -0,0 +1,115 @@ +-- Step 1: Get device presence events with previous timestamps +WITH start_date AS ( + SELECT + 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' +), + +-- Step 2: Identify periods when device reports "none" +device_none_periods AS ( + SELECT + 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 as event_date, + 86400 - total_missing_seconds AS total_occupied_seconds, + (86400 - total_missing_seconds)/86400*100 as occupancy_prct + FROM missing_seconds_per_day +) + +-- Final Output +, final_data as ( +SELECT space_id, + event_date, + total_occupied_seconds, + occupancy_prct +FROM occupied_seconds_per_day +ORDER BY 1,2 +) + +INSERT INTO public."space-daily-occupancy-duration" ( + space_uuid, + event_date, + occupied_seconds, + occupancy_percentage +) +select space_id, + event_date, + total_occupied_seconds, + occupancy_prct +FROM final_data +ON CONFLICT (space_uuid, event_date) DO UPDATE +SET + occupancy_percentage = EXCLUDED.occupancy_percentage; + + + \ No newline at end of file diff --git a/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_select_daily_space_occupancy_duration.sql b/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_select_daily_space_occupancy_duration.sql new file mode 100644 index 0000000..f279e91 --- /dev/null +++ b/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_select_daily_space_occupancy_duration.sql @@ -0,0 +1,17 @@ +WITH params AS ( + SELECT + $1::uuid AS space_uuid, + TO_DATE(NULLIF($2, ''), 'YYYY-MM') AS event_month +) + + +SELECT sdo.space_uuid, +event_date, +occupancy_percentage, +occupied_seconds +FROM public."space-daily-occupancy-duration" as sdo +JOIN params P ON true +where (sdo.space_uuid = P.space_uuid +OR P.event_month IS null) +AND TO_CHAR(sdo.event_date, 'YYYY-MM') = TO_CHAR(P.event_month, 'YYYY-MM') +ORDER BY sdo.space_uuid, sdo.event_date; 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 new file mode 100644 index 0000000..d3c1e88 --- /dev/null +++ b/libs/common/src/sql/procedures/fact_daily_space_occupancy_duration/procedure_update_daily_space_occupancy_duration.sql @@ -0,0 +1,117 @@ +WITH params AS ( + SELECT + TO_DATE(NULLIF($1, ''), 'YYYY-MM-DD') AS event_date, + $2::uuid AS space_id +) + +, start_date AS ( + SELECT + 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' +), + +-- Step 2: Identify periods when device reports "none" +device_none_periods AS ( + SELECT + 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 as event_date, + 86400 - total_missing_seconds AS total_occupied_seconds, + (86400 - total_missing_seconds)/86400*100 as occupancy_percentage + FROM missing_seconds_per_day +) + +-- Final Output +, final_data as ( +SELECT occupied_seconds_per_day.space_id, + occupied_seconds_per_day.event_date, + occupied_seconds_per_day.occupancy_percentage +FROM occupied_seconds_per_day +join params p on true + and p.space_id = occupied_seconds_per_day.space_id + and p.event_date = occupied_seconds_per_day.event_date +ORDER BY 1,2 +) + +INSERT INTO public."space-daily-occupancy-duration" ( + space_uuid, + event_date, + occupancy_percentage +) +select space_id, + event_date, + occupancy_percentage +FROM final_data +ON CONFLICT (space_uuid, event_date) DO UPDATE +SET + occupancy_percentage = EXCLUDED.occupancy_percentage;