|
| 1 | +# Pre- and post-steps for benchmark iterations |
| 2 | + |
| 3 | +> 我每天都会发布一篇新的 PostgreSQL "howto" 文章。加入我的旅程吧 — 订阅、提供反馈、分享! |
| 4 | +
|
| 5 | +在进行 PostgreSQL 基准测试时 (参照 [Day 13: How to benchmark]()),我们通常需要在相同的设置上运行多次基准测试迭代。为保证每次迭代的统一性,通常会在每次迭代前后执行以下步骤: |
| 6 | + |
| 7 | +- 前置:刷新缓存 (或者,相反地,预热缓存)。 |
| 8 | +- 前置:重置累积统计信息。 |
| 9 | +- 后置:保存统计信息和其他基准测试结果。 |
| 10 | + |
| 11 | +这里描述的方法允许以统一的方式进行基准测试。 |
| 12 | + |
| 13 | +## 前置步骤:刷新缓存 |
| 14 | + |
| 15 | +在准备工作时,通常有两种策略: |
| 16 | + |
| 17 | +- 预热缓存 (可以使用 `pg_prewarm` 扩展,或者多次执行基准测试多次,只记录最后一次的结果。)此处就不讨论了。 |
| 18 | +- 刷新缓存 (清空操作系统页面缓存和 PostgreSQL 缓冲池),使每次迭代从"冷启动"开始。 |
| 19 | + |
| 20 | +如果选择第二种策略,建议: |
| 21 | + |
| 22 | +- 增加每次迭代的持续时间,以便缓存有足够时间热起来。 |
| 23 | +- 查看每次迭代内的时间序列指标 (例如,使用 `pgbench` 的 `-P 10` 选项以每隔 10 秒显示延迟/吞吐量)。 |
| 24 | + |
| 25 | +如何刷新缓存: |
| 26 | + |
| 27 | +1. PostgreSQL 缓冲池 – 只需重启 Postgres 即可: |
| 28 | + |
| 29 | +```bash |
| 30 | +pg_ctl restart -D $PGDATA -m fast |
| 31 | +``` |
| 32 | + |
| 33 | +2. 释放 `pagecache`、`dentry` 和 `inode`: |
| 34 | + |
| 35 | +```bash |
| 36 | +sync # 将所有缓冲操作写入磁盘 |
| 37 | +echo 3 > /proc/sys/vm/drop_caches |
| 38 | +``` |
| 39 | + |
| 40 | +## 前置步骤:重置统计信息 |
| 41 | + |
| 42 | +在运行基准测试之前,可能需要重置集群中的所有累积统计信息 (取决于当前的 PostgreSQL 版本),包括标准扩展如 `pg_stat_statements` 和其他扩展如 `pg_wait_sampling`、`pg_stat_kcache`、`pg_qualstats`(如果安装了)。 |
| 43 | + |
| 44 | +以下是重置统计信息的脚本: |
| 45 | + |
| 46 | +```sql |
| 47 | +do $$ |
| 48 | +declare |
| 49 | + reset_cmd_main json := $json${ |
| 50 | + "pg_stat_reset()": 90000, |
| 51 | + "pg_stat_reset_shared('bgwriter')": 90000, |
| 52 | + "pg_stat_reset_shared('archiver')": 90000, |
| 53 | + "pg_stat_reset_shared('io')": 160000, |
| 54 | + "pg_stat_reset_shared('wal')": 140000, |
| 55 | + "pg_stat_reset_shared('recovery_prefetch')": 140000, |
| 56 | + "pg_stat_reset_slru(null)": 130000 |
| 57 | + }$json$; |
| 58 | + |
| 59 | + reset_cmd_et json := $json${ |
| 60 | + "pg_stat_statements_reset()": "pg_stat_statements", |
| 61 | + "pg_stat_kcache_reset()": "pg_stat_kcache", |
| 62 | + "pg_wait_sampling_reset_profile()": "pg_wait_sampling", |
| 63 | + "pg_qualstats_reset()": "pg_qualstats" |
| 64 | + }$json$; |
| 65 | + |
| 66 | + cmd record; |
| 67 | + cur_ver int; |
| 68 | +begin |
| 69 | + cur_ver := current_setting('server_version_num')::int; |
| 70 | + raise info 'Current PG version (num): %', cur_ver; |
| 71 | + |
| 72 | + -- Main reset commands |
| 73 | + for cmd in select * from json_each_text(reset_cmd_main) loop |
| 74 | + if cur_ver >= (cmd.value)::int then |
| 75 | + raise info 'Execute SQL: select %', cmd.key; |
| 76 | + execute format ('select %s', cmd.key); |
| 77 | + end if; |
| 78 | + end loop; |
| 79 | + |
| 80 | + -- Extension reset commands |
| 81 | + for cmd in select * from json_each_text(reset_cmd_et) loop |
| 82 | + if '' <> ( |
| 83 | + select installed_version |
| 84 | + from pg_available_extensions |
| 85 | + where name = cmd.value |
| 86 | + ) then |
| 87 | + raise info 'Execute SQL: select %', cmd.key; |
| 88 | + execute format ('select %s', cmd.key); |
| 89 | + end if; |
| 90 | + end loop; |
| 91 | +end |
| 92 | +$$; |
| 93 | +``` |
| 94 | + |
| 95 | +在基准测试之前运行该步骤,确保统计信息是干净的,并且不会受到准备操作的影响。 |
| 96 | + |
| 97 | +## 后置步骤:收集基准测试结果 |
| 98 | + |
| 99 | +建议执行以下步骤: |
| 100 | + |
| 101 | +1. 导出所有 `pg_stat_*` 视图的内容: |
| 102 | + |
| 103 | +```bash |
| 104 | +for viewname in $(psql -tAXc " |
| 105 | + select relname |
| 106 | + from pg_catalog.pg_class |
| 107 | + where relkind = 'view' and relname like 'pg_stat%'" \ |
| 108 | +); do |
| 109 | + psql -Xc "copy (select * from ${viewname}) |
| 110 | + to stdout with csv header delimiter ','" \ |
| 111 | + > "${destination}/${viewname}.csv" |
| 112 | +done |
| 113 | + |
| 114 | +psql -Xc "copy (select * from pg_stat_kcache()) |
| 115 | + to stdout with csv header delimiter ','" \ |
| 116 | + > "${destination}/pg_stat_kcache.csv" |
| 117 | + |
| 118 | +psql -Xc "copy ( |
| 119 | + select |
| 120 | + event_type as wait_type, |
| 121 | + event as wait_event, |
| 122 | + sum(count) as of_events |
| 123 | + from pg_wait_sampling_profile |
| 124 | + group by event_type, event |
| 125 | + order by of_events desc |
| 126 | + ) to stdout with csv header delimiter ','" \ |
| 127 | + > "${destination}/pg_wait_sampling_profile.csv" |
| 128 | +``` |
| 129 | + |
| 130 | +2. 收集日志文件:压缩并复制日志目录中的文件。 |
| 131 | + |
| 132 | +3. 导出当前配置 (`pg_settings`): |
| 133 | + |
| 134 | +```bash |
| 135 | +psql -Xc "copy ( |
| 136 | + select * from pg_settings order by name |
| 137 | + ) to stdout with csv header delimiter ','" \ |
| 138 | + > "${destination}/pg_settings_all.csv" |
| 139 | + |
| 140 | +psql -Xc " |
| 141 | + select name, setting as current_setting, unit, boot_val as default, context |
| 142 | + from pg_settings |
| 143 | + where source <> 'default'" \ |
| 144 | + > "${destination}/pg_settings_non_default.txt" |
| 145 | +``` |
| 146 | + |
| 147 | +4. 其他有用的基准测试数据:如果需要,收集系统日志、sar 数据等。 |
| 148 | + |
0 commit comments