PostgreSQL vs Greenplum Hash outer join (hash表的选择)

本文涉及的产品
云原生数据库 PolarDB MySQL 版,Serverless 5000PCU 100GB
云原生数据库 PolarDB 分布式版,标准版 2核8GB
云数据库 RDS MySQL Serverless,0.5-2RCU 50GB
简介:

标签

PostgreSQL , Greenplum , hash outer join , hash table


背景

数据分析、大表JOIN、多表JOIN时,哈希JOIN是比较好的提速手段。

hash join会首先扫描其中的一张表(包括需要输出的字段),根据JOIN列生成哈希表。然后扫描另一张表。

hash join介绍

https://www.postgresql.org/docs/10/static/planner-optimizer.html

the right relation is first scanned and loaded into a hash table, using its join attributes as hash keys.

Next the left relation is scanned and the appropriate values of every row found are used as hash keys to locate the matching rows in the table.

hash table的选择

理论上应该选择小表作为哈希表。但是2011年以前的版本,对HASH表的选择是有讲究的,并不是自由选择,只支OUTER JOIN时返回可以为空的表生成哈希表。

hash join演进

PostgreSQL在1997年的时候已经支持HashJoin,Greenplum基于PostgreSQL 8.2开发,因此也是天然支持HashJoin的。

在2011年时,PostgreSQL对hashjoin做出了两个改进,支持full outer join,同时支持outer join任意表生成哈希表(原来的版本只支OUTER JOIN时返回可以为空的表生成哈希表):

https://www.postgresql.org/docs/current/static/release-9-1.html

Allow FULL OUTER JOIN to be implemented as a hash join, and allow either side of a LEFT OUTER JOIN or RIGHT OUTER JOIN to be hashed (Tom Lane)

Previously FULL OUTER JOIN could only be implemented as a merge join, and LEFT OUTER JOIN and RIGHT OUTER JOIN could hash only the nullable side of the join.

These changes provide additional query optimization possibilities.

对应patch

https://git.postgresql.org/gitweb/?p=postgresql.git;a=commit;h=f4e4b3274317d9ce30de7e7e5b04dece7c4e1791

这个改进非常有意义,特别是可以为空的表非常庞大时,作为哈希表是不合适的。后面就来对比一下。

几种JOIN介绍

INNER JOIN

For each row R1 of T1, the joined table has a row for each row in T2 that satisfies the join condition with R1.

LEFT OUTER JOIN

First, an inner join is performed.

Then, for each row in T1 that does not satisfy the join condition with any row in T2,

a joined row is added with null values in columns of T2.

Thus, the joined table always has at least one row for each row in T1.

RIGHT OUTER JOIN

First, an inner join is performed.

Then, for each row in T2 that does not satisfy the join condition with any row in T1,

a joined row is added with null values in columns of T1.

This is the converse of a left join: the result table will always have a row for each row in T2.

FULL OUTER JOIN

First, an inner join is performed.

Then, for each row in T1 that does not satisfy the join condition with any row in T2,

a joined row is added with null values in columns of T2.

Also, for each row of T2 that does not satisfy the join condition with any row in T1,

a joined row with null values in the columns of T1 is added.

PostgreSQL vs Greenplum outer join 对比

left\right outer join

PostgreSQL 9.1+

postgres=# create table t1(id int, info text);  
CREATE TABLE  
postgres=# create table t2(id int, info text);  
CREATE TABLE  
  
t1为小表, t2为大表  
  
postgres=# insert into t1 select generate_series(1,10000);  
INSERT 0 10000  
postgres=# insert into t2 select generate_series(1,10000000);  
INSERT 0 10000000  
postgres=# analyze t1;  
ANALYZE  
postgres=# analyze t2;  
ANALYZE  

PostgreSQL自动选择了小表作为哈希表。

postgres=# explain (analyze,verbose,timing,costs,buffers) select t1.*,t2.* from t1 left outer join t2 on (t1.id=t2.id);  
                                                          QUERY PLAN                                                             
-------------------------------------------------------------------------------------------------------------------------------  
 Hash Right Join  (cost=270.00..182117.68 rows=10000 width=72) (actual time=3.367..2736.484 rows=10000 loops=1)  
   Output: t1.id, t1.info, t2.id, t2.info  
   Hash Cond: (t2.id = t1.id)  
   Buffers: shared hit=16260 read=28033 dirtied=7288 written=5780  
   ->  Seq Scan on public.t2  (cost=0.00..144247.77 rows=9999977 width=36) (actual time=0.014..1262.472 rows=10000000 loops=1)  
         Output: t2.id, t2.info  
         Buffers: shared hit=16228 read=28020 dirtied=7288 written=5780  
   ->  Hash  (cost=145.00..145.00 rows=10000 width=36) (actual time=3.323..3.323 rows=10000 loops=1)  
         Output: t1.id, t1.info  
         Buckets: 16384  Batches: 1  Memory Usage: 480kB  
         Buffers: shared hit=32 read=13  
         ->  Seq Scan on public.t1  (cost=0.00..145.00 rows=10000 width=36) (actual time=0.033..1.501 rows=10000 loops=1)  
               Output: t1.id, t1.info  
               Buffers: shared hit=32 read=13  
 Planning time: 0.076 ms  
 Execution time: 2737.441 ms  
(16 rows)  

Greenplum

greenplum只能选择nullable端的表作为哈希表。即t2.

postgres=# explain analyze select t1.*,t2.* from t1 left outer join t2 on (t1.id=t2.id);  
                                                                      QUERY PLAN                                                                         
-------------------------------------------------------------------------------------------------------------------------------------------------------  
 Gather Motion 48:1  (slice1; segments: 48)  (cost=236070.60..236368.60 rows=10000 width=72)  
   Rows out:  10000 rows at destination with 215 ms to end, start offset by 1.350 ms.  
   ->  Hash Left Join  (cost=236070.60..236368.60 rows=209 width=72)  
         Hash Cond: t1.id = t2.id  
         Rows out:  Avg 208.3 rows x 48 workers.  Max 223 rows (seg17) with 0.043 ms to first row, 81 ms to end, start offset by 15 ms.  
         Executor memory:  6511K bytes avg, 6513K bytes max (seg18).  
         Work_mem used:  6511K bytes avg, 6513K bytes max (seg18). Workfile: (0 spilling, 0 reused)  
         ->  Seq Scan on t1  (cost=0.00..148.00 rows=209 width=36)  
               Rows out:  Avg 208.3 rows x 48 workers.  Max 223 rows (seg17) with 0.006 ms to first row, 0.025 ms to end, start offset by 15 ms.  
         ->  Hash  (cost=111053.60..111053.60 rows=208362 width=36)  
               Rows in:  (No row requested) 0 rows (seg0) with 0 ms to end.  
               ->  Seq Scan on t2  (cost=0.00..111053.60 rows=208362 width=36)  
                     Rows out:  Avg 208333.3 rows x 48 workers.  Max 208401 rows (seg18) with 79 ms to first row, 98 ms to end, start offset by 15 ms.  
 Slice statistics:  
   (slice0)    Executor memory: 283K bytes.  
   (slice1)    Executor memory: 250K bytes avg x 48 workers, 250K bytes max (seg0).  Work_mem: 6513K bytes max.  
 Statement statistics:  
   Memory used: 128000K bytes  
 Settings:  optimizer=off  
 Optimizer status: legacy query optimizer  
 Total runtime: 216.814 ms  
(21 rows)  

full outer join

PostgreSQL 9.1+

PostgreSQL 9.1+ 支持full outer join使用hash join.

postgres=# explain (analyze,verbose,timing,costs,buffers) select t1.*,t2.* from t2 full outer join t1 on (t1.id=t2.id);  
                                                          QUERY PLAN                                                             
-------------------------------------------------------------------------------------------------------------------------------  
 Hash Full Join  (cost=270.00..182117.68 rows=9999977 width=72) (actual time=3.434..3728.277 rows=10000000 loops=1)  
   Output: t1.id, t1.info, t2.id, t2.info  
   Hash Cond: (t2.id = t1.id)  
   Buffers: shared hit=16301 read=27992  
   ->  Seq Scan on public.t2  (cost=0.00..144247.77 rows=9999977 width=36) (actual time=0.246..1187.189 rows=10000000 loops=1)  
         Output: t2.id, t2.info  
         Buffers: shared hit=16256 read=27992  
   ->  Hash  (cost=145.00..145.00 rows=10000 width=36) (actual time=3.157..3.157 rows=10000 loops=1)  
         Output: t1.id, t1.info  
         Buckets: 16384  Batches: 1  Memory Usage: 480kB  
         Buffers: shared hit=45  
         ->  Seq Scan on public.t1  (cost=0.00..145.00 rows=10000 width=36) (actual time=0.013..1.438 rows=10000 loops=1)  
               Output: t1.id, t1.info  
               Buffers: shared hit=45  
 Planning time: 0.095 ms  
 Execution time: 4527.421 ms  
(16 rows)  

Greenplum

Greenplum 8.2版本,不支持full outer join使用hash join.

使用了merge join.

postgres=# explain analyze select t1.*,t2.* from t2 full outer join t1 on (t1.id=t2.id);  
                                                                        QUERY PLAN                                                                           
-----------------------------------------------------------------------------------------------------------------------------------------------------------  
 Gather Motion 48:1  (slice1; segments: 48)  (cost=1274708.75..1324865.55 rows=10001360 width=72)  
   Rows out:  10000000 rows at destination with 2310 ms to end, start offset by 229 ms.  
   ->  Merge Full Join  (cost=1274708.75..1324865.55 rows=208362 width=72)  
         Merge Cond: t2.id = t1.id  
         Rows out:  Avg 208333.3 rows x 48 workers.  Max 208401 rows (seg18) with 0.002 ms to first row, 36 ms to end, start offset by 274 ms.  
         ->  Sort  (cost=1273896.37..1298899.77 rows=208362 width=36)  
               Sort Key: t2.id  
               Rows out:  Avg 208333.3 rows x 48 workers.  Max 208401 rows (seg18) with 0.006 ms to end, start offset by 274 ms.  
               Executor memory:  14329K bytes avg, 14329K bytes max (seg0).  
               Work_mem used:  14329K bytes avg, 14329K bytes max (seg0). Workfile: (0 spilling, 0 reused)  
               ->  Seq Scan on t2  (cost=0.00..111053.60 rows=208362 width=36)  
                     Rows out:  Avg 208333.3 rows x 48 workers.  Max 208401 rows (seg18) with 0.003 ms to first row, 67 ms to end, start offset by 274 ms.  
         ->  Sort  (cost=812.39..837.39 rows=209 width=36)  
               Sort Key: t1.id  
               Rows out:  Avg 208.3 rows x 48 workers.  Max 223 rows (seg17) with 0.002 ms to end, start offset by 273 ms.  
               Executor memory:  58K bytes avg, 58K bytes max (seg0).  
               Work_mem used:  58K bytes avg, 58K bytes max (seg0). Workfile: (0 spilling, 0 reused)  
               ->  Seq Scan on t1  (cost=0.00..148.00 rows=209 width=36)  
                     Rows out:  Avg 208.3 rows x 48 workers.  Max 223 rows (seg17) with 31 ms to first row, 32 ms to end, start offset by 273 ms.  
 Slice statistics:  
   (slice0)    Executor memory: 411K bytes.  
   (slice1)    Executor memory: 14597K bytes avg x 48 workers, 14597K bytes max (seg0).  Work_mem: 14329K bytes max.  
 Statement statistics:  
   Memory used: 128000K bytes  
 Settings:  optimizer=off  
 Optimizer status: legacy query optimizer  
 Total runtime: 2539.416 ms  
(27 rows)  
相关实践学习
使用PolarDB和ECS搭建门户网站
本场景主要介绍基于PolarDB和ECS实现搭建门户网站。
阿里云数据库产品家族及特性
阿里云智能数据库产品团队一直致力于不断健全产品体系,提升产品性能,打磨产品功能,从而帮助客户实现更加极致的弹性能力、具备更强的扩展能力、并利用云设施进一步降低企业成本。以云原生+分布式为核心技术抓手,打造以自研的在线事务型(OLTP)数据库Polar DB和在线分析型(OLAP)数据库Analytic DB为代表的新一代企业级云原生数据库产品体系, 结合NoSQL数据库、数据库生态工具、云原生智能化数据库管控平台,为阿里巴巴经济体以及各个行业的企业客户和开发者提供从公共云到混合云再到私有云的完整解决方案,提供基于云基础设施进行数据从处理、到存储、再到计算与分析的一体化解决方案。本节课带你了解阿里云数据库产品家族及特性。
相关文章
|
SQL 弹性计算 关系型数据库
HTAP数据库 PostgreSQL 场景与性能测试之 3.1 - (OLAP) 大表JOIN统计查询-10亿 join 1亿 agg
标签 PostgreSQL , HTAP , OLTP , OLAP , 场景与性能测试 背景 PostgreSQL是一个历史悠久的数据库,历史可以追溯到1973年,最早由2014计算机图灵奖得主,关系数据库的鼻祖Michael_Stonebraker 操刀设计,PostgreSQL具备与Oracle类似的功能、性能、架构以及稳定性。 PostgreSQL社区的贡献者众多
1809 0
|
3月前
|
关系型数据库 分布式数据库 PolarDB
在PolarDB中,如果一条join条件都不符合
【1月更文挑战第21天】【1月更文挑战第104篇】在PolarDB中,如果一条join条件都不符合
23 6
|
3月前
|
关系型数据库 分布式数据库 PolarDB
在PolarDB中,对于join操作,系统会采用拉取内表
【1月更文挑战第21天】【1月更文挑战第103篇】在PolarDB中,对于join操作,系统会采用拉取内表
19 1
|
10月前
|
SQL 算法 Cloud Native
数据库内核那些事|细说PolarDB优化器查询变换 - join消除篇
数据库的查询优化器是整个系统的"大脑",一条SQL语句执行是否高效在不同的优化决策下可能会产生几个数量级的性能差异,因此优化器也是数据库系统中最为核心的组件和竞争力之一。阿里云瑶池旗下的云原生数据库PolarDB MySQL版作为领先的云原生数据库,希望能够应对广泛用户场景、承接各类用户负载,助力企业数据业务持续在线、数据价值不断放大,因此对优化器能力的打磨是必须要做的工作之一。 本系列将从PolarDB for MySQL的查询变换能力开始,介绍我们在这个优化器方向上逐步积累的一些工作。
11356 0
|
SQL Oracle 架构师
PolarDB for MySQL优化器查询变换系列 - join条件下推
本篇是PolarDB 优化器查询变换系列的第四篇,之前的文章请见:窗口函数解相关:https://ata.alibaba-inc.com/articles/194578IN-list变换:https://ata.alibaba-inc.com/articles/254779Join消除:https://ata.alibaba-inc.com/articles/252403引言在数据库的查询优化特性
189 0
PolarDB for MySQL优化器查询变换系列 - join条件下推
|
SQL Cloud Native 算法
PolarDB 优化器查询变换系列 - join消除
背景众所周知,数据库的查询优化器可以说是整个系统的"大脑",一条查询语句执行的是否高效,在不同的优化器决策下,可能会产生几个数量级的性能差异,因此优化器也是数据库系统中最为核心的组件和核心竞争力之一。对于各个商业数据库,其优化器通过常年积累下来的能力,是其最为核心的商业机密,而另一方面从现有的开源数据库来看,很可惜大多数产品的优化器还都十分初级,也包括老牌的MySQL/Post
187 0
|
算法 测试技术 分布式数据库
PolarDB-X 数据分布解读 :Hash vs Range
Hash与Range对于数据库,到底意味着什么?作为应用,又该如何选择?PolarDB-X的Hash分区与其它数据库的Hash分区有什么区别?
257 1
|
SQL 关系型数据库 PostgreSQL
PostgreSQL连接(JOIN)
PostgreSQL JOIN子句用于把两个或多个表的行结合起来,基于这些表之间的共同变量。 在PostgreSQL中,JOIN有五种连接类型: CROSS JOIN:交叉连接 内连接:内连接 LEFT OUTER JOIN:左外连接 右外连接:右外连接 FULL OUTER JOIN:全外连接 接下来让我们创建两张表COMPANY和DEPARTMENT。
451 0
|
SQL 存储 缓存
PolarDB-X 1.0-用户指南-SQL调优指南-SQL调优进阶-JOIN与子查询的优化和执行
本文主要介绍如何使用JOIN和子查询。JOIN将多个表以某个或某些列为条件进行连接操作而检索出关联数据的过程,多个表之间以共同列而关联在一起。子查询是指在父查询的WHERE子句或HAVING子句中嵌套另一个SELECT语句的查询。
147 0
PolarDB-X 1.0-用户指南-SQL调优指南-SQL调优进阶-JOIN与子查询的优化和执行
|
SQL 算法
PolarDB-X 1.0-SQL 手册-拆分函数使用说明-HASH
本文将介绍HASH函数使用方式。
128 0

相关产品

  • 云原生数据库 PolarDB