mirror of
https://github.com/SyncrowIOT/backend.git
synced 2025-07-10 15:17:41 +00:00
SQL model for aqi score and processing air data
This commit is contained in:
@ -0,0 +1,145 @@
|
|||||||
|
-- Function to calculate AQI
|
||||||
|
CREATE OR REPLACE FUNCTION calculate_aqi(p_pollutant TEXT, concentration NUMERIC)
|
||||||
|
RETURNS NUMERIC AS $$
|
||||||
|
DECLARE
|
||||||
|
c_low NUMERIC;
|
||||||
|
c_high NUMERIC;
|
||||||
|
i_low INT;
|
||||||
|
i_high INT;
|
||||||
|
BEGIN
|
||||||
|
SELECT v.c_low, v.c_high, v.i_low, v.i_high
|
||||||
|
INTO c_low, c_high, i_low, i_high
|
||||||
|
FROM (
|
||||||
|
VALUES
|
||||||
|
-- PM2.5
|
||||||
|
('pm25', 0.0, 12.0, 0, 50),
|
||||||
|
('pm25', 12.1, 35.4, 51, 100),
|
||||||
|
('pm25', 35.5, 55.4, 101, 150),
|
||||||
|
('pm25', 55.5, 150.4, 151, 200),
|
||||||
|
('pm25', 150.5, 250.4, 201, 300),
|
||||||
|
('pm25', 250.5, 500.4, 301, 500),
|
||||||
|
|
||||||
|
-- PM10
|
||||||
|
('pm10', 0, 54, 0, 50),
|
||||||
|
('pm10', 55, 154, 51, 100),
|
||||||
|
('pm10', 155, 254, 101, 150),
|
||||||
|
('pm10', 255, 354, 151, 200),
|
||||||
|
|
||||||
|
-- VOC
|
||||||
|
('voc_value', 0, 200, 0, 50),
|
||||||
|
('voc_value', 201, 400, 51, 100),
|
||||||
|
('voc_value', 401, 600, 101, 150),
|
||||||
|
('voc_value', 601, 1000, 151, 200),
|
||||||
|
|
||||||
|
-- CH2O
|
||||||
|
('ch2o_value', 0, 2, 0, 50),
|
||||||
|
('ch2o_value', 2.1, 4, 51, 100),
|
||||||
|
('ch2o_value', 4.1, 6, 101, 150),
|
||||||
|
|
||||||
|
-- CO2
|
||||||
|
('co2_value', 350, 1000, 0, 50),
|
||||||
|
('co2_value', 1001, 1250, 51, 100),
|
||||||
|
('co2_value', 1251, 1500, 101, 150),
|
||||||
|
('co2_value', 1501, 2000, 151, 200)
|
||||||
|
) AS v(pollutant, c_low, c_high, i_low, i_high)
|
||||||
|
WHERE v.pollutant = LOWER(p_pollutant)
|
||||||
|
AND concentration BETWEEN v.c_low AND v.c_high
|
||||||
|
LIMIT 1;
|
||||||
|
|
||||||
|
-- Linear interpolation
|
||||||
|
RETURN ROUND(((i_high - i_low) * (concentration - c_low) / (c_high - c_low)) + i_low);
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
-- CTE for device + space
|
||||||
|
WITH device_space AS (
|
||||||
|
SELECT
|
||||||
|
device.uuid AS device_id,
|
||||||
|
device.created_at,
|
||||||
|
device.space_device_uuid AS space_id,
|
||||||
|
"device-status-log".event_id,
|
||||||
|
"device-status-log".event_time::timestamp,
|
||||||
|
"device-status-log".code,
|
||||||
|
"device-status-log".value,
|
||||||
|
"device-status-log".log
|
||||||
|
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 = 'hjjcy'
|
||||||
|
),
|
||||||
|
|
||||||
|
-- Aggregate air sensor data per device per day
|
||||||
|
air_data AS (
|
||||||
|
SELECT
|
||||||
|
DATE_TRUNC('day', event_time) AS date,
|
||||||
|
device_id,
|
||||||
|
space_id,
|
||||||
|
|
||||||
|
-- VOC
|
||||||
|
MIN(CASE WHEN code = 'voc_value' THEN value::numeric END) AS voc_min,
|
||||||
|
MAX(CASE WHEN code = 'voc_value' THEN value::numeric END) AS voc_max,
|
||||||
|
AVG(CASE WHEN code = 'voc_value' THEN value::numeric END) AS voc_avg,
|
||||||
|
|
||||||
|
-- PM1
|
||||||
|
MIN(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_min,
|
||||||
|
MAX(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_max,
|
||||||
|
AVG(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_avg,
|
||||||
|
|
||||||
|
-- PM2.5
|
||||||
|
MIN(CASE WHEN code = 'pm25' THEN value::numeric END) AS pm25_min,
|
||||||
|
MAX(CASE WHEN code = 'pm25' THEN value::numeric END) AS pm25_max,
|
||||||
|
AVG(CASE WHEN code = 'pm25' THEN value::numeric END) AS pm25_avg,
|
||||||
|
|
||||||
|
-- PM10
|
||||||
|
MIN(CASE WHEN code = 'pm10' THEN value::numeric END) AS pm10_min,
|
||||||
|
MAX(CASE WHEN code = 'pm10' THEN value::numeric END) AS pm10_max,
|
||||||
|
AVG(CASE WHEN code = 'pm10' THEN value::numeric END) AS pm10_avg,
|
||||||
|
|
||||||
|
-- CH2O
|
||||||
|
MIN(CASE WHEN code = 'ch2o_value' THEN value::numeric END) AS ch2o_min,
|
||||||
|
MAX(CASE WHEN code = 'ch2o_value' THEN value::numeric END) AS ch2o_max,
|
||||||
|
AVG(CASE WHEN code = 'ch2o_value' THEN value::numeric END) AS ch2o_avg,
|
||||||
|
|
||||||
|
-- Humidity
|
||||||
|
MIN(CASE WHEN code = 'humidity_value' THEN value::numeric END) AS humidity_low,
|
||||||
|
MAX(CASE WHEN code = 'humidity_value' THEN value::numeric END) AS humidity_high,
|
||||||
|
AVG(CASE WHEN code = 'humidity_value' THEN value::numeric END) AS humidity_avg,
|
||||||
|
|
||||||
|
-- Temperature
|
||||||
|
MIN(CASE WHEN code = 'temp_current' THEN value::numeric END) AS temp_low,
|
||||||
|
MAX(CASE WHEN code = 'temp_current' THEN value::numeric END) AS temp_high,
|
||||||
|
AVG(CASE WHEN code = 'temp_current' THEN value::numeric END) AS temp_avg,
|
||||||
|
|
||||||
|
-- CO2
|
||||||
|
MIN(CASE WHEN code = 'co2_value' THEN value::numeric END) AS co2_min,
|
||||||
|
MAX(CASE WHEN code = 'co2_value' THEN value::numeric END) AS co2_max,
|
||||||
|
AVG(CASE WHEN code = 'co2_value' THEN value::numeric END) AS co2_avg
|
||||||
|
|
||||||
|
FROM device_space
|
||||||
|
GROUP BY date, device_id, space_id
|
||||||
|
)
|
||||||
|
|
||||||
|
-- Final select with AQI calculation
|
||||||
|
SELECT
|
||||||
|
date,
|
||||||
|
device_id,
|
||||||
|
space_id,
|
||||||
|
voc_min, voc_max, voc_avg,
|
||||||
|
pm1_min, pm1_max, pm1_avg,
|
||||||
|
pm25_min, pm25_max, pm25_avg,
|
||||||
|
pm10_min, pm10_max, pm10_avg,
|
||||||
|
ch2o_min, ch2o_max, ch2o_avg,
|
||||||
|
humidity_low, humidity_high, humidity_avg,
|
||||||
|
temp_low, temp_high, temp_avg,
|
||||||
|
co2_min, co2_max, co2_avg,
|
||||||
|
GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_avg),
|
||||||
|
calculate_aqi('pm10', pm10_avg),
|
||||||
|
calculate_aqi('voc_value', voc_avg),
|
||||||
|
calculate_aqi('co2_value', co2_avg),
|
||||||
|
calculate_aqi('ch2o_value', ch2o_avg)
|
||||||
|
) AS overall_AQI
|
||||||
|
FROM air_data;
|
||||||
|
|
Reference in New Issue
Block a user