set vs current temperature

This commit is contained in:
Dona Maria Absi
2025-03-27 14:35:55 +03:00
parent 4ae776dd92
commit ec62439f40
2 changed files with 64 additions and 28 deletions

View File

@ -1,3 +1,6 @@
--This model shows the number of times a presence was detected per hour, per day.
WITH device_logs AS ( WITH device_logs AS (
SELECT SELECT
device.uuid AS device_id, device.uuid AS device_id,

View File

@ -1,5 +1,6 @@
WITH avg_set_temp AS ( -- This model gives the average hourly set and current temperatures per space, per device
-- Step 1: Compute the average set temperature per device per hour
WITH avg_set_temp AS (-- average set temperature per device per hour
SELECT SELECT
device.uuid AS device_id, device.uuid AS device_id,
device.space_device_uuid AS space_id, device.space_device_uuid AS space_id,
@ -16,29 +17,61 @@ WITH avg_set_temp AS (
GROUP BY 1,2,3,4 GROUP BY 1,2,3,4
) )
SELECT DISTINCT , avg_current_temp as (
d.uuid AS device_id, SELECT
d.space_device_uuid AS space_id, device.uuid AS device_id,
l.event_time::date AS date, device.space_device_uuid AS space_id,
-- l.event_time, -- Include event_time in SELECT to use it in ORDER BY event_time::date AS date,
DATE_PART('hour', l.event_time) AS hour, DATE_PART('hour', event_time) AS hour,
CASE WHEN l.code = 'temp_current' THEN l.value END AS current_temp, AVG("device-status-log".value::INTEGER) AS avg_current_temp
COALESCE(f.avg_set_temp, FROM device
MAX(f.avg_set_temp) OVER ( LEFT JOIN "device-status-log"
PARTITION BY d.uuid ON device.uuid = "device-status-log".device_id
ORDER BY l.event_time LEFT JOIN product
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW ON product.uuid = device.product_device_uuid
) WHERE product.name = 'Smart Thermostat'
) AS final_filled_avg_set_temp AND "device-status-log".code = 'temp_current'
FROM device d GROUP BY 1,2,3,4
LEFT JOIN "device-status-log" l )
ON d.uuid = l.device_id
LEFT JOIN product p , joined_data AS ( -- this will return null values for hours where there was no previously set temperature
ON p.uuid = d.product_device_uuid SELECT
LEFT JOIN avg_set_temp f current_temp.device_id,
ON f.device_id = d.uuid current_temp.space_id,
AND f.date = l.event_time::date current_temp.date,
AND f.hour = DATE_PART('hour', l.event_time) -- Ensure correct hour match current_temp.hour,
WHERE p.name = 'Smart Thermostat' set_temp.avg_set_temp,
AND l.code = 'temp_current' current_temp.avg_current_temp,
ORDER BY 1,3; ROW_NUMBER() OVER (PARTITION BY current_temp.device_id, current_temp.space_id ORDER BY current_temp.date, current_temp.hour) AS row_num
FROM avg_current_temp AS current_temp
LEFT JOIN avg_set_temp AS set_temp
ON set_temp.device_id = current_temp.device_id
AND set_temp.space_id = current_temp.space_id
AND set_temp.date = current_temp.date
AND set_temp.hour = current_temp.hour
)
, filled_data AS (
SELECT
a.device_id,
a.space_id,
a.date,
a.hour,
COALESCE(
a.avg_set_temp,
(SELECT b.avg_set_temp
FROM joined_data b
WHERE b.device_id = a.device_id
AND b.space_id = a.space_id
AND b.row_num < a.row_num
AND b.avg_set_temp IS NOT NULL
ORDER BY b.row_num DESC
LIMIT 1)
) AS avg_set_temp,
a.avg_current_temp
FROM joined_data a
)
SELECT *
FROM filled_data
ORDER BY 1,3,4;