|
1 | | -## PostgreSQL 统计信息(dbms_stats)导出,导入,锁定,替换 |
| 1 | +## PostgreSQL 并行计算解说 之28 - parallel CREATE INDEX CONCURRENTLY - 不堵塞读写 |
| 2 | + |
| 3 | +### 作者 |
| 4 | +digoal |
| 5 | + |
| 6 | +### 日期 |
| 7 | +2019-03-18 |
| 8 | + |
| 9 | +### 标签 |
| 10 | +PostgreSQL , cpu 并行 , smp 并行 , 并行计算 , gpu 并行 , 并行过程支持 |
| 11 | + |
| 12 | +---- |
| 13 | + |
| 14 | +## 背景 |
| 15 | +PostgreSQL 11 优化器已经支持了非常多场合的并行。简单估计,已支持27余种场景的并行计算。 |
| 16 | + |
| 17 | +``` |
| 18 | +parallel seq scan |
| 19 | + |
| 20 | +parallel index scan |
| 21 | + |
| 22 | +parallel index only scan |
| 23 | + |
| 24 | +parallel bitmap scan |
| 25 | + |
| 26 | +parallel filter |
| 27 | + |
| 28 | +parallel hash agg |
| 29 | + |
| 30 | +parallel group agg |
| 31 | + |
| 32 | +parallel cte |
| 33 | + |
| 34 | +parallel subquery |
| 35 | + |
| 36 | +parallel create table |
| 37 | + |
| 38 | +parallel create index |
| 39 | + |
| 40 | +parallel CREATE INDEX CONCURRENTLY - 不堵塞读写 |
| 41 | + |
| 42 | +parallel select into |
| 43 | + |
| 44 | +parallel CREATE MATERIALIZED VIEW |
| 45 | + |
| 46 | +parallel 排序 : gather merge |
| 47 | + |
| 48 | +parallel nestloop join |
| 49 | + |
| 50 | +parallel hash join |
| 51 | + |
| 52 | +parallel merge join |
| 53 | + |
| 54 | +parallel 自定义并行聚合 |
| 55 | + |
| 56 | +parallel 自定义并行UDF |
| 57 | + |
| 58 | +parallel append |
| 59 | + |
| 60 | +parallel append merge |
| 61 | + |
| 62 | +parallel union all |
| 63 | + |
| 64 | +parallel fdw table scan |
| 65 | + |
| 66 | +parallel partition join |
| 67 | + |
| 68 | +parallel partition agg |
| 69 | + |
| 70 | +parallel gather |
| 71 | + |
| 72 | +parallel gather merge |
| 73 | + |
| 74 | +parallel rc 并行 |
| 75 | + |
| 76 | +parallel rr 并行 |
| 77 | + |
| 78 | +parallel GPU 并行 |
| 79 | + |
| 80 | +parallel unlogged table |
| 81 | + |
| 82 | +lead parallel |
| 83 | +``` |
| 84 | + |
| 85 | +接下来进行一一介绍。 |
| 86 | + |
| 87 | +关键知识请先自行了解: |
| 88 | + |
| 89 | +1、优化器自动并行度算法 CBO |
| 90 | + |
| 91 | +[《PostgreSQL 9.6 并行计算 优化器算法浅析》](../201608/20160816_02.md) |
| 92 | + |
| 93 | +[《PostgreSQL 11 并行计算算法,参数,强制并行度设置》](../201812/20181218_01.md) |
| 94 | + |
| 95 | +## parallel CREATE INDEX CONCURRENTLY - 不堵塞读写 |
| 96 | +支持并行创建索引,并且不堵塞读写操作。 |
2 | 97 |
|
3 | | -### 作者 |
4 | | -digoal |
| 98 | +数据量:10亿 |
| 99 | + |
| 100 | +场景 | 数据量 | 关闭并行 | 开启并行 | 并行度 | 开启并行性能提升倍数 |
| 101 | +---|---|---|---|---|--- |
| 102 | +parallel CREATE INDEX CONCURRENTLY - 不堵塞读写 | 10亿 | 509.6 秒 | 355 秒 | 16 | 1.44 倍 |
| 103 | + |
| 104 | +``` |
| 105 | +drop table a1; |
| 106 | +create unlogged table a1(id int); |
| 107 | +insert into a1 select generate_series(1,1000000000); |
| 108 | +INSERT 0 1000000000 |
| 109 | +alter table a1 set (parallel_workers =16); |
| 110 | +vacuum analyze a1; |
| 111 | + |
| 112 | +set min_parallel_index_scan_size =0; |
| 113 | +set max_parallel_workers=64; |
| 114 | +set max_parallel_workers_per_gather =16; |
| 115 | +set max_parallel_maintenance_workers =16; |
| 116 | +set parallel_setup_cost =0; |
| 117 | +set parallel_tuple_cost =0; |
| 118 | +set maintenance_work_mem ='4GB'; |
| 119 | +set parallel_leader_participation=off; |
| 120 | +``` |
| 121 | + |
| 122 | +### 1、关闭并行,耗时: 509.6 秒。 |
| 123 | +``` |
| 124 | +postgres=# create index concurrently idx_a1_id on a1(id); |
| 125 | +CREATE INDEX |
| 126 | +Time: 509594.515 ms (08:29.595) |
| 127 | + |
| 128 | +创建索引时不影响读写 |
| 129 | + |
| 130 | +postgres=# select * from a1 where ctid='(1,5)'; |
| 131 | + id |
| 132 | +----- |
| 133 | + 231 |
| 134 | +(1 row) |
| 135 | + |
| 136 | +Time: 1.988 ms |
| 137 | + |
| 138 | +postgres=# insert into a1 values (0) returning ctid; |
| 139 | + ctid |
| 140 | +--------------- |
| 141 | + (4424778,176) |
| 142 | +(1 row) |
| 143 | + |
| 144 | +INSERT 0 1 |
| 145 | +Time: 0.650 ms |
| 146 | +postgres=# select * from a1 where ctid='(4424778,176)'; |
| 147 | + id |
| 148 | +---- |
| 149 | + 0 |
| 150 | +(1 row) |
| 151 | + |
| 152 | +Time: 0.427 ms |
| 153 | + |
| 154 | +postgres=# delete from a1 where ctid='(1,5)' returning xmin,xmax,cmin,cmax,ctid,*; |
| 155 | + xmin | xmax | cmin | cmax | ctid | id |
| 156 | +------------+------------+------+------+-------+----- |
| 157 | + 1328166328 | 1328166343 | 0 | 0 | (1,5) | 231 |
| 158 | +(1 row) |
| 159 | + |
| 160 | +DELETE 1 |
| 161 | +Time: 0.488 ms |
| 162 | +``` |
| 163 | + |
| 164 | +### 2、开启并行,耗时: 355 秒。 |
| 165 | + |
| 166 | +``` |
| 167 | +postgres=# create index concurrently idx_a1_id on a1(id); |
| 168 | +CREATE INDEX |
| 169 | +Time: 355070.593 ms (05:55.071) |
| 170 | + |
| 171 | +创建索引时不影响读写 |
| 172 | + |
| 173 | +postgres=# insert into a1 values (0); |
| 174 | +INSERT 0 1 |
| 175 | +postgres=# delete from a1 where ctid='(1,1)'; |
| 176 | +DELETE 1 |
| 177 | +postgres=# insert into a1 values (0); |
| 178 | +INSERT 0 1 |
| 179 | +Time: 0.376 ms |
| 180 | +postgres=# insert into a1 values (0) returning ctid; |
| 181 | + ctid |
| 182 | +--------------- |
| 183 | + (4424778,175) |
| 184 | +(1 row) |
| 185 | +INSERT 0 1 |
| 186 | +Time: 0.372 ms |
| 187 | +postgres=# delete from a1 where ctid='(4424778,175)'; |
| 188 | +DELETE 1 |
| 189 | +Time: 0.324 ms |
| 190 | +postgres=# select * from a1 where ctid='(1,2)'; |
| 191 | + id |
| 192 | +----- |
| 193 | + 228 |
| 194 | +(1 row) |
| 195 | +Time: 0.384 ms |
| 196 | +``` |
| 197 | + |
| 198 | +## 其他知识 |
| 199 | + |
| 200 | +1、优化器自动并行度算法 CBO |
| 201 | + |
| 202 | +[《PostgreSQL 9.6 并行计算 优化器算法浅析》](../201608/20160816_02.md) |
| 203 | + |
| 204 | +[《PostgreSQL 11 并行计算算法,参数,强制并行度设置》](../201812/20181218_01.md) |
| 205 | + |
| 206 | +2、function, op 识别是否支持parallel |
| 207 | + |
| 208 | +``` |
| 209 | +postgres=# select proparallel,proname from pg_proc; |
| 210 | + proparallel | proname |
| 211 | +-------------+---------------------------------------------- |
| 212 | + s | boolin |
| 213 | + s | boolout |
| 214 | + s | byteain |
| 215 | + s | byteaout |
| 216 | +``` |
| 217 | + |
| 218 | +3、subquery mapreduce unlogged table |
| 219 | + |
| 220 | +对于一些情况,如果期望简化优化器对非常非常复杂的SQL并行优化的负担,可以自己将SQL拆成几段,中间结果使用unlogged table保存,类似mapreduce的思想。unlogged table同样支持parallel 计算。 |
| 221 | + |
| 222 | +4、vacuum,垃圾回收并行。 |
| 223 | + |
| 224 | +5、dblink 异步调用并行 |
| 225 | + |
| 226 | +[《PostgreSQL VOPS 向量计算 + DBLINK异步并行 - 单实例 10亿 聚合计算跑进2秒》](../201802/20180210_01.md) |
| 227 | + |
| 228 | +[《PostgreSQL 相似搜索分布式架构设计与实践 - dblink异步调用与多机并行(远程 游标+记录 UDF实例)》](../201802/20180205_03.md) |
| 229 | + |
| 230 | +[《PostgreSQL dblink异步调用实现 并行hash分片JOIN - 含数据交、并、差 提速案例 - 含dblink VS pg 11 parallel hash join VS pg 11 智能分区JOIN》](../201802/20180201_02.md) |
| 231 | + |
| 232 | +暂时不允许并行的场景(将来PG会继续扩大支持范围): |
| 233 | + |
| 234 | +1、修改行,锁行,除了create table as , select into, create mview这几个可以使用并行。 |
| 235 | + |
| 236 | +2、query 会被中断时,例如cursor , loop in PL/SQL ,因为涉及到中间处理,所以不建议开启并行。 |
| 237 | + |
| 238 | +3、paralle unsafe udf ,这种UDF不会并行 |
| 239 | + |
| 240 | +4、嵌套并行(udf (内部query并行)),外部调用这个UDF的SQL不会并行。(主要是防止large parallel workers ) |
| 241 | + |
| 242 | +5、SSI 隔离级别 |
| 243 | + |
| 244 | +## 参考 |
| 245 | +https://www.postgresql.org/docs/11/parallel-plans.html |
| 246 | + |
| 247 | +[《PostgreSQL 11 并行计算算法,参数,强制并行度设置》](../201812/20181218_01.md) |
| 248 | + |
| 249 | +[《PostgreSQL 11 preview - 并行计算 增强 汇总》](../201805/20180519_02.md) |
| 250 | + |
| 251 | +[《PostgreSQL 10 自定义并行计算聚合函数的原理与实践 - (含array_agg合并多个数组为单个一元数组的例子)》](../201801/20180119_04.md) |
| 252 | + |
| 253 | +[《PostgreSQL 9.6 并行计算 优化器算法浅析》](../201608/20160816_02.md) |
| 254 | + |
| 255 | + |
| 256 | +<a rel="nofollow" href="http://info.flagcounter.com/h9V1" ><img src="http://s03.flagcounter.com/count/h9V1/bg_FFFFFF/txt_000000/border_CCCCCC/columns_2/maxflags_12/viewers_0/labels_0/pageviews_0/flags_0/" alt="Flag Counter" border="0" ></a> |
| 257 | + |
| 258 | + |
| 259 | +## [digoal's 大量PostgreSQL文章入口](https://github.com/digoal/blog/blob/master/README.md "22709685feb7cab07d30f30387f0a9ae") |
| 260 | + |
| 261 | + |
| 262 | +## [免费领取阿里云RDS PostgreSQL实例、ECS虚拟机](https://free.aliyun.com/ "57258f76c37864c6e6d23383d05714ea") |
5 | 263 | |
6 | | -### 日期 |
7 | | -2019-03-18 |
8 | | - |
9 | | -### 标签 |
10 | | -PostgreSQL , 统计信息 , 优化器 , dbms_stats , stats , 锁定 |
11 | | - |
12 | | ----- |
13 | | - |
14 | | -## 背景 |
15 | | -PostgreSQL 插件pg_dbms_stats插件,可以将统计信息导出,导入(锁定到内存),并且修改PLANNER的行为(从元数据pg_stats中读取改成从dbms_stats中读取统计信息)。从而达到统计信息的导出,锁定目的。 |
16 | | - |
17 | | -pg_dbms_stats govern to hold and provide statistical information to generate execution plan, instead of statistic generated by ANALYZE. To use statistical information can be done by either of following ways. |
18 | | - |
19 | | -Lock the current statistic. |
20 | | - |
21 | | -Restore from backup. |
22 | | - |
23 | | -Use save in exported file. |
24 | | - |
25 | | -pg_dbms_stats manages its own statistics in some table/file groups. |
26 | | - |
27 | | -Currently valid statistics |
28 | | - |
29 | | -Statistics planner looking via pg_dbms_stats currently. It can be edit and turned back in production static information, also can be included in OS file backup. |
30 | | - |
31 | | -Backup statistic |
32 | | - |
33 | | -Statistical information can be backup any point of time and hold multiple version of statistics. Backup history is maintained in the history table. In restore feature uses to replaces with valid statistics. |
34 | | - |
35 | | -Statistic that have been exported |
36 | | - |
37 | | -This can be used to export Statistical information to save on OS file system. By changing name of file can be hold the multiple version of Statistics. Same import feature used to load valid statistical information. |
38 | | - |
39 | | -pg_dbms_stats provide its own function, it does not change original PostgreSQL statistics(pg_catalog.pg_class and pg_catalog.pg_statistic). |
40 | | - |
41 | | - |
42 | | - |
43 | | -https://github.com/ossc-db/pg_dbms_stats |
44 | | - |
45 | | -## 参考 |
46 | | -http://pgdbmsstats.osdn.jp/pg_dbms_stats-en.html |
47 | | - |
48 | | -https://github.com/ossc-db |
49 | | - |
50 | | -[《PostgreSQL 统计信息pg_statistic格式及导入导出dump_stat - 兼容Oracle》](../201710/20171030_02.md) |
51 | | - |
52 | | -[《PostgreSQL pg_stat_ pg_statio_ 统计信息(scan,read,fetch,hit)源码解读》](../201610/20161018_03.md) |
53 | | - |
54 | | - |
55 | | - |
56 | | -<a rel="nofollow" href="http://info.flagcounter.com/h9V1" ><img src="http://s03.flagcounter.com/count/h9V1/bg_FFFFFF/txt_000000/border_CCCCCC/columns_2/maxflags_12/viewers_0/labels_0/pageviews_0/flags_0/" alt="Flag Counter" border="0" ></a> |
57 | | - |
58 | | - |
59 | | -## [digoal's 大量PostgreSQL文章入口](https://github.com/digoal/blog/blob/master/README.md "22709685feb7cab07d30f30387f0a9ae") |
60 | | - |
61 | | - |
62 | | -## [免费领取阿里云RDS PostgreSQL实例、ECS虚拟机](https://free.aliyun.com/ "57258f76c37864c6e6d23383d05714ea") |
63 | | - |
|
0 commit comments