mirror of
https://github.com/SyncrowIOT/backend.git
synced 2025-07-14 18:05:48 +00:00
Merge pull request #358 from SyncrowIOT/DATA-daily-occupancy-procedure
DATA-daily occupancy procedure
This commit is contained in:
@ -17,4 +17,5 @@ JOIN params P ON TRUE
|
||||
WHERE B."uuid"::TEXT = ANY(P.device_ids)
|
||||
AND (P.start_date IS NULL OR A.date >= P.start_date)
|
||||
AND (P.end_date IS NULL OR A.date <= P.end_date)
|
||||
GROUP BY 1;
|
||||
GROUP BY 1
|
||||
|
||||
|
@ -0,0 +1,114 @@
|
||||
WITH params AS (
|
||||
SELECT
|
||||
TO_DATE(NULLIF($2, ''), 'YYYY-MM-DD') AS event_date,
|
||||
$4::text AS device_id
|
||||
),
|
||||
|
||||
device_logs AS (
|
||||
SELECT
|
||||
device.uuid AS device_id,
|
||||
device.created_at,
|
||||
device.device_tuya_uuid,
|
||||
device.space_device_uuid AS space_id,
|
||||
"device-status-log".event_id,
|
||||
"device-status-log".event_time::timestamp,
|
||||
"device-status-log".code,
|
||||
"device-status-log".value,
|
||||
"device-status-log".log,
|
||||
LAG("device-status-log".event_time::timestamp)
|
||||
OVER (PARTITION BY device.uuid
|
||||
ORDER BY "device-status-log".event_time) AS prev_timestamp,
|
||||
LAG("device-status-log".value)
|
||||
OVER (PARTITION BY device.uuid
|
||||
ORDER BY "device-status-log".event_time) AS prev_value
|
||||
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
|
||||
JOIN params P ON TRUE
|
||||
WHERE product.cat_name = 'hps'
|
||||
AND "device-status-log".code = 'presence_state'
|
||||
AND device.uuid::text = P.device_id
|
||||
AND (P.event_date IS NULL OR "device-status-log".event_time::date = P.event_date)
|
||||
),
|
||||
|
||||
presence_detection AS (
|
||||
SELECT *,
|
||||
CASE
|
||||
WHEN value = 'motion' AND prev_value = 'none' THEN 1 ELSE 0
|
||||
END AS motion_detected,
|
||||
CASE
|
||||
WHEN value = 'presence' AND prev_value = 'none' THEN 1 ELSE 0
|
||||
END AS presence_detected
|
||||
FROM device_logs
|
||||
),
|
||||
|
||||
presence_detection_summary AS (
|
||||
SELECT
|
||||
pd.device_id,
|
||||
d.subspace_id,
|
||||
pd.space_id,
|
||||
pd.event_time::date AS event_date,
|
||||
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
|
||||
FROM presence_detection pd
|
||||
LEFT JOIN device d ON d.uuid = pd.device_id
|
||||
GROUP BY 1, 2, 3, 4, 5
|
||||
),
|
||||
|
||||
all_dates_and_hours AS (
|
||||
SELECT device_id, subspace_id, space_id, event_date, event_hour
|
||||
FROM (
|
||||
SELECT DISTINCT device_id, subspace_id, space_id, event_date
|
||||
FROM presence_detection_summary
|
||||
) d
|
||||
CROSS JOIN generate_series(0, 23) AS event_hour
|
||||
),
|
||||
|
||||
table_final AS (
|
||||
SELECT
|
||||
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
|
||||
FROM all_dates_and_hours adah
|
||||
LEFT JOIN presence_detection_summary pds
|
||||
ON pds.device_id = adah.device_id
|
||||
AND pds.event_date = adah.event_date
|
||||
AND pds.event_hour = adah.event_hour
|
||||
),
|
||||
|
||||
daily_aggregates AS (
|
||||
SELECT
|
||||
device_id,
|
||||
event_date,
|
||||
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 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_aggregates
|
||||
ON CONFLICT (device_uuid, event_date) DO UPDATE
|
||||
SET
|
||||
count_motion_detected = EXCLUDED.count_motion_detected,
|
||||
count_presence_detected = EXCLUDED.count_presence_detected,
|
||||
count_total_presence_detected = EXCLUDED.count_total_presence_detected;
|
@ -0,0 +1,19 @@
|
||||
-- will return the presence metrics for the days of the selected month
|
||||
WITH params AS (
|
||||
SELECT
|
||||
TO_DATE(NULLIF($2, ''), 'YYYY-MM') AS month,
|
||||
string_to_array(NULLIF($4, ''), ',') AS device_ids
|
||||
)
|
||||
|
||||
SELECT
|
||||
A.device_uuid,
|
||||
A.event_date,
|
||||
A.count_motion_detected,
|
||||
A.count_presence_detected,
|
||||
A.count_total_presence_detected
|
||||
FROM public."presence-sensor-daily-detection" AS A
|
||||
JOIN params P ON TRUE
|
||||
WHERE A.device_uuid::text = ANY(P.device_ids)
|
||||
AND (P.month IS NULL
|
||||
OR date_trunc('month', A.event_date) = P.month
|
||||
)
|
@ -0,0 +1,106 @@
|
||||
-- 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,
|
||||
device.created_at,
|
||||
device.device_tuya_uuid,
|
||||
device.space_device_uuid AS space_id,
|
||||
"device-status-log".event_id,
|
||||
"device-status-log".event_time::timestamp,
|
||||
"device-status-log".code,
|
||||
"device-status-log".value,
|
||||
"device-status-log".log,
|
||||
LAG("device-status-log".event_time::timestamp)
|
||||
OVER (PARTITION BY device.uuid
|
||||
ORDER BY "device-status-log".event_time) AS prev_timestamp,
|
||||
LAG("device-status-log".value)
|
||||
OVER (PARTITION BY device.uuid
|
||||
ORDER BY "device-status-log".event_time) AS prev_value
|
||||
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'
|
||||
),
|
||||
|
||||
presence_detection AS (
|
||||
SELECT *,
|
||||
CASE
|
||||
WHEN value = 'motion' AND prev_value = 'none' THEN 1 ELSE 0
|
||||
END AS motion_detected,
|
||||
CASE
|
||||
WHEN value = 'presence' AND prev_value = 'none' THEN 1 ELSE 0
|
||||
END AS presence_detected
|
||||
FROM device_logs
|
||||
),
|
||||
|
||||
presence_detection_summary AS (
|
||||
SELECT
|
||||
pd.device_id,
|
||||
d.subspace_id,
|
||||
pd.space_id,
|
||||
pd.event_time::date AS event_date,
|
||||
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
|
||||
FROM presence_detection pd
|
||||
LEFT JOIN device d ON d.uuid = pd.device_id
|
||||
GROUP BY 1, 2, 3, 4, 5
|
||||
),
|
||||
|
||||
all_dates_and_hours AS (
|
||||
SELECT device_id, subspace_id, space_id, event_date, event_hour
|
||||
FROM (
|
||||
SELECT DISTINCT device_id, subspace_id, space_id, event_date
|
||||
FROM presence_detection_summary
|
||||
) d
|
||||
CROSS JOIN generate_series(0, 23) AS event_hour
|
||||
),
|
||||
|
||||
table_final AS (
|
||||
SELECT
|
||||
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
|
||||
FROM all_dates_and_hours adah
|
||||
LEFT JOIN presence_detection_summary pds
|
||||
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) 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 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,
|
||||
count_presence_detected = EXCLUDED.count_presence_detected,
|
||||
count_total_presence_detected = EXCLUDED.count_total_presence_detected;
|
Reference in New Issue
Block a user