diff --git a/gin_server.go b/gin_server.go index 61b378e..6495565 100644 --- a/gin_server.go +++ b/gin_server.go @@ -149,86 +149,144 @@ func getDataHandler(c *gin.Context) { hexID := fmt.Sprintf("%06X", decimalNum) stationID := fmt.Sprintf("RS485-%s", hexID) - // 构建查询SQL + // 构建查询SQL(统一风向矢量平均,雨量为累计量的正增量求和) var query string switch interval { case "10min": query = ` - WITH grouped_data AS ( + WITH base AS ( SELECT - date_trunc('hour', timestamp) + - (floor(date_part('minute', timestamp) / 10) * interval '10 minute') as time_group, + date_trunc('hour', timestamp) + (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(humidity) as humidity, AVG(pressure) as pressure, AVG(wind_speed) as wind_speed, - AVG(wind_direction) as wind_direction, - MAX(rainfall) - MIN(rainfall) as rainfall, + DEGREES(ATAN2(AVG(SIN(RADIANS(wind_direction))), AVG(COS(RADIANS(wind_direction))))) AS wind_direction_raw, AVG(light) as light, AVG(uv) as uv - FROM rs485_weather_data - WHERE station_id = $1 AND timestamp BETWEEN $2 AND $3 + FROM base GROUP BY time_group - ORDER BY time_group ) SELECT - to_char(time_group, 'YYYY-MM-DD HH24:MI:SS') as date_time, - temperature, humidity, pressure, wind_speed, wind_direction, - CASE WHEN rainfall < 0 THEN 0 ELSE rainfall END as rainfall, - light, uv - FROM grouped_data - ORDER BY time_group` + to_char(g.time_group, 'YYYY-MM-DD HH24:MI:SS') as date_time, + ROUND(g.temperature::numeric, 2) as temperature, + ROUND(g.humidity::numeric, 2) as humidity, + ROUND(g.pressure::numeric, 2) as pressure, + ROUND(g.wind_speed::numeric, 2) as wind_speed, + 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": query = ` - WITH grouped_data AS ( + WITH base AS ( SELECT - date_trunc('hour', timestamp) + - (floor(date_part('minute', timestamp) / 30) * interval '30 minute') as time_group, + date_trunc('hour', timestamp) + (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(humidity) as humidity, AVG(pressure) as pressure, AVG(wind_speed) as wind_speed, - AVG(wind_direction) as wind_direction, - MAX(rainfall) - MIN(rainfall) as rainfall, + DEGREES(ATAN2(AVG(SIN(RADIANS(wind_direction))), AVG(COS(RADIANS(wind_direction))))) AS wind_direction_raw, AVG(light) as light, AVG(uv) as uv - FROM rs485_weather_data - WHERE station_id = $1 AND timestamp BETWEEN $2 AND $3 + FROM base GROUP BY time_group - ORDER BY time_group ) SELECT - to_char(time_group, 'YYYY-MM-DD HH24:MI:SS') as date_time, - temperature, humidity, pressure, wind_speed, wind_direction, - CASE WHEN rainfall < 0 THEN 0 ELSE rainfall END as rainfall, - light, uv - FROM grouped_data - ORDER BY time_group` + to_char(g.time_group, 'YYYY-MM-DD HH24:MI:SS') as date_time, + ROUND(g.temperature::numeric, 2) as temperature, + ROUND(g.humidity::numeric, 2) as humidity, + ROUND(g.pressure::numeric, 2) as pressure, + ROUND(g.wind_speed::numeric, 2) as wind_speed, + 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 query = ` - WITH grouped_data AS ( + WITH base AS ( SELECT 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(humidity) as humidity, AVG(pressure) as pressure, AVG(wind_speed) as wind_speed, - AVG(wind_direction) as wind_direction, - MAX(rainfall) - MIN(rainfall) as rainfall, + DEGREES(ATAN2(AVG(SIN(RADIANS(wind_direction))), AVG(COS(RADIANS(wind_direction))))) AS wind_direction_raw, AVG(light) as light, AVG(uv) as uv - FROM rs485_weather_data - WHERE station_id = $1 AND timestamp BETWEEN $2 AND $3 + FROM base GROUP BY time_group - ORDER BY time_group ) SELECT - to_char(time_group, 'YYYY-MM-DD HH24:MI:SS') as date_time, - temperature, humidity, pressure, wind_speed, wind_direction, - CASE WHEN rainfall < 0 THEN 0 ELSE rainfall END as rainfall, - light, uv - FROM grouped_data - ORDER BY time_group` + to_char(g.time_group, 'YYYY-MM-DD HH24:MI:SS') as date_time, + ROUND(g.temperature::numeric, 2) as temperature, + ROUND(g.humidity::numeric, 2) as humidity, + ROUND(g.pressure::numeric, 2) as pressure, + ROUND(g.wind_speed::numeric, 2) as wind_speed, + 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` } // 执行查询 diff --git a/web_server.go b/web_server.go index 7d8e52c..5a5994d 100644 --- a/web_server.go +++ b/web_server.go @@ -112,12 +112,13 @@ func getStationData(w http.ResponseWriter, r *http.Request) { intervalSQL = "1 hour" } - // 构建查询SQL - 使用时间窗口聚合 + // 构建查询SQL - 使用时间窗口聚合(风向矢量平均,雨量按累计量正增量求和) query = fmt.Sprintf(` WITH time_series AS ( SELECT date_trunc('hour', timestamp) + INTERVAL '%s' * FLOOR(EXTRACT(EPOCH FROM timestamp - date_trunc('hour', timestamp)) / EXTRACT(EPOCH FROM INTERVAL '%s')) as time_bucket, + timestamp as ts, temperature, humidity, pressure, @@ -131,6 +132,17 @@ func getStationData(w http.ResponseWriter, r *http.Request) { AND timestamp >= $2::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 ( SELECT time_bucket, @@ -149,25 +161,24 @@ func getStationData(w http.ResponseWriter, r *http.Request) { )) < 0 THEN 360 ELSE 0 END, 2) as wind_direction, - -- 雨量使用差值计算 - ROUND((MAX(rainfall) - MIN(rainfall))::numeric, 3) as rainfall_diff, ROUND(AVG(light)::numeric, 2) as light, ROUND(AVG(uv)::numeric, 2) as uv FROM time_series GROUP BY time_bucket ) SELECT - time_bucket, - COALESCE(temperature, 0) as temperature, - COALESCE(humidity, 0) as humidity, - COALESCE(pressure, 0) as pressure, - COALESCE(wind_speed, 0) as wind_speed, - COALESCE(wind_direction, 0) as wind_direction, - COALESCE(rainfall_diff, 0) as rainfall, - COALESCE(light, 0) as light, - COALESCE(uv, 0) as uv - FROM aggregated_data - ORDER BY time_bucket`, intervalSQL, intervalSQL) + ad.time_bucket as time_bucket, + COALESCE(ad.temperature, 0) as temperature, + COALESCE(ad.humidity, 0) as humidity, + COALESCE(ad.pressure, 0) as pressure, + COALESCE(ad.wind_speed, 0) as wind_speed, + COALESCE(ad.wind_direction, 0) as wind_direction, + COALESCE(rs.rainfall, 0) as rainfall, + COALESCE(ad.light, 0) as light, + COALESCE(ad.uv, 0) as uv + FROM aggregated_data ad + 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) if err != nil {