This commit is contained in:
Dona Maria Absi
2025-04-16 11:18:51 +03:00
parent 5d6b9dc244
commit 5275651a2e
2 changed files with 98 additions and 56 deletions

View File

@ -1,71 +1,93 @@
WITH total_energy AS (
SELECT
device_id,
event_time::date AS date,
EXTRACT(HOUR FROM event_time) AS hour,
MIN(value)::integer AS min_value,
MAX(value)::integer AS max_value
FROM "device-status-log"
WHERE code = 'EnergyConsumed'
GROUP BY device_id, date, hour
WITH params AS (
SELECT
NULL::uuid AS device_id, -- filter: specific device (or NULL for all)
NULL::date AS start_date, -- filter: start date (or NULL for open range)
NULL::date AS end_date, -- filter: end date (or NULL for open range)
NULL::int AS hour, -- filter: hour of day (or NULL for all hours)
NULL::int AS energy_consumed_kW -- filter: min kW consumed (or NULL for no filter)
),
-- Total Energy Calculation
total_energy AS (
SELECT
log.device_id,
log.event_time::date AS date,
EXTRACT(HOUR FROM log.event_time) AS hour,
MIN(log.value)::int AS min_value,
MAX(log.value)::int AS max_value
FROM "device-status-log" log, params
WHERE log.code = 'EnergyConsumed'
AND (params.device_id IS NULL OR log.device_id = params.device_id)
AND (params.start_date IS NULL OR log.event_time::date >= params.start_date)
AND (params.end_date IS NULL OR log.event_time::date <= params.end_date)
AND (params.hour IS NULL OR EXTRACT(HOUR FROM log.event_time) = params.hour)
GROUP BY log.device_id, log.event_time::date, EXTRACT(HOUR FROM log.event_time)
),
-- Phase A
energy_phase_A AS (
SELECT
device_id,
event_time::date AS date,
EXTRACT(HOUR FROM event_time) AS hour,
MIN(value)::integer AS min_value,
MAX(value)::integer AS max_value
FROM "device-status-log"
WHERE code = 'EnergyConsumedA'
GROUP BY device_id, date, hour
log.device_id,
log.event_time::date AS date,
EXTRACT(HOUR FROM log.event_time) AS hour,
MIN(log.value)::int AS min_value,
MAX(log.value)::int AS max_value
FROM "device-status-log" log, params
WHERE log.code = 'EnergyConsumedA'
AND (params.device_id IS NULL OR log.device_id = params.device_id)
AND (params.start_date IS NULL OR log.event_time::date >= params.start_date)
AND (params.end_date IS NULL OR log.event_time::date <= params.end_date)
AND (params.hour IS NULL OR EXTRACT(HOUR FROM log.event_time) = params.hour)
GROUP BY log.device_id, log.event_time::date, EXTRACT(HOUR FROM log.event_time)
),
-- Phase B
energy_phase_B AS (
SELECT
device_id,
event_time::date AS date,
EXTRACT(HOUR FROM event_time) AS hour,
MIN(value)::integer AS min_value,
MAX(value)::integer AS max_value
FROM "device-status-log"
WHERE code = 'EnergyConsumedB'
GROUP BY device_id, date, hour
log.device_id,
log.event_time::date AS date,
EXTRACT(HOUR FROM log.event_time) AS hour,
MIN(log.value)::int AS min_value,
MAX(log.value)::int AS max_value
FROM "device-status-log" log, params
WHERE log.code = 'EnergyConsumedB'
AND (params.device_id IS NULL OR log.device_id = params.device_id)
AND (params.start_date IS NULL OR log.event_time::date >= params.start_date)
AND (params.end_date IS NULL OR log.event_time::date <= params.end_date)
AND (params.hour IS NULL OR EXTRACT(HOUR FROM log.event_time) = params.hour)
GROUP BY log.device_id, log.event_time::date, EXTRACT(HOUR FROM log.event_time)
),
-- Phase C
energy_phase_C AS (
SELECT
device_id,
event_time::date AS date,
EXTRACT(HOUR FROM event_time) AS hour,
MIN(value)::integer AS min_value,
MAX(value)::integer AS max_value
FROM "device-status-log"
WHERE code = 'EnergyConsumedC'
GROUP BY device_id, date, hour
log.device_id,
log.event_time::date AS date,
EXTRACT(HOUR FROM log.event_time) AS hour,
MIN(log.value)::int AS min_value,
MAX(log.value)::int AS max_value
FROM "device-status-log" log, params
WHERE log.code = 'EnergyConsumedC'
AND (params.device_id IS NULL OR log.device_id = params.device_id)
AND (params.start_date IS NULL OR log.event_time::date >= params.start_date)
AND (params.end_date IS NULL OR log.event_time::date <= params.end_date)
AND (params.hour IS NULL OR EXTRACT(HOUR FROM log.event_time) = params.hour)
GROUP BY log.device_id, log.event_time::date, EXTRACT(HOUR FROM log.event_time)
)
-- Final Output with Optional kW Filter
SELECT
total_energy.device_id,
total_energy.date,
total_energy.hour,
(total_energy.max_value - total_energy.min_value) AS energy_consumed_kW,
(energy_phase_A.max_value - energy_phase_A.min_value) AS energy_consumed_A,
(energy_phase_B.max_value - energy_phase_B.min_value) AS energy_consumed_B,
(energy_phase_C.max_value - energy_phase_C.min_value) AS energy_consumed_C
FROM total_energy
JOIN energy_phase_A
ON total_energy.device_id = energy_phase_A.device_id
AND total_energy.date = energy_phase_A.date
AND total_energy.hour = energy_phase_A.hour
JOIN energy_phase_B
ON total_energy.device_id = energy_phase_B.device_id
AND total_energy.date = energy_phase_B.date
AND total_energy.hour = energy_phase_B.hour
JOIN energy_phase_C
ON total_energy.device_id = energy_phase_C.device_id
AND total_energy.date = energy_phase_C.date
AND total_energy.hour = energy_phase_C.hour
ORDER BY total_energy.device_id, total_energy.date, total_energy.hour;
t.device_id,
t.date,
t.hour,
(t.max_value - t.min_value) AS energy_consumed_kW,
(a.max_value - a.min_value) AS energy_consumed_A,
(b.max_value - b.min_value) AS energy_consumed_B,
(c.max_value - c.min_value) AS energy_consumed_C
FROM total_energy t
JOIN energy_phase_A a ON t.device_id = a.device_id AND t.date = a.date AND t.hour = a.hour
JOIN energy_phase_B b ON t.device_id = b.device_id AND t.date = b.date AND t.hour = b.hour
JOIN energy_phase_C c ON t.device_id = c.device_id AND t.date = c.date AND t.hour = c.hour
JOIN params p ON TRUE
WHERE (p.min_kw IS NULL OR (t.max_value - t.min_value) >= p.min_kw)
ORDER BY t.device_id, t.date, t.hour;

20
test.sql Normal file
View File

@ -0,0 +1,20 @@
WITH ranked_dsl AS (
SELECT
dsl.*,
product.name AS product_name,
ROW_NUMBER() OVER (PARTITION BY product.name, dsl.code ORDER BY dsl.event_time) AS row_num
FROM
"device-status-log" AS dsl
LEFT JOIN device ON device.uuid = dsl.device_id
LEFT JOIN product ON product.uuid = device.product_device_uuid
)
SELECT
product_name,
ranked_dsl.*
FROM
ranked_dsl
WHERE ranked_dsl.row_num = 1;
SELECT * FROM SPACE LIMIT 100
--test test