This commit is contained in:
Dona Maria Absi
2025-05-07 14:51:06 +03:00
parent 59ffa233ee
commit 10005c7897

View File

@ -1,11 +1,4 @@
-- This model shows the number of times a presence was detected per hour, per day.
INSERT INTO public."presence-sensor-daily-detection" (
device_uuid,
event_date,
count_motion_detected,
count_presence_detected,
count_total_presence_detected
)
-- This model shows the number of times a presence was detected per hour, per day
WITH device_logs AS (
SELECT
device.uuid AS device_id,
@ -49,7 +42,7 @@ presence_detection_summary AS (
d.subspace_id,
pd.space_id,
pd.event_time::date AS event_date,
EXTRACT(HOUR FROM date_trunc('hour', pd.event_time)) AS event_hour,
EXTRACT(HOUR FROM pd.event_time)::int AS event_hour,
SUM(motion_detected) AS count_motion_detected,
SUM(presence_detected) AS count_presence_detected,
SUM(motion_detected + presence_detected) AS count_total_presence_detected
@ -63,13 +56,14 @@ all_dates_and_hours AS (
FROM (
SELECT DISTINCT device_id, subspace_id, space_id, event_date
FROM presence_detection_summary
) d,
generate_series(0, 23) AS event_hour
) d
CROSS JOIN generate_series(0, 23) AS event_hour
),
table_final AS (
SELECT
adah.*,
adah.device_id,
adah.event_date,
COALESCE(pds.count_motion_detected, 0) AS count_motion_detected,
COALESCE(pds.count_presence_detected, 0) AS count_presence_detected,
COALESCE(pds.count_total_presence_detected, 0) AS count_total_presence_detected
@ -78,16 +72,33 @@ table_final AS (
ON pds.device_id = adah.device_id
AND pds.event_date = adah.event_date
AND pds.event_hour = adah.event_hour
)
),
daily_aggregate AS (
SELECT
device_id,
event_date,
SUM(count_motion_detected),
SUM(count_presence_detected),
SUM(count_total_presence_detected)
SUM(count_motion_detected) AS count_motion_detected,
SUM(count_presence_detected) AS count_presence_detected,
SUM(count_total_presence_detected) AS count_total_presence_detected
FROM table_final
GROUP BY 1, 2
GROUP BY device_id, event_date
)
INSERT INTO public."presence-sensor-daily-detection" (
device_uuid,
event_date,
count_motion_detected,
count_presence_detected,
count_total_presence_detected
)
SELECT
device_id,
event_date,
count_motion_detected,
count_presence_detected,
count_total_presence_detected
FROM daily_aggregate
ON CONFLICT (device_uuid, event_date) DO UPDATE
SET
count_motion_detected = EXCLUDED.count_motion_detected,