mirror of
https://github.com/SyncrowIOT/data.git
synced 2025-07-10 07:07:18 +00:00
55 lines
1.6 KiB
SQL
55 lines
1.6 KiB
SQL
WITH avg_set_temp AS (
|
|
-- Step 1: Compute the average set temperature per device per hour
|
|
SELECT
|
|
device.uuid AS device_id,
|
|
device.space_device_uuid AS space_id,
|
|
event_time::date AS date,
|
|
DATE_PART('hour', event_time) AS hour,
|
|
AVG("device-status-log".value::INTEGER) AS avg_set_temp
|
|
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.name = 'Smart Thermostat'
|
|
AND "device-status-log".code = 'temp_set'
|
|
GROUP BY 1,2,3,4
|
|
),
|
|
|
|
avg_set_temp_filled AS (
|
|
SELECT
|
|
device_id,
|
|
space_id,
|
|
date,
|
|
hour,
|
|
avg_set_temp,
|
|
COALESCE(
|
|
avg_set_temp,
|
|
LAG(avg_set_temp) OVER (
|
|
PARTITION BY device_id
|
|
ORDER BY date, hour
|
|
)
|
|
) AS filled_avg_set_temp
|
|
FROM avg_set_temp
|
|
)
|
|
|
|
SELECT
|
|
d.uuid AS device_id,
|
|
d.space_device_uuid AS space_id,
|
|
l.event_time::date AS date,
|
|
DATE_PART('hour', l.event_time) AS hour,
|
|
CASE WHEN l.code = 'temp_current' THEN l.value END AS current_temp,
|
|
f.filled_avg_set_temp
|
|
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
|
|
LEFT JOIN avg_set_temp_filled f
|
|
ON f.device_id = d.uuid
|
|
AND f.date = l.event_time::date
|
|
and f.date = l.event_time::date AND f.hour <= DATE_PART('hour', l.event_time)
|
|
WHERE p.name = 'Smart Thermostat'
|
|
and l.code = 'temp_current'
|
|
ORDER BY d.uuid, l.event_time;
|