@
mmm159357456 用 SQLite 测试了生成整张表、计算整张表,结果如下:
项目 结果大小 用时
————————————————————
生成数据库 1.02GB的数据库 2分钟
计算整张表 1.35GB的CSV 7分钟
## 数据库预览( CSV 形式预览。200 年 x 365/366 天 x 360 个经纬度 = 26297640 行):
year,dateday,geometry_x,geometry_y,element1,element2,element3,element4
1900,1900-01-01,0.0,0.0,1,1001,2001,3001
1900,1900-01-02,0.0,0.0,2,1002,2002,3002
1900,1900-01-03,0.0,0.0,3,1003,2003,3003
……
1900,1900-12-29,0.0,0.0,363,1363,2363,3363
1900,1900-12-30,0.0,0.0,364,1364,2364,3364
1900,1900-12-31,0.0,0.0,365,1365,2365,3365
1900,1900-01-01,1.0,-1.0,1,1001,2001,3001
1900,1900-01-02,1.0,-1.0,2,1002,2002,3002
1900,1900-01-03,1.0,-1.0,3,1003,2003,3003
……
1900,1900-12-29,359.0,-359.0,363,1363,2363,3363
1900,1900-12-30,359.0,-359.0,364,1364,2364,3364
1900,1900-12-31,359.0,-359.0,365,1365,2365,3365
1901,1901-01-01,0.0,0.0,1,1001,2001,3001
1901,1901-01-02,0.0,0.0,2,1002,2002,3002
1901,1901-01-03,0.0,0.0,3,1003,2003,3003
……
2099,2099-12-29,359.0,-359.0,363,1363,2363,3363
2099,2099-12-30,359.0,-359.0,364,1364,2364,3364
2099,2099-12-31,359.0,-359.0,365,1365,2365,3365
## 计算结果预览( CSV 文件):
1900,0.0,0.0,1900-01-01,1.0,1001.0,2001.0,3001.0
1900,0.0,0.0,1900-01-02,1.5,1001.5,2001.5,3001.5
1900,0.0,0.0,1900-01-03,2.0,1002.0,2002.0,3002.0
1900,0.0,0.0,1900-01-04,2.5,1002.5,2002.5,3002.5
1900,0.0,0.0,1900-01-05,3.0,1003.0,2003.0,3003.0
1900,0.0,0.0,1900-01-06,4.0,1003.5,2003.5,3004.0
……
## 计算方式预览( CSV 形式。可保存后用 Excel 查看):
1900,0.0,0.0,1900-01-01,(1)/1,(1001)/1,(2001)/1,(3001)/1
1900,0.0,0.0,1900-01-02,(1+2)/2,(1001+1002)/2,(2001+2002)/2,(3001+3002)/2
1900,0.0,0.0,1900-01-03,(1+2+3)/3,(1001+1002+1003)/3,(2001+2002+2003)/3,(3001+3002+3003)/3
1900,0.0,0.0,1900-01-04,(1+2+3+4)/4,(1001+1002+1003+1004)/4,(2001+2002+2003+2004)/4,(3001+3002+3003+3004)/4
1900,0.0,0.0,1900-01-05,(1+2+3+4+5)/5,(1001+1002+1003+1004+1005)/5,(2001+2002+2003+2004+2005)/5,(3001+3002+3003+3004+3005)/5
1900,0.0,0.0,1900-01-06,(2+3+4+5+6)/5,(1001+1002+1003+1004+1005+1006)/6,(2001+2002+2003+2004+2005+2006)/6,(3002+3003+3004+3005+3006)/5
1900,0.0,0.0,1900-01-07,(3+4+5+6+7)/5,(1001+1002+1003+1004+1005+1006+1007)/7,(2001+2002+2003+2004+2005+2006+2007)/7,(3003+3004+3005+3006+3007)/5
1900,0.0,0.0,1900-01-08,(4+5+6+7+8)/5,(1001+1002+1003+1004+1005+1006+1007+1008)/8,(2001+2002+2003+2004+2005+2006+2007+2008)/8,(3004+3005+3006+3007+3008)/5
1900,0.0,0.0,1900-01-09,(5+6+7+8+9)/5,(1001+1002+1003+1004+1005+1006+1007+1008+1009)/9,(2001+2002+2003+2004+2005+2006+2007+2008+2009)/9,(3005+3006+3007+3008+3009)/5
1900,0.0,0.0,1900-01-10,(6+7+8+9+10)/5,(1001+1002+1003+1004+1005+1006+1007+1008+1009+1010)/10,(2001+2002+2003+2004+2005+2006+2007+2008+2009+2010)/10,(3006+3007+3008+3009+3010)/5
1900,0.0,0.0,1900-01-11,(7+8+9+10+11)/5,(1002+1003+1004+1005+1006+1007+1008+1009+1010+1011)/10,(2001+2002+2003+2004+2005+2006+2007+2008+2009+2010+2011)/11,(3007+3008+3009+3010+3011)/5
……
1900,0.0,0.0,1900-12-31,(361+362+363+364+365)/5,(1356+1357+1358+1359+1360+1361+1362+1363+1364+1365)/10,(2351+2352+2353+2354+2355+2356+2357+2358+2359+2360+2361+2362+2363+2364+2365)/15,(3361+3362+3363+3364+3365)/5
1900,1.0,-1.0,1900-01-01,(1)/1,(1001)/1,(2001)/1,(3001)/1
1900,1.0,-1.0,1900-01-02,(1+2)/2,(1001+1002)/2,(2001+2002)/2,(3001+3002)/2
……
## 使用方式:
去 SQLite 官网下载个 1 MB 的 sqlite3.exe ,然后保存下面的 SQLite 代码为 main.sql ,然后命令行运行:
```shell
sqlite3.exe data.db < main.sql
```
## SQLite 代码:
*( V 站排版原因,行首有全角空格)*
```sql
-- PRAGMA journal_mode = off; -- 取消日志记录。但这会输出个 off 。。
PRAGMA synchronous = off; -- 提交写请求给操作系统后,就可继续后续计算
PRAGMA cache_size = -8192; -- 占用 8 MB 内存
-- 建表
CREATE TABLE IF NOT EXISTS data (
year INT,
dateday DATE,
geometry_x REAL,
geometry_y REAL,
element1 INT,
element2 INT,
element3 INT,
element4 INT,
PRIMARY KEY (year, geometry_x, geometry_y, dateday)
) WITHOUT ROWID;
-- 生成数据
INSERT INTO data
SELECT year.value,
DATE(year.value || '-01-01', day_of_year.value || ' days'),
area.value * 1.0,
area.value * -1.0,
day_of_year.value + 1,
day_of_year.value + 1001,
day_of_year.value + 2001,
day_of_year.value + 3001
FROM generate_series(1900, 2099) year,
generate_series(0, STRFTIME('%j', year.value || '-12-31') - 1) day_of_year,
generate_series(0, 359) area;
-- 计算表
SELECT year,
geometry_x,
geometry_y,
dateday,
/* -- 下面 4 行用于预览平均值的计算方式对不对
FORMAT('(%s)/%d', GROUP_CONCAT(element1, '+') OVER win5, COUNT(*) OVER win5),
FORMAT('(%s)/%d', GROUP_CONCAT(element2, '+') OVER win10, COUNT(*) OVER win10),
FORMAT('(%s)/%d', GROUP_CONCAT(element3, '+') OVER win15, COUNT(*) OVER win15),
FORMAT('(%s)/%d', GROUP_CONCAT(element4, '+') OVER win5, COUNT(*) OVER win5)
*/
AVG(element1) OVER win5,
AVG(element2) OVER win10,
AVG(element3) OVER win15,
AVG(element4) OVER win5
FROM data
WINDOW win AS (PARTITION BY year, geometry_x, geometry_y ORDER BY dateday),
win5 AS (win ROWS 4 PRECEDING),
win10 AS (win ROWS 9 PRECEDING),
win15 AS (win ROWS 14 PRECEDING);
```