fixed pm25 code + date format. Added average AQI level from device

This commit is contained in:
khuss
2025-05-28 20:42:56 -04:00
parent f44dc793a6
commit efdf918159

View File

@ -51,6 +51,18 @@ BEGIN
END;
$$ LANGUAGE plpgsql;
-- Function to convert Tuya AQI level (e.g., level_0, level_1) to numeric value
CREATE OR REPLACE FUNCTION level_to_numeric(level_text TEXT)
RETURNS NUMERIC AS $$
BEGIN
-- Extract the number from the string, default to NULL if not found
RETURN CAST(regexp_replace(level_text, '[^0-9]', '', 'g') AS NUMERIC);
EXCEPTION WHEN others THEN
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
-- CTE for device + status log + space
WITH device_space AS (
SELECT
@ -58,7 +70,7 @@ WITH device_space AS (
device.created_at,
device.space_device_uuid AS space_id,
"device-status-log".event_id,
"device-status-log".event_time::timestamp,
"device-status-log".event_time::date,
"device-status-log".code,
"device-status-log".value,
"device-status-log".log
@ -73,7 +85,7 @@ WITH device_space AS (
-- Aggregate air sensor data per device per day
air_data AS (
SELECT
DATE_TRUNC('day', event_time) AS date,
event_time AS date,
device_id,
space_id,
@ -88,9 +100,9 @@ air_data AS (
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,
MIN(CASE WHEN code = 'pm25_value' THEN value::numeric END) AS pm25_min,
MAX(CASE WHEN code = 'pm25_value' THEN value::numeric END) AS pm25_max,
AVG(CASE WHEN code = 'pm25_value' THEN value::numeric END) AS pm25_avg,
-- PM10
MIN(CASE WHEN code = 'pm10' THEN value::numeric END) AS pm10_min,
@ -115,7 +127,11 @@ air_data AS (
-- 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
AVG(CASE WHEN code = 'co2_value' THEN value::numeric END) AS co2_avg,
-- AQI
AVG(CASE WHEN code = 'air_quality_index' then level_to_numeric(value) END) as air_quality_index
FROM device_space
GROUP BY date, device_id, space_id
@ -140,5 +156,7 @@ SELECT
calculate_aqi('voc_value', voc_avg),
calculate_aqi('co2_value', co2_avg),
calculate_aqi('ch2o_value', ch2o_avg)
) AS overall_AQI
) AS overall_AQI,
air_quality_index as avg_device_index
FROM air_data;