PostgreSQL 10.0 preview 多核并行增强 - tuplesort 多核并行创建索引

本文涉及的产品
RDS PostgreSQL Serverless,0.5-4RCU 50GB 3个月
推荐场景:
对影评进行热评分析
RDS SQL Server Serverless,2-4RCU 50GB 3个月
推荐场景:
云数据库 RDS MySQL,集群系列 2核4GB
推荐场景:
搭建个人博客
简介:

标签

PostgreSQL , 10.0 , 并行增强 , 多核并行创建索引


背景

PostgreSQL 10.0的多核并行有了诸多增强,比如多核并行排序,可以用于提升创建btree索引的速度。

As some of you know, I've been working on parallel sort. I think I've  
gone as long as I can without feedback on the design (and I see that  
we're accepting stuff for September CF now), so I'd like to share what  
I came up with. This project is something that I've worked on  
inconsistently since late last year. It can be thought of as the  
Postgres 10 follow-up to the 9.6 work on external sorting.  

Attached WIP patch series:  

* Adds a parallel sorting capability to tuplesort.c.  

* Adds a new client of this capability: btbuild()/nbtsort.c can now  
create B-Trees in parallel.  

Most of the complexity here relates to the first item; the tuplesort  
module has been extended to support sorting in parallel. This is  
usable in principle by every existing tuplesort caller, without any  
restriction imposed by the newly expanded tuplesort.h interface. So,  
for example, randomAccess MinimalTuple support has been added,  
although it goes unused for now.  

I went with CREATE INDEX as the first client of parallel sort in part  
because the cost model and so on can be relatively straightforward.  
Even CLUSTER uses the optimizer to determine if a sort strategy is  
appropriate, and that would need to be taught about parallelism if its  
tuplesort is to be parallelized. I suppose that I'll probably try to  
get CLUSTER (with a tuplesort) done in the Postgres 10 development  
cycle too, but not just yet.  

For now, I would prefer to focus discussion on tuplesort itself. If  
you can only look at one part of this patch, please look at the  
high-level description of the interface/caller contract that was added  
to tuplesort.h.  

Performance  
===========  

Without further ado, I'll demonstrate how the patch series improves  
performance in one case. This benchmark was run on an AWS server with  
many disks. A d2.4xlarge instance was used, with 16 vCPUs, 122 GiB  
RAM, 12 x 2 TB HDDs, running Amazon Linux. Apparently, this AWS  
instance type can sustain 1,750 MB/second of I/O, which I was able to  
verify during testing (when a parallel sequential scan ran, iotop  
reported read throughput slightly above that for multi-second bursts).  
Disks were configured in software RAID0. These instances have disks  
that are optimized for sequential performance, which suits the patch  
quite well. I don't usually trust AWS EC2 for performance testing, but  
it seemed to work well here (results were pretty consistent).  

Setup:  

CREATE TABLE parallel_sort_test AS  
    SELECT hashint8(i) randint,  
    md5(i::text) collate "C" padding1,  
    md5(i::text || '2') collate "C" padding2  
    FROM generate_series(0, 1e9::bigint) i;  

CHECKPOINT;  

This leaves us with a parallel_sort_test table that is 94 GB in size.  

SET maintenance_work_mem = '8GB';  

-- Serial case (external sort, should closely match master branch):  
CREATE INDEX serial_idx ON parallel_sort_test (randint) WITH  
(parallel_workers = 0);  

Total time: 00:15:42.15  

-- Patch with 8 tuplesort "sort-and-scan" workers (leader process  
participates as a worker here):  
CREATE INDEX patch_8_idx ON parallel_sort_test (randint) WITH  
(parallel_workers = 7);  

Total time: 00:06:03.86  

这个patch的讨论,详见邮件组,本文末尾URL。

PostgreSQL社区的作风非常严谨,一个patch可能在邮件组中讨论几个月甚至几年,根据大家的意见反复的修正,patch合并到master已经非常成熟,所以PostgreSQL的稳定性也是远近闻名的。

参考

https://commitfest.postgresql.org/13/690/

https://www.postgresql.org/message-id/flat/CAM3SWZQKM=Pzc=CAHzRixKjp2eO5Q0Jg1SoFQqeXFQ647JiwqQ@mail.gmail.com#CAM3SWZQKM=Pzc=CAHzRixKjp2eO5Q0Jg1SoFQqeXFQ647JiwqQ@mail.gmail.com

相关实践学习
使用PolarDB和ECS搭建门户网站
本场景主要介绍基于PolarDB和ECS实现搭建门户网站。
阿里云数据库产品家族及特性
阿里云智能数据库产品团队一直致力于不断健全产品体系,提升产品性能,打磨产品功能,从而帮助客户实现更加极致的弹性能力、具备更强的扩展能力、并利用云设施进一步降低企业成本。以云原生+分布式为核心技术抓手,打造以自研的在线事务型(OLTP)数据库Polar DB和在线分析型(OLAP)数据库Analytic DB为代表的新一代企业级云原生数据库产品体系, 结合NoSQL数据库、数据库生态工具、云原生智能化数据库管控平台,为阿里巴巴经济体以及各个行业的企业客户和开发者提供从公共云到混合云再到私有云的完整解决方案,提供基于云基础设施进行数据从处理、到存储、再到计算与分析的一体化解决方案。本节课带你了解阿里云数据库产品家族及特性。
目录
相关文章
|
消息中间件 存储 关系型数据库
PostgreSQL技术大讲堂 - 第33讲:并行查询管理
PostgreSQL从小白到专家,技术大讲堂 - 第33讲:并行查询管理
474 1
|
关系型数据库 大数据 PostgreSQL
PostgreSQL16-新特性-并行聚合
PostgreSQL16-新特性-并行聚合
152 0
|
存储 SQL 关系型数据库
PostgreSQL插件HypoPG:支持虚拟索引
PostgreSQL插件HypoPG:支持虚拟索引
420 0
|
存储 缓存 关系型数据库
PostgreSQL 14新特性--减少索引膨胀
PostgreSQL 14新特性--减少索引膨胀
497 0
|
关系型数据库 PostgreSQL 索引
PostgreSQL通过索引获取heap tuple解析
PostgreSQL通过索引获取heap tuple解析
184 0
|
存储 SQL 关系型数据库
PostgreSQL的B-tree索引(下)
PostgreSQL的B-tree索引(下)
127 0
|
存储 算法 关系型数据库
PostgreSQL的B-tree索引(上)
PostgreSQL的B-tree索引
135 0
|
存储 SQL 人工智能
4 PostgreSQL 索引,全文检索,模糊匹配,近似度匹配(三)
4 PostgreSQL 索引,全文检索,模糊匹配,近似度匹配(三)
4 PostgreSQL 索引,全文检索,模糊匹配,近似度匹配(三)
|
SQL JSON 搜索推荐
认识 PostgreSQL 中与众不同的索引(一)|学习笔记
快速学习认识 PostgreSQL 中与众不同的索引(一)
285 0
认识 PostgreSQL 中与众不同的索引(一)|学习笔记
|
关系型数据库 分布式数据库 数据库
测试创建 PolarDB for PostgreSQL 数据库和连接数据库
测试创建 PolarDB for PostgreSQL 数据库和连接数据库
168 0
测试创建 PolarDB for PostgreSQL 数据库和连接数据库

相关产品

  • 云原生数据库 PolarDB
  • 云数据库 RDS PostgreSQL 版