mirror of
https://github.com/SyncrowIOT/data.git
synced 2025-07-10 07:07:18 +00:00
set vs current temperature
This commit is contained in:
@ -1,3 +1,6 @@
|
||||
--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,
|
||||
|
@ -1,5 +1,6 @@
|
||||
WITH avg_set_temp AS (
|
||||
-- Step 1: Compute the average set temperature per device per hour
|
||||
-- This model gives the average hourly set and current temperatures per space, per device
|
||||
|
||||
WITH avg_set_temp AS (-- average set temperature per device per hour
|
||||
SELECT
|
||||
device.uuid AS device_id,
|
||||
device.space_device_uuid AS space_id,
|
||||
@ -16,29 +17,61 @@ WITH avg_set_temp AS (
|
||||
GROUP BY 1,2,3,4
|
||||
)
|
||||
|
||||
SELECT DISTINCT
|
||||
d.uuid AS device_id,
|
||||
d.space_device_uuid AS space_id,
|
||||
l.event_time::date AS date,
|
||||
-- l.event_time, -- Include event_time in SELECT to use it in ORDER BY
|
||||
DATE_PART('hour', l.event_time) AS hour,
|
||||
CASE WHEN l.code = 'temp_current' THEN l.value END AS current_temp,
|
||||
COALESCE(f.avg_set_temp,
|
||||
MAX(f.avg_set_temp) OVER (
|
||||
PARTITION BY d.uuid
|
||||
ORDER BY l.event_time
|
||||
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
|
||||
)
|
||||
) AS final_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 f
|
||||
ON f.device_id = d.uuid
|
||||
AND f.date = l.event_time::date
|
||||
AND f.hour = DATE_PART('hour', l.event_time) -- Ensure correct hour match
|
||||
WHERE p.name = 'Smart Thermostat'
|
||||
AND l.code = 'temp_current'
|
||||
ORDER BY 1,3;
|
||||
, avg_current_temp as (
|
||||
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_current_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_current'
|
||||
GROUP BY 1,2,3,4
|
||||
)
|
||||
|
||||
, joined_data AS ( -- this will return null values for hours where there was no previously set temperature
|
||||
SELECT
|
||||
current_temp.device_id,
|
||||
current_temp.space_id,
|
||||
current_temp.date,
|
||||
current_temp.hour,
|
||||
set_temp.avg_set_temp,
|
||||
current_temp.avg_current_temp,
|
||||
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;
|
Reference in New Issue
Block a user