|
| 1 | +## 最受开发者欢迎的HTAP数据库PostgreSQL 10特性 |
| 2 | + |
| 3 | +### 作者 |
| 4 | +digoal |
| 5 | + |
| 6 | +### 日期 |
| 7 | +2017-10-29 |
| 8 | + |
| 9 | +### 标签 |
| 10 | +PostgreSQL , 10 , 特性 , 开发者 |
| 11 | + |
| 12 | +---- |
| 13 | + |
| 14 | +## 背景 |
| 15 | +作为一款HTAP数据库(同时支持 "OLTP高并发在线事务处理" 与 "OLAP在线分析" 业务场景),PostgreSQL 10的哪些特性是开发人员、DBA、架构师都喜欢的呢? |
| 16 | + |
| 17 | +## 多核并行增强 |
| 18 | +9.6的版本支持如下并行: |
| 19 | + |
| 20 | +``` |
| 21 | +Sequential scans |
| 22 | +Aggregates |
| 23 | +Hash and loop joins |
| 24 | +``` |
| 25 | + |
| 26 | +10 并行增强: |
| 27 | + |
| 28 | +``` |
| 29 | +1、通过 max_parallel_workers 控制最大并行度, |
| 30 | + |
| 31 | +可以避免分析型SQL把资源全部耗光。从而支持HTAP混合型业务。 |
| 32 | + |
| 33 | +2、新增的并行索引扫描 |
| 34 | + |
| 35 | +Regular index scans (btree) |
| 36 | + |
| 37 | +Index Only scans (btree) |
| 38 | + |
| 39 | +Bitmap Heap Scan |
| 40 | + |
| 41 | +Index still scanned serially |
| 42 | + |
| 43 | +3、并行的合并JOIN |
| 44 | + |
| 45 | +Merge joins |
| 46 | + |
| 47 | +4、多表扫描(append scan)支持并行排序 |
| 48 | + |
| 49 | +Merge Sort |
| 50 | +``` |
| 51 | + |
| 52 | +## fdw 聚合下推 |
| 53 | +FDW聚合下推,使得PostgreSQL 10可以作为一个任意数据库的sharding管理节点,用于分发路由SQL,支持where, sort, join, select-clause, agg等下推。 |
| 54 | + |
| 55 | + |
| 56 | + |
| 57 | + |
| 58 | + |
| 59 | +## 逻辑订阅 |
| 60 | +逻辑订阅有很多用途: |
| 61 | + |
| 62 | +1、迁移、大版本升级 |
| 63 | + |
| 64 | + |
| 65 | + |
| 66 | +2、数仓聚合 |
| 67 | + |
| 68 | + |
| 69 | + |
| 70 | +3、拆库 |
| 71 | + |
| 72 | + |
| 73 | + |
| 74 | +4、多个业务系统共享、分发数据 |
| 75 | + |
| 76 | + |
| 77 | + |
| 78 | +5、多master架构 |
| 79 | + |
| 80 | +## 分区 |
| 81 | +内置的分区功能,不需要依赖插件。 |
| 82 | + |
| 83 | +[《PostgreSQL 10 内置分区 vs pg_pathman perf profiling》](../201710/20171015_01.md) |
| 84 | + |
| 85 | +[《PostgreSQL 10.0 preview 功能增强 - 内置分区表》](../201612/20161215_01.md) |
| 86 | + |
| 87 | +## libpq支持failover和load balance |
| 88 | +libpq支持配置多个连接地址,同时支持failover和负载均衡。 |
| 89 | + |
| 90 | +[《PostgreSQL 10.0 preview 功能增强 - libpq支持多主机连接(failover,LB)让数据库HA和应用配合更紧密》](../201704/20170420_01.md) |
| 91 | + |
| 92 | +## 事务状态可查询 |
| 93 | +用户可以根据事务号,查询事务的状态。实现业务层的控制,包括闪回等功能。 |
| 94 | + |
| 95 | +[《PostgreSQL flashback(闪回) 功能实现与介绍》](../201710/20171010_01.md) |
| 96 | + |
| 97 | +[《PostgreSQL 10.0 preview 功能增强 - 更强可靠性, 过去式事务状态可查(杜绝unknown事务)》](../201704/20170420_06.md) |
| 98 | + |
| 99 | +## 任意多副本同步 - 金融级可靠性 |
| 100 | +用户可以根据事务的重要性,选择需要落几个副本(WAL),从而实现多副本持久化。 |
| 101 | + |
| 102 | +[《PG多节点(quorum based), 0丢失 HA(failover,switchover)方案》](../201706/20170612_02.md) |
| 103 | + |
| 104 | +## 自定义多列混合统计信息 |
| 105 | +[《PostgreSQL 10 黑科技 - 自定义统计信息》](../201709/20170902_02.md) |
| 106 | + |
| 107 | +统计信息可以用于评估SQL的执行成本、查看数据分布、估算唯一值、估算记录数、查看数据存储的相关性 等。默认情况下,数据库的柱状图是单列的,当输入多列条件时,使用多列统计信息,可以估算更加精确的成本。实现更精准的执行计划。 |
| 108 | + |
| 109 | +## hash index增强(持久化、性能) |
| 110 | +PostgreSQL 10 hash index支持持久化(写WAL),同时在vacuum, 查询性能等方面都有巨大的优化。如果是等值查询,或者超长列,使用hash index可以获得比btree更好的性能。 |
| 111 | + |
| 112 | +## 重命名枚举值 |
| 113 | +是的,枚举值可以rename了。 |
| 114 | + |
| 115 | +## JSON,JSONB全文检索 |
| 116 | +JSON, JSONB类型,支持全文检索。 |
| 117 | + |
| 118 | +The functions ts_headline() and to_tsvector() can now be used on these data types. |
| 119 | + |
| 120 | +## file_fdw支持命令行返回值作为源 |
| 121 | +file_fdw是一个文件外部表接口,用于将文件作为外部表数据源来使用,现在,file_fdw支持command的输出结果作为外部表的输入源了。 |
| 122 | + |
| 123 | +``` |
| 124 | +CREATE FOREIGN TABLE |
| 125 | +test(a int, b text) |
| 126 | +SERVER csv |
| 127 | +OPTIONS (program 'gunzip -c /tmp/data.csv.gz'); |
| 128 | +``` |
| 129 | + |
| 130 | +## 不依赖OS层的通用全球化支持 - ICU库 |
| 131 | +编译时,使用ICU |
| 132 | + |
| 133 | +--with-icu |
| 134 | +Build with support for the ICU library. |
| 135 | +This requires the ICU4C package to be installed. |
| 136 | +The minimum required version of ICU4C is currently 4.2. |
| 137 | + |
| 138 | +By default, pkg-config will be used to find the required compilation options. |
| 139 | +This is supported for ICU4C version 4.6 and later. |
| 140 | +For older versions, or if pkg-config is not available, |
| 141 | +the variables ICU_CFLAGS and ICU_LIBS can be specified to configure, like in this example: |
| 142 | + |
| 143 | +./configure ... --with-icu ICU_CFLAGS='-I/some/where/include' ICU_LIBS='-L/some/where/lib -licui18n -licuuc -licudata' |
| 144 | + |
| 145 | +(If ICU4C is in the default search path for the compiler, |
| 146 | +then you still need to specify a nonempty string in order to avoid use of pkg-config, |
| 147 | +for example, ICU_CFLAGS=' '.) |
| 148 | + |
| 149 | +例子 |
| 150 | + |
| 151 | +``` |
| 152 | +SELECT * FROM t ORDER BY a COLLATE "sv-SE-x-icu"; |
| 153 | +valle |
| 154 | +vera |
| 155 | +walle |
| 156 | +wera |
| 157 | + |
| 158 | +SELECT * FROM t ORDER BY a COLLATE "sv-SE-u-co-standard-x-icu"; |
| 159 | +valle |
| 160 | +walle |
| 161 | +vera |
| 162 | +wera |
| 163 | +``` |
| 164 | + |
| 165 | +## scram-sha-256 安全认证 |
| 166 | +[《PostgreSQL 10.0 preview 安全增强 - SASL认证方法 之 scram-sha-256 安全认证机制》](../201703/20170309_01.md) |
| 167 | + |
| 168 | +## 监控角色 |
| 169 | +新增了一些内置的监控角色,不需要使用SUPERUSER,只要给了这些角色,就可以获得读一些系统表的权限,或者获得杀会话的权限。 |
| 170 | + |
| 171 | +便于管理,提高了安全性。 |
| 172 | + |
| 173 | +``` |
| 174 | +postgres=# select * from pg_roles ; |
| 175 | + rolname | rolsuper | rolinherit | rolcreaterole | rolcreatedb | rolcanlogin | rolreplication | rolconnlimit | rolpassword | rolvaliduntil | rolbypassrls | rolconfig | oid |
| 176 | +----------------------+----------+------------+---------------+-------------+-------------+----------------+--------------+-------------+---------------+--------------+-----------+------- |
| 177 | + pg_signal_backend | f | t | f | f | f | f | -1 | ******** | | f | | 4200 |
| 178 | + pg_read_all_stats | f | t | f | f | f | f | -1 | ******** | | f | | 3375 |
| 179 | + pg_monitor | f | t | f | f | f | f | -1 | ******** | | f | | 3373 |
| 180 | + pg_read_all_settings | f | t | f | f | f | f | -1 | ******** | | f | | 3374 |
| 181 | + pg_stat_scan_tables | f | t | f | f | f | f | -1 | ******** | | f | | 3377 |
| 182 | +``` |
| 183 | + |
| 184 | +## 动态视图增强 - 添加系统进程的状态监控 |
| 185 | + |
| 186 | +``` |
| 187 | +postgres=# select pid,backend_type,wait_event_type,wait_event from pg_stat_activity ; |
| 188 | + pid | backend_type | wait_event_type | wait_event |
| 189 | +-------+---------------------+-----------------+--------------------- |
| 190 | + 2077 | background worker | Activity | LogicalLauncherMain |
| 191 | + 2074 | autovacuum launcher | Activity | AutoVacuumMain |
| 192 | + 15397 | client backend | | |
| 193 | + 2072 | background writer | Activity | BgWriterMain |
| 194 | + 2071 | checkpointer | Activity | CheckpointerMain |
| 195 | + 2073 | walwriter | Activity | WalWriterMain |
| 196 | +(6 rows) |
| 197 | +``` |
| 198 | + |
| 199 | +## 等待事件 |
| 200 | +https://www.postgresql.org/docs/10/static/monitoring-stats.html#monitoring-stats-views |
| 201 | + |
| 202 | +新增了一些等待事件。 |
| 203 | + |
| 204 | +``` |
| 205 | +Latches |
| 206 | +Extensions |
| 207 | +Client/socket |
| 208 | +Timeout |
| 209 | +... |
| 210 | + |
| 211 | +I/O events |
| 212 | +Reads |
| 213 | +Writes |
| 214 | +Individually identified |
| 215 | +``` |
| 216 | + |
| 217 | +## IDENTITY列 |
| 218 | +实际上就是自增列,兼容SQL Server。PG原有的serial, default sequence都可以实现类似的功能。 |
| 219 | + |
| 220 | +[《PostgreSQL 10 新特性 - identity column (serial, 自增)》](../201710/20171029_02.md) |
| 221 | + |
| 222 | +## XMLTABLE |
| 223 | +https://www.postgresql.org/docs/current/static/functions-xml.html#functions-xml-processing-xmltable |
| 224 | + |
| 225 | +xml的支持更加强大了。xmltable可以将XML解析为一张表输出。 |
| 226 | + |
| 227 | + |
| 228 | +``` |
| 229 | +CREATE TABLE xmldata AS SELECT |
| 230 | +xml $$ |
| 231 | +<ROWS> |
| 232 | + <ROW id="1"> |
| 233 | + <COUNTRY_ID>AU</COUNTRY_ID> |
| 234 | + <COUNTRY_NAME>Australia</COUNTRY_NAME> |
| 235 | + </ROW> |
| 236 | + <ROW id="5"> |
| 237 | + <COUNTRY_ID>JP</COUNTRY_ID> |
| 238 | + <COUNTRY_NAME>Japan</COUNTRY_NAME> |
| 239 | + <PREMIER_NAME>Shinzo Abe</PREMIER_NAME> |
| 240 | + <SIZE unit="sq_mi">145935</SIZE> |
| 241 | + </ROW> |
| 242 | + <ROW id="6"> |
| 243 | + <COUNTRY_ID>SG</COUNTRY_ID> |
| 244 | + <COUNTRY_NAME>Singapore</COUNTRY_NAME> |
| 245 | + <SIZE unit="sq_km">697</SIZE> |
| 246 | + </ROW> |
| 247 | +</ROWS> |
| 248 | +$$ AS data; |
| 249 | + |
| 250 | +SELECT xmltable.* |
| 251 | + FROM xmldata, |
| 252 | + XMLTABLE('//ROWS/ROW' |
| 253 | + PASSING data |
| 254 | + COLUMNS id int PATH '@id', |
| 255 | + ordinality FOR ORDINALITY, |
| 256 | + "COUNTRY_NAME" text, |
| 257 | + country_id text PATH 'COUNTRY_ID', |
| 258 | + size_sq_km float PATH 'SIZE[@unit = "sq_km"]', |
| 259 | + size_other text PATH |
| 260 | + 'concat(SIZE[@unit!="sq_km"], " ", SIZE[@unit!="sq_km"]/@unit)', |
| 261 | + premier_name text PATH 'PREMIER_NAME' DEFAULT 'not specified') ; |
| 262 | + |
| 263 | + id | ordinality | COUNTRY_NAME | country_id | size_sq_km | size_other | premier_name |
| 264 | +----+------------+--------------+------------+------------+--------------+--------------- |
| 265 | + 1 | 1 | Australia | AU | | | not specified |
| 266 | + 5 | 2 | Japan | JP | | 145935 sq_mi | Shinzo Abe |
| 267 | + 6 | 3 | Singapore | SG | 697 | | not specified |
| 268 | +``` |
| 269 | + |
| 270 | +## 流式物理备库支持snapshot |
| 271 | +备库支持快照,意味着可以在备库创建一致性的并行任务,比如pg_dump在备库可以支持并行备份。 |
| 272 | + |
| 273 | + |
| 274 | +## 排序性能优化 |
| 275 | + |
| 276 | +## 语句级触发器支持transition tables |
| 277 | +支持transition tables,在AFTER语句级触发器中,通过这个transition tables,可以得到语句中触及的所有行。 |
| 278 | + |
| 279 | +方便批处理,提高性能。 |
| 280 | + |
| 281 | +``` |
| 282 | + AFTER trigger transition tables |
| 283 | +``` |
| 284 | + |
| 285 | +[《PostgreSQL 10.0 preview 功能增强 - 触发器函数内置中间表》](../201704/20170401_01.md) |
| 286 | + |
| 287 | +## 参考 |
| 288 | +1、PostgreSQL 特性全矩阵 |
| 289 | + |
| 290 | +https://www.postgresql.org/about/featurematrix/ |
| 291 | + |
| 292 | +2、PostgreSQL 特性矩阵 |
| 293 | + |
| 294 | +http://www.cybertec.at/best-of-postgresql-10-for-the-developer/ |
| 295 | + |
| 296 | +3、[《PostgreSQL 10 解读》](../201705/20170509_01.md) |
| 297 | + |
| 298 | +4、[Major Features: Postgres 10](20171029_01_pdf_001.pdf) |
| 299 | + |
| 300 | +5、[A look at the Elephants Trunk - PostgreSQL 10](20171029_01_pdf_002.pdf) |
| 301 | + |
| 302 | +6、[PostgreSQL 10 New Features With Examples](20171029_01_pdf_003.pdf) |
| 303 | + |
| 304 | +7、https://www.postgresql.org/about/press/presskit10/ |
| 305 | + |
| 306 | +8、https://wiki.postgresql.org/wiki/New_in_postgres_10 |
0 commit comments