性能增强

大量连接高并发优化

  • 场景: SaaS场景,微服务架构下的中心库场景
  • 业务特点:客户端多,在线用户多,数据库并发连接非常多
  • 价值: 比连接池网络少1跳, 性能更好, 支持绑定变量等连接池会话模式不支持的全部功能

索引增强

  1. 缓解高频更新负载下的btree索引膨胀
    • 场景: 数据频繁更新,如游戏、交易、共享出行、IoT等行业
    • 价值: 减少膨胀, 降低存储和内存使用率, 提高效率
  2. 支持sort接口, 大幅提升Create GiST和SP-GiST索引的速度
    • 场景: 地理信息、物联网、共享出行等使用了地理信息、JSON、range等数据类型的业务
    • 价值: GiST和SP-GiST索引创建速度提升一个数量级
  3. 支持SP-GiST覆盖索引功能满足任意维度聚集存储
    • 场景: 地理信息、物联网、共享出行等使用了地理信息、JSON、range等数据类型的业务
    • 价值: 将value集成到索引叶子结点, 减少block扫描, 提高基于空间、JSON、range的范围搜索的响应速度
    • DEMO:
  1. create index idx_tbl_1 on tbl using spgist (gis) include (col1,col2); -- 叶子结点加入col1,col2内容
  2. select col1,col2,gis from tbl where gis xx; -- VM clearly heap page 可以不需要回表, 提高性能
  1. BRIN索引支持布隆过滤和 multi range
    • 场景: 时序类场景,如IoT行业
    • 价值: 提高BRIN索引的过滤精度, 减少返回的block数,通过布隆过滤器支持任意字段组合条件过滤

并行计算增强

  1. 并行顺序扫描支持chunk
    • 场景: 数据分析类业务
    • 价值: 大IO利用prefetch能力大幅提升顺序IO扫描吞吐性能, 解决小IO无法打满块设备吞吐指标的问题。提高大范围数据扫描的IO吞吐, 逼近块设备IO吞吐极限
  2. PL/pgSQL RETURN QUERY支持并行计算
    • 场景: 数据分析类业务
    • 价值: 在PL/pgSQL函数内使用return query返回结果时支持query的并行计算来提升性能
    • DEMO:
  1. create or replace function xx.... return query select xx from xx ... -- 这里到select xx query可以支持并行计算
  1. 刷新物化事务支持并行计算
    • 场景: 预计算场景,如数据分析类业务
    • 价值: 物化视图的刷新支持并行计算, 大幅度提高刷新速度
    • DEMO:
  1. REFRESH MATERIALIZED VIEW [ CONCURRENTLY ] name -- 支持并行计算

内置sharding功能接口,postgres_fdw 持续增强

  1. 支持外部表异步并行计算
    • 场景: sharding分库分表的数据分析场景, 多个实例或sharding分片的数据需要并行分析的场景
    • 价值: 提高多个实例并行计算的效率
    • DEMO:
  1. create foreign table ft1 AT Server1;
  2. ...
  3. create foreign table ftn AT ServerN;
  4. create partition table tbl partition by ....
  5. alter table ft1 attach to tbl ...
  6. ...
  7. alter table ftn attach to tbl ...
  8. select count(*),avg(x),max(x)... from tbl group by xxxx -- 支持NServer同时计算.
  1. 远程分区表的子分区可以import foreign schema生成外部表
    • 场景: sharding分库分表
    • 价值: 简化一键生成shard的步骤, 同时支持按分区生成shard
    • DEMO:
  1. IMPORT FOREIGN SCHEMA remote_schema
  2. [ { LIMIT TO | EXCEPT } ( table_name [, ...] ) ] table_name -- 支持子分区.
  1. 支持truncate外部表
    • 场景: sharding分库分表
    • 价值: 支持更丰富的语法, truncate清理远程不产生redo, 更快
    • DEMO:
  1. truncate 外部表;
  1. 支持会话级持久化foreign server连接
    • 场景: sharding 分库分表
    • 价值: 提高sharding场景的OLTP性能 (以往的版本每一个远程事务都需要重新创建一次远程库连接, 无法支持OLTP高频小事务)

分区表性能趋近完美

  1. 分区裁剪能力提升减少子分区subplan和重复的cached plans
    • 场景: 大数据量, 使用了分区表, 分区表高频操作, OLTP类业务场景
    • 价值: 减少内存使用, 同时大幅提升涉及少量分区的SQL性能
  2. 增减分区时使用alter table detach|attach PARTITION concurrently模式完全避免锁冲突
    • 场景: 核心在线业务
    • 价值: 绑定和解绑分区支持无锁操作, 消除加减分区对在线业务的影响

DEMO:

  1. ALTER TABLE [ IF EXISTS ] name
  2. DETACH PARTITION partition_name [ CONCURRENTLY | FINALIZE ]

大表 search IN ( consts ) 优化

  • 场景: SaaS业务, 电商, 社交等场景
  • 业务特点:IN的输入条件很多导致IN过滤慢
  • 价值: 支持 linear search TO hash table probe,提高IN语句的处理性能, 在条件多、被过滤掉的数据量大的SQL中性能提升非常明显
  • DEMO:
  1. select x from tbl where id in (1,2,3,4,5,6,7,8,9);

TOAST 支持 lz4 压缩算法

  • 场景: 通用业务
  • 价值: 提高压缩性能
  • DEMO:
  1. CREATE TABLE cmdata(f1 text COMPRESSION pglz);
  2. CREATE INDEX idx ON cmdata(f1);
  3. INSERT INTO cmdata VALUES(repeat('1234567890', 1000));
  4. \d+ cmdata
  5. Table "public.cmdata"
  6. Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
  7. --------+------+-----------+----------+---------+----------+-------------+--------------+-------------
  8. f1 | text | | | | extended | pglz | |
  9. Indexes:
  10. "idx" btree (f1)
  11. CREATE TABLE cmdata1(f1 TEXT COMPRESSION lz4);
  12. INSERT INTO cmdata1 VALUES(repeat('1234567890', 1004));
  13. \d+ cmdata1
  14. Table "public.cmdata1"
  15. Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
  16. --------+------+-----------+----------+---------+----------+-------------+--------------+-------------
  17. f1 | text | | | | extended | lz4 | |

注意:如果要使用 lz4 压缩,则 PostgreSQL 编译时需要带上--with-lz4选项

引入管道查询模式

  • 场景: 时序、IoT类、日志appendonly类业务
  • 业务特点:跨网段、跨公网的业务与数据库网络访问延时较高的场景, 同时有较大的写入吞吐需求
  • 价值: 提高网络环境较差的数据写入吞吐, 可以达到接近本地网络的数据写入吞吐性能。在高延迟网络连接,或是有频繁更新操作(INSERT/UPDATE/DELETE)的负载场景下,大幅提升系统性能

安全增强

新增 pg_read_all_data 和 pg_write_all_data 角色

  • 场景: 通用场景
  • 价值: 支持一次性赋予tables/views/sequences对象的读、写权限,支持只读角色, 只写角色,提高DBA管理效率
  • DEMO:
  1. postgres=# select * from pg_roles ;
  2. rolname | rolsuper | rolinherit | rolcreaterole | rolcreatedb | rolcanlogin | rolreplication | rolconnlimit | rolpassword | rolvaliduntil | rolbypassrls | rolconfig | oid
  3. ---------------------------+----------+------------+---------------+-------------+-------------+----------------+--------------+-------------+---------------+--------------+-----------+------
  4. postgres | t | t | t | t | t | t | -1 | ******** | | t | | 10
  5. pg_database_owner | f | t | f | f | f | f | -1 | ******** | | f | | 6171
  6. pg_read_all_data | f | t | f | f | f | f | -1 | ******** | | f | | 6181
  7. pg_write_all_data | f | t | f | f | f | f | -1 | ******** | | f | | 6182
  8. pg_monitor | f | t | f | f | f | f | -1 | ******** | | f | | 3373
  9. pg_read_all_settings | f | t | f | f | f | f | -1 | ******** | | f | | 3374
  10. pg_read_all_stats | f | t | f | f | f | f | -1 | ******** | | f | | 3375
  11. pg_stat_scan_tables | f | t | f | f | f | f | -1 | ******** | | f | | 3377
  12. pg_read_server_files | f | t | f | f | f | f | -1 | ******** | | f | | 4569
  13. pg_write_server_files | f | t | f | f | f | f | -1 | ******** | | f | | 4570
  14. pg_execute_server_program | f | t | f | f | f | f | -1 | ******** | | f | | 4571
  15. pg_signal_backend | f | t | f | f | f | f | -1 | ******** | | f | | 4200
  16. (12 rows)
  17. -- 创建全局只读,全局只写用户
  18. postgres=# create user global_read_only password '******';
  19. CREATE ROLE
  20. postgres=# create user global_write_only password '******';
  21. CREATE ROLE
  22. -- 授权
  23. postgres=# grant pg_read_all_data to global_read_only ;
  24. GRANT ROLE
  25. postgres=# grant pg_write_all_data to global_write_only ;
  26. GRANT ROLE
  27. -- 全局只读用户只有只读权限
  28. postgres=# \c - global_read_only
  29. Password for user global_read_only:
  30. psql (12.4, server 14.1)
  31. WARNING: psql major version 12, server major version 14.
  32. Some psql features might not work.
  33. You are now connected to database "postgres" as user "global_read_only".
  34. postgres=> select * from employees limit 1;
  35. employee_id | full_name | manager_id
  36. -------------+---------------+------------
  37. 1 | Michael North |
  38. (1 row)
  39. postgres=> insert into employees (employee_id, full_name, manager_id) values(22, 'xgq', 2);
  40. ERROR: permission denied for table employees
  41. -- 全局只写用户只有只写权限
  42. postgres=> \c - global_write_only ;
  43. Password for user global_write_only:
  44. psql (12.4, server 14.1)
  45. WARNING: psql major version 12, server major version 14.
  46. Some psql features might not work.
  47. You are now connected to database "postgres" as user "global_write_only".
  48. postgres=> select * from employees limit 1;
  49. ERROR: permission denied for table employees
  50. postgres=> insert into employees (employee_id, full_name, manager_id) values(22, 'xgq', 2);
  51. INSERT 0 1

默认使用 SCRAM-SHA-256 认证方法

  • 场景: 通用场景
  • 价值: 完全规避md5可能的密钥泄露和协议攻击问题,提高认证方式和密码认证安全性
  • DEMO:
  1. postgres=> select * from pg_settings where name='password_encryption';
  2. -[ RECORD 1 ]---+------------------------------------------------
  3. name | password_encryption
  4. setting | md5
  5. unit |
  6. category | Connections and Authentication / Authentication
  7. short_desc | Chooses the algorithm for encrypting passwords.
  8. extra_desc |
  9. context | user
  10. vartype | enum
  11. source | configuration file
  12. min_val |
  13. max_val |
  14. enumvals | {md5,scram-sha-256}
  15. boot_val | scram-sha-256
  16. reset_val | md5
  17. sourcefile |
  18. sourceline |
  19. pending_restart | f

注意:较旧的客户端库不支持 SCRAM-SHA-256认证,会有类似报错psycopg2.OperationalError: authentication method 10 not supported,升级客户端库到最新版本即可支持

数据类型和SQL

支持multi range类型, 兼容range类型已知的所有操作符和索引

  • 场景: 物联网
  • 价值: 存储传感器的指标波动范围, 允许在一个value里面存储多个范围区间,同时支持范围的包含、相交、左、右、相邻等逻辑查询(支持索引加速)
  • DEMO:
  1. SELECT '{}'::int4multirange;
  2. SELECT '{[3,7)}'::int4multirange;
  3. SELECT '{[3,7), [8,9)}'::int4multirange;

支持JSONB下标语法

  • 场景: 通用场景
  • 价值: 大幅度简化JSON类型的使用, 支持set原子操作
  • DEMO:
  1. select ('{"postgres": {"release": "Alibaba Cloud RDS PG 14"}}'::jsonb)['postgres']['release'];
  2. jsonb
  3. ---------------------------
  4. "Alibaba Cloud RDS PG 14"
  5. (1 row)

支持存储过程OUT参数

  • 场景: 通用场景
  • 价值: 支持存储过程返回VALUE
  • DEMO:
  1. -- 表结构
  2. postgres=> \d range_test
  3. Table "public.range_test"
  4. Column | Type | Collation | Nullable | Default
  5. -----------+---------+-----------+----------+----------------------------------------
  6. id | integer | | not null | nextval('range_test_id_seq'::regclass)
  7. date_time | tsrange | | |
  8. Indexes:
  9. "range_test_pkey" PRIMARY KEY, btree (id)
  10. -- 表数据
  11. postgres=> select * from range_test;
  12. id | date_time
  13. ----+-----------------------------------------------
  14. 1 | ["2010-01-01 17:00:00","2010-01-01 18:00:00")
  15. 2 | ["2010-01-01 15:00:00","2010-01-01 16:00:00")
  16. (2 rows)
  17. -- 定义存储过程,o_date_time 使用 out 类型
  18. postgres=> create or replace procedure p1 ( i_id in int, o_date_time out tsrange )
  19. as $$
  20. declare
  21. begin
  22. select date_time
  23. into o_date_time
  24. from range_test where id=i_id;
  25. end;
  26. $$ language plpgsql;
  27. CREATE PROCEDURE
  28. -- 调用p1存储过程通过n返回数据
  29. postgres=> do
  30. $$
  31. declare
  32. n tsrange;
  33. begin
  34. call p1(1, n);
  35. raise notice '%', n;
  36. end;
  37. $$;
  38. NOTICE: ["2010-01-01 17:00:00","2010-01-01 18:00:00")
  39. DO

递归(CTE)图式搜索增加广度优先、深度优先语法和循环语法

  • 场景: 社交、风控、图式数据、图谱等场景
  • 价值: 简化广度优先、深度优先语法, 增加循环检测的SQL写法
  • DEMO:
  1. -- 创建表
  2. CREATE TABLE employees (
  3. employee_id serial PRIMARY KEY,
  4. full_name VARCHAR NOT NULL,
  5. manager_id INT
  6. );
  7. -- 插入数据
  8. INSERT INTO employees (
  9. employee_id,
  10. full_name,
  11. manager_id
  12. )
  13. VALUES
  14. (1, 'Michael North', NULL),
  15. (2, 'Megan Berry', 1),
  16. (3, 'Sarah Berry', 1),
  17. (4, 'Zoe Black', 1),
  18. (5, 'Tim James', 1),
  19. (6, 'Bella Tucker', 2),
  20. (7, 'Ryan Metcalfe', 2),
  21. (8, 'Max Mills', 2),
  22. (9, 'Benjamin Glover', 2),
  23. (10, 'Carolyn Henderson', 3),
  24. (11, 'Nicola Kelly', 3),
  25. (12, 'Alexandra Climo', 3),
  26. (13, 'Dominic King', 3),
  27. (14, 'Leonard Gray', 4),
  28. (15, 'Eric Rampling', 4),
  29. (16, 'Piers Paige', 7),
  30. (17, 'Ryan Henderson', 7),
  31. (18, 'Frank Tucker', 8),
  32. (19, 'Nathan Ferguson', 8),
  33. (20, 'Kevin Rampling', 8);
  34. -- 深度优先
  35. WITH RECURSIVE subordinates(employee_id, manager_id, full_name) AS (
  36. SELECT
  37. employee_id,
  38. manager_id,
  39. full_name
  40. FROM
  41. employees
  42. WHERE
  43. employee_id = 2
  44. UNION
  45. SELECT
  46. e.employee_id,
  47. e.manager_id,
  48. e.full_name
  49. FROM
  50. employees e, subordinates s
  51. WHERE
  52. s.employee_id = e.manager_id
  53. ) SEARCH DEPTH FIRST BY employee_id SET ordercol
  54. SELECT * FROM subordinates;
  55. -- 广度优先
  56. WITH RECURSIVE subordinates(employee_id, manager_id, full_name) AS (
  57. SELECT
  58. employee_id,
  59. manager_id,
  60. full_name
  61. FROM
  62. employees
  63. WHERE
  64. employee_id = 2
  65. UNION
  66. SELECT
  67. e.employee_id,
  68. e.manager_id,
  69. e.full_name
  70. FROM
  71. employees e, subordinates s
  72. WHERE
  73. s.employee_id = e.manager_id
  74. ) SEARCH BREADTH FIRST BY employee_id SET ordercol
  75. SELECT * FROM subordinates;
  76. -- 循环语法
  77. WITH RECURSIVE subordinates(employee_id, manager_id, full_name) AS (
  78. SELECT
  79. employee_id,
  80. manager_id,
  81. full_name
  82. FROM
  83. employees
  84. WHERE
  85. employee_id = 2
  86. UNION
  87. SELECT
  88. e.employee_id,
  89. e.manager_id,
  90. e.full_name
  91. FROM
  92. employees e, subordinates s
  93. WHERE
  94. s.employee_id = e.manager_id
  95. ) CYCLE employee_id SET is_cycle USING path
  96. SELECT * FROM subordinates;

增加date_bin函数

  • 场景: 时序场景、分析场景
  • 价值: 按时间间隔打点聚合, 简化打点的算法。支持任意起点, 按任意interval切分bucket, 输入一个时间戳返回这个时间戳所在的bucket timestamp
  • DEMO:
  1. 语法:
  2. date_bin(stride, source, origin)
  3. SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01');
  4. Result: 2020-02-11 15:30:00
  5. SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01 00:02:30');
  6. Result: 2020-02-11 15:32:30

支持tid range scan扫描方法

  • 场景: 通用场景, 高并发场景, 大数据吞吐计算场景
  • 价值: 增加了一种新的搜索算法, 按HEAP表的物理存储数据块ctid地址进行搜索。支持自定义业务层的并行数据扫描逻辑、随机数据扫描逻辑,允许用户输入需要扫描指定数据块的范围。结合rr snapshot export支持一致性单表并行导出,全表并行无锁冲突的更新。
  • DEMO:
  1. select e.*, e.ctid from employees e;
  2. employee_id | full_name | manager_id | ctid
  3. -------------+-------------------+------------+--------
  4. 1 | Michael North | | (0,1)
  5. 2 | Megan Berry | 1 | (0,2)
  6. 3 | Sarah Berry | 1 | (0,3)
  7. 4 | Zoe Black | 1 | (0,4)
  8. 5 | Tim James | 1 | (0,5)
  9. 6 | Bella Tucker | 2 | (0,6)
  10. 7 | Ryan Metcalfe | 2 | (0,7)
  11. 8 | Max Mills | 2 | (0,8)
  12. 9 | Benjamin Glover | 2 | (0,9)
  13. 10 | Carolyn Henderson | 3 | (0,10)
  14. 11 | Nicola Kelly | 3 | (0,11)
  15. 12 | Alexandra Climo | 3 | (0,12)
  16. 13 | Dominic King | 3 | (0,13)
  17. 14 | Leonard Gray | 4 | (0,14)
  18. 15 | Eric Rampling | 4 | (0,15)
  19. 16 | Piers Paige | 7 | (0,16)
  20. 17 | Ryan Henderson | 7 | (0,17)
  21. 18 | Frank Tucker | 8 | (0,18)
  22. 19 | Nathan Ferguson | 8 | (0,19)
  23. 20 | Kevin Rampling | 8 | (0,20)
  24. (20 rows)
  25. select * from employees where ctid > '(0,10)' and ctid < '(0,20)';
  26. employee_id | full_name | manager_id
  27. -------------+-----------------+------------
  28. 11 | Nicola Kelly | 3
  29. 12 | Alexandra Climo | 3
  30. 13 | Dominic King | 3
  31. 14 | Leonard Gray | 4
  32. 15 | Eric Rampling | 4
  33. 16 | Piers Paige | 7
  34. 17 | Ryan Henderson | 7
  35. 18 | Frank Tucker | 8
  36. 19 | Nathan Ferguson | 8
  37. (9 rows)

数据库管理

垃圾回收增强

  1. concurrently模式创建索引不会引起垃圾膨胀
    • 场景: OLTP业务
    • 价值: 降低膨胀概率
    • DEMO:
  1. -- 以下操作不管持续多久, 不影响vacuum回收这之间产生的垃圾
  2. create index CONCURRENTLY abc ...
  3. reindex CONCURRENTLY xxx ...
  1. 加速vacuum freeze, 降低xid wrapped风险
  • 场景: OLTP业务
  • 价值: 增加一个全速vacuum模式,在触发后会忽略索引和sleep参数执行vacuum以最快速度完成vacuum freeze
  • DEMO:
  1. select * from pg_settings where name ~ 'failsafe';
  2. -[ RECORD 1 ]---+------------------------------------------------------------------------------------
  3. name | vacuum_failsafe_age
  4. setting | 1600000000
  5. unit |
  6. category | Client Connection Defaults / Statement Behavior
  7. short_desc | Age at which VACUUM should trigger failsafe to avoid a wraparound outage.
  8. extra_desc |
  9. context | user
  10. vartype | integer
  11. source | default
  12. min_val | 0
  13. max_val | 2100000000
  14. enumvals |
  15. boot_val | 1600000000
  16. reset_val | 1600000000
  17. sourcefile |
  18. sourceline |
  19. pending_restart | f
  20. -[ RECORD 2 ]---+------------------------------------------------------------------------------------
  21. name | vacuum_multixact_failsafe_age
  22. setting | 1600000000
  23. unit |
  24. category | Client Connection Defaults / Statement Behavior
  25. short_desc | Multixact age at which VACUUM should trigger failsafe to avoid a wraparound outage.
  26. extra_desc |
  27. context | user
  28. vartype | integer
  29. source | default
  30. min_val | 0
  31. max_val | 2100000000
  32. enumvals |
  33. boot_val | 1600000000
  34. reset_val | 1600000000
  35. sourcefile |
  36. sourceline |
  37. pending_restart | f
  1. 加速垃圾回收效率

    • 场景: OLTP业务
    • 价值: 在表里的垃圾占用的PAGE较少时跳过 index vacuum 从而提高 vacuum 效率

      提高统计信息数据采集速度

  • 场景: 通用场景
  • 价值: analyze 提升(支持父表的全局视角统计信息, 支持IO prefetch加速analyze)

    系统视图和管理函数增强

  1. 新增pg_stat_progress_copy视图 , 支持COPY导入数据进度监控 , 导入多少行, 排除多少行(where filter)
    • 场景: DBA效能
    • 价值: 掌握copy倒入进度和速度
    • DEMO:
  1. postgres=> \d pg_stat_progress_copy
  2. View "pg_catalog.pg_stat_progress_copy"
  3. Column | Type | Collation | Nullable | Default
  4. ------------------+---------+-----------+----------+---------
  5. pid | integer | | |
  6. datid | oid | | |
  7. datname | name | | |
  8. relid | oid | | |
  9. command | text | | |
  10. type | text | | |
  11. bytes_processed | bigint | | |
  12. bytes_total | bigint | | |
  13. tuples_processed | bigint | | |
  14. tuples_excluded | bigint | | |
  1. 新增 replication slot 统计信息视图 - pg_stat_wal
    • 场景: DBA效能
    • 价值: 掌握数据库WAL日志相关的统计信息
    • DEMO:
  1. postgres=> \d pg_stat_wal
  2. View "pg_catalog.pg_stat_wal"
  3. Column | Type | Collation | Nullable | Default
  4. ------------------+--------------------------+-----------+----------+---------
  5. wal_records | bigint | | |
  6. wal_fpi | bigint | | |
  7. wal_bytes | numeric | | |
  8. wal_buffers_full | bigint | | |
  9. wal_write | bigint | | |
  10. wal_sync | bigint | | |
  11. wal_write_time | double precision | | |
  12. wal_sync_time | double precision | | |
  13. stats_reset | timestamp with time zone | | |
  1. 新增 replication slot 统计信息视图 - pg_stat_replication_slots
    • 场景: DBA效能
    • 价值: 掌握每个SLOT的统计信息
    • DEMO:
  1. postgres=> \d pg_stat_replication_slots
  2. View "pg_catalog.pg_stat_replication_slots"
  3. Column | Type | Collation | Nullable | Default
  4. --------------+--------------------------+-----------+----------+---------
  5. slot_name | text | | |
  6. spill_txns | bigint | | |
  7. spill_count | bigint | | |
  8. spill_bytes | bigint | | |
  9. stream_txns | bigint | | |
  10. stream_count | bigint | | |
  11. stream_bytes | bigint | | |
  12. total_txns | bigint | | |
  13. total_bytes | bigint | | |
  14. stats_reset | timestamp with time zone | | |
  1. pg_locks 增加 wait_start 字段
    • 场景: DBA效能
    • 价值: 跟踪锁等待开始时间,掌握更多锁等待细节, 例如等待时长
    • DEMO:
  1. postgres=> \d pg_locks
  2. View "pg_catalog.pg_locks"
  3. Column | Type | Collation | Nullable | Default
  4. --------------------+--------------------------+-----------+----------+---------
  5. locktype | text | | |
  6. database | oid | | |
  7. relation | oid | | |
  8. page | integer | | |
  9. tuple | smallint | | |
  10. virtualxid | text | | |
  11. transactionid | xid | | |
  12. classid | oid | | |
  13. objid | oid | | |
  14. objsubid | smallint | | |
  15. virtualtransaction | text | | |
  16. pid | integer | | |
  17. mode | text | | |
  18. granted | boolean | | |
  19. fastpath | boolean | | |
  20. waitstart | timestamp with time zone | | |
  1. pg_stat_database 多个统计指标
  • 场景: DBA效能
  • 价值: 增加 active_time, idle_in_transaction_time, sessions, sessions_abandoned, sessions_fatal, sessions_killed统计指标,掌握更多数据库级别的活跃时间、空闲时间、会话量等统计信息, 了解数据库是否达到瓶颈
  • DEMO:
  1. postgres=> \d pg_stat_database
  2. View "pg_catalog.pg_stat_database"
  3. Column | Type | Collation | Nullable | Default
  4. --------------------------+--------------------------+-----------+----------+---------
  5. datid | oid | | |
  6. datname | name | | |
  7. numbackends | integer | | |
  8. xact_commit | bigint | | |
  9. xact_rollback | bigint | | |
  10. blks_read | bigint | | |
  11. blks_hit | bigint | | |
  12. tup_returned | bigint | | |
  13. tup_fetched | bigint | | |
  14. tup_inserted | bigint | | |
  15. tup_updated | bigint | | |
  16. tup_deleted | bigint | | |
  17. conflicts | bigint | | |
  18. temp_files | bigint | | |
  19. temp_bytes | bigint | | |
  20. deadlocks | bigint | | |
  21. checksum_failures | bigint | | |
  22. checksum_last_failure | timestamp with time zone | | |
  23. blk_read_time | double precision | | |
  24. blk_write_time | double precision | | |
  25. session_time | double precision | | |
  26. active_time | double precision | | |
  27. idle_in_transaction_time | double precision | | |
  28. sessions | bigint | | |
  29. sessions_abandoned | bigint | | |
  30. sessions_fatal | bigint | | |
  31. sessions_killed | bigint | | |
  32. stats_reset | timestamp with time zone | | |
  1. pg_prepared_statements 增加硬解析和软解析次数统计
    • 场景: DBA效能
    • 价值: 掌握SQL的软解、硬解次数, 分析SQL解析层消耗和优化方法
    • DEMO:
  1. postgres=> \d pg_prepared_statements
  2. View "pg_catalog.pg_prepared_statements"
  3. Column | Type | Collation | Nullable | Default
  4. -----------------+--------------------------+-----------+----------+---------
  5. name | text | | |
  6. statement | text | | |
  7. prepare_time | timestamp with time zone | | |
  8. parameter_types | regtype[] | | |
  9. from_sql | boolean | | |
  10. generic_plans | bigint | | |
  11. custom_plans | bigint | | |

新增 GUC 参数

  1. 增加 log_recovery_conflict_waits GUC参数
    • 场景: DBA效能
    • 价值: 支持 standby query&startup process conflict 恢复冲突超时(deadlock_timeout) 日志打印,掌握只读standby库的查询和WAL恢复进程的冲突等待时间
    • DEMO:
  1. postgres=> select * from pg_settings where name='log_recovery_conflict_waits';
  2. -[ RECORD 1 ]---+--------------------------------------
  3. name | log_recovery_conflict_waits
  4. setting | off
  5. unit |
  6. category | Reporting and Logging / What to Log
  7. short_desc | Logs standby recovery conflict waits.
  8. extra_desc |
  9. context | sighup
  10. vartype | bool
  11. source | default
  12. min_val |
  13. max_val |
  14. enumvals |
  15. boot_val | off
  16. reset_val | off
  17. sourcefile |
  18. sourceline |
  19. pending_restart | f
  1. 增加 track_wal_io_timing GUC参数
    • 场景: DBA效能
    • 价值: 支持wal日志buffer write, fsync IO等待时长统计 , 掌握IO资源使用情况和WAL瓶颈分析
    • DEMO:
  1. postgres=> select * from pg_settings where name='track_wal_io_timing';
  2. -[ RECORD 1 ]---+--------------------------------------------------
  3. name | track_wal_io_timing
  4. setting | off
  5. unit |
  6. category | Statistics / Query and Index Statistics Collector
  7. short_desc | Collects timing statistics for WAL I/O activity.
  8. extra_desc |
  9. context | superuser
  10. vartype | bool
  11. source | default
  12. min_val |
  13. max_val |
  14. enumvals |
  15. boot_val | off
  16. reset_val | off
  17. sourcefile |
  18. sourceline |
  19. pending_restart | f
  1. 增加 idle_session_timeout GUC参数
    • 场景: DBA效能
    • 价值: 断开长时间空闲的会话,减少空闲会话的资源占用
    • DEMO:
  1. postgres=> select * from pg_settings where name='idle_session_timeout';
  2. -[ RECORD 1 ]---+-------------------------------------------------------------------------------
  3. name | idle_session_timeout
  4. setting | 0
  5. unit | ms
  6. category | Client Connection Defaults / Statement Behavior
  7. short_desc | Sets the maximum allowed idle time between queries, when not in a transaction.
  8. extra_desc | A value of 0 turns off the timeout.
  9. context | user
  10. vartype | integer
  11. source | default
  12. min_val | 0
  13. max_val | 2147483647
  14. enumvals |
  15. boot_val | 0
  16. reset_val | 0
  17. sourcefile |
  18. sourceline |
  19. pending_restart | f
  1. 增加 client_connection_check_interval GUC参数
    • 场景: 分析师、开发者、DBA效能
    • 价值: 协议层支持心跳包, 如果客户端已离线, 可以快速中断这个客户端此前运行中的长SQL - Detect POLLHUP/POLLRDHUP while running queries,不需要等执行结束, 检测到客户端退出后SQL即刻退出
    • DEMO:
  1. postgres=> select * from pg_settings where name='client_connection_check_interval';
  2. -[ RECORD 1 ]---+-------------------------------------------------------------------------------
  3. name | client_connection_check_interval
  4. setting | 0
  5. unit | ms
  6. category | Connections and Authentication / Connection Settings
  7. short_desc | Sets the time interval between checks for disconnection while running queries.
  8. extra_desc |
  9. context | user
  10. vartype | integer
  11. source | configuration file
  12. min_val | 0
  13. max_val | 2147483647
  14. enumvals |
  15. boot_val | 0
  16. reset_val | 0
  17. sourcefile |
  18. sourceline |
  19. pending_restart | f

SQL 命令增强

  1. REINDEX command 增加 tablespace 选项
    • 场景: DBA效能
    • 价值: 支持重建索引到指定表空间,更好的利用块设备
    • DEMO:
  1. REINDEX [ ( option [, ...] ) ] { INDEX | TABLE | SCHEMA | DATABASE | SYSTEM } [ CONCURRENTLY ] name
  2. where option can be one of:
  3. CONCURRENTLY [ boolean ]
  4. TABLESPACE new_tablespace
  5. VERBOSE [ boolean ]
  1. REINDEX command 支持分区表
    • 场景: DBA效能
    • 价值: 自动重建所有子分区的索引,提高分区表索引重建的便捷度

流复制与备份恢复

逻辑复制增强

  1. 长事务逻辑复制优化
    • 场景: 多机房部署、单元化部署、跨库同步订阅数据场景
    • 价值: 增加streaming接口, 逻辑复制支持流式decoder和发送, 无需等待事务结束, 大幅度降低大事务、长事务的复制延迟
  2. 逻辑复制sync table data阶段支持多线程
    • 场景: 跨库逻辑订阅、数据迁移等场景
    • 价值: 允许同步全量数据的同时接收wal逻辑日志, 可以缩短大表首次同步到达最终一致的耗时
  3. alter subscription语法增强
    • 场景: 逻辑订阅
    • 价值: 支持add/drop publication,提高订阅端的操作便捷性
    • DEMO:
  1. ALTER SUBSCRIPTION name CONNECTION 'conninfo'
  2. ALTER SUBSCRIPTION name SET PUBLICATION publication_name [, ...] [ WITH ( publication_option [= value] [, ... ] ) ]
  3. ALTER SUBSCRIPTION name ADD PUBLICATION publication_name [, ...] [ WITH ( publication_option [= value] [, ... ] ) ]
  4. ALTER SUBSCRIPTION name DROP PUBLICATION publication_name [, ...] [ WITH ( publication_option [= value] [, ... ] ) ]
  5. ALTER SUBSCRIPTION name REFRESH PUBLICATION [ WITH ( refresh_option [= value] [, ... ] ) ]
  6. ALTER SUBSCRIPTION name ENABLE
  7. ALTER SUBSCRIPTION name DISABLE
  8. ALTER SUBSCRIPTION name SET ( subscription_parameter [= value] [, ... ] )
  9. ALTER SUBSCRIPTION name OWNER TO { new_owner | CURRENT_ROLE | CURRENT_USER | SESSION_USER }
  10. ALTER SUBSCRIPTION name RENAME TO new_name

允许hot standby 作为pg_rewind的源库

  • 场景: 通用场景
  • 价值: 可以使用standby来修复坏库

增加 remove_temp_files_after_crash GUC参数

  • 场景: 通用场景
  • 价值: 在数据库crash后重启时自动清理临时文件,避免数据库遇到连续性崩溃恢复问题时可能导致存储爆满的问题
  • DEMO:
  1. postgres=> select * from pg_settings where name='remove_temp_files_after_crash';
  2. -[ RECORD 1 ]---+--------------------------------------------
  3. name | remove_temp_files_after_crash
  4. setting | on
  5. unit |
  6. category | Developer Options
  7. short_desc | Remove temporary files after backend crash.
  8. extra_desc |
  9. context | sighup
  10. vartype | bool
  11. source | default
  12. min_val |
  13. max_val |
  14. enumvals |
  15. boot_val | on
  16. reset_val | on
  17. sourcefile |
  18. sourceline |
  19. pending_restart | f

standby wal receiver 接收时延优化

  • 场景: 基于流复制的只读实例, 基于流复制的高可用等场景
  • 价值: 需等待startup process replay结束, 大幅度降低standby在重启后的wal接收延迟

参考文档:https://github.com/digoal/blog/blob/master/202105/20210513_02.md