mirror of
https://github.com/SyncrowIOT/backend.git
synced 2025-07-10 07:07:21 +00:00
Merge branch 'dev' into aqi-test
This commit is contained in:
@ -1,18 +1,18 @@
|
|||||||
|
import { PlatformType } from '@app/common/constants/platform-type.enum';
|
||||||
|
import { RoleType } from '@app/common/constants/role.type.enum';
|
||||||
import {
|
import {
|
||||||
BadRequestException,
|
BadRequestException,
|
||||||
Injectable,
|
Injectable,
|
||||||
UnauthorizedException,
|
UnauthorizedException,
|
||||||
} from '@nestjs/common';
|
} from '@nestjs/common';
|
||||||
|
import { ConfigService } from '@nestjs/config';
|
||||||
import { JwtService } from '@nestjs/jwt';
|
import { JwtService } from '@nestjs/jwt';
|
||||||
import * as argon2 from 'argon2';
|
import * as argon2 from 'argon2';
|
||||||
import { HelperHashService } from '../../helper/services';
|
|
||||||
import { UserRepository } from '../../../../common/src/modules/user/repositories';
|
|
||||||
import { UserSessionRepository } from '../../../../common/src/modules/session/repositories/session.repository';
|
|
||||||
import { UserSessionEntity } from '../../../../common/src/modules/session/entities';
|
|
||||||
import { ConfigService } from '@nestjs/config';
|
|
||||||
import { OAuth2Client } from 'google-auth-library';
|
import { OAuth2Client } from 'google-auth-library';
|
||||||
import { PlatformType } from '@app/common/constants/platform-type.enum';
|
import { UserSessionEntity } from '../../../../common/src/modules/session/entities';
|
||||||
import { RoleType } from '@app/common/constants/role.type.enum';
|
import { UserSessionRepository } from '../../../../common/src/modules/session/repositories/session.repository';
|
||||||
|
import { UserRepository } from '../../../../common/src/modules/user/repositories';
|
||||||
|
import { HelperHashService } from '../../helper/services';
|
||||||
|
|
||||||
@Injectable()
|
@Injectable()
|
||||||
export class AuthService {
|
export class AuthService {
|
||||||
@ -40,16 +40,17 @@ export class AuthService {
|
|||||||
},
|
},
|
||||||
relations: ['roleType', 'project'],
|
relations: ['roleType', 'project'],
|
||||||
});
|
});
|
||||||
if (
|
|
||||||
platform === PlatformType.WEB &&
|
|
||||||
(user.roleType.type === RoleType.SPACE_OWNER ||
|
|
||||||
user.roleType.type === RoleType.SPACE_MEMBER)
|
|
||||||
) {
|
|
||||||
throw new UnauthorizedException('Access denied for web platform');
|
|
||||||
}
|
|
||||||
if (!user) {
|
if (!user) {
|
||||||
throw new BadRequestException('Invalid credentials');
|
throw new BadRequestException('Invalid credentials');
|
||||||
}
|
}
|
||||||
|
if (
|
||||||
|
platform === PlatformType.WEB &&
|
||||||
|
[RoleType.SPACE_OWNER, RoleType.SPACE_MEMBER].includes(
|
||||||
|
user.roleType.type as RoleType,
|
||||||
|
)
|
||||||
|
) {
|
||||||
|
throw new UnauthorizedException('Access denied for web platform');
|
||||||
|
}
|
||||||
|
|
||||||
if (!user.isUserVerified) {
|
if (!user.isUserVerified) {
|
||||||
throw new BadRequestException('User is not verified');
|
throw new BadRequestException('User is not verified');
|
||||||
|
@ -465,7 +465,16 @@ export class ControllerRoute {
|
|||||||
'This endpoint retrieves the terms and conditions for the application.';
|
'This endpoint retrieves the terms and conditions for the application.';
|
||||||
};
|
};
|
||||||
};
|
};
|
||||||
|
static WEATHER = class {
|
||||||
|
public static readonly ROUTE = 'weather';
|
||||||
|
|
||||||
|
static ACTIONS = class {
|
||||||
|
public static readonly FETCH_WEATHER_DETAILS_SUMMARY =
|
||||||
|
'Fetch Weather Details';
|
||||||
|
public static readonly FETCH_WEATHER_DETAILS_DESCRIPTION =
|
||||||
|
'This endpoint retrieves the current weather details for a specified location like temperature, humidity, etc.';
|
||||||
|
};
|
||||||
|
};
|
||||||
static PRIVACY_POLICY = class {
|
static PRIVACY_POLICY = class {
|
||||||
public static readonly ROUTE = 'policy';
|
public static readonly ROUTE = 'policy';
|
||||||
|
|
||||||
|
@ -2,15 +2,15 @@ import { SourceType } from '@app/common/constants/source-type.enum';
|
|||||||
import { Entity, Column, PrimaryColumn, Unique } from 'typeorm';
|
import { Entity, Column, PrimaryColumn, Unique } from 'typeorm';
|
||||||
|
|
||||||
@Entity('device-status-log')
|
@Entity('device-status-log')
|
||||||
@Unique('event_time_idx', ['eventTime'])
|
@Unique('event_time_idx', ['eventTime', 'deviceId', 'code', 'value'])
|
||||||
export class DeviceStatusLogEntity {
|
export class DeviceStatusLogEntity {
|
||||||
@Column({ type: 'int', generated: true, unsigned: true })
|
@PrimaryColumn({ type: 'int', generated: true, unsigned: true })
|
||||||
id: number;
|
id: number;
|
||||||
|
|
||||||
@Column({ type: 'text' })
|
@Column({ type: 'text' })
|
||||||
eventId: string;
|
eventId: string;
|
||||||
|
|
||||||
@PrimaryColumn({ type: 'timestamptz' })
|
@Column({ type: 'timestamptz' })
|
||||||
eventTime: Date;
|
eventTime: Date;
|
||||||
|
|
||||||
@Column({
|
@Column({
|
||||||
|
@ -12,6 +12,7 @@ export class RoleTypeEntity extends AbstractEntity<RoleTypeDto> {
|
|||||||
nullable: false,
|
nullable: false,
|
||||||
enum: Object.values(RoleType),
|
enum: Object.values(RoleType),
|
||||||
})
|
})
|
||||||
|
// why is this ts-type string not enum?
|
||||||
type: string;
|
type: string;
|
||||||
@OneToMany(() => UserEntity, (inviteUser) => inviteUser.roleType, {
|
@OneToMany(() => UserEntity, (inviteUser) => inviteUser.roleType, {
|
||||||
nullable: true,
|
nullable: true,
|
||||||
|
@ -0,0 +1,39 @@
|
|||||||
|
WITH params AS (
|
||||||
|
SELECT
|
||||||
|
$1::uuid AS space_uuid,
|
||||||
|
TO_DATE(NULLIF($2, ''), 'YYYY-MM') AS event_month
|
||||||
|
)
|
||||||
|
|
||||||
|
SELECT
|
||||||
|
sdp.space_uuid,
|
||||||
|
sdp.event_date,
|
||||||
|
sdp.good_aqi_percentage, sdp.moderate_aqi_percentage, sdp.unhealthy_sensitive_aqi_percentage, sdp.unhealthy_aqi_percentage,
|
||||||
|
sdp.very_unhealthy_aqi_percentage, sdp.hazardous_aqi_percentage,
|
||||||
|
sdp.daily_avg_aqi, sdp.daily_max_aqi, sdp.daily_min_aqi,
|
||||||
|
|
||||||
|
sdp.good_pm25_percentage, sdp.moderate_pm25_percentage, sdp.unhealthy_sensitive_pm25_percentage, sdp.unhealthy_pm25_percentage,
|
||||||
|
sdp.very_unhealthy_pm25_percentage, sdp.hazardous_pm25_percentage,
|
||||||
|
sdp.daily_avg_pm25, sdp.daily_max_pm25, sdp.daily_min_pm25,
|
||||||
|
|
||||||
|
sdp.good_pm10_percentage, sdp.moderate_pm10_percentage, sdp.unhealthy_sensitive_pm10_percentage, sdp.unhealthy_pm10_percentage,
|
||||||
|
sdp.very_unhealthy_pm10_percentage, sdp.hazardous_pm10_percentage,
|
||||||
|
sdp.daily_avg_pm10, sdp.daily_max_pm10, sdp.daily_min_pm10,
|
||||||
|
|
||||||
|
sdp.good_voc_percentage, sdp.moderate_voc_percentage, sdp.unhealthy_sensitive_voc_percentage, sdp.unhealthy_voc_percentage,
|
||||||
|
sdp.very_unhealthy_voc_percentage, sdp.hazardous_voc_percentage,
|
||||||
|
sdp.daily_avg_voc, sdp.daily_max_voc, sdp.daily_min_voc,
|
||||||
|
|
||||||
|
sdp.good_co2_percentage, sdp.moderate_co2_percentage, sdp.unhealthy_sensitive_co2_percentage, sdp.unhealthy_co2_percentage,
|
||||||
|
sdp.very_unhealthy_co2_percentage, sdp.hazardous_co2_percentage,
|
||||||
|
sdp.daily_avg_co2, sdp.daily_max_co2, sdp.daily_min_co2,
|
||||||
|
|
||||||
|
sdp.good_ch2o_percentage, sdp.moderate_ch2o_percentage, sdp.unhealthy_sensitive_ch2o_percentage, sdp.unhealthy_ch2o_percentage,
|
||||||
|
sdp.very_unhealthy_ch2o_percentage, sdp.hazardous_ch2o_percentage,
|
||||||
|
sdp.daily_avg_ch2o, sdp.daily_max_ch2o, sdp.daily_min_ch2o
|
||||||
|
|
||||||
|
FROM public."space-daily-pollutant-stats" AS sdp
|
||||||
|
CROSS JOIN params p
|
||||||
|
WHERE
|
||||||
|
(p.space_uuid IS NULL OR sdp.space_uuid = p.space_uuid)
|
||||||
|
AND (p.event_month IS NULL OR TO_CHAR(sdp.event_date, 'YYYY-MM') = TO_CHAR(p.event_month, 'YYYY-MM'))
|
||||||
|
ORDER BY sdp.space_uuid, sdp.event_date;
|
@ -0,0 +1,374 @@
|
|||||||
|
WITH params AS (
|
||||||
|
SELECT
|
||||||
|
TO_DATE(NULLIF($1, ''), 'YYYY-MM-DD') AS event_date,
|
||||||
|
$2::uuid AS space_id
|
||||||
|
),
|
||||||
|
|
||||||
|
-- Query Pipeline Starts Here
|
||||||
|
device_space AS (
|
||||||
|
SELECT
|
||||||
|
device.uuid AS device_id,
|
||||||
|
device.space_device_uuid AS space_id,
|
||||||
|
"device-status-log".event_time::timestamp AS event_time,
|
||||||
|
"device-status-log".code,
|
||||||
|
"device-status-log".value
|
||||||
|
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'
|
||||||
|
),
|
||||||
|
|
||||||
|
average_pollutants AS (
|
||||||
|
SELECT
|
||||||
|
event_time::date AS event_date,
|
||||||
|
date_trunc('hour', event_time) AS event_hour,
|
||||||
|
space_id,
|
||||||
|
|
||||||
|
-- PM1
|
||||||
|
MIN(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_min,
|
||||||
|
AVG(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_avg,
|
||||||
|
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,
|
||||||
|
|
||||||
|
-- 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,
|
||||||
|
|
||||||
|
-- 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,
|
||||||
|
|
||||||
|
-- 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
|
||||||
|
|
||||||
|
FROM device_space
|
||||||
|
GROUP BY space_id, event_hour, event_date
|
||||||
|
),
|
||||||
|
|
||||||
|
filled_pollutants AS (
|
||||||
|
SELECT
|
||||||
|
*,
|
||||||
|
-- AVG
|
||||||
|
COALESCE(pm25_avg, LAG(pm25_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm25_avg_f,
|
||||||
|
COALESCE(pm10_avg, LAG(pm10_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm10_avg_f,
|
||||||
|
COALESCE(voc_avg, LAG(voc_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS voc_avg_f,
|
||||||
|
COALESCE(co2_avg, LAG(co2_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS co2_avg_f,
|
||||||
|
COALESCE(ch2o_avg, LAG(ch2o_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS ch2o_avg_f,
|
||||||
|
|
||||||
|
-- MIN
|
||||||
|
COALESCE(pm25_min, LAG(pm25_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm25_min_f,
|
||||||
|
COALESCE(pm10_min, LAG(pm10_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm10_min_f,
|
||||||
|
COALESCE(voc_min, LAG(voc_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS voc_min_f,
|
||||||
|
COALESCE(co2_min, LAG(co2_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS co2_min_f,
|
||||||
|
COALESCE(ch2o_min, LAG(ch2o_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS ch2o_min_f,
|
||||||
|
|
||||||
|
-- MAX
|
||||||
|
COALESCE(pm25_max, LAG(pm25_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm25_max_f,
|
||||||
|
COALESCE(pm10_max, LAG(pm10_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm10_max_f,
|
||||||
|
COALESCE(voc_max, LAG(voc_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS voc_max_f,
|
||||||
|
COALESCE(co2_max, LAG(co2_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS co2_max_f,
|
||||||
|
COALESCE(ch2o_max, LAG(ch2o_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS ch2o_max_f
|
||||||
|
FROM average_pollutants
|
||||||
|
),
|
||||||
|
|
||||||
|
hourly_results AS (
|
||||||
|
SELECT
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
event_hour,
|
||||||
|
pm1_min, pm1_avg, pm1_max,
|
||||||
|
pm25_min_f, pm25_avg_f, pm25_max_f,
|
||||||
|
pm10_min_f, pm10_avg_f, pm10_max_f,
|
||||||
|
voc_min_f, voc_avg_f, voc_max_f,
|
||||||
|
co2_min_f, co2_avg_f, co2_max_f,
|
||||||
|
ch2o_min_f, ch2o_avg_f, ch2o_max_f,
|
||||||
|
|
||||||
|
GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_min_f),
|
||||||
|
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,
|
||||||
|
|
||||||
|
GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_max_f),
|
||||||
|
calculate_aqi('pm10', pm10_max_f)
|
||||||
|
) AS hourly_max_aqi,
|
||||||
|
|
||||||
|
classify_aqi(GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_avg_f),
|
||||||
|
calculate_aqi('pm10', pm10_avg_f)
|
||||||
|
)) AS aqi_category,
|
||||||
|
|
||||||
|
classify_aqi(calculate_aqi('pm25',pm25_avg_f)) as pm25_category,
|
||||||
|
classify_aqi(calculate_aqi('pm10',pm10_avg_f)) as pm10_category,
|
||||||
|
classify_aqi(calculate_aqi('voc',voc_avg_f)) as voc_category,
|
||||||
|
classify_aqi(calculate_aqi('co2',co2_avg_f)) as co2_category,
|
||||||
|
classify_aqi(calculate_aqi('ch2o',ch2o_avg_f)) as ch2o_category
|
||||||
|
|
||||||
|
FROM filled_pollutants
|
||||||
|
),
|
||||||
|
|
||||||
|
daily_category_counts AS (
|
||||||
|
SELECT space_id, event_date, aqi_category AS category, 'aqi' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, aqi_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, pm25_category AS category, 'pm25' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, pm25_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, pm10_category AS category, 'pm10' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, pm10_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, voc_category AS category, 'voc' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, voc_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, co2_category AS category, 'co2' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, co2_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, ch2o_category AS category, 'ch2o' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, ch2o_category
|
||||||
|
),
|
||||||
|
|
||||||
|
daily_totals AS (
|
||||||
|
SELECT
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
SUM(category_count) AS total_count
|
||||||
|
FROM daily_category_counts
|
||||||
|
where pollutant = 'aqi'
|
||||||
|
GROUP BY space_id, event_date
|
||||||
|
),
|
||||||
|
|
||||||
|
-- Pivot Categories into Columns
|
||||||
|
daily_percentages AS (
|
||||||
|
select
|
||||||
|
dt.space_id,
|
||||||
|
dt.event_date,
|
||||||
|
-- AQI CATEGORIES
|
||||||
|
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.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.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.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.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
|
||||||
|
LEFT JOIN daily_category_counts dcc
|
||||||
|
ON dt.space_id = dcc.space_id AND dt.event_date = dcc.event_date
|
||||||
|
GROUP BY dt.space_id, dt.event_date, dt.total_count
|
||||||
|
),
|
||||||
|
|
||||||
|
daily_averages AS (
|
||||||
|
SELECT
|
||||||
|
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 space_id, event_date
|
||||||
|
),
|
||||||
|
|
||||||
|
final_data as(
|
||||||
|
SELECT
|
||||||
|
p.space_id,
|
||||||
|
p.event_date,
|
||||||
|
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,
|
||||||
|
a.daily_avg_aqi,a.daily_max_aqi, a.daily_min_aqi,
|
||||||
|
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,
|
||||||
|
a.daily_avg_pm25,a.daily_max_pm25, a.daily_min_pm25,
|
||||||
|
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,
|
||||||
|
a.daily_avg_pm10, a.daily_max_pm10, a.daily_min_pm10,
|
||||||
|
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_avg_voc, a.daily_max_voc, a.daily_min_voc,
|
||||||
|
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
|
||||||
|
LEFT JOIN daily_averages a
|
||||||
|
ON p.space_id = a.space_id AND p.event_date = a.event_date
|
||||||
|
ORDER BY p.space_id, p.event_date)
|
||||||
|
|
||||||
|
|
||||||
|
INSERT INTO public."space-daily-pollutant-stats" (
|
||||||
|
space_uuid,
|
||||||
|
event_date,
|
||||||
|
good_aqi_percentage, moderate_aqi_percentage, unhealthy_sensitive_aqi_percentage, unhealthy_aqi_percentage, very_unhealthy_aqi_percentage, hazardous_aqi_percentage,
|
||||||
|
daily_avg_aqi, daily_max_aqi, daily_min_aqi,
|
||||||
|
good_pm25_percentage, moderate_pm25_percentage, unhealthy_sensitive_pm25_percentage, unhealthy_pm25_percentage, very_unhealthy_pm25_percentage, hazardous_pm25_percentage,
|
||||||
|
daily_avg_pm25, daily_max_pm25, daily_min_pm25,
|
||||||
|
good_pm10_percentage, moderate_pm10_percentage, unhealthy_sensitive_pm10_percentage, unhealthy_pm10_percentage, very_unhealthy_pm10_percentage, hazardous_pm10_percentage,
|
||||||
|
daily_avg_pm10, daily_max_pm10, daily_min_pm10,
|
||||||
|
good_voc_percentage, moderate_voc_percentage, unhealthy_sensitive_voc_percentage, unhealthy_voc_percentage, very_unhealthy_voc_percentage, hazardous_voc_percentage,
|
||||||
|
daily_avg_voc, daily_max_voc, daily_min_voc,
|
||||||
|
good_co2_percentage, moderate_co2_percentage, unhealthy_sensitive_co2_percentage, unhealthy_co2_percentage, very_unhealthy_co2_percentage, hazardous_co2_percentage,
|
||||||
|
daily_avg_co2, daily_max_co2, daily_min_co2,
|
||||||
|
good_ch2o_percentage, moderate_ch2o_percentage, unhealthy_sensitive_ch2o_percentage, unhealthy_ch2o_percentage, very_unhealthy_ch2o_percentage, hazardous_ch2o_percentage,
|
||||||
|
daily_avg_ch2o, daily_max_ch2o, daily_min_ch2o
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
good_aqi_percentage, moderate_aqi_percentage, unhealthy_sensitive_aqi_percentage, unhealthy_aqi_percentage, very_unhealthy_aqi_percentage, hazardous_aqi_percentage,
|
||||||
|
daily_avg_aqi, daily_max_aqi, daily_min_aqi,
|
||||||
|
good_pm25_percentage, moderate_pm25_percentage, unhealthy_sensitive_pm25_percentage, unhealthy_pm25_percentage, very_unhealthy_pm25_percentage, hazardous_pm25_percentage,
|
||||||
|
daily_avg_pm25, daily_max_pm25, daily_min_pm25,
|
||||||
|
good_pm10_percentage, moderate_pm10_percentage, unhealthy_sensitive_pm10_percentage, unhealthy_pm10_percentage, very_unhealthy_pm10_percentage, hazardous_pm10_percentage,
|
||||||
|
daily_avg_pm10, daily_max_pm10, daily_min_pm10,
|
||||||
|
good_voc_percentage, moderate_voc_percentage, unhealthy_sensitive_voc_percentage, unhealthy_voc_percentage, very_unhealthy_voc_percentage, hazardous_voc_percentage,
|
||||||
|
daily_avg_voc, daily_max_voc, daily_min_voc,
|
||||||
|
good_co2_percentage, moderate_co2_percentage, unhealthy_sensitive_co2_percentage, unhealthy_co2_percentage, very_unhealthy_co2_percentage, hazardous_co2_percentage,
|
||||||
|
daily_avg_co2, daily_max_co2, daily_min_co2,
|
||||||
|
good_ch2o_percentage, moderate_ch2o_percentage, unhealthy_sensitive_ch2o_percentage, unhealthy_ch2o_percentage, very_unhealthy_ch2o_percentage, hazardous_ch2o_percentage,
|
||||||
|
daily_avg_ch2o, daily_max_ch2o, daily_min_ch2o
|
||||||
|
FROM final_data
|
||||||
|
ON CONFLICT (space_uuid, event_date) DO UPDATE
|
||||||
|
SET
|
||||||
|
good_aqi_percentage = EXCLUDED.good_aqi_percentage,
|
||||||
|
moderate_aqi_percentage = EXCLUDED.moderate_aqi_percentage,
|
||||||
|
unhealthy_sensitive_aqi_percentage = EXCLUDED.unhealthy_sensitive_aqi_percentage,
|
||||||
|
unhealthy_aqi_percentage = EXCLUDED.unhealthy_aqi_percentage,
|
||||||
|
very_unhealthy_aqi_percentage = EXCLUDED.very_unhealthy_aqi_percentage,
|
||||||
|
hazardous_aqi_percentage = EXCLUDED.hazardous_aqi_percentage,
|
||||||
|
daily_avg_aqi = EXCLUDED.daily_avg_aqi,
|
||||||
|
daily_max_aqi = EXCLUDED.daily_max_aqi,
|
||||||
|
daily_min_aqi = EXCLUDED.daily_min_aqi,
|
||||||
|
good_pm25_percentage = EXCLUDED.good_pm25_percentage,
|
||||||
|
moderate_pm25_percentage = EXCLUDED.moderate_pm25_percentage,
|
||||||
|
unhealthy_sensitive_pm25_percentage = EXCLUDED.unhealthy_sensitive_pm25_percentage,
|
||||||
|
unhealthy_pm25_percentage = EXCLUDED.unhealthy_pm25_percentage,
|
||||||
|
very_unhealthy_pm25_percentage = EXCLUDED.very_unhealthy_pm25_percentage,
|
||||||
|
hazardous_pm25_percentage = EXCLUDED.hazardous_pm25_percentage,
|
||||||
|
daily_avg_pm25 = EXCLUDED.daily_avg_pm25,
|
||||||
|
daily_max_pm25 = EXCLUDED.daily_max_pm25,
|
||||||
|
daily_min_pm25 = EXCLUDED.daily_min_pm25,
|
||||||
|
good_pm10_percentage = EXCLUDED.good_pm10_percentage,
|
||||||
|
moderate_pm10_percentage = EXCLUDED.moderate_pm10_percentage,
|
||||||
|
unhealthy_sensitive_pm10_percentage = EXCLUDED.unhealthy_sensitive_pm10_percentage,
|
||||||
|
unhealthy_pm10_percentage = EXCLUDED.unhealthy_pm10_percentage,
|
||||||
|
very_unhealthy_pm10_percentage = EXCLUDED.very_unhealthy_pm10_percentage,
|
||||||
|
hazardous_pm10_percentage = EXCLUDED.hazardous_pm10_percentage,
|
||||||
|
daily_avg_pm10 = EXCLUDED.daily_avg_pm10,
|
||||||
|
daily_max_pm10 = EXCLUDED.daily_max_pm10,
|
||||||
|
daily_min_pm10 = EXCLUDED.daily_min_pm10,
|
||||||
|
good_voc_percentage = EXCLUDED.good_voc_percentage,
|
||||||
|
moderate_voc_percentage = EXCLUDED.moderate_voc_percentage,
|
||||||
|
unhealthy_sensitive_voc_percentage = EXCLUDED.unhealthy_sensitive_voc_percentage,
|
||||||
|
unhealthy_voc_percentage = EXCLUDED.unhealthy_voc_percentage,
|
||||||
|
very_unhealthy_voc_percentage = EXCLUDED.very_unhealthy_voc_percentage,
|
||||||
|
hazardous_voc_percentage = EXCLUDED.hazardous_voc_percentage,
|
||||||
|
daily_avg_voc = EXCLUDED.daily_avg_voc,
|
||||||
|
daily_max_voc = EXCLUDED.daily_max_voc,
|
||||||
|
daily_min_voc = EXCLUDED.daily_min_voc,
|
||||||
|
good_co2_percentage = EXCLUDED.good_co2_percentage,
|
||||||
|
moderate_co2_percentage = EXCLUDED.moderate_co2_percentage,
|
||||||
|
unhealthy_sensitive_co2_percentage = EXCLUDED.unhealthy_sensitive_co2_percentage,
|
||||||
|
unhealthy_co2_percentage = EXCLUDED.unhealthy_co2_percentage,
|
||||||
|
very_unhealthy_co2_percentage = EXCLUDED.very_unhealthy_co2_percentage,
|
||||||
|
hazardous_co2_percentage = EXCLUDED.hazardous_co2_percentage,
|
||||||
|
daily_avg_co2 = EXCLUDED.daily_avg_co2,
|
||||||
|
daily_max_co2 = EXCLUDED.daily_max_co2,
|
||||||
|
daily_min_co2 = EXCLUDED.daily_min_co2,
|
||||||
|
good_ch2o_percentage = EXCLUDED.good_ch2o_percentage,
|
||||||
|
moderate_ch2o_percentage = EXCLUDED.moderate_ch2o_percentage,
|
||||||
|
unhealthy_sensitive_ch2o_percentage = EXCLUDED.unhealthy_sensitive_ch2o_percentage,
|
||||||
|
unhealthy_ch2o_percentage = EXCLUDED.unhealthy_ch2o_percentage,
|
||||||
|
very_unhealthy_ch2o_percentage = EXCLUDED.very_unhealthy_ch2o_percentage,
|
||||||
|
hazardous_ch2o_percentage = EXCLUDED.hazardous_ch2o_percentage,
|
||||||
|
daily_avg_ch2o = EXCLUDED.daily_avg_ch2o,
|
||||||
|
daily_max_ch2o = EXCLUDED.daily_max_ch2o,
|
||||||
|
daily_min_ch2o = EXCLUDED.daily_min_ch2o;
|
||||||
|
|
||||||
|
|
||||||
|
|
@ -0,0 +1,367 @@
|
|||||||
|
-- Query Pipeline Starts Here
|
||||||
|
WITH device_space AS (
|
||||||
|
SELECT
|
||||||
|
device.uuid AS device_id,
|
||||||
|
device.space_device_uuid AS space_id,
|
||||||
|
"device-status-log".event_time::timestamp AS event_time,
|
||||||
|
"device-status-log".code,
|
||||||
|
"device-status-log".value
|
||||||
|
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'
|
||||||
|
),
|
||||||
|
|
||||||
|
average_pollutants AS (
|
||||||
|
SELECT
|
||||||
|
event_time::date AS event_date,
|
||||||
|
date_trunc('hour', event_time) AS event_hour,
|
||||||
|
space_id,
|
||||||
|
|
||||||
|
-- PM1
|
||||||
|
MIN(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_min,
|
||||||
|
AVG(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_avg,
|
||||||
|
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,
|
||||||
|
|
||||||
|
-- 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,
|
||||||
|
|
||||||
|
-- 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,
|
||||||
|
|
||||||
|
-- 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
|
||||||
|
|
||||||
|
FROM device_space
|
||||||
|
GROUP BY space_id, event_hour, event_date
|
||||||
|
),
|
||||||
|
|
||||||
|
filled_pollutants AS (
|
||||||
|
SELECT
|
||||||
|
*,
|
||||||
|
-- AVG
|
||||||
|
COALESCE(pm25_avg, LAG(pm25_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm25_avg_f,
|
||||||
|
COALESCE(pm10_avg, LAG(pm10_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm10_avg_f,
|
||||||
|
COALESCE(voc_avg, LAG(voc_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS voc_avg_f,
|
||||||
|
COALESCE(co2_avg, LAG(co2_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS co2_avg_f,
|
||||||
|
COALESCE(ch2o_avg, LAG(ch2o_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS ch2o_avg_f,
|
||||||
|
|
||||||
|
-- MIN
|
||||||
|
COALESCE(pm25_min, LAG(pm25_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm25_min_f,
|
||||||
|
COALESCE(pm10_min, LAG(pm10_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm10_min_f,
|
||||||
|
COALESCE(voc_min, LAG(voc_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS voc_min_f,
|
||||||
|
COALESCE(co2_min, LAG(co2_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS co2_min_f,
|
||||||
|
COALESCE(ch2o_min, LAG(ch2o_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS ch2o_min_f,
|
||||||
|
|
||||||
|
-- MAX
|
||||||
|
COALESCE(pm25_max, LAG(pm25_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm25_max_f,
|
||||||
|
COALESCE(pm10_max, LAG(pm10_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm10_max_f,
|
||||||
|
COALESCE(voc_max, LAG(voc_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS voc_max_f,
|
||||||
|
COALESCE(co2_max, LAG(co2_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS co2_max_f,
|
||||||
|
COALESCE(ch2o_max, LAG(ch2o_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS ch2o_max_f
|
||||||
|
FROM average_pollutants
|
||||||
|
),
|
||||||
|
|
||||||
|
hourly_results AS (
|
||||||
|
SELECT
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
event_hour,
|
||||||
|
pm1_min, pm1_avg, pm1_max,
|
||||||
|
pm25_min_f, pm25_avg_f, pm25_max_f,
|
||||||
|
pm10_min_f, pm10_avg_f, pm10_max_f,
|
||||||
|
voc_min_f, voc_avg_f, voc_max_f,
|
||||||
|
co2_min_f, co2_avg_f, co2_max_f,
|
||||||
|
ch2o_min_f, ch2o_avg_f, ch2o_max_f,
|
||||||
|
|
||||||
|
GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_min_f),
|
||||||
|
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,
|
||||||
|
|
||||||
|
GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_max_f),
|
||||||
|
calculate_aqi('pm10', pm10_max_f)
|
||||||
|
) AS hourly_max_aqi,
|
||||||
|
|
||||||
|
classify_aqi(GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_avg_f),
|
||||||
|
calculate_aqi('pm10', pm10_avg_f)
|
||||||
|
)) AS aqi_category,
|
||||||
|
|
||||||
|
classify_aqi(calculate_aqi('pm25',pm25_avg_f)) as pm25_category,
|
||||||
|
classify_aqi(calculate_aqi('pm10',pm10_avg_f)) as pm10_category,
|
||||||
|
classify_aqi(calculate_aqi('voc',voc_avg_f)) as voc_category,
|
||||||
|
classify_aqi(calculate_aqi('co2',co2_avg_f)) as co2_category,
|
||||||
|
classify_aqi(calculate_aqi('ch2o',ch2o_avg_f)) as ch2o_category
|
||||||
|
|
||||||
|
FROM filled_pollutants
|
||||||
|
),
|
||||||
|
|
||||||
|
daily_category_counts AS (
|
||||||
|
SELECT space_id, event_date, aqi_category AS category, 'aqi' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, aqi_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, pm25_category AS category, 'pm25' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, pm25_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, pm10_category AS category, 'pm10' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, pm10_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, voc_category AS category, 'voc' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, voc_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, co2_category AS category, 'co2' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, co2_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, ch2o_category AS category, 'ch2o' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, ch2o_category
|
||||||
|
),
|
||||||
|
|
||||||
|
daily_totals AS (
|
||||||
|
SELECT
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
SUM(category_count) AS total_count
|
||||||
|
FROM daily_category_counts
|
||||||
|
where pollutant = 'aqi'
|
||||||
|
GROUP BY space_id, event_date
|
||||||
|
),
|
||||||
|
|
||||||
|
-- Pivot Categories into Columns
|
||||||
|
daily_percentages AS (
|
||||||
|
select
|
||||||
|
dt.space_id,
|
||||||
|
dt.event_date,
|
||||||
|
-- AQI CATEGORIES
|
||||||
|
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.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.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.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.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
|
||||||
|
LEFT JOIN daily_category_counts dcc
|
||||||
|
ON dt.space_id = dcc.space_id AND dt.event_date = dcc.event_date
|
||||||
|
GROUP BY dt.space_id, dt.event_date, dt.total_count
|
||||||
|
),
|
||||||
|
|
||||||
|
daily_averages AS (
|
||||||
|
SELECT
|
||||||
|
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 space_id, event_date
|
||||||
|
),
|
||||||
|
|
||||||
|
final_data as(
|
||||||
|
SELECT
|
||||||
|
p.space_id,
|
||||||
|
p.event_date,
|
||||||
|
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,
|
||||||
|
a.daily_avg_aqi,a.daily_max_aqi, a.daily_min_aqi,
|
||||||
|
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,
|
||||||
|
a.daily_avg_pm25,a.daily_max_pm25, a.daily_min_pm25,
|
||||||
|
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,
|
||||||
|
a.daily_avg_pm10, a.daily_max_pm10, a.daily_min_pm10,
|
||||||
|
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_avg_voc, a.daily_max_voc, a.daily_min_voc,
|
||||||
|
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
|
||||||
|
LEFT JOIN daily_averages a
|
||||||
|
ON p.space_id = a.space_id AND p.event_date = a.event_date
|
||||||
|
ORDER BY p.space_id, p.event_date)
|
||||||
|
|
||||||
|
|
||||||
|
INSERT INTO public."space-daily-pollutant-stats" (
|
||||||
|
space_uuid,
|
||||||
|
event_date,
|
||||||
|
good_aqi_percentage, moderate_aqi_percentage, unhealthy_sensitive_aqi_percentage, unhealthy_aqi_percentage, very_unhealthy_aqi_percentage, hazardous_aqi_percentage,
|
||||||
|
daily_avg_aqi, daily_max_aqi, daily_min_aqi,
|
||||||
|
good_pm25_percentage, moderate_pm25_percentage, unhealthy_sensitive_pm25_percentage, unhealthy_pm25_percentage, very_unhealthy_pm25_percentage, hazardous_pm25_percentage,
|
||||||
|
daily_avg_pm25, daily_max_pm25, daily_min_pm25,
|
||||||
|
good_pm10_percentage, moderate_pm10_percentage, unhealthy_sensitive_pm10_percentage, unhealthy_pm10_percentage, very_unhealthy_pm10_percentage, hazardous_pm10_percentage,
|
||||||
|
daily_avg_pm10, daily_max_pm10, daily_min_pm10,
|
||||||
|
good_voc_percentage, moderate_voc_percentage, unhealthy_sensitive_voc_percentage, unhealthy_voc_percentage, very_unhealthy_voc_percentage, hazardous_voc_percentage,
|
||||||
|
daily_avg_voc, daily_max_voc, daily_min_voc,
|
||||||
|
good_co2_percentage, moderate_co2_percentage, unhealthy_sensitive_co2_percentage, unhealthy_co2_percentage, very_unhealthy_co2_percentage, hazardous_co2_percentage,
|
||||||
|
daily_avg_co2, daily_max_co2, daily_min_co2,
|
||||||
|
good_ch2o_percentage, moderate_ch2o_percentage, unhealthy_sensitive_ch2o_percentage, unhealthy_ch2o_percentage, very_unhealthy_ch2o_percentage, hazardous_ch2o_percentage,
|
||||||
|
daily_avg_ch2o, daily_max_ch2o, daily_min_ch2o
|
||||||
|
)
|
||||||
|
SELECT
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
good_aqi_percentage, moderate_aqi_percentage, unhealthy_sensitive_aqi_percentage, unhealthy_aqi_percentage, very_unhealthy_aqi_percentage, hazardous_aqi_percentage,
|
||||||
|
daily_avg_aqi, daily_max_aqi, daily_min_aqi,
|
||||||
|
good_pm25_percentage, moderate_pm25_percentage, unhealthy_sensitive_pm25_percentage, unhealthy_pm25_percentage, very_unhealthy_pm25_percentage, hazardous_pm25_percentage,
|
||||||
|
daily_avg_pm25, daily_max_pm25, daily_min_pm25,
|
||||||
|
good_pm10_percentage, moderate_pm10_percentage, unhealthy_sensitive_pm10_percentage, unhealthy_pm10_percentage, very_unhealthy_pm10_percentage, hazardous_pm10_percentage,
|
||||||
|
daily_avg_pm10, daily_max_pm10, daily_min_pm10,
|
||||||
|
good_voc_percentage, moderate_voc_percentage, unhealthy_sensitive_voc_percentage, unhealthy_voc_percentage, very_unhealthy_voc_percentage, hazardous_voc_percentage,
|
||||||
|
daily_avg_voc, daily_max_voc, daily_min_voc,
|
||||||
|
good_co2_percentage, moderate_co2_percentage, unhealthy_sensitive_co2_percentage, unhealthy_co2_percentage, very_unhealthy_co2_percentage, hazardous_co2_percentage,
|
||||||
|
daily_avg_co2, daily_max_co2, daily_min_co2,
|
||||||
|
good_ch2o_percentage, moderate_ch2o_percentage, unhealthy_sensitive_ch2o_percentage, unhealthy_ch2o_percentage, very_unhealthy_ch2o_percentage, hazardous_ch2o_percentage,
|
||||||
|
daily_avg_ch2o, daily_max_ch2o, daily_min_ch2o
|
||||||
|
FROM final_data
|
||||||
|
ON CONFLICT (space_uuid, event_date) DO UPDATE
|
||||||
|
SET
|
||||||
|
good_aqi_percentage = EXCLUDED.good_aqi_percentage,
|
||||||
|
moderate_aqi_percentage = EXCLUDED.moderate_aqi_percentage,
|
||||||
|
unhealthy_sensitive_aqi_percentage = EXCLUDED.unhealthy_sensitive_aqi_percentage,
|
||||||
|
unhealthy_aqi_percentage = EXCLUDED.unhealthy_aqi_percentage,
|
||||||
|
very_unhealthy_aqi_percentage = EXCLUDED.very_unhealthy_aqi_percentage,
|
||||||
|
hazardous_aqi_percentage = EXCLUDED.hazardous_aqi_percentage,
|
||||||
|
daily_avg_aqi = EXCLUDED.daily_avg_aqi,
|
||||||
|
daily_max_aqi = EXCLUDED.daily_max_aqi,
|
||||||
|
daily_min_aqi = EXCLUDED.daily_min_aqi,
|
||||||
|
good_pm25_percentage = EXCLUDED.good_pm25_percentage,
|
||||||
|
moderate_pm25_percentage = EXCLUDED.moderate_pm25_percentage,
|
||||||
|
unhealthy_sensitive_pm25_percentage = EXCLUDED.unhealthy_sensitive_pm25_percentage,
|
||||||
|
unhealthy_pm25_percentage = EXCLUDED.unhealthy_pm25_percentage,
|
||||||
|
very_unhealthy_pm25_percentage = EXCLUDED.very_unhealthy_pm25_percentage,
|
||||||
|
hazardous_pm25_percentage = EXCLUDED.hazardous_pm25_percentage,
|
||||||
|
daily_avg_pm25 = EXCLUDED.daily_avg_pm25,
|
||||||
|
daily_max_pm25 = EXCLUDED.daily_max_pm25,
|
||||||
|
daily_min_pm25 = EXCLUDED.daily_min_pm25,
|
||||||
|
good_pm10_percentage = EXCLUDED.good_pm10_percentage,
|
||||||
|
moderate_pm10_percentage = EXCLUDED.moderate_pm10_percentage,
|
||||||
|
unhealthy_sensitive_pm10_percentage = EXCLUDED.unhealthy_sensitive_pm10_percentage,
|
||||||
|
unhealthy_pm10_percentage = EXCLUDED.unhealthy_pm10_percentage,
|
||||||
|
very_unhealthy_pm10_percentage = EXCLUDED.very_unhealthy_pm10_percentage,
|
||||||
|
hazardous_pm10_percentage = EXCLUDED.hazardous_pm10_percentage,
|
||||||
|
daily_avg_pm10 = EXCLUDED.daily_avg_pm10,
|
||||||
|
daily_max_pm10 = EXCLUDED.daily_max_pm10,
|
||||||
|
daily_min_pm10 = EXCLUDED.daily_min_pm10,
|
||||||
|
good_voc_percentage = EXCLUDED.good_voc_percentage,
|
||||||
|
moderate_voc_percentage = EXCLUDED.moderate_voc_percentage,
|
||||||
|
unhealthy_sensitive_voc_percentage = EXCLUDED.unhealthy_sensitive_voc_percentage,
|
||||||
|
unhealthy_voc_percentage = EXCLUDED.unhealthy_voc_percentage,
|
||||||
|
very_unhealthy_voc_percentage = EXCLUDED.very_unhealthy_voc_percentage,
|
||||||
|
hazardous_voc_percentage = EXCLUDED.hazardous_voc_percentage,
|
||||||
|
daily_avg_voc = EXCLUDED.daily_avg_voc,
|
||||||
|
daily_max_voc = EXCLUDED.daily_max_voc,
|
||||||
|
daily_min_voc = EXCLUDED.daily_min_voc,
|
||||||
|
good_co2_percentage = EXCLUDED.good_co2_percentage,
|
||||||
|
moderate_co2_percentage = EXCLUDED.moderate_co2_percentage,
|
||||||
|
unhealthy_sensitive_co2_percentage = EXCLUDED.unhealthy_sensitive_co2_percentage,
|
||||||
|
unhealthy_co2_percentage = EXCLUDED.unhealthy_co2_percentage,
|
||||||
|
very_unhealthy_co2_percentage = EXCLUDED.very_unhealthy_co2_percentage,
|
||||||
|
hazardous_co2_percentage = EXCLUDED.hazardous_co2_percentage,
|
||||||
|
daily_avg_co2 = EXCLUDED.daily_avg_co2,
|
||||||
|
daily_max_co2 = EXCLUDED.daily_max_co2,
|
||||||
|
daily_min_co2 = EXCLUDED.daily_min_co2,
|
||||||
|
good_ch2o_percentage = EXCLUDED.good_ch2o_percentage,
|
||||||
|
moderate_ch2o_percentage = EXCLUDED.moderate_ch2o_percentage,
|
||||||
|
unhealthy_sensitive_ch2o_percentage = EXCLUDED.unhealthy_sensitive_ch2o_percentage,
|
||||||
|
unhealthy_ch2o_percentage = EXCLUDED.unhealthy_ch2o_percentage,
|
||||||
|
very_unhealthy_ch2o_percentage = EXCLUDED.very_unhealthy_ch2o_percentage,
|
||||||
|
hazardous_ch2o_percentage = EXCLUDED.hazardous_ch2o_percentage,
|
||||||
|
daily_avg_ch2o = EXCLUDED.daily_avg_ch2o,
|
||||||
|
daily_max_ch2o = EXCLUDED.daily_max_ch2o,
|
||||||
|
daily_min_ch2o = EXCLUDED.daily_min_ch2o;
|
||||||
|
|
||||||
|
|
@ -26,36 +26,52 @@ 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_0, level_1) 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;
|
||||||
@ -63,100 +79,284 @@ 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,
|
||||||
device.created_at,
|
|
||||||
device.space_device_uuid AS space_id,
|
device.space_device_uuid AS space_id,
|
||||||
"device-status-log".event_id,
|
"device-status-log".event_time::timestamp AS event_time,
|
||||||
"device-status-log".event_time::date,
|
|
||||||
"device-status-log".code,
|
"device-status-log".code,
|
||||||
"device-status-log".value,
|
"device-status-log".value
|
||||||
"device-status-log".log
|
|
||||||
FROM device
|
FROM device
|
||||||
LEFT JOIN "device-status-log"
|
LEFT JOIN "device-status-log"
|
||||||
ON device.uuid = "device-status-log".device_id
|
ON device.uuid = "device-status-log".device_id
|
||||||
LEFT JOIN product
|
LEFT JOIN product
|
||||||
ON product.uuid = device.product_device_uuid
|
ON product.uuid = device.product_device_uuid
|
||||||
WHERE product.cat_name = 'hjjcy'
|
WHERE product.cat_name = 'hjjcy'
|
||||||
),
|
),
|
||||||
|
|
||||||
-- Aggregate air sensor data per device per day
|
average_pollutants AS (
|
||||||
air_data AS (
|
|
||||||
SELECT
|
SELECT
|
||||||
event_time AS date,
|
event_time::date AS event_date,
|
||||||
|
date_trunc('hour', event_time) AS event_hour,
|
||||||
device_id,
|
device_id,
|
||||||
space_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
|
-- PM1
|
||||||
MIN(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_min,
|
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,
|
AVG(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_avg,
|
||||||
|
MAX(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_max,
|
||||||
|
|
||||||
-- PM2.5
|
-- PM25
|
||||||
MIN(CASE WHEN code = 'pm25_value' THEN value::numeric END) AS pm25_min,
|
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,
|
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,
|
||||||
|
|
||||||
-- PM10
|
-- PM10
|
||||||
MIN(CASE WHEN code = 'pm10' THEN value::numeric END) AS pm10_min,
|
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,
|
AVG(CASE WHEN code = 'pm10' THEN value::numeric END) AS pm10_avg,
|
||||||
|
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
|
-- CH2O
|
||||||
MIN(CASE WHEN code = 'ch2o_value' THEN value::numeric END) AS ch2o_min,
|
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,
|
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,
|
||||||
-- 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
|
-- CO2
|
||||||
MIN(CASE WHEN code = 'co2_value' THEN value::numeric END) AS co2_min,
|
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,
|
||||||
|
MAX(CASE WHEN code = 'co2_value' THEN value::numeric END) AS co2_max
|
||||||
-- AQI
|
|
||||||
AVG(CASE WHEN code = 'air_quality_index' then level_to_numeric(value) END) as air_quality_index
|
|
||||||
|
|
||||||
|
|
||||||
FROM device_space
|
FROM device_space
|
||||||
GROUP BY date, device_id, space_id
|
GROUP BY device_id, space_id, event_hour, event_date
|
||||||
|
),
|
||||||
|
|
||||||
|
filled_pollutants AS (
|
||||||
|
SELECT
|
||||||
|
*,
|
||||||
|
-- AVG
|
||||||
|
COALESCE(pm25_avg, LAG(pm25_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm25_avg_f,
|
||||||
|
COALESCE(pm10_avg, LAG(pm10_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS pm10_avg_f,
|
||||||
|
COALESCE(voc_avg, LAG(voc_avg) OVER (PARTITION BY device_id ORDER BY event_hour)) AS voc_avg_f,
|
||||||
|
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,
|
||||||
|
|
||||||
|
-- MIN
|
||||||
|
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(voc_min, LAG(voc_min) OVER (PARTITION BY device_id ORDER BY event_hour)) AS voc_min_f,
|
||||||
|
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
|
||||||
|
),
|
||||||
|
|
||||||
|
hourly_results AS (
|
||||||
|
SELECT
|
||||||
|
device_id,
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
event_hour,
|
||||||
|
pm1_min, pm1_avg, pm1_max,
|
||||||
|
pm25_min_f, pm25_avg_f, pm25_max_f,
|
||||||
|
pm10_min_f, pm10_avg_f, pm10_max_f,
|
||||||
|
voc_min_f, voc_avg_f, voc_max_f,
|
||||||
|
co2_min_f, co2_avg_f, co2_max_f,
|
||||||
|
ch2o_min_f, ch2o_avg_f, ch2o_max_f,
|
||||||
|
|
||||||
|
GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_min_f),
|
||||||
|
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,
|
||||||
|
|
||||||
|
GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_max_f),
|
||||||
|
calculate_aqi('pm10', pm10_max_f)
|
||||||
|
) AS hourly_max_aqi,
|
||||||
|
|
||||||
|
classify_aqi(GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_avg_f),
|
||||||
|
calculate_aqi('pm10', pm10_avg_f)
|
||||||
|
)) AS aqi_category,
|
||||||
|
|
||||||
|
classify_aqi(calculate_aqi('pm25',pm25_avg_f)) as pm25_category,
|
||||||
|
classify_aqi(calculate_aqi('pm10',pm10_avg_f)) as pm10_category,
|
||||||
|
classify_aqi(calculate_aqi('voc',voc_avg_f)) as voc_category,
|
||||||
|
classify_aqi(calculate_aqi('co2',co2_avg_f)) as co2_category,
|
||||||
|
classify_aqi(calculate_aqi('ch2o',ch2o_avg_f)) as ch2o_category
|
||||||
|
|
||||||
|
FROM filled_pollutants
|
||||||
|
),
|
||||||
|
|
||||||
|
daily_category_counts AS (
|
||||||
|
SELECT device_id, space_id, event_date, aqi_category AS category, 'aqi' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
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
|
||||||
|
),
|
||||||
|
|
||||||
|
daily_totals AS (
|
||||||
|
SELECT
|
||||||
|
device_id,
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
SUM(category_count) AS total_count
|
||||||
|
FROM daily_category_counts
|
||||||
|
where pollutant = 'aqi'
|
||||||
|
GROUP BY device_id, space_id, event_date
|
||||||
|
),
|
||||||
|
|
||||||
|
-- Pivot Categories into Columns
|
||||||
|
daily_percentages AS (
|
||||||
|
select
|
||||||
|
dt.device_id,
|
||||||
|
dt.space_id,
|
||||||
|
dt.event_date,
|
||||||
|
-- AQI CATEGORIES
|
||||||
|
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.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.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.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.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
|
||||||
|
LEFT JOIN daily_category_counts dcc
|
||||||
|
ON dt.device_id = dcc.device_id AND dt.event_date = dcc.event_date
|
||||||
|
GROUP BY dt.device_id, dt.space_id, dt.event_date, dt.total_count
|
||||||
|
),
|
||||||
|
|
||||||
|
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
|
||||||
|
p.device_id,
|
||||||
|
p.space_id,
|
||||||
|
p.event_date,
|
||||||
|
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,
|
||||||
|
a.daily_avg_aqi,a.daily_max_aqi, a.daily_min_aqi,
|
||||||
|
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,
|
||||||
|
a.daily_avg_pm25,a.daily_max_pm25, a.daily_min_pm25,
|
||||||
|
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,
|
||||||
|
a.daily_avg_pm10, a.daily_max_pm10, a.daily_min_pm10,
|
||||||
|
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_avg_voc, a.daily_max_voc, a.daily_min_voc,
|
||||||
|
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
|
||||||
|
LEFT JOIN daily_averages a
|
||||||
|
ON p.device_id = a.device_id AND p.event_date = a.event_date
|
||||||
|
ORDER BY p.space_id, p.event_date;
|
||||||
|
|
||||||
-- 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,
|
|
||||||
air_quality_index as avg_device_index
|
|
||||||
FROM air_data;
|
|
||||||
|
|
||||||
|
@ -1,54 +1,275 @@
|
|||||||
WITH device_space AS (
|
-- Query Pipeline Starts Here
|
||||||
|
WITH device_space AS (
|
||||||
SELECT
|
SELECT
|
||||||
device.uuid AS device_id,
|
device.uuid AS device_id,
|
||||||
device.created_at,
|
|
||||||
device.space_device_uuid AS space_id,
|
device.space_device_uuid AS space_id,
|
||||||
"device-status-log".event_time::date,
|
"device-status-log".event_time::timestamp AS event_time,
|
||||||
"device-status-log".code,
|
"device-status-log".code,
|
||||||
"device-status-log".value,
|
"device-status-log".value
|
||||||
"device-status-log".log
|
|
||||||
FROM device
|
FROM device
|
||||||
LEFT JOIN "device-status-log"
|
LEFT JOIN "device-status-log"
|
||||||
ON device.uuid = "device-status-log".device_id
|
ON device.uuid = "device-status-log".device_id
|
||||||
LEFT JOIN product
|
LEFT JOIN product
|
||||||
ON product.uuid = device.product_device_uuid
|
ON product.uuid = device.product_device_uuid
|
||||||
WHERE product.cat_name = 'hjjcy'
|
WHERE product.cat_name = 'hjjcy'
|
||||||
),
|
),
|
||||||
|
|
||||||
average_pollutants as(
|
average_pollutants AS (
|
||||||
SELECT
|
SELECT
|
||||||
event_time,
|
event_time::date AS event_date,
|
||||||
space_id,
|
date_trunc('hour', event_time) AS event_hour,
|
||||||
AVG(CASE WHEN code = 'voc_value' THEN value::numeric END) AS voc_avg,
|
space_id,
|
||||||
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,
|
|
||||||
AVG(CASE WHEN code = 'air_quality_index' then level_to_numeric(value) END) as air_quality_index
|
|
||||||
|
|
||||||
FROM device_space
|
-- PM1
|
||||||
--WHERE code IN ('pm25_value', 'pm10')
|
MIN(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_min,
|
||||||
GROUP BY space_id, event_time
|
AVG(CASE WHEN code = 'pm1' THEN value::numeric END) AS pm1_avg,
|
||||||
|
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,
|
||||||
|
|
||||||
|
-- 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,
|
||||||
|
|
||||||
|
-- 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,
|
||||||
|
|
||||||
|
-- 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
|
||||||
|
|
||||||
|
FROM device_space
|
||||||
|
GROUP BY space_id, event_hour, event_date
|
||||||
|
),
|
||||||
|
|
||||||
|
filled_pollutants AS (
|
||||||
|
SELECT
|
||||||
|
*,
|
||||||
|
-- AVG
|
||||||
|
COALESCE(pm25_avg, LAG(pm25_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm25_avg_f,
|
||||||
|
COALESCE(pm10_avg, LAG(pm10_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm10_avg_f,
|
||||||
|
COALESCE(voc_avg, LAG(voc_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS voc_avg_f,
|
||||||
|
COALESCE(co2_avg, LAG(co2_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS co2_avg_f,
|
||||||
|
COALESCE(ch2o_avg, LAG(ch2o_avg) OVER (PARTITION BY space_id ORDER BY event_hour)) AS ch2o_avg_f,
|
||||||
|
|
||||||
|
-- MIN
|
||||||
|
COALESCE(pm25_min, LAG(pm25_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm25_min_f,
|
||||||
|
COALESCE(pm10_min, LAG(pm10_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm10_min_f,
|
||||||
|
COALESCE(voc_min, LAG(voc_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS voc_min_f,
|
||||||
|
COALESCE(co2_min, LAG(co2_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS co2_min_f,
|
||||||
|
COALESCE(ch2o_min, LAG(ch2o_min) OVER (PARTITION BY space_id ORDER BY event_hour)) AS ch2o_min_f,
|
||||||
|
|
||||||
|
-- MAX
|
||||||
|
COALESCE(pm25_max, LAG(pm25_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm25_max_f,
|
||||||
|
COALESCE(pm10_max, LAG(pm10_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS pm10_max_f,
|
||||||
|
COALESCE(voc_max, LAG(voc_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS voc_max_f,
|
||||||
|
COALESCE(co2_max, LAG(co2_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS co2_max_f,
|
||||||
|
COALESCE(ch2o_max, LAG(ch2o_max) OVER (PARTITION BY space_id ORDER BY event_hour)) AS ch2o_max_f
|
||||||
|
FROM average_pollutants
|
||||||
|
),
|
||||||
|
|
||||||
|
hourly_results AS (
|
||||||
|
SELECT
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
event_hour,
|
||||||
|
pm1_min, pm1_avg, pm1_max,
|
||||||
|
pm25_min_f, pm25_avg_f, pm25_max_f,
|
||||||
|
pm10_min_f, pm10_avg_f, pm10_max_f,
|
||||||
|
voc_min_f, voc_avg_f, voc_max_f,
|
||||||
|
co2_min_f, co2_avg_f, co2_max_f,
|
||||||
|
ch2o_min_f, ch2o_avg_f, ch2o_max_f,
|
||||||
|
|
||||||
|
GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_min_f),
|
||||||
|
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,
|
||||||
|
|
||||||
|
GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_max_f),
|
||||||
|
calculate_aqi('pm10', pm10_max_f)
|
||||||
|
) AS hourly_max_aqi,
|
||||||
|
|
||||||
|
classify_aqi(GREATEST(
|
||||||
|
calculate_aqi('pm25', pm25_avg_f),
|
||||||
|
calculate_aqi('pm10', pm10_avg_f)
|
||||||
|
)) AS aqi_category,
|
||||||
|
|
||||||
|
classify_aqi(calculate_aqi('pm25',pm25_avg_f)) as pm25_category,
|
||||||
|
classify_aqi(calculate_aqi('pm10',pm10_avg_f)) as pm10_category,
|
||||||
|
classify_aqi(calculate_aqi('voc',voc_avg_f)) as voc_category,
|
||||||
|
classify_aqi(calculate_aqi('co2',co2_avg_f)) as co2_category,
|
||||||
|
classify_aqi(calculate_aqi('ch2o',ch2o_avg_f)) as ch2o_category
|
||||||
|
|
||||||
|
FROM filled_pollutants
|
||||||
|
),
|
||||||
|
|
||||||
|
daily_category_counts AS (
|
||||||
|
SELECT space_id, event_date, aqi_category AS category, 'aqi' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, aqi_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, pm25_category AS category, 'pm25' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, pm25_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, pm10_category AS category, 'pm10' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, pm10_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, voc_category AS category, 'voc' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, voc_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, co2_category AS category, 'co2' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, co2_category
|
||||||
|
|
||||||
|
UNION ALL
|
||||||
|
|
||||||
|
SELECT space_id, event_date, ch2o_category AS category, 'ch2o' AS pollutant, COUNT(*) AS category_count
|
||||||
|
FROM hourly_results
|
||||||
|
GROUP BY space_id, event_date, ch2o_category
|
||||||
|
),
|
||||||
|
|
||||||
|
daily_totals AS (
|
||||||
|
SELECT
|
||||||
|
space_id,
|
||||||
|
event_date,
|
||||||
|
SUM(category_count) AS total_count
|
||||||
|
FROM daily_category_counts
|
||||||
|
where pollutant = 'aqi'
|
||||||
|
GROUP BY space_id, event_date
|
||||||
|
),
|
||||||
|
|
||||||
|
-- Pivot Categories into Columns
|
||||||
|
daily_percentages AS (
|
||||||
|
select
|
||||||
|
dt.space_id,
|
||||||
|
dt.event_date,
|
||||||
|
-- AQI CATEGORIES
|
||||||
|
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.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.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.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.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
|
||||||
|
LEFT JOIN daily_category_counts dcc
|
||||||
|
ON dt.space_id = dcc.space_id AND dt.event_date = dcc.event_date
|
||||||
|
GROUP BY dt.space_id, dt.event_date, dt.total_count
|
||||||
|
),
|
||||||
|
|
||||||
|
daily_averages AS (
|
||||||
|
SELECT
|
||||||
|
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 space_id, event_date
|
||||||
)
|
)
|
||||||
|
SELECT
|
||||||
|
p.space_id,
|
||||||
|
p.event_date,
|
||||||
|
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,
|
||||||
|
a.daily_avg_aqi,a.daily_max_aqi, a.daily_min_aqi,
|
||||||
|
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,
|
||||||
|
a.daily_avg_pm25,a.daily_max_pm25, a.daily_min_pm25,
|
||||||
|
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,
|
||||||
|
a.daily_avg_pm10, a.daily_max_pm10, a.daily_min_pm10,
|
||||||
|
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_avg_voc, a.daily_max_voc, a.daily_min_voc,
|
||||||
|
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
|
||||||
|
LEFT JOIN daily_averages a
|
||||||
|
ON p.space_id = a.space_id AND p.event_date = a.event_date
|
||||||
|
ORDER BY p.space_id, p.event_date;
|
||||||
|
|
||||||
|
|
||||||
SELECT
|
|
||||||
event_time::date as date,
|
|
||||||
space_id,
|
|
||||||
pm1_avg,
|
|
||||||
pm25_avg,
|
|
||||||
pm10_avg,
|
|
||||||
voc_avg,
|
|
||||||
ch2o_avg,
|
|
||||||
co2_avg,
|
|
||||||
--calculate_aqi('pm25', pm25_avg) AS aqi_pm25,
|
|
||||||
--calculate_aqi('pm10', pm10_avg) AS aqi_pm10,
|
|
||||||
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,
|
|
||||||
air_quality_index as avg_space_device_aqi
|
|
||||||
FROM average_pollutants;
|
|
18
libs/common/src/util/calculate.aqi.ts
Normal file
18
libs/common/src/util/calculate.aqi.ts
Normal file
@ -0,0 +1,18 @@
|
|||||||
|
export function calculateAQI(pm2_5: number): number {
|
||||||
|
const breakpoints = [
|
||||||
|
{ pmLow: 0.0, pmHigh: 12.0, aqiLow: 0, aqiHigh: 50 },
|
||||||
|
{ pmLow: 12.1, pmHigh: 35.4, aqiLow: 51, aqiHigh: 100 },
|
||||||
|
{ pmLow: 35.5, pmHigh: 55.4, aqiLow: 101, aqiHigh: 150 },
|
||||||
|
{ pmLow: 55.5, pmHigh: 150.4, aqiLow: 151, aqiHigh: 200 },
|
||||||
|
{ pmLow: 150.5, pmHigh: 250.4, aqiLow: 201, aqiHigh: 300 },
|
||||||
|
{ pmLow: 250.5, pmHigh: 500.4, aqiLow: 301, aqiHigh: 500 },
|
||||||
|
];
|
||||||
|
|
||||||
|
const bp = breakpoints.find((b) => pm2_5 >= b.pmLow && pm2_5 <= b.pmHigh);
|
||||||
|
if (!bp) return pm2_5 > 500.4 ? 500 : 0; // Handle out-of-range values
|
||||||
|
|
||||||
|
return Math.round(
|
||||||
|
((bp.aqiHigh - bp.aqiLow) / (bp.pmHigh - bp.pmLow)) * (pm2_5 - bp.pmLow) +
|
||||||
|
bp.aqiLow,
|
||||||
|
);
|
||||||
|
}
|
@ -38,6 +38,7 @@ import { HealthModule } from './health/health.module';
|
|||||||
|
|
||||||
import { winstonLoggerOptions } from '../libs/common/src/logger/services/winston.logger';
|
import { winstonLoggerOptions } from '../libs/common/src/logger/services/winston.logger';
|
||||||
import { OccupancyModule } from './occupancy/occupancy.module';
|
import { OccupancyModule } from './occupancy/occupancy.module';
|
||||||
|
import { WeatherModule } from './weather/weather.module';
|
||||||
@Module({
|
@Module({
|
||||||
imports: [
|
imports: [
|
||||||
ConfigModule.forRoot({
|
ConfigModule.forRoot({
|
||||||
@ -79,6 +80,7 @@ import { OccupancyModule } from './occupancy/occupancy.module';
|
|||||||
PowerClampModule,
|
PowerClampModule,
|
||||||
HealthModule,
|
HealthModule,
|
||||||
OccupancyModule,
|
OccupancyModule,
|
||||||
|
WeatherModule,
|
||||||
],
|
],
|
||||||
providers: [
|
providers: [
|
||||||
{
|
{
|
||||||
|
@ -1,4 +1,5 @@
|
|||||||
import AuthConfig from './auth.config';
|
import AuthConfig from './auth.config';
|
||||||
import AppConfig from './app.config';
|
import AppConfig from './app.config';
|
||||||
import JwtConfig from './jwt.config';
|
import JwtConfig from './jwt.config';
|
||||||
export default [AuthConfig, AppConfig, JwtConfig];
|
import WeatherOpenConfig from './weather.open.config';
|
||||||
|
export default [AuthConfig, AppConfig, JwtConfig, WeatherOpenConfig];
|
||||||
|
9
src/config/weather.open.config.ts
Normal file
9
src/config/weather.open.config.ts
Normal file
@ -0,0 +1,9 @@
|
|||||||
|
import { registerAs } from '@nestjs/config';
|
||||||
|
|
||||||
|
export default registerAs(
|
||||||
|
'openweather-config',
|
||||||
|
(): Record<string, any> => ({
|
||||||
|
OPEN_WEATHER_MAP_API_KEY: process.env.OPEN_WEATHER_MAP_API_KEY,
|
||||||
|
WEATHER_API_URL: process.env.WEATHER_API_URL,
|
||||||
|
}),
|
||||||
|
);
|
@ -213,8 +213,8 @@ export class SpaceService {
|
|||||||
{ incomingConnectionDisabled: false },
|
{ incomingConnectionDisabled: false },
|
||||||
)
|
)
|
||||||
.leftJoinAndSelect('space.productAllocations', 'productAllocations')
|
.leftJoinAndSelect('space.productAllocations', 'productAllocations')
|
||||||
.leftJoinAndSelect('productAllocations.tags', 'tags')
|
// .leftJoinAndSelect('productAllocations.tags', 'tags')
|
||||||
.leftJoinAndSelect('tags.product', 'tagProduct')
|
// .leftJoinAndSelect('productAllocations.product', 'product')
|
||||||
.leftJoinAndSelect(
|
.leftJoinAndSelect(
|
||||||
'space.subspaces',
|
'space.subspaces',
|
||||||
'subspaces',
|
'subspaces',
|
||||||
@ -225,8 +225,11 @@ export class SpaceService {
|
|||||||
'subspaces.productAllocations',
|
'subspaces.productAllocations',
|
||||||
'subspaceProductAllocations',
|
'subspaceProductAllocations',
|
||||||
)
|
)
|
||||||
.leftJoinAndSelect('subspaceProductAllocations.tags', 'subspaceTags')
|
// .leftJoinAndSelect('subspaceProductAllocations.tags', 'subspaceTag')
|
||||||
.leftJoinAndSelect('subspaceTags.product', 'subspaceTagProduct')
|
// .leftJoinAndSelect(
|
||||||
|
// 'subspaceProductAllocations.product',
|
||||||
|
// 'subspaceProduct',
|
||||||
|
// )
|
||||||
.leftJoinAndSelect('space.spaceModel', 'spaceModel')
|
.leftJoinAndSelect('space.spaceModel', 'spaceModel')
|
||||||
.where('space.community_id = :communityUuid', { communityUuid })
|
.where('space.community_id = :communityUuid', { communityUuid })
|
||||||
.andWhere('space.spaceName != :orphanSpaceName', {
|
.andWhere('space.spaceName != :orphanSpaceName', {
|
||||||
@ -264,9 +267,7 @@ export class SpaceService {
|
|||||||
}),
|
}),
|
||||||
);
|
);
|
||||||
}
|
}
|
||||||
|
const spaceHierarchy = this.buildSpaceHierarchy(spaces);
|
||||||
const transformedSpaces = spaces.map(this.transformSpace);
|
|
||||||
const spaceHierarchy = this.buildSpaceHierarchy(transformedSpaces);
|
|
||||||
|
|
||||||
return new SuccessResponseDto({
|
return new SuccessResponseDto({
|
||||||
message: `Spaces in community ${communityUuid} successfully fetched in hierarchy`,
|
message: `Spaces in community ${communityUuid} successfully fetched in hierarchy`,
|
||||||
@ -326,13 +327,13 @@ export class SpaceService {
|
|||||||
'incomingConnections.disabled = :incomingConnectionDisabled',
|
'incomingConnections.disabled = :incomingConnectionDisabled',
|
||||||
{ incomingConnectionDisabled: false },
|
{ incomingConnectionDisabled: false },
|
||||||
)
|
)
|
||||||
.leftJoinAndSelect(
|
// .leftJoinAndSelect(
|
||||||
'space.tags',
|
// 'space.tags',
|
||||||
'tags',
|
// 'tags',
|
||||||
'tags.disabled = :tagDisabled',
|
// 'tags.disabled = :tagDisabled',
|
||||||
{ tagDisabled: false },
|
// { tagDisabled: false },
|
||||||
)
|
// )
|
||||||
.leftJoinAndSelect('tags.product', 'tagProduct')
|
// .leftJoinAndSelect('tags.product', 'tagProduct')
|
||||||
.leftJoinAndSelect(
|
.leftJoinAndSelect(
|
||||||
'space.subspaces',
|
'space.subspaces',
|
||||||
'subspaces',
|
'subspaces',
|
||||||
@ -345,7 +346,7 @@ export class SpaceService {
|
|||||||
'subspaceTags.disabled = :subspaceTagsDisabled',
|
'subspaceTags.disabled = :subspaceTagsDisabled',
|
||||||
{ subspaceTagsDisabled: false },
|
{ subspaceTagsDisabled: false },
|
||||||
)
|
)
|
||||||
.leftJoinAndSelect('subspaceTags.product', 'subspaceTagProduct')
|
// .leftJoinAndSelect('subspaceTags.product', 'subspaceTagProduct')
|
||||||
.where('space.community_id = :communityUuid', { communityUuid })
|
.where('space.community_id = :communityUuid', { communityUuid })
|
||||||
.andWhere('space.spaceName != :orphanSpaceName', {
|
.andWhere('space.spaceName != :orphanSpaceName', {
|
||||||
orphanSpaceName: ORPHAN_SPACE_NAME,
|
orphanSpaceName: ORPHAN_SPACE_NAME,
|
||||||
|
1
src/weather/controllers/index.ts
Normal file
1
src/weather/controllers/index.ts
Normal file
@ -0,0 +1 @@
|
|||||||
|
export * from './weather.controller';
|
28
src/weather/controllers/weather.controller.ts
Normal file
28
src/weather/controllers/weather.controller.ts
Normal file
@ -0,0 +1,28 @@
|
|||||||
|
import { Controller, Get, Query } from '@nestjs/common';
|
||||||
|
import { ApiOperation, ApiTags } from '@nestjs/swagger';
|
||||||
|
import { EnableDisableStatusEnum } from '@app/common/constants/days.enum';
|
||||||
|
import { ControllerRoute } from '@app/common/constants/controller-route'; // Assuming this is where the routes are defined
|
||||||
|
import { WeatherService } from '../services';
|
||||||
|
import { BaseResponseDto } from '@app/common/dto/base.response.dto';
|
||||||
|
import { GetWeatherDetailsDto } from '../dto/get.weather.dto';
|
||||||
|
|
||||||
|
@ApiTags('Weather Module')
|
||||||
|
@Controller({
|
||||||
|
version: EnableDisableStatusEnum.ENABLED,
|
||||||
|
path: ControllerRoute.WEATHER.ROUTE, // use the static route constant
|
||||||
|
})
|
||||||
|
export class WeatherController {
|
||||||
|
constructor(private readonly weatherService: WeatherService) {}
|
||||||
|
|
||||||
|
@Get()
|
||||||
|
@ApiOperation({
|
||||||
|
summary: ControllerRoute.WEATHER.ACTIONS.FETCH_WEATHER_DETAILS_SUMMARY,
|
||||||
|
description:
|
||||||
|
ControllerRoute.WEATHER.ACTIONS.FETCH_WEATHER_DETAILS_DESCRIPTION,
|
||||||
|
})
|
||||||
|
async fetchWeatherDetails(
|
||||||
|
@Query() query: GetWeatherDetailsDto,
|
||||||
|
): Promise<BaseResponseDto> {
|
||||||
|
return await this.weatherService.fetchWeatherDetails(query);
|
||||||
|
}
|
||||||
|
}
|
21
src/weather/dto/get.weather.dto.ts
Normal file
21
src/weather/dto/get.weather.dto.ts
Normal file
@ -0,0 +1,21 @@
|
|||||||
|
import { ApiProperty } from '@nestjs/swagger';
|
||||||
|
import { Type } from 'class-transformer';
|
||||||
|
import { IsNumber } from 'class-validator';
|
||||||
|
|
||||||
|
export class GetWeatherDetailsDto {
|
||||||
|
@ApiProperty({
|
||||||
|
description: 'Latitude coordinate',
|
||||||
|
example: 35.6895,
|
||||||
|
})
|
||||||
|
@IsNumber()
|
||||||
|
@Type(() => Number)
|
||||||
|
lat: number;
|
||||||
|
|
||||||
|
@ApiProperty({
|
||||||
|
description: 'Longitude coordinate',
|
||||||
|
example: 139.6917,
|
||||||
|
})
|
||||||
|
@IsNumber()
|
||||||
|
@Type(() => Number)
|
||||||
|
lon: number;
|
||||||
|
}
|
1
src/weather/services/index.ts
Normal file
1
src/weather/services/index.ts
Normal file
@ -0,0 +1 @@
|
|||||||
|
export * from './weather.service';
|
51
src/weather/services/weather.service.ts
Normal file
51
src/weather/services/weather.service.ts
Normal file
@ -0,0 +1,51 @@
|
|||||||
|
import { HttpException, HttpStatus, Injectable } from '@nestjs/common';
|
||||||
|
import { HttpService } from '@nestjs/axios';
|
||||||
|
import { ConfigService } from '@nestjs/config';
|
||||||
|
import { firstValueFrom } from 'rxjs';
|
||||||
|
import { GetWeatherDetailsDto } from '../dto/get.weather.dto';
|
||||||
|
import { calculateAQI } from '@app/common/util/calculate.aqi';
|
||||||
|
import { BaseResponseDto } from '@app/common/dto/base.response.dto';
|
||||||
|
import { SuccessResponseDto } from '@app/common/dto/success.response.dto';
|
||||||
|
|
||||||
|
@Injectable()
|
||||||
|
export class WeatherService {
|
||||||
|
private readonly weatherApiUrl: string;
|
||||||
|
constructor(
|
||||||
|
private readonly configService: ConfigService,
|
||||||
|
private readonly httpService: HttpService,
|
||||||
|
) {
|
||||||
|
this.weatherApiUrl = this.configService.get<string>('WEATHER_API_URL');
|
||||||
|
}
|
||||||
|
|
||||||
|
async fetchWeatherDetails(
|
||||||
|
query: GetWeatherDetailsDto,
|
||||||
|
): Promise<BaseResponseDto> {
|
||||||
|
try {
|
||||||
|
const { lat, lon } = query;
|
||||||
|
const weatherApiKey = this.configService.get<string>(
|
||||||
|
'OPEN_WEATHER_MAP_API_KEY',
|
||||||
|
);
|
||||||
|
const url = `${this.weatherApiUrl}/current.json?key=${weatherApiKey}&q=${lat},${lon}&aqi=yes`;
|
||||||
|
|
||||||
|
const response = await firstValueFrom(this.httpService.get(url));
|
||||||
|
const pm2_5 = response.data.current.air_quality.pm2_5; // Raw PM2.5 (µg/m³)
|
||||||
|
|
||||||
|
return new SuccessResponseDto({
|
||||||
|
message: `Weather details fetched successfully`,
|
||||||
|
data: {
|
||||||
|
aqi: calculateAQI(pm2_5), // Converted AQI (0-500)
|
||||||
|
temperature: response.data.current.temp_c,
|
||||||
|
humidity: response.data.current.humidity,
|
||||||
|
},
|
||||||
|
statusCode: HttpStatus.OK,
|
||||||
|
});
|
||||||
|
} catch (error) {
|
||||||
|
console.log(`Error fetching weather data: ${error}`);
|
||||||
|
|
||||||
|
throw new HttpException(
|
||||||
|
`Api can't handle these lat and lon values`,
|
||||||
|
error.response?.status || HttpStatus.INTERNAL_SERVER_ERROR,
|
||||||
|
);
|
||||||
|
}
|
||||||
|
}
|
||||||
|
}
|
12
src/weather/weather.module.ts
Normal file
12
src/weather/weather.module.ts
Normal file
@ -0,0 +1,12 @@
|
|||||||
|
import { Module } from '@nestjs/common';
|
||||||
|
import { ConfigModule } from '@nestjs/config';
|
||||||
|
import { HttpModule } from '@nestjs/axios'; // <-- Import this!
|
||||||
|
import { WeatherController } from './controllers';
|
||||||
|
import { WeatherService } from './services';
|
||||||
|
|
||||||
|
@Module({
|
||||||
|
imports: [ConfigModule, HttpModule],
|
||||||
|
controllers: [WeatherController],
|
||||||
|
providers: [WeatherService],
|
||||||
|
})
|
||||||
|
export class WeatherModule {}
|
Reference in New Issue
Block a user