(编辑:jimmy 日期: 2024/12/26 浏览:2)
今天遇到一个问题 之前用TimescaleDB创建的超表 是已7天为单位的 由于7天的数据量过大 影响查询效率 需要把7天的分区改为一天一分区
1.创建普通版表
CREATE TABLE "超表名" ( "collect_time" timestamp(6) NOT NULL, "code" varchar(36) COLLATE "pg_catalog"."default" NOT NULL, "value" numeric(14,4) NOT NULL, "create_time" timestamp(6) NOT NULL ) ;
2.改为超表 create_hypertable()
SELECT create_hypertable('超表名', 'collect_time', chunk_time_interval => INTERVAL '7 day');
3.插入数据
INSERT INTO 超表名("collect_time", "code", "value", "create_time") VALUES ('2020-10-15 16:35:00', '22255220522', '23.4672', '2020-10-14 16:35:26.659'); INSERT INTO 超表名("collect_time", "code", "value", "create_time") VALUES ('2020-10-16 16:35:00', '26622569666', '0.1085', '2020-10-14 16:35:27.546'); INSERT INTO 超表名("collect_time", "code", "value", "create_time") VALUES ('2020-10-13 16:35:00', '525941155555', '25.0549', '2020-10-14 16:35:28.473'); INSERT INTO 超表名("collect_time", "code", "value", "create_time") VALUES ('2020-10-14 16:35:00', '744445411114', '0.0000', '2020-10-14 16:35:24.01'); INSERT INTO 超表名("collect_time", "code", "value", "create_time") VALUES ('2020-10-12 16:35:00', '774484457444', '0.0000', '2020-10-14 16:35:23.032');
查看分区,你会发现这些数据在2个分区内
1.查看_timescaledb_catalog.dimension 表
SELECT * FROM "_timescaledb_catalog"."dimension"
interval_length上显示 604800000000 (TIMESTAMP类型)意思是一周
2.查看分区块状态
查看 dimension_slice 表
转换时间戳
1602720000000000 2020-10-15 08:00:00
1603324800000000 2020-10-22 08:00:00
这里可以看到分区是7天的
1.修改分区时间
SELECT set_chunk_time_interval('超表名', interval '24 hours');
2.插入数据验证
INSERT INTO 超表名("collect_time", "code", "value", "create_time") VALUES ('2021-1-14 16:35:00', '375222D001', '27.7932', '2020-10-14 16:35:15.011'); INSERT INTO 超表名("collect_time", "code", "value", "create_time") VALUES ('2021-1-15 16:35:00', '3715044111', '0.0000', '2020-10-14 16:35:20.389'); INSERT INTO 超表名("collect_time", "code", "value", "create_time") VALUES ('2021-1-16 16:35:00', '202Q0019QT001', '0.3663', '2020-10-14 16:35:19.087'); INSERT INTO 超表名("collect_time", "code", "value", "create_time") VALUES ('2021-1-17 16:35:00', '3702000284441', '22.2946', '2020-10-14 16:35:15.035'); INSERT INTO 超表名("collect_time", "code", "value", "create_time") VALUES ('2021-1-18 16:35:00', '37075225555501', '0.3022', '2020-10-14 16:35:24.041'); INSERT INTO 超表名("collect_time", "code", "value", "create_time") VALUES ('2021-1-19 16:35:00', '25555222206001', '0.0000', '2020-10-14 16:35:23.956');
查看_timescaledb_catalog.dimension 表
变成 86400000000 了
2.查看分区
分区也多了
还有第2种(未测试)
我想能不能直接"_timescaledb_catalog".“dimension” 表的 interval_length 字段直接 改为86400000000