Merge pull request #347 from SyncrowIOT/DATA-inserting-historical-data

DATA-inserting historical data
This commit is contained in:
faljawhary
2025-04-23 16:23:41 +03:00
committed by GitHub

View File

@ -0,0 +1,135 @@
WITH total_energy AS (
SELECT
log.device_id,
log.event_time::date AS date,
EXTRACT(HOUR FROM log.event_time) AS hour,
TO_CHAR(log.event_time, 'MM-YYYY') AS event_month,
EXTRACT(YEAR FROM log.event_time)::int AS event_year,
MIN(log.value)::integer AS min_value,
MAX(log.value)::integer AS max_value
FROM "device-status-log" log
WHERE log.code = 'EnergyConsumed'
GROUP BY 1,2,3,4,5
),
energy_phase_A AS (
SELECT
log.device_id,
log.event_time::date AS date,
EXTRACT(HOUR FROM log.event_time) AS hour,
TO_CHAR(log.event_time, 'MM-YYYY') AS event_month,
EXTRACT(YEAR FROM log.event_time)::int AS event_year,
MIN(log.value)::integer AS min_value,
MAX(log.value)::integer AS max_value
FROM "device-status-log" log
WHERE log.code = 'EnergyConsumedA'
GROUP BY 1,2,3,4,5
),
energy_phase_B AS (
SELECT
log.device_id,
log.event_time::date AS date,
EXTRACT(HOUR FROM log.event_time) AS hour,
TO_CHAR(log.event_time, 'MM-YYYY') AS event_month,
EXTRACT(YEAR FROM log.event_time)::int AS event_year,
MIN(log.value)::integer AS min_value,
MAX(log.value)::integer AS max_value
FROM "device-status-log" log
WHERE log.code = 'EnergyConsumedB'
GROUP BY 1,2,3,4,5
),
energy_phase_C AS (
SELECT
log.device_id,
log.event_time::date AS date,
EXTRACT(HOUR FROM log.event_time) AS hour,
TO_CHAR(log.event_time, 'MM-YYYY') AS event_month,
EXTRACT(YEAR FROM log.event_time)::int AS event_year,
MIN(log.value)::integer AS min_value,
MAX(log.value)::integer AS max_value
FROM "device-status-log" log
WHERE log.code = 'EnergyConsumedC'
GROUP BY 1,2,3,4,5
)
, final_data as (
SELECT
t.device_id,
t.date,
t.event_year::text,
t.event_month,
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
ORDER BY 1,2)
INSERT INTO public."power-clamp-energy-consumed-daily"(
device_uuid,
energy_consumed_kw,
energy_consumed_a,
energy_consumed_b,
energy_consumed_c,
date
)
SELECT
device_id,
SUM(CAST(energy_consumed_kw AS NUMERIC))::VARCHAR,
SUM(CAST(energy_consumed_a AS NUMERIC))::VARCHAR,
SUM(CAST(energy_consumed_b AS NUMERIC))::VARCHAR,
SUM(CAST(energy_consumed_c AS NUMERIC))::VARCHAR,
date
FROM final_data
GROUP BY device_id, date;
INSERT INTO public."power-clamp-energy-consumed-hourly"(
device_uuid,
energy_consumed_kw,
energy_consumed_a,
energy_consumed_b,
energy_consumed_c,
date,
hour
)
SELECT
device_id,
SUM(CAST(energy_consumed_kw AS NUMERIC))::VARCHAR,
SUM(CAST(energy_consumed_a AS NUMERIC))::VARCHAR,
SUM(CAST(energy_consumed_b AS NUMERIC))::VARCHAR,
SUM(CAST(energy_consumed_c AS NUMERIC))::VARCHAR,
date,
hour
FROM final_data
GROUP BY 1,6,7
INSERT INTO public."power-clamp-energy-consumed-monthly"(
device_uuid,
energy_consumed_kw,
energy_consumed_a,
energy_consumed_b,
energy_consumed_c,
month
)
SELECT
device_id,
SUM(CAST(energy_consumed_kw AS NUMERIC))::VARCHAR,
SUM(CAST(energy_consumed_a AS NUMERIC))::VARCHAR,
SUM(CAST(energy_consumed_b AS NUMERIC))::VARCHAR,
SUM(CAST(energy_consumed_c AS NUMERIC))::VARCHAR,
TO_CHAR(date, 'MM-YYYY')
FROM final_data
GROUP BY 1,6;