2025-08-21 15:57:09 +08:00

162 lines
4.3 KiB
Go
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

package database
import (
"database/sql"
"time"
"weatherstation/pkg/types"
)
// GetOnlineDevicesCount 获取在线设备数量
func GetOnlineDevicesCount(db *sql.DB) int {
query := `
SELECT COUNT(DISTINCT station_id)
FROM rs485_weather_data
WHERE timestamp > NOW() - INTERVAL '5 minutes'`
var count int
if err := db.QueryRow(query).Scan(&count); err != nil {
return 0
}
return count
}
// GetStations 获取所有WH65LP站点列表
func GetStations(db *sql.DB) ([]types.Station, error) {
query := `
SELECT DISTINCT s.station_id,
COALESCE(s.password, '') as station_name,
'WH65LP' as device_type,
COALESCE(MAX(r.timestamp), '1970-01-01'::timestamp) as last_update,
COALESCE(s.latitude, 0) as latitude,
COALESCE(s.longitude, 0) as longitude,
COALESCE(s.name, '') as name,
COALESCE(s.location, '') as location
FROM stations s
LEFT JOIN rs485_weather_data r ON s.station_id = r.station_id
WHERE s.station_id LIKE 'RS485-%'
GROUP BY s.station_id, s.password, s.latitude, s.longitude, s.name, s.location
ORDER BY s.station_id`
rows, err := db.Query(query)
if err != nil {
return nil, err
}
defer rows.Close()
var stations []types.Station
for rows.Next() {
var station types.Station
var lastUpdate time.Time
err := rows.Scan(
&station.StationID,
&station.StationName,
&station.DeviceType,
&lastUpdate,
&station.Latitude,
&station.Longitude,
&station.Name,
&station.Location,
)
if err != nil {
continue
}
station.LastUpdate = lastUpdate.Format("2006-01-02 15:04:05")
stations = append(stations, station)
}
return stations, nil
}
// GetWeatherData 获取指定站点的历史天气数据
func GetWeatherData(db *sql.DB, stationID string, startTime, endTime time.Time, interval string) ([]types.WeatherPoint, error) {
// 构建查询SQL统一风向矢量平均雨量为累计量的正增量求和
var query string
var intervalStr string
switch interval {
case "10min":
intervalStr = "10 minutes"
case "30min":
intervalStr = "30 minutes"
default: // 1hour
intervalStr = "1 hour"
}
query = buildWeatherDataQuery(intervalStr)
rows, err := db.Query(query, intervalStr, stationID, startTime, endTime)
if err != nil {
return nil, err
}
defer rows.Close()
var points []types.WeatherPoint
for rows.Next() {
var point types.WeatherPoint
err := rows.Scan(
&point.DateTime,
&point.Temperature,
&point.Humidity,
&point.Pressure,
&point.WindSpeed,
&point.WindDir,
&point.Rainfall,
&point.Light,
&point.UV,
)
if err != nil {
continue
}
points = append(points, point)
}
return points, nil
}
// buildWeatherDataQuery 构建天气数据查询SQL
func buildWeatherDataQuery(interval string) string {
return `
WITH base AS (
SELECT
date_trunc('hour', timestamp) +
(floor(date_part('minute', timestamp) / extract(epoch from $1::interval) * 60) * $1::interval) as time_group,
timestamp as ts,
temperature, humidity, pressure, wind_speed, wind_direction, rainfall, light, uv
FROM rs485_weather_data
WHERE station_id = $2 AND timestamp BETWEEN $3 AND $4
),
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,
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 base
GROUP BY time_group
)
SELECT
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`
}