fix: 优化平滑逻辑

This commit is contained in:
yarnom 2025-08-21 15:41:04 +08:00
parent c55f089247
commit cc5c607457
2 changed files with 124 additions and 55 deletions

View File

@ -149,86 +149,144 @@ func getDataHandler(c *gin.Context) {
hexID := fmt.Sprintf("%06X", decimalNum) hexID := fmt.Sprintf("%06X", decimalNum)
stationID := fmt.Sprintf("RS485-%s", hexID) stationID := fmt.Sprintf("RS485-%s", hexID)
// 构建查询SQL // 构建查询SQL(统一风向矢量平均,雨量为累计量的正增量求和)
var query string var query string
switch interval { switch interval {
case "10min": case "10min":
query = ` query = `
WITH grouped_data AS ( WITH base AS (
SELECT SELECT
date_trunc('hour', timestamp) + date_trunc('hour', timestamp) + (floor(date_part('minute', timestamp) / 10) * interval '10 minute') as time_group,
(floor(date_part('minute', timestamp) / 10) * interval '10 minute') as time_group, timestamp as ts,
temperature, humidity, pressure, wind_speed, wind_direction, rainfall, light, uv
FROM rs485_weather_data
WHERE station_id = $1 AND timestamp BETWEEN $2 AND $3
),
rain_inc AS (
SELECT time_group, GREATEST(rainfall - LAG(rainfall) OVER (PARTITION BY time_group ORDER BY ts), 0) AS inc
FROM base
),
rain_sum AS (
SELECT time_group, SUM(inc) AS rainfall
FROM rain_inc
GROUP BY time_group
),
grouped_data AS (
SELECT
time_group,
AVG(temperature) as temperature, AVG(temperature) as temperature,
AVG(humidity) as humidity, AVG(humidity) as humidity,
AVG(pressure) as pressure, AVG(pressure) as pressure,
AVG(wind_speed) as wind_speed, AVG(wind_speed) as wind_speed,
AVG(wind_direction) as wind_direction, DEGREES(ATAN2(AVG(SIN(RADIANS(wind_direction))), AVG(COS(RADIANS(wind_direction))))) AS wind_direction_raw,
MAX(rainfall) - MIN(rainfall) as rainfall,
AVG(light) as light, AVG(light) as light,
AVG(uv) as uv AVG(uv) as uv
FROM rs485_weather_data FROM base
WHERE station_id = $1 AND timestamp BETWEEN $2 AND $3
GROUP BY time_group GROUP BY time_group
ORDER BY time_group
) )
SELECT SELECT
to_char(time_group, 'YYYY-MM-DD HH24:MI:SS') as date_time, to_char(g.time_group, 'YYYY-MM-DD HH24:MI:SS') as date_time,
temperature, humidity, pressure, wind_speed, wind_direction, ROUND(g.temperature::numeric, 2) as temperature,
CASE WHEN rainfall < 0 THEN 0 ELSE rainfall END as rainfall, ROUND(g.humidity::numeric, 2) as humidity,
light, uv ROUND(g.pressure::numeric, 2) as pressure,
FROM grouped_data ROUND(g.wind_speed::numeric, 2) as wind_speed,
ORDER BY time_group` ROUND((CASE WHEN g.wind_direction_raw < 0 THEN g.wind_direction_raw + 360 ELSE g.wind_direction_raw END)::numeric, 2) AS wind_direction,
ROUND(COALESCE(r.rainfall, 0)::numeric, 3) as rainfall,
ROUND(g.light::numeric, 2) as light,
ROUND(g.uv::numeric, 2) as uv
FROM grouped_data g
LEFT JOIN rain_sum r ON r.time_group = g.time_group
ORDER BY g.time_group`
case "30min": case "30min":
query = ` query = `
WITH grouped_data AS ( WITH base AS (
SELECT SELECT
date_trunc('hour', timestamp) + date_trunc('hour', timestamp) + (floor(date_part('minute', timestamp) / 30) * interval '30 minute') as time_group,
(floor(date_part('minute', timestamp) / 30) * interval '30 minute') as time_group, timestamp as ts,
temperature, humidity, pressure, wind_speed, wind_direction, rainfall, light, uv
FROM rs485_weather_data
WHERE station_id = $1 AND timestamp BETWEEN $2 AND $3
),
rain_inc AS (
SELECT time_group, GREATEST(rainfall - LAG(rainfall) OVER (PARTITION BY time_group ORDER BY ts), 0) AS inc
FROM base
),
rain_sum AS (
SELECT time_group, SUM(inc) AS rainfall
FROM rain_inc
GROUP BY time_group
),
grouped_data AS (
SELECT
time_group,
AVG(temperature) as temperature, AVG(temperature) as temperature,
AVG(humidity) as humidity, AVG(humidity) as humidity,
AVG(pressure) as pressure, AVG(pressure) as pressure,
AVG(wind_speed) as wind_speed, AVG(wind_speed) as wind_speed,
AVG(wind_direction) as wind_direction, DEGREES(ATAN2(AVG(SIN(RADIANS(wind_direction))), AVG(COS(RADIANS(wind_direction))))) AS wind_direction_raw,
MAX(rainfall) - MIN(rainfall) as rainfall,
AVG(light) as light, AVG(light) as light,
AVG(uv) as uv AVG(uv) as uv
FROM rs485_weather_data FROM base
WHERE station_id = $1 AND timestamp BETWEEN $2 AND $3
GROUP BY time_group GROUP BY time_group
ORDER BY time_group
) )
SELECT SELECT
to_char(time_group, 'YYYY-MM-DD HH24:MI:SS') as date_time, to_char(g.time_group, 'YYYY-MM-DD HH24:MI:SS') as date_time,
temperature, humidity, pressure, wind_speed, wind_direction, ROUND(g.temperature::numeric, 2) as temperature,
CASE WHEN rainfall < 0 THEN 0 ELSE rainfall END as rainfall, ROUND(g.humidity::numeric, 2) as humidity,
light, uv ROUND(g.pressure::numeric, 2) as pressure,
FROM grouped_data ROUND(g.wind_speed::numeric, 2) as wind_speed,
ORDER BY time_group` ROUND((CASE WHEN g.wind_direction_raw < 0 THEN g.wind_direction_raw + 360 ELSE g.wind_direction_raw END)::numeric, 2) AS wind_direction,
ROUND(COALESCE(r.rainfall, 0)::numeric, 3) as rainfall,
ROUND(g.light::numeric, 2) as light,
ROUND(g.uv::numeric, 2) as uv
FROM grouped_data g
LEFT JOIN rain_sum r ON r.time_group = g.time_group
ORDER BY g.time_group`
default: // 1hour default: // 1hour
query = ` query = `
WITH grouped_data AS ( WITH base AS (
SELECT SELECT
date_trunc('hour', timestamp) as time_group, date_trunc('hour', timestamp) as time_group,
timestamp as ts,
temperature, humidity, pressure, wind_speed, wind_direction, rainfall, light, uv
FROM rs485_weather_data
WHERE station_id = $1 AND timestamp BETWEEN $2 AND $3
),
rain_inc AS (
SELECT time_group, GREATEST(rainfall - LAG(rainfall) OVER (PARTITION BY time_group ORDER BY ts), 0) AS inc
FROM base
),
rain_sum AS (
SELECT time_group, SUM(inc) AS rainfall
FROM rain_inc
GROUP BY time_group
),
grouped_data AS (
SELECT
time_group,
AVG(temperature) as temperature, AVG(temperature) as temperature,
AVG(humidity) as humidity, AVG(humidity) as humidity,
AVG(pressure) as pressure, AVG(pressure) as pressure,
AVG(wind_speed) as wind_speed, AVG(wind_speed) as wind_speed,
AVG(wind_direction) as wind_direction, DEGREES(ATAN2(AVG(SIN(RADIANS(wind_direction))), AVG(COS(RADIANS(wind_direction))))) AS wind_direction_raw,
MAX(rainfall) - MIN(rainfall) as rainfall,
AVG(light) as light, AVG(light) as light,
AVG(uv) as uv AVG(uv) as uv
FROM rs485_weather_data FROM base
WHERE station_id = $1 AND timestamp BETWEEN $2 AND $3
GROUP BY time_group GROUP BY time_group
ORDER BY time_group
) )
SELECT SELECT
to_char(time_group, 'YYYY-MM-DD HH24:MI:SS') as date_time, to_char(g.time_group, 'YYYY-MM-DD HH24:MI:SS') as date_time,
temperature, humidity, pressure, wind_speed, wind_direction, ROUND(g.temperature::numeric, 2) as temperature,
CASE WHEN rainfall < 0 THEN 0 ELSE rainfall END as rainfall, ROUND(g.humidity::numeric, 2) as humidity,
light, uv ROUND(g.pressure::numeric, 2) as pressure,
FROM grouped_data ROUND(g.wind_speed::numeric, 2) as wind_speed,
ORDER BY time_group` ROUND((CASE WHEN g.wind_direction_raw < 0 THEN g.wind_direction_raw + 360 ELSE g.wind_direction_raw END)::numeric, 2) AS wind_direction,
ROUND(COALESCE(r.rainfall, 0)::numeric, 3) as rainfall,
ROUND(g.light::numeric, 2) as light,
ROUND(g.uv::numeric, 2) as uv
FROM grouped_data g
LEFT JOIN rain_sum r ON r.time_group = g.time_group
ORDER BY g.time_group`
} }
// 执行查询 // 执行查询

View File

@ -112,12 +112,13 @@ func getStationData(w http.ResponseWriter, r *http.Request) {
intervalSQL = "1 hour" intervalSQL = "1 hour"
} }
// 构建查询SQL - 使用时间窗口聚合 // 构建查询SQL - 使用时间窗口聚合(风向矢量平均,雨量按累计量正增量求和)
query = fmt.Sprintf(` query = fmt.Sprintf(`
WITH time_series AS ( WITH time_series AS (
SELECT SELECT
date_trunc('hour', timestamp) + date_trunc('hour', timestamp) +
INTERVAL '%s' * FLOOR(EXTRACT(EPOCH FROM timestamp - date_trunc('hour', timestamp)) / EXTRACT(EPOCH FROM INTERVAL '%s')) as time_bucket, INTERVAL '%s' * FLOOR(EXTRACT(EPOCH FROM timestamp - date_trunc('hour', timestamp)) / EXTRACT(EPOCH FROM INTERVAL '%s')) as time_bucket,
timestamp as ts,
temperature, temperature,
humidity, humidity,
pressure, pressure,
@ -131,6 +132,17 @@ func getStationData(w http.ResponseWriter, r *http.Request) {
AND timestamp >= $2::timestamp AND timestamp >= $2::timestamp
AND timestamp <= $3::timestamp AND timestamp <= $3::timestamp
), ),
rain_increments AS (
SELECT
time_bucket,
GREATEST(rainfall - LAG(rainfall) OVER (PARTITION BY time_bucket ORDER BY ts), 0) AS inc
FROM time_series
),
rain_sums AS (
SELECT time_bucket, SUM(inc) AS rainfall
FROM rain_increments
GROUP BY time_bucket
),
aggregated_data AS ( aggregated_data AS (
SELECT SELECT
time_bucket, time_bucket,
@ -149,25 +161,24 @@ func getStationData(w http.ResponseWriter, r *http.Request) {
)) < 0 THEN 360 )) < 0 THEN 360
ELSE 0 ELSE 0
END, 2) as wind_direction, END, 2) as wind_direction,
-- 雨量使用差值计算
ROUND((MAX(rainfall) - MIN(rainfall))::numeric, 3) as rainfall_diff,
ROUND(AVG(light)::numeric, 2) as light, ROUND(AVG(light)::numeric, 2) as light,
ROUND(AVG(uv)::numeric, 2) as uv ROUND(AVG(uv)::numeric, 2) as uv
FROM time_series FROM time_series
GROUP BY time_bucket GROUP BY time_bucket
) )
SELECT SELECT
time_bucket, ad.time_bucket as time_bucket,
COALESCE(temperature, 0) as temperature, COALESCE(ad.temperature, 0) as temperature,
COALESCE(humidity, 0) as humidity, COALESCE(ad.humidity, 0) as humidity,
COALESCE(pressure, 0) as pressure, COALESCE(ad.pressure, 0) as pressure,
COALESCE(wind_speed, 0) as wind_speed, COALESCE(ad.wind_speed, 0) as wind_speed,
COALESCE(wind_direction, 0) as wind_direction, COALESCE(ad.wind_direction, 0) as wind_direction,
COALESCE(rainfall_diff, 0) as rainfall, COALESCE(rs.rainfall, 0) as rainfall,
COALESCE(light, 0) as light, COALESCE(ad.light, 0) as light,
COALESCE(uv, 0) as uv COALESCE(ad.uv, 0) as uv
FROM aggregated_data FROM aggregated_data ad
ORDER BY time_bucket`, intervalSQL, intervalSQL) LEFT JOIN rain_sums rs ON rs.time_bucket = ad.time_bucket
ORDER BY ad.time_bucket`, intervalSQL, intervalSQL)
rows, err := db.Query(query, stationID, startTime, endTime) rows, err := db.Query(query, stationID, startTime, endTime)
if err != nil { if err != nil {