go_rain_dtu/data/hourly_rain_schema.sql
2025-04-24 14:44:30 +08:00

40 lines
1.5 KiB
SQL
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.

-- 创建小时雨量统计表
CREATE TABLE IF NOT EXISTS hourly_rainfall (
id INTEGER PRIMARY KEY AUTOINCREMENT,
hour_start DATETIME NOT NULL, -- 小时开始时间例如2025-04-21 18:00:00
hour_end DATETIME NOT NULL, -- 小时结束时间例如2025-04-21 19:00:00
rainfall INTEGER NOT NULL, -- 该小时的雨量整数实际值需除以10
min_value INTEGER, -- 该小时内记录的最小累积值
max_value INTEGER, -- 该小时内记录的最大累积值
samples INTEGER, -- 该小时内的采样数量
created_at DATETIME NOT NULL, -- 记录创建时间
UNIQUE(hour_start) -- 确保每小时只有一条记录
);
-- 创建用于计算历史数据的临时视图
CREATE TEMP VIEW IF NOT EXISTS hourly_data AS
SELECT
datetime(strftime('%Y-%m-%d %H:00:00', timestamp)) as hour_start,
datetime(strftime('%Y-%m-%d %H:59:59', timestamp)) as hour_end,
MIN(optical_rain) as min_value,
MAX(optical_rain) as max_value,
COUNT(*) as samples,
MAX(optical_rain) - MIN(optical_rain) as rainfall
FROM sensor_data
WHERE timestamp >= '2025-04-21 18:00:00'
GROUP BY strftime('%Y-%m-%d %H', timestamp)
ORDER BY hour_start;
-- 将历史数据插入小时雨量表
INSERT OR IGNORE INTO hourly_rainfall
(hour_start, hour_end, rainfall, min_value, max_value, samples, created_at)
SELECT
hour_start,
hour_end,
rainfall,
min_value,
max_value,
samples,
datetime('now')
FROM hourly_data;