前
言
当前数字化进程不断加快,全球数据量呈指数级增长,对数据库系统的性能提出了巨大的挑战。优化器作为数据库管理系统中的关键技术,对数据库性能和效率具有重要影响,它通过对用户的查询请求进行解析和优化来生成高效的执行计划,进而快速返回查询结果,同一条 SQL 语句在不同的优化决策下可能会产生数量级的性能差异。
拓数派吉祥物「派派」
「聚集下推」原理演示
有无「聚集下推」对比
CREATE TABLE t (x int, y int);
INSERT INTO t SELECT i % 30, i % 30 FROM generate_series(1, 10240) i;
ANALYZE t;
SELECT t1.x, sum(t2.y + t3.y), count(*) FROM t t1
JOIN t t2 ON t1.x = t2.x JOIN t t3 ON t2.x = t3.x
GROUP BY t1.x;
EXPLAIN (ANALYZE, COSTS OFF)
SELECT t1.x, sum(t2.y + t3.y), count(*) FROM t t1 JOIN t t2 ON t1.x = t2.x JOIN t t3 ON t2.x = t3.x GROUP BY t1.x;
QUERY PLAN
---------------------------------------------------------------------------------------------------------------------------
Gather Motion 3:1 (slice1; segments: 3) (actual time=153884.859..274102.066 rows=30 loops=1)
-> HashAggregate (actual time=274100.004..274100.011 rows=12 loops=1)
Group Key: t1.x
Peak Memory Usage: 0 kB
-> Hash Join (actual time=38.717..100579.782 rows=477571187 loops=1)
Hash Cond: (t1.x = t3.x)
Extra Text: (seg0) Hash chain length 341.4 avg, 342 max, using 12 of 131072 buckets.
-> Hash Join (actual time=2.088..429.203 rows=1398787 loops=1)
Hash Cond: (t1.x = t2.x)
Extra Text: (seg0) Hash chain length 341.4 avg, 342 max, using 12 of 131072 buckets.
-> Redistribute Motion 3:3 (slice2; segments: 3) (actual time=0.044..4.590 rows=4097 loops=1)
Hash Key: t1.x
-> Seq Scan on t t1 (actual time=1.382..32.683 rows=3496 loops=1)
-> Hash (actual time=1.760..1.761 rows=4097 loops=1)
Buckets: 131072 Batches: 1 Memory Usage: 1185kB
-> Redistribute Motion 3:3 (slice3; segments: 3) (actual time=0.049..0.922 rows=4097 loops=1)
Hash Key: t2.x
-> Seq Scan on t t2 (actual time=1.628..32.837 rows=3496 loops=1)
-> Hash (actual time=36.153..36.153 rows=4097 loops=1)
Buckets: 131072 Batches: 1 Memory Usage: 1185kB
-> Redistribute Motion 3:3 (slice4; segments: 3) (actual time=3.918..35.169 rows=4097 loops=1)
Hash Key: t3.x
-> Seq Scan on t t3 (actual time=1.380..30.316 rows=3496 loops=1)
Planning Time: 8.810 ms
(slice0) Executor memory: 257K bytes.
(slice1) Executor memory: 2484K bytes avg x 3 workers, 2570K bytes max (seg0). Work_mem: 1185K bytes max.
(slice2) Executor memory: 32840K bytes avg x 3 workers, 32841K bytes max (seg0).
(slice3) Executor memory: 32860K bytes avg x 3 workers, 32860K bytes max (seg0).
(slice4) Executor memory: 32860K bytes avg x 3 workers, 32860K bytes max (seg0).
Memory used: 128000kB
Optimizer: Postgres query optimizer
Execution Time: 274130.589 ms
(32 rows)
EXPLAIN (ANALYZE, COSTS OFF)
SELECT t1.x, sum(t2.y + t3.y), count(*) FROM t t1 JOIN t t2 ON t1.x = t2.x JOIN t t3 ON t2.x = t3.x GROUP BY t1.x;
QUERY PLAN
----------------------------------------------------------------------------------------------------------------------------------------------------------
Gather Motion 3:1 (slice1; segments: 3) (actual time=835.755..836.406 rows=30 loops=1)
-> Finalize GroupAggregate (actual time=834.227..835.432 rows=12 loops=1)
Group Key: t1.x
-> Sort (actual time=834.031..834.441 rows=4097 loops=1)
Sort Key: t1.x
Sort Method: quicksort Memory: 1266kB
-> Redistribute Motion 3:3 (slice2; segments: 3) (actual time=812.139..830.706 rows=4097 loops=1)
Hash Key: t1.x
-> Hash Join (actual time=810.536..828.097 rows=3496 loops=1)
Hash Cond: (t1.x = t2.x)
Extra Text: (seg0) Hash chain length 1.0 avg, 1 max, using 30 of 131072 buckets.
-> Seq Scan on t t1 (actual time=1.689..16.674 rows=3496 loops=1)
-> Hash (actual time=808.497..808.498 rows=30 loops=1)
Buckets: 131072 Batches: 1 Memory Usage: 1026kB
-> Broadcast Motion 3:3 (slice3; segments: 3) (actual time=461.065..808.466 rows=30 loops=1)
-> Partial HashAggregate (actual time=810.026..810.033 rows=12 loops=1)
Group Key: t2.x
Peak Memory Usage: 0 kB
-> Hash Join (actual time=28.070..331.181 rows=1398787 loops=1)
Hash Cond: (t2.x = t3.x)
Extra Text: (seg0) Hash chain length 341.4 avg, 342 max, using 12 of 262144 buckets.
-> Redistribute Motion 3:3 (slice4; segments: 3) (actual time=0.040..1.270 rows=4097 loops=1)
Hash Key: t2.x
-> Seq Scan on t t2 (actual time=1.449..19.963 rows=3496 loops=1)
-> Hash (actual time=27.834..27.835 rows=4097 loops=1)
Buckets: 262144 Batches: 1 Memory Usage: 2209kB
-> Redistribute Motion 3:3 (slice5; segments: 3) (actual time=3.836..27.025 rows=4097 loops=1)
Hash Key: t3.x
-> Seq Scan on t t3 (actual time=1.537..23.654 rows=3496 loops=1)
Planning Time: 14.425 ms
(slice0) Executor memory: 328K bytes.
(slice1) Executor memory: 408K bytes avg x 3 workers, 514K bytes max (seg0). Work_mem: 450K bytes max.
(slice2) Executor memory: 33951K bytes avg x 3 workers, 33952K bytes max (seg0). Work_mem: 1026K bytes max.
(slice3) Executor memory: 2298K bytes avg x 3 workers, 2341K bytes max (seg0). Work_mem: 2209K bytes max.
(slice4) Executor memory: 32860K bytes avg x 3 workers, 32860K bytes max (seg0).
(slice5) Executor memory: 32860K bytes avg x 3 workers, 32860K bytes max (seg0).
Memory used: 128000kB
Optimizer: Postgres query optimizer
Execution Time: 865.305 ms
(39 rows)
无聚集下推 VS 有聚集下推对比
关于 PieCloudDB
本文分享自微信公众号 - 开源软件联盟PostgreSQL分会(kaiyuanlianmeng)。
如有侵权,请联系 support@oschina.cn 删除。
本文参与“OSC源创计划”,欢迎正在阅读的你也加入,一起分享。