mirror of
https://github.com/SyncrowIOT/data.git
synced 2025-07-10 07:07:18 +00:00
94 lines
4.0 KiB
SQL
94 lines
4.0 KiB
SQL
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
|
|
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
|
|
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
|
|
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
|
|
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;
|