mirror of
https://github.com/SyncrowIOT/backend.git
synced 2025-07-14 18:05:48 +00:00
device model updated to include the fixes and final columns
This commit is contained in:
@ -26,43 +26,60 @@ BEGIN
|
|||||||
('pm10', 255, 354, 151, 200),
|
('pm10', 255, 354, 151, 200),
|
||||||
|
|
||||||
-- VOC
|
-- VOC
|
||||||
('voc_value', 0, 200, 0, 50),
|
('voc', 0, 200, 0, 50),
|
||||||
('voc_value', 201, 400, 51, 100),
|
('voc', 201, 400, 51, 100),
|
||||||
('voc_value', 401, 600, 101, 150),
|
('voc', 401, 600, 101, 150),
|
||||||
('voc_value', 601, 1000, 151, 200),
|
('voc', 601, 1000, 151, 200),
|
||||||
|
|
||||||
-- CH2O
|
-- CH2O
|
||||||
('ch2o_value', 0, 2, 0, 50),
|
('ch2o', 0, 2, 0, 50),
|
||||||
('ch2o_value', 2.1, 4, 51, 100),
|
('ch2o', 2.1, 4, 51, 100),
|
||||||
('ch2o_value', 4.1, 6, 101, 150),
|
('ch2o', 4.1, 6, 101, 150),
|
||||||
|
|
||||||
-- CO2
|
-- CO2
|
||||||
('co2_value', 350, 1000, 0, 50),
|
('co2', 350, 1000, 0, 50),
|
||||||
('co2_value', 1001, 1250, 51, 100),
|
('co2', 1001, 1250, 51, 100),
|
||||||
('co2_value', 1251, 1500, 101, 150),
|
('co2', 1251, 1500, 101, 150),
|
||||||
('co2_value', 1501, 2000, 151, 200)
|
('co2', 1501, 2000, 151, 200)
|
||||||
) AS v(pollutant, c_low, c_high, i_low, i_high)
|
) AS v(pollutant, c_low, c_high, i_low, i_high)
|
||||||
WHERE v.pollutant = LOWER(p_pollutant)
|
WHERE v.pollutant = LOWER(p_pollutant)
|
||||||
AND concentration BETWEEN v.c_low AND v.c_high
|
AND concentration BETWEEN v.c_low AND v.c_high
|
||||||
LIMIT 1;
|
LIMIT 1;
|
||||||
|
|
||||||
-- Linear interpolation
|
|
||||||
RETURN ROUND(((i_high - i_low) * (concentration - c_low) / (c_high - c_low)) + i_low);
|
RETURN ROUND(((i_high - i_low) * (concentration - c_low) / (c_high - c_low)) + i_low);
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql;
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
-- Function to convert Tuya AQI level (e.g., level_1, level_2) to numeric value
|
|
||||||
|
-- Function to classify AQI
|
||||||
|
CREATE OR REPLACE FUNCTION classify_aqi(aqi NUMERIC)
|
||||||
|
RETURNS TEXT AS $$
|
||||||
|
BEGIN
|
||||||
|
RETURN CASE
|
||||||
|
WHEN aqi BETWEEN 0 AND 50 THEN 'Good'
|
||||||
|
WHEN aqi BETWEEN 51 AND 100 THEN 'Moderate'
|
||||||
|
WHEN aqi BETWEEN 101 AND 150 THEN 'Unhealthy for Sensitive Groups'
|
||||||
|
WHEN aqi BETWEEN 151 AND 200 THEN 'Unhealthy'
|
||||||
|
WHEN aqi BETWEEN 201 AND 300 THEN 'Very Unhealthy'
|
||||||
|
WHEN aqi >= 301 THEN 'Hazardous'
|
||||||
|
ELSE NULL
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
|
||||||
|
-- Function to convert AQI level string to number
|
||||||
CREATE OR REPLACE FUNCTION level_to_numeric(level_text TEXT)
|
CREATE OR REPLACE FUNCTION level_to_numeric(level_text TEXT)
|
||||||
RETURNS NUMERIC AS $$
|
RETURNS NUMERIC AS $$
|
||||||
BEGIN
|
BEGIN
|
||||||
-- Extract the number from the string, default to NULL if not found
|
|
||||||
RETURN CAST(regexp_replace(level_text, '[^0-9]', '', 'g') AS NUMERIC);
|
RETURN CAST(regexp_replace(level_text, '[^0-9]', '', 'g') AS NUMERIC);
|
||||||
EXCEPTION WHEN others THEN
|
EXCEPTION WHEN others THEN
|
||||||
RETURN NULL;
|
RETURN NULL;
|
||||||
END;
|
END;
|
||||||
$$ LANGUAGE plpgsql;
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
-- CTE for device + status log + space
|
|
||||||
|
-- Query Pipeline Starts Here
|
||||||
WITH device_space AS (
|
WITH device_space AS (
|
||||||
SELECT
|
SELECT
|
||||||
device.uuid AS device_id,
|
device.uuid AS device_id,
|
||||||
@ -78,149 +95,160 @@ WITH device_space AS (
|
|||||||
WHERE product.cat_name = 'hjjcy'
|
WHERE product.cat_name = 'hjjcy'
|
||||||
),
|
),
|
||||||
|
|
||||||
-- Getting the hourly pollutants max min avg for each device
|
|
||||||
average_pollutants AS (
|
average_pollutants AS (
|
||||||
SELECT
|
SELECT
|
||||||
|
event_time::date AS event_date,
|
||||||
date_trunc('hour', event_time) AS event_hour,
|
date_trunc('hour', event_time) AS event_hour,
|
||||||
device_id,
|
device_id,
|
||||||
space_id,
|
space_id,
|
||||||
|
|
||||||
-- AVG READINGS
|
-- PM1
|
||||||
AVG(CASE WHEN code = 'voc_value' THEN value::numeric END) AS voc_avg,
|
|
||||||
AVG(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_avg,
|
|
||||||
AVG(CASE WHEN code = 'pm25_value' THEN value::numeric END) AS pm25_avg,
|
|
||||||
AVG(CASE WHEN code = 'pm10' THEN value::numeric END) AS pm10_avg,
|
|
||||||
AVG(CASE WHEN code = 'ch2o_value' THEN value::numeric END) AS ch2o_avg,
|
|
||||||
AVG(CASE WHEN code = 'co2_value' THEN value::numeric END) AS co2_avg,
|
|
||||||
|
|
||||||
-- MIN READINGS
|
|
||||||
MIN(CASE WHEN code = 'voc_value' THEN value::numeric END) AS voc_min,
|
|
||||||
MIN(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_min,
|
MIN(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_min,
|
||||||
MIN(CASE WHEN code = 'pm25_value' THEN value::numeric END) AS pm25_min,
|
AVG(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_avg,
|
||||||
MIN(CASE WHEN code = 'pm10' THEN value::numeric END) AS pm10_min,
|
|
||||||
MIN(CASE WHEN code = 'ch2o_value' THEN value::numeric END) AS ch2o_min,
|
|
||||||
MIN(CASE WHEN code = 'co2_value' THEN value::numeric END) AS co2_min,
|
|
||||||
|
|
||||||
-- MAX READINGS
|
|
||||||
MAX(CASE WHEN code = 'voc_value' THEN value::numeric END) AS voc_max,
|
|
||||||
MAX(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_max,
|
MAX(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_max,
|
||||||
|
|
||||||
|
-- PM25
|
||||||
|
MIN(CASE WHEN code = 'pm25_value' THEN value::numeric END) AS pm25_min,
|
||||||
|
AVG(CASE WHEN code = 'pm25_value' THEN value::numeric END) AS pm25_avg,
|
||||||
MAX(CASE WHEN code = 'pm25_value' THEN value::numeric END) AS pm25_max,
|
MAX(CASE WHEN code = 'pm25_value' THEN value::numeric END) AS pm25_max,
|
||||||
|
|
||||||
|
-- PM10
|
||||||
|
MIN(CASE WHEN code = 'pm10' THEN value::numeric END) AS pm10_min,
|
||||||
|
AVG(CASE WHEN code = 'pm10' THEN value::numeric END) AS pm10_avg,
|
||||||
MAX(CASE WHEN code = 'pm10' THEN value::numeric END) AS pm10_max,
|
MAX(CASE WHEN code = 'pm10' THEN value::numeric END) AS pm10_max,
|
||||||
|
|
||||||
|
-- VOC
|
||||||
|
MIN(CASE WHEN code = 'voc_value' THEN value::numeric END) AS voc_min,
|
||||||
|
AVG(CASE WHEN code = 'voc_value' THEN value::numeric END) AS voc_avg,
|
||||||
|
MAX(CASE WHEN code = 'voc_value' THEN value::numeric END) AS voc_max,
|
||||||
|
|
||||||
|
-- CH2O
|
||||||
|
MIN(CASE WHEN code = 'ch2o_value' THEN value::numeric END) AS ch2o_min,
|
||||||
|
AVG(CASE WHEN code = 'ch2o_value' THEN value::numeric END) AS ch2o_avg,
|
||||||
MAX(CASE WHEN code = 'ch2o_value' THEN value::numeric END) AS ch2o_max,
|
MAX(CASE WHEN code = 'ch2o_value' THEN value::numeric END) AS ch2o_max,
|
||||||
|
|
||||||
|
-- CO2
|
||||||
|
MIN(CASE WHEN code = 'co2_value' THEN value::numeric END) AS co2_min,
|
||||||
|
AVG(CASE WHEN code = 'co2_value' THEN value::numeric END) AS co2_avg,
|
||||||
MAX(CASE WHEN code = 'co2_value' THEN value::numeric END) AS co2_max
|
MAX(CASE WHEN code = 'co2_value' THEN value::numeric END) AS co2_max
|
||||||
|
|
||||||
FROM device_space
|
FROM device_space
|
||||||
GROUP BY device_id, space_id, event_hour
|
GROUP BY device_id, space_id, event_hour, event_date
|
||||||
),
|
),
|
||||||
|
|
||||||
|
|
||||||
-- Fill NULLs due to missing log values
|
|
||||||
filled_pollutants AS (
|
filled_pollutants AS (
|
||||||
SELECT
|
SELECT
|
||||||
*,
|
*,
|
||||||
COALESCE(pm25_avg, LAG(pm25_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm25_filled_avg,
|
-- AVG
|
||||||
COALESCE(pm10_avg, LAG(pm10_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm10_filled_avg,
|
COALESCE(pm25_avg, LAG(pm25_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm25_avg_f,
|
||||||
COALESCE(voc_avg, LAG(voc_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS voc_filled_avg,
|
COALESCE(pm10_avg, LAG(pm10_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm10_avg_f,
|
||||||
COALESCE(co2_avg, LAG(co2_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS co2_filled_avg,
|
COALESCE(voc_avg, LAG(voc_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS voc_avg_f,
|
||||||
COALESCE(ch2o_avg, LAG(ch2o_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS ch2o_filled_avg,
|
COALESCE(co2_avg, LAG(co2_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS co2_avg_f,
|
||||||
|
COALESCE(ch2o_avg, LAG(ch2o_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS ch2o_avg_f,
|
||||||
|
|
||||||
COALESCE(pm25_min, LAG(pm25_min) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm25_min_filled,
|
-- MIN
|
||||||
COALESCE(pm10_min, LAG(pm10_min) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm10_min_filled,
|
COALESCE(pm25_min, LAG(pm25_min) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm25_min_f,
|
||||||
|
COALESCE(pm10_min, LAG(pm10_min) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm10_min_f,
|
||||||
COALESCE(pm25_max, LAG(pm25_max) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm25_max_filled,
|
COALESCE(voc_min, LAG(voc_min) OVER (PARTITION BY device_id ORDER BY event_hour)) AS voc_min_f,
|
||||||
COALESCE(pm10_max, LAG(pm10_max) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm10_max_filled
|
COALESCE(co2_min, LAG(co2_min) OVER (PARTITION BY device_id ORDER BY event_hour)) AS co2_min_f,
|
||||||
|
COALESCE(ch2o_min, LAG(ch2o_min) OVER (PARTITION BY device_id ORDER BY event_hour)) AS ch2o_min_f,
|
||||||
|
|
||||||
|
-- MAX
|
||||||
|
COALESCE(pm25_max, LAG(pm25_max) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm25_max_f,
|
||||||
|
COALESCE(pm10_max, LAG(pm10_max) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm10_max_f,
|
||||||
|
COALESCE(voc_max, LAG(voc_max) OVER (PARTITION BY device_id ORDER BY event_hour)) AS voc_max_f,
|
||||||
|
COALESCE(co2_max, LAG(co2_max) OVER (PARTITION BY device_id ORDER BY event_hour)) AS co2_max_f,
|
||||||
|
COALESCE(ch2o_max, LAG(ch2o_max) OVER (PARTITION BY device_id ORDER BY event_hour)) AS ch2o_max_f
|
||||||
FROM average_pollutants
|
FROM average_pollutants
|
||||||
),
|
),
|
||||||
-- Calculate max, min, avg hourly AQI for each device
|
|
||||||
hourly_results AS (
|
hourly_results AS (
|
||||||
SELECT
|
SELECT
|
||||||
device_id,
|
device_id,
|
||||||
space_id,
|
space_id,
|
||||||
|
event_date,
|
||||||
event_hour,
|
event_hour,
|
||||||
pm25_filled_avg,
|
pm1_min, pm1_avg, pm1_max,
|
||||||
pm10_filled_avg,
|
pm25_min_f, pm25_avg_f, pm25_max_f,
|
||||||
pm25_max_filled,
|
pm10_min_f, pm10_avg_f, pm10_max_f,
|
||||||
pm10_max_filled,
|
voc_min_f, voc_avg_f, voc_max_f,
|
||||||
pm25_min_filled,
|
co2_min_f, co2_avg_f, co2_max_f,
|
||||||
pm10_min_filled,
|
ch2o_min_f, ch2o_avg_f, ch2o_max_f,
|
||||||
|
|
||||||
GREATEST(
|
GREATEST(
|
||||||
calculate_aqi('pm25', pm25_filled_avg),
|
calculate_aqi('pm25', pm25_min_f),
|
||||||
calculate_aqi('pm10', pm10_filled_avg)
|
calculate_aqi('pm10', pm10_min_f)
|
||||||
|
) AS hourly_min_aqi,
|
||||||
|
|
||||||
|
GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_avg_f),
|
||||||
|
calculate_aqi('pm10', pm10_avg_f)
|
||||||
) AS hourly_avg_aqi,
|
) AS hourly_avg_aqi,
|
||||||
|
|
||||||
GREATEST(
|
GREATEST(
|
||||||
calculate_aqi('pm25', pm25_max_filled),
|
calculate_aqi('pm25', pm25_max_f),
|
||||||
calculate_aqi('pm10', pm10_max_filled)
|
calculate_aqi('pm10', pm10_max_f)
|
||||||
) AS hourly_max_aqi,
|
) AS hourly_max_aqi,
|
||||||
|
|
||||||
GREATEST(
|
classify_aqi(GREATEST(
|
||||||
calculate_aqi('pm25', pm25_min_filled),
|
calculate_aqi('pm25', pm25_avg_f),
|
||||||
calculate_aqi('pm10', pm10_min_filled)
|
calculate_aqi('pm10', pm10_avg_f)
|
||||||
) AS hourly_min_aqi,
|
)) AS aqi_category,
|
||||||
|
|
||||||
CASE
|
classify_aqi(calculate_aqi('pm25',pm25_avg_f)) as pm25_category,
|
||||||
WHEN GREATEST(
|
classify_aqi(calculate_aqi('pm10',pm10_avg_f)) as pm10_category,
|
||||||
calculate_aqi('pm25', pm25_filled_avg),
|
classify_aqi(calculate_aqi('voc',voc_avg_f)) as voc_category,
|
||||||
calculate_aqi('pm10', pm10_filled_avg)
|
classify_aqi(calculate_aqi('co2',co2_avg_f)) as co2_category,
|
||||||
) <= 50 THEN 'Good'
|
classify_aqi(calculate_aqi('ch2o',ch2o_avg_f)) as ch2o_category
|
||||||
WHEN GREATEST(
|
|
||||||
calculate_aqi('pm25', pm25_filled_avg),
|
|
||||||
calculate_aqi('pm10', pm10_filled_avg)
|
|
||||||
) <= 100 THEN 'Moderate'
|
|
||||||
WHEN GREATEST(
|
|
||||||
calculate_aqi('pm25', pm25_filled_avg),
|
|
||||||
calculate_aqi('pm10', pm10_filled_avg)
|
|
||||||
) <= 150 THEN 'Unhealthy for Sensitive Groups'
|
|
||||||
WHEN GREATEST(
|
|
||||||
calculate_aqi('pm25', pm25_filled_avg),
|
|
||||||
calculate_aqi('pm10', pm10_filled_avg)
|
|
||||||
) <= 200 THEN 'Unhealthy'
|
|
||||||
WHEN GREATEST(
|
|
||||||
calculate_aqi('pm25', pm25_filled_avg),
|
|
||||||
calculate_aqi('pm10', pm10_filled_avg)
|
|
||||||
) <= 300 THEN 'Very Unhealthy'
|
|
||||||
ELSE 'Hazardous'
|
|
||||||
END AS aqi_category
|
|
||||||
|
|
||||||
FROM filled_pollutants
|
FROM filled_pollutants
|
||||||
ORDER BY device_id, event_hour
|
|
||||||
),
|
),
|
||||||
|
|
||||||
-- counting how many categories/hours are there in total (in case device was disconnected could be less than 24)
|
|
||||||
daily_category_counts AS (
|
daily_category_counts AS (
|
||||||
SELECT
|
SELECT device_id, space_id, event_date, aqi_category AS category, 'aqi' AS pollutant, COUNT(*) AS category_count
|
||||||
space_id,
|
|
||||||
device_id,
|
|
||||||
date_trunc('day', event_hour) AS event_day,
|
|
||||||
aqi_category,
|
|
||||||
COUNT(*) AS category_count
|
|
||||||
FROM hourly_results
|
FROM hourly_results
|
||||||
GROUP BY device_id, space_id, event_day, aqi_category
|
GROUP BY device_id, space_id, event_date, aqi_category
|
||||||
),
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT device_id, space_id, event_date, pm25_category AS category, 'pm25' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY device_id, space_id, event_date, pm25_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT device_id, space_id, event_date, pm10_category AS category, 'pm10' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY device_id, space_id, event_date, pm10_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT device_id, space_id, event_date, voc_category AS category, 'voc' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY device_id, space_id, event_date, voc_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT device_id, space_id, event_date, co2_category AS category, 'co2' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY device_id, space_id, event_date, co2_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT device_id, space_id, event_date, ch2o_category AS category, 'ch2o' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY device_id, space_id, event_date, ch2o_category
|
||||||
|
),
|
||||||
|
|
||||||
-- Aggregate Total Counts per Day
|
|
||||||
daily_totals AS (
|
daily_totals AS (
|
||||||
select
|
SELECT
|
||||||
device_id,
|
device_id,
|
||||||
space_id,
|
space_id,
|
||||||
event_day,
|
event_date,
|
||||||
SUM(category_count) AS total_count
|
SUM(category_count) AS total_count
|
||||||
FROM daily_category_counts
|
FROM daily_category_counts
|
||||||
GROUP BY device_id, space_id, event_day
|
where pollutant = 'aqi'
|
||||||
),
|
GROUP BY device_id, space_id, event_date
|
||||||
-- Calculate the daily of the daily min max avg AQI values
|
|
||||||
daily_averages AS (
|
|
||||||
select
|
|
||||||
device_id,
|
|
||||||
space_id,
|
|
||||||
date_trunc('day', event_hour) AS event_day,
|
|
||||||
ROUND(AVG(hourly_avg_aqi)::numeric, 2) AS daily_avg_aqi,
|
|
||||||
ROUND(AVG(hourly_max_aqi)::numeric, 2) AS daily_max_aqi,
|
|
||||||
ROUND(AVG(hourly_min_aqi)::numeric, 2) AS daily_min_aqi
|
|
||||||
FROM hourly_results
|
|
||||||
GROUP BY device_id, space_id, event_day
|
|
||||||
),
|
),
|
||||||
|
|
||||||
-- Pivot Categories into Columns
|
-- Pivot Categories into Columns
|
||||||
@ -228,35 +256,107 @@ daily_percentages AS (
|
|||||||
select
|
select
|
||||||
dt.device_id,
|
dt.device_id,
|
||||||
dt.space_id,
|
dt.space_id,
|
||||||
dt.event_day,
|
dt.event_date,
|
||||||
ROUND(COALESCE(SUM(CASE WHEN dcc.aqi_category = 'Good' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS good_percentage,
|
-- AQI CATEGORIES
|
||||||
ROUND(COALESCE(SUM(CASE WHEN dcc.aqi_category = 'Moderate' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS moderate_percentage,
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Good' and dcc.pollutant = 'aqi' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS good_aqi_percentage,
|
||||||
ROUND(COALESCE(SUM(CASE WHEN dcc.aqi_category = 'Unhealthy for Sensitive Groups' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_sensitive_percentage,
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Moderate' and dcc.pollutant = 'aqi' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS moderate_aqi_percentage,
|
||||||
ROUND(COALESCE(SUM(CASE WHEN dcc.aqi_category = 'Unhealthy' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_percentage,
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Unhealthy for Sensitive Groups' and dcc.pollutant = 'aqi' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_sensitive_aqi_percentage,
|
||||||
ROUND(COALESCE(SUM(CASE WHEN dcc.aqi_category = 'Very Unhealthy' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS very_unhealthy_percentage,
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Unhealthy' and dcc.pollutant = 'aqi' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_aqi_percentage,
|
||||||
ROUND(COALESCE(SUM(CASE WHEN dcc.aqi_category = 'Hazardous' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS hazardous_percentage
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Very Unhealthy' and dcc.pollutant = 'aqi' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS very_unhealthy_aqi_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Hazardous' and dcc.pollutant = 'aqi' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS hazardous_aqi_percentage,
|
||||||
|
-- PM25 CATEGORIES
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Good' and dcc.pollutant = 'pm25' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS good_pm25_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Moderate' and dcc.pollutant = 'pm25' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS moderate_pm25_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Unhealthy for Sensitive Groups' and dcc.pollutant = 'pm25' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_sensitive_pm25_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Unhealthy' and dcc.pollutant = 'pm25' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_pm25_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Very Unhealthy' and dcc.pollutant = 'pm25' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS very_unhealthy_pm25_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Hazardous' and dcc.pollutant = 'pm25' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS hazardous_pm25_percentage,
|
||||||
|
-- PM10 CATEGORIES
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Good' and dcc.pollutant = 'pm10' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS good_pm10_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Moderate' and dcc.pollutant = 'pm10' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS moderate_pm10_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Unhealthy for Sensitive Groups' and dcc.pollutant = 'pm10' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_sensitive_pm10_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Unhealthy' and dcc.pollutant = 'pm10' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_pm10_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Very Unhealthy' and dcc.pollutant = 'pm10' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS very_unhealthy_pm10_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Hazardous' and dcc.pollutant = 'pm10' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS hazardous_pm10_percentage,
|
||||||
|
-- VOC CATEGORIES
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Good' and dcc.pollutant = 'voc' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS good_voc_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Moderate' and dcc.pollutant = 'voc' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS moderate_voc_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Unhealthy for Sensitive Groups' and dcc.pollutant = 'voc' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_sensitive_voc_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Unhealthy' and dcc.pollutant = 'voc' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_voc_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Very Unhealthy' and dcc.pollutant = 'voc' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS very_unhealthy_voc_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Hazardous' and dcc.pollutant = 'voc' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS hazardous_voc_percentage,
|
||||||
|
-- CO2 CATEGORIES
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Good' and dcc.pollutant = 'co2' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS good_co2_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Moderate' and dcc.pollutant = 'co2' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS moderate_co2_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Unhealthy for Sensitive Groups' and dcc.pollutant = 'co2' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_sensitive_co2_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Unhealthy' and dcc.pollutant = 'co2' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_co2_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Very Unhealthy' and dcc.pollutant = 'co2' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS very_unhealthy_co2_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Hazardous' and dcc.pollutant = 'co2' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS hazardous_co2_percentage,
|
||||||
|
-- CH20 CATEGORIES
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Good' and dcc.pollutant = 'ch2o' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS good_ch2o_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Moderate' and dcc.pollutant = 'ch2o' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS moderate_ch2o_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Unhealthy for Sensitive Groups' and dcc.pollutant = 'ch2o' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_sensitive_ch2o_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Unhealthy' and dcc.pollutant = 'ch2o' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS unhealthy_ch2o_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Very Unhealthy' and dcc.pollutant = 'ch2o' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS very_unhealthy_ch2o_percentage,
|
||||||
|
ROUND(COALESCE(SUM(CASE WHEN dcc.category = 'Hazardous' and dcc.pollutant = 'ch2o' THEN dcc.category_count ELSE 0 END) * 100.0 / dt.total_count, 0), 2) AS hazardous_ch2o_percentage
|
||||||
FROM daily_totals dt
|
FROM daily_totals dt
|
||||||
LEFT JOIN daily_category_counts dcc
|
LEFT JOIN daily_category_counts dcc
|
||||||
ON dt.device_id = dcc.device_id AND dt.event_day = dcc.event_day
|
ON dt.device_id = dcc.device_id AND dt.event_date = dcc.event_date
|
||||||
GROUP BY dt.device_id, dt.space_id, dt.event_day, dt.total_count
|
GROUP BY dt.device_id, dt.space_id, dt.event_date, dt.total_count
|
||||||
)
|
),
|
||||||
|
|
||||||
-- Final Output
|
daily_averages AS (
|
||||||
|
SELECT
|
||||||
|
device_id,
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
-- AQI
|
||||||
|
ROUND(AVG(hourly_min_aqi)::numeric, 2) AS daily_min_aqi,
|
||||||
|
ROUND(AVG(hourly_avg_aqi)::numeric, 2) AS daily_avg_aqi,
|
||||||
|
ROUND(AVG(hourly_max_aqi)::numeric, 2) AS daily_max_aqi,
|
||||||
|
-- PM25
|
||||||
|
ROUND(AVG(pm25_min_f)::numeric, 2) AS daily_min_pm25,
|
||||||
|
ROUND(AVG(pm25_avg_f)::numeric, 2) AS daily_avg_pm25,
|
||||||
|
ROUND(AVG(pm25_max_f)::numeric, 2) AS daily_max_pm25,
|
||||||
|
-- PM10
|
||||||
|
ROUND(AVG(pm10_min_f)::numeric, 2) AS daily_min_pm10,
|
||||||
|
ROUND(AVG(pm10_avg_f)::numeric, 2) AS daily_avg_pm10,
|
||||||
|
ROUND(AVG(pm10_max_f)::numeric, 2) AS daily_max_pm10,
|
||||||
|
-- VOC
|
||||||
|
ROUND(AVG(voc_min_f)::numeric, 2) AS daily_min_voc,
|
||||||
|
ROUND(AVG(voc_avg_f)::numeric, 2) AS daily_avg_voc,
|
||||||
|
ROUND(AVG(voc_max_f)::numeric, 2) AS daily_max_voc,
|
||||||
|
-- CO2
|
||||||
|
ROUND(AVG(co2_min_f)::numeric, 2) AS daily_min_co2,
|
||||||
|
ROUND(AVG(co2_avg_f)::numeric, 2) AS daily_avg_co2,
|
||||||
|
ROUND(AVG(co2_max_f)::numeric, 2) AS daily_max_co2,
|
||||||
|
-- CH2O
|
||||||
|
ROUND(AVG(ch2o_min_f)::numeric, 2) AS daily_min_ch2o,
|
||||||
|
ROUND(AVG(ch2o_avg_f)::numeric, 2) AS daily_avg_ch2o,
|
||||||
|
ROUND(AVG(ch2o_max_f)::numeric, 2) AS daily_max_ch2o
|
||||||
|
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY device_id, space_id, event_date
|
||||||
|
)
|
||||||
SELECT
|
SELECT
|
||||||
p.device_id,
|
p.device_id,
|
||||||
p.space_id,
|
p.space_id,
|
||||||
p.event_day,
|
p.event_date,
|
||||||
p.good_percentage,
|
p.good_aqi_percentage, p.moderate_aqi_percentage, p.unhealthy_sensitive_aqi_percentage, p.unhealthy_aqi_percentage, p.very_unhealthy_aqi_percentage, p.hazardous_aqi_percentage,
|
||||||
p.moderate_percentage,
|
a.daily_avg_aqi,a.daily_max_aqi, a.daily_min_aqi,
|
||||||
p.unhealthy_sensitive_percentage,
|
p.good_pm25_percentage, p.moderate_pm25_percentage, p.unhealthy_sensitive_pm25_percentage, p.unhealthy_pm25_percentage, p.very_unhealthy_pm25_percentage, p.hazardous_pm25_percentage,
|
||||||
p.unhealthy_percentage,
|
a.daily_avg_pm25,a.daily_max_pm25, a.daily_min_pm25,
|
||||||
p.very_unhealthy_percentage,
|
p.good_pm10_percentage, p.moderate_pm10_percentage, p.unhealthy_sensitive_pm10_percentage, p.unhealthy_pm10_percentage, p.very_unhealthy_pm10_percentage, p.hazardous_pm10_percentage,
|
||||||
p.hazardous_percentage,
|
a.daily_avg_pm10, a.daily_max_pm10, a.daily_min_pm10,
|
||||||
a.daily_avg_aqi,
|
p.good_voc_percentage, p.moderate_voc_percentage, p.unhealthy_sensitive_voc_percentage, p.unhealthy_voc_percentage, p.very_unhealthy_voc_percentage, p.hazardous_voc_percentage,
|
||||||
a.daily_max_aqi,
|
a.daily_avg_voc, a.daily_max_voc, a.daily_min_voc,
|
||||||
a.daily_min_aqi
|
p.good_co2_percentage, p.moderate_co2_percentage, p.unhealthy_sensitive_co2_percentage, p.unhealthy_co2_percentage, p.very_unhealthy_co2_percentage, p.hazardous_co2_percentage,
|
||||||
|
a.daily_avg_co2,a.daily_max_co2, a.daily_min_co2,
|
||||||
|
p.good_ch2o_percentage, p.moderate_ch2o_percentage, p.unhealthy_sensitive_ch2o_percentage, p.unhealthy_ch2o_percentage, p.very_unhealthy_ch2o_percentage, p.hazardous_ch2o_percentage,
|
||||||
|
a.daily_avg_ch2o,a.daily_max_ch2o, a.daily_min_ch2o
|
||||||
FROM daily_percentages p
|
FROM daily_percentages p
|
||||||
LEFT JOIN daily_averages a
|
LEFT JOIN daily_averages a
|
||||||
ON p.device_id = a.device_id AND p.event_day = a.event_day
|
ON p.device_id = a.device_id AND p.event_date = a.event_date
|
||||||
ORDER BY p.space_id, p.event_day;
|
ORDER BY p.space_id, p.event_date;
|
||||||
|
|
||||||
|
|
||||||
|
Reference in New Issue
Block a user