mirror of
https://github.com/SyncrowIOT/backend.git
synced 2025-11-26 08:24:55 +00:00
add SQL query for hourly energy consumption analysis
This commit is contained in:
@ -0,0 +1,62 @@
|
|||||||
|
WITH params AS (
|
||||||
|
SELECT
|
||||||
|
'd72f3d5d-02e5-4a9e-a1f7-7ab8c3534910'::uuid AS device_id,
|
||||||
|
NULL::date AS input_date, -- e.g., '2025-03-07'
|
||||||
|
NULL::text AS event_month, -- e.g., '03-2025'
|
||||||
|
'2025'::text AS event_year, -- e.g., '2025'
|
||||||
|
NULL::int AS hour,
|
||||||
|
NULL::int AS min_kw
|
||||||
|
),
|
||||||
|
|
||||||
|
log_data AS (
|
||||||
|
SELECT
|
||||||
|
log.device_id,
|
||||||
|
log.event_time::date AS date,
|
||||||
|
EXTRACT(HOUR FROM log.event_time)::int AS hour,
|
||||||
|
TO_CHAR(log.event_time, 'MM-YYYY') AS month,
|
||||||
|
TO_CHAR(EXTRACT(YEAR FROM log.event_time), 'FM9999') AS year,
|
||||||
|
log.code,
|
||||||
|
log.value::numeric AS value
|
||||||
|
FROM "device-status-log" log, params
|
||||||
|
WHERE (params.device_id IS NULL OR log.device_id = params.device_id)
|
||||||
|
AND (params.event_year IS NULL OR TO_CHAR(EXTRACT(YEAR FROM log.event_time), 'FM9999') = params.event_year)
|
||||||
|
AND (params.event_month IS NULL OR TO_CHAR(log.event_time, 'MM-YYYY') = params.event_month)
|
||||||
|
AND (params.input_date IS NULL OR log.event_time::date = params.input_date)
|
||||||
|
),
|
||||||
|
|
||||||
|
base_data AS (
|
||||||
|
SELECT
|
||||||
|
device_id,
|
||||||
|
CASE
|
||||||
|
WHEN (SELECT input_date FROM params) IS NOT NULL THEN date::text
|
||||||
|
WHEN (SELECT event_month FROM params) IS NOT NULL THEN date::text
|
||||||
|
ELSE month
|
||||||
|
END AS group_by_field,
|
||||||
|
CASE
|
||||||
|
WHEN (SELECT input_date FROM params) IS NOT NULL THEN hour
|
||||||
|
ELSE NULL
|
||||||
|
END AS hour,
|
||||||
|
code,
|
||||||
|
MIN(value)::int AS min_value,
|
||||||
|
MAX(value)::int AS max_value
|
||||||
|
FROM log_data
|
||||||
|
GROUP BY 1,2,3,4
|
||||||
|
),
|
||||||
|
|
||||||
|
pivoted AS (
|
||||||
|
SELECT
|
||||||
|
device_id,
|
||||||
|
group_by_field,
|
||||||
|
hour,
|
||||||
|
MAX(CASE WHEN code = 'EnergyConsumed' THEN max_value - min_value END) AS energy_consumed_kw,
|
||||||
|
MAX(CASE WHEN code = 'EnergyConsumedA' THEN max_value - min_value END) AS energy_consumed_a,
|
||||||
|
MAX(CASE WHEN code = 'EnergyConsumedB' THEN max_value - min_value END) AS energy_consumed_b,
|
||||||
|
MAX(CASE WHEN code = 'EnergyConsumedC' THEN max_value - min_value END) AS energy_consumed_c
|
||||||
|
FROM base_data
|
||||||
|
GROUP BY 1,2,3
|
||||||
|
)
|
||||||
|
|
||||||
|
SELECT *
|
||||||
|
FROM pivoted, params
|
||||||
|
WHERE (params.min_kw IS NULL OR energy_consumed_kw >= params.min_kw)
|
||||||
|
ORDER BY pivoted.group_by_field, pivoted.hour;
|
||||||
Reference in New Issue
Block a user