标签
PostgreSQL , HTAP , OLTP , OLAP , 场景与性能测试
背景
PostgreSQL是一个历史悠久的数据库,历史可以追溯到1973年,最早由2014计算机图灵奖得主,关系数据库的鼻祖Michael_Stonebraker 操刀设计,PostgreSQL具备与Oracle类似的功能、性能、架构以及稳定性。
PostgreSQL社区的贡献者众多,来自全球各个行业,历经数年,PostgreSQL 每年发布一个大版本,以持久的生命力和稳定性著称。
2017年10月,PostgreSQL 推出10 版本,携带诸多惊天特性,目标是胜任OLAP和OLTP的HTAP混合场景的需求:
《最受开发者欢迎的HTAP数据库PostgreSQL 10特性》
1、多核并行增强
2、fdw 聚合下推
3、逻辑订阅
4、分区
5、金融级多副本
6、json、jsonb全文检索
7、还有插件化形式存在的特性,如 向量计算、JIT、SQL图计算、SQL流计算、分布式并行计算、时序处理、基因测序、化学分析、图像分析 等。
在各种应用场景中都可以看到PostgreSQL的应用:
PostgreSQL近年来的发展非常迅猛,从知名数据库评测网站dbranking的数据库评分趋势,可以看到PostgreSQL向上发展的趋势:
从每年PostgreSQL中国召开的社区会议,也能看到同样的趋势,参与的公司越来越多,分享的公司越来越多,分享的主题越来越丰富,横跨了 传统企业、互联网、医疗、金融、国企、物流、电商、社交、车联网、共享XX、云、游戏、公共交通、航空、铁路、军工、培训、咨询服务等 行业。
接下来的一系列文章,将给大家介绍PostgreSQL的各种应用场景以及对应的性能指标。
环境
环境部署方法参考:
《PostgreSQL 10 + PostGIS + Sharding(pg_pathman) + MySQL(fdw外部表) on ECS 部署指南(适合新用户)》
阿里云 ECS:56核,224G,1.5TB*2 SSD云盘
。
操作系统:CentOS 7.4 x64
数据库版本:PostgreSQL 10
PS:ECS的CPU和IO性能相比物理机会打一定的折扣,可以按下降1倍性能来估算。跑物理主机可以按这里测试的性能乘以2来估算。
场景 - 用户画像圈人场景 - 多个字段任意组合条件筛选与透视 (OLAP)
1、背景
用户画像表有多个字段,表示不同类型的标签属性,在进行人群圈选时,需要对任意字段的组合条件进行条件筛选,并对人群结果进行透视。
PostgreSQL 有3种方法实现多个字段的任意组合过滤。
1、布隆过滤,支持任意字段组合的等值查询。
《PostgreSQL 9.6 黑科技 bloom 算法索引,一个索引支撑任意列组合查询》
2、多索引 bitmap scan
gin复合索引,或者多个b-tree单列索引,都可以实现bitmap scan。
当输入多个条件时,过滤、收敛到更少的数据块,顺序扫描+FILTER。
《PostgreSQL bitmapAnd, bitmapOr, bitmap index scan, bitmap heap scan》
3、GIN复合索引 bitmap scan
当输入多个条件时,过滤、收敛到更少的数据块,顺序扫描+FILTER。
《宝剑赠英雄 - 任意组合字段等效查询, 探探PostgreSQL多列展开式B树 (GIN)》
2、设计
1亿条记录,每条记录包含32个标签字段,每个字段的标签取值范围1万。另外包含3个属性字段用于透视。
3、准备测试表
do language plpgsql $$
declare
sql text;
begin
sql := 'create table t_multi_col (id int8, c1 int default random()*100, c2 int default random()*10, c3 int default random()*10, ';
for i in 4..35 loop
sql := sql||'c'||i||' int default random()*10000,';
end loop;
sql := rtrim(sql, ',');
sql := sql||')';
execute sql;
end;
$$;
4、准备测试函数(可选)
5、准备测试数据
insert into t_multi_col (id) select generate_series(1,100000000);
1、布隆索引
create extension bloom;
do language plpgsql $$
declare
sql text;
begin
sql := 'create index idx_t_multi_col on t_multi_col using bloom (';
for i in 4..35 loop
sql := sql||'c'||i||',';
end loop;
sql := rtrim(sql, ',');
sql := sql||') with (length=80, ';
for i in 1..32 loop
sql := sql||'col'||i||'=2,';
end loop;
sql := rtrim(sql, ',');
sql := sql||')';
execute sql;
end;
$$;
2、GIN索引
create extension btree_gin;
do language plpgsql $$
declare
sql text;
begin
sql := 'create index idx_t_multi_col_gin on t_multi_col using gin (';
for i in 4..35 loop
sql := sql||'c'||i||',';
end loop;
sql := rtrim(sql, ',');
sql := sql||')';
execute sql;
end;
$$;
6、准备测试脚本
vi test.sql
\set a4 random(1,10000)
\set a5 random(1,10000)
\set a6 random(1,10000)
\set a7 random(1,10000)
\set a8 random(1,10000)
\set a9 random(1,10000)
select c1,c2,c3,count(*) from t_multi_col where c4=:a4 and c5=:a5 and c6=:a6 and c7=:a7 and c8=:a8 and c9=:a9 group by grouping sets ((c1),(c2),(c3));
7、测试
1、布隆索引,由于需要扫整个索引,耗时略高。500毫秒。
postgres=# explain (analyze,verbose,timing,costs,buffers) select c1,c2,c3,count(*) from t_multi_col where c4=3 and c5=2 and c6=1 and c7=4 and c8=5 and c9=6 and c10=1 and c11=1 and c12=1 group by grouping sets ((c1),(c2),(c3));
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------
HashAggregate (cost=2985297.24..2985297.28 rows=3 width=20) (actual time=499.961..499.961 rows=0 loops=1)
Output: c1, c2, c3, count(*)
Hash Key: t_multi_col.c1
Hash Key: t_multi_col.c2
Hash Key: t_multi_col.c3
Buffers: shared hit=197418
-> Bitmap Heap Scan on public.t_multi_col (cost=2985296.00..2985297.23 rows=1 width=12) (actual time=499.958..499.958 rows=0 loops=1)
Output: id, c1, c2, c3, c4, c5, c6, c7, c8, c9, c10, c11, c12, c13, c14, c15, c16, c17, c18, c19, c20, c21, c22, c23, c24, c25, c26, c27, c28, c29, c30, c31, c32, c33, c34, c35
Recheck Cond: ((t_multi_col.c4 = 3) AND (t_multi_col.c5 = 2) AND (t_multi_col.c6 = 1) AND (t_multi_col.c7 = 4) AND (t_multi_col.c8 = 5) AND (t_multi_col.c9 = 6) AND (t_multi_col.c10 = 1) AND (t_multi_col.c11 = 1) AND (t_multi_col.c12 = 1))
Rows Removed by Index Recheck: 1339
Heap Blocks: exact=1339
Buffers: shared hit=197418
-> Bitmap Index Scan on idx_t_multi_col (cost=0.00..2985296.00 rows=1 width=0) (actual time=497.718..497.718 rows=1339 loops=1)
Index Cond: ((t_multi_col.c4 = 3) AND (t_multi_col.c5 = 2) AND (t_multi_col.c6 = 1) AND (t_multi_col.c7 = 4) AND (t_multi_col.c8 = 5) AND (t_multi_col.c9 = 6) AND (t_multi_col.c10 = 1) AND (t_multi_col.c11 = 1) AND (t_multi_col.c12 = 1))
Buffers: shared hit=196079
Planning time: 0.165 ms
Execution time: 500.025 ms
(17 rows)
2、gin索引,精准定位,耗时2毫秒以内。
postgres=# explain (analyze,verbose,timing,costs,buffers) select c1,c2,c3,count(*) from t_multi_col where c4=3 and c5=2 and c6=1 and c7=4 and c8=5 and c9=6 and c10=1 and c11=1 and c12=1 group by grouping sets ((c1),(c2),(c3));
QUERY PLAN
--------------------------------------------------------------------------------------------------------------------------------
HashAggregate (cost=69.64..69.68 rows=3 width=20) (actual time=1.151..1.151 rows=0 loops=1)
Output: c1, c2, c3, count(*)
Hash Key: t_multi_col.c1
Hash Key: t_multi_col.c2
Hash Key: t_multi_col.c3
Buffers: shared hit=69
-> Bitmap Heap Scan on public.t_multi_col (cost=68.40..69.63 rows=1 width=12) (actual time=1.149..1.149 rows=0 loops=1)
Output: id, c1, c2, c3, c4, c5, c6, c7, c8, c9, c10, c11, c12, c13, c14, c15, c16, c17, c18, c19, c20, c21, c22, c23, c24, c25, c26, c27, c28, c29, c30, c31, c32, c33, c34, c35
Recheck Cond: ((t_multi_col.c4 = 3) AND (t_multi_col.c5 = 2) AND (t_multi_col.c6 = 1) AND (t_multi_col.c7 = 4) AND (t_multi_col.c8 = 5) AND (t_multi_col.c9 = 6) AND (t_multi_col.c10 = 1) AND (t_multi_col.c11 = 1) AND (t_multi_col.c12 = 1))
Buffers: shared hit=69
-> Bitmap Index Scan on idx_t_multi_col_gin (cost=0.00..68.40 rows=1 width=0) (actual time=1.146..1.146 rows=0 loops=1)
Index Cond: ((t_multi_col.c4 = 3) AND (t_multi_col.c5 = 2) AND (t_multi_col.c6 = 1) AND (t_multi_col.c7 = 4) AND (t_multi_col.c8 = 5) AND (t_multi_col.c9 = 6) AND (t_multi_col.c10 = 1) AND (t_multi_col.c11 = 1) AND (t_multi_col.c12 = 1))
Buffers: shared hit=69
Planning time: 0.263 ms
Execution time: 1.245 ms
(15 rows)
压测
CONNECTS=56
TIMES=300
export PGHOST=$PGDATA
export PGPORT=1999
export PGUSER=postgres
export PGPASSWORD=postgres
export PGDATABASE=postgres
pgbench -M prepared -n -r -f ./test.sql -P 5 -c $CONNECTS -j $CONNECTS -T $TIMES
8、测试结果
transaction type: ./test.sql
scaling factor: 1
query mode: prepared
number of clients: 56
number of threads: 56
duration: 300 s
number of transactions actually processed: 10740407
latency average = 1.564 ms
latency stddev = 0.561 ms
tps = 35796.375710 (including connections establishing)
tps = 35800.169989 (excluding connections establishing)
script statistics:
- statement latencies in milliseconds:
0.002 \set a4 random(1,10000)
0.000 \set a5 random(1,10000)
0.000 \set a6 random(1,10000)
0.000 \set a7 random(1,10000)
0.000 \set a8 random(1,10000)
0.000 \set a9 random(1,10000)
1.562 select c1,c2,c3,count(*) from t_multi_col where c4=:a4 and c5=:a5 and c6=:a6 and c7=:a7 and c8=:a8 and c9=:a9 group by grouping sets ((c1),(c2),(c3));
TPS: 35800
平均响应时间: 1.564 毫秒
实际上,除了BITMAPSCAN,还有一种存储层优化,目前PostgreSQL内部引擎为行存储引擎,通过插件支持列存储,列存储优化可以减少扫描的数据块的数量,提高性能。
参考
《PostgreSQL、Greenplum 应用案例宝典《如来神掌》 - 目录》
《PostgreSQL 使用 pgbench 测试 sysbench 相关case》
https://www.postgresql.org/docs/10/static/pgbench.html