energy consummed

This commit is contained in:
Dona Maria Absi
2025-03-18 15:05:15 +03:00
parent 3e0849e3fc
commit c231b000ce
3 changed files with 52 additions and 108 deletions

View File

@ -1,22 +1,18 @@
with energy_consumed as (
SELECT event_time::date,
EXTRACT(HOUR FROM event_time) AS hour,
device_id ,
space_device_uuid as space_id,
sum (case when code ='EnergyConsumed' then value::integer end) as total_energy_consummed,
sum (case when code='EnergyConsumedA' then value::integer end) as energy_consumed_phaseA,
sum (case when code='EnergyConsumedB' then value::integer end) as energy_consumed_phaseB,
sum (case when code='EnergyConsumedC' then value::integer end) as energy_consumed_phaseC
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
group by 1,2,3,4
ORDER BY 1,3,2
)
WITH first_last_times AS (
-- Get the first and last event_time per device per day
SELECT
device_id,
event_time::date AS date,
MIN(value)::integer AS min_value,
MAX(value)::integer AS max_value
FROM "device-status-log"
where code='EnergyConsumed'
GROUP BY device_id, date
)
select *
from energy_consumed
where total_energy_consummed is not null
SELECT
device_id,
date,
(max_value-min_value) as energy_consumed_kW
FROM first_last_times

View File

@ -2,7 +2,7 @@ WITH start_date AS (
SELECT
device.uuid AS device_id,
device.space_device_uuid AS space_id,
-- Mark none_flag if value is 'none'
"device-status-log".value,
CASE
WHEN "device-status-log".value = 'none' THEN 1
ELSE 0
@ -13,7 +13,7 @@ WITH start_date AS (
ORDER BY "device-status-log".event_time) AS prev_timestamp,
LAG(
CASE
WHEN "device-status-log".value = 'none' THEN 1 -- identifies if there was a 'none' flag detected
WHEN "device-status-log".value = 'none' THEN 1
ELSE 0
END
) OVER (PARTITION BY device.uuid
@ -26,9 +26,9 @@ WITH start_date AS (
WHERE product.cat_name = 'hps'
AND "device-status-log".code = 'presence_state'
ORDER BY device.uuid, "device-status-log".event_time
),
)
time_intervals AS (
, time_intervals AS (
SELECT
device_id,
space_id,
@ -36,63 +36,38 @@ time_intervals AS (
prev_timestamp AS start_time,
event_time AS end_time
FROM start_date
WHERE prev_none_flag = 1 -- Only consider intervals where the previous state was 'none'
),
grouped_none_intervals AS (
SELECT
space_id,
start_time,
end_time,
COUNT(DISTINCT device_id) AS simultaneous_none_count
FROM time_intervals
GROUP BY space_id, start_time, end_time
),
space_empty_intervals AS (
SELECT
space_id,
start_time,
end_time
FROM grouped_none_intervals
WHERE simultaneous_none_count = (SELECT COUNT(DISTINCT uuid)
FROM device
WHERE device.space_device_uuid = grouped_none_intervals.space_id)
-- Ensures all devices in the space detected 'none' simultaneously
),
daily_empty_duration AS (
SELECT
space_id,
DATE(start_time) AS occupancy_date,
(SUM(EXTRACT(EPOCH FROM (end_time - start_time))) / 60) AS total_empty_minutes
FROM space_empty_intervals
GROUP BY space_id, DATE(start_time)
),
all_spaces_dates AS (
SELECT
DISTINCT
device.space_device_uuid AS space_id,
DATE("device-status-log".event_time) AS occupancy_date
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'
WHERE prev_none_flag = 1
)
SELECT
, overlaping_none_presence AS (
SELECT
a.space_id,
s.space_name,
a.occupancy_date,
24 * 60 - COALESCE(d.total_empty_minutes, 0) AS total_occupancy_minutes,
24 - (COALESCE(d.total_empty_minutes, 0)/60) as total_occupancy_hours
FROM all_spaces_dates a
LEFT JOIN daily_empty_duration d
ON a.space_id = d.space_id
AND a.occupancy_date = d.occupancy_date
join "space" s
on s."uuid" =a.space_id
GREATEST(a.start_time, b.start_time) AS overlap_start,
LEAST(a.end_time, b.end_time) AS overlap_end,
EXTRACT(EPOCH FROM (LEAST(a.end_time, b.end_time) - GREATEST(a.start_time, b.start_time))) AS overlap_duration_seconds
FROM time_intervals a
JOIN time_intervals b
ON a.space_id = b.space_id
AND a.device_id <> b.device_id
AND a.start_time < b.end_time
AND b.start_time < a.end_time
)
, daily_total_occupancy AS (
SELECT
start_date.space_id,
dim_date.daily_date,
86,400 - COALESCE(SUM(o.overlap_duration_seconds), 0) AS total_occupancy_seconds
FROM dim_date
LEFT JOIN overlaping_none_presence o
--ON t.space_id = o.space_id
ON dim_date.daily_date = o.overlap_start::date
--AND t.start_time < o.overlap_end
-- AND o.overlap_start < t.end_time
left join start_date
on start_date.space_id = o.space_id
GROUP BY 1,2
)
SELECT * FROM daily_total_occupancy

View File

@ -1,27 +0,0 @@
SELECT
device.uuid AS device_id,
device.space_device_uuid AS space_id,
-- Mark none_flag if value is 'none'
CASE
WHEN "device-status-log".value = 'none' THEN 1
ELSE 0
END AS none_flag,
"device-status-log".event_time::timestamp AS event_time,
LAG("device-status-log".event_time::timestamp)
OVER (PARTITION BY device.uuid
ORDER BY "device-status-log".event_time) AS prev_timestamp,
LAG(
CASE
WHEN "device-status-log".value = 'none' THEN 1 -- identifies if there was a 'none' flag detected
ELSE 0
END
) OVER (PARTITION BY device.uuid
ORDER BY "device-status-log".event_time) AS prev_none_flag
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'
ORDER BY device.uuid, "device-status-log".event_time