autovacuum基于表变更统计动态触发,每20秒扫描表并按阈值(默认20%行变更或50行死元组)决定是否执行;其IO由cost_delay和cost_limit节流,手动VACUUM默认无节流但会阻塞写操作。

autovacuum 是怎么决定什么时候跑的
PostgreSQL 的 autovacuum 不是定时任务,而是基于表的变更统计动态触发的。它每 20 秒(由 autovacuum_naptime 控制)唤醒一次,扫描所有表,对满足阈值的表发起 vacuum 或 analyze。
关键判断逻辑是:pg_class.reltuples(预估行数) × autovacuum_vacuum_scale_factor + autovacuum_vacuum_threshold ≤ 已死亡元组数(n_dead_tup)。默认是 20% 行变更或 50 行(取大),所以小表很容易被频繁扫到,大表则可能拖很久才触发。
- 修改
autovacuum_vacuum_scale_factor要谨慎:设为0.01对 1 亿行表意味着只要 100 万死元组就触发,IO 压力陡增 -
autovacuum_vacuum_cost_delay和autovacuum_vacuum_cost_limit才真正控制 IO 节流——前者是每次 I/O 操作后休眠毫秒数,后者是单次 autovacuum 进程允许消耗的“成本点数” - 查看当前状态用:
SELECT schemaname, tablename, n_dead_tup, last_autovacuum FROM pg_stat_all_tables ORDER BY n_dead_tup DESC LIMIT 5;
manual VACUUM 为什么有时比 autovacuum 更快
手动 VACUUM 默认不走 cost-based 节流,也不受 autovacuum_vacuum_cost_delay 限制,能用满可用 IO 带宽。但它会阻塞写操作(除非加 CONCURRENTLY,但仅限于 VACUUM ANALYZE 且不支持索引重建)。
-
VACUUM (FULL)会锁表、重写整个堆,适合严重膨胀后一次性清理,但期间表不可读写 -
VACUUM (PARALLEL 4)在 13+ 版本可用,能加速扫描和清理,但并行进程仍共享同一套 cost 限制(除非显式关掉:VACUUM (PARALLEL 4, DISABLE_PAGE_SKIPPING OFF)) - 生产环境慎用无参数
VACUUM:它默认跳过已 clean 的页(DISABLE_PAGE_SKIPPING ON),但若表刚被大量 DELETE,可能漏掉部分页
autovacuum 和 manual VACUUM 同时运行会冲突吗
会,但不是“报错退出”,而是竞争资源与锁。autovacuum 进程和手动 VACUUM 都需要获取 ShareUpdateExclusiveLock,所以手动命令会等 autovacuum 先释放锁;反过来,如果 autovacuum 正在跑,新启动的 autovacuum worker 也会跳过该表(避免重复)。
- 查看锁等待:
SELECT blocked_locks.pid AS blocked_pid, blocking_locks.pid AS blocking_pid FROM pg_catalog.pg_locks blocked_locks JOIN pg_catalog.pg_locks blocking_locks ON blocking_locks.locktype = blocked_locks.locktype AND blocking_locks.database IS NOT DISTINCT FROM blocked_locks.database AND blocking_locks.relation IS NOT DISTINCT FROM blocked_locks.relation AND blocking_locks.page IS NOT DISTINCT FROM blocked_locks.page AND blocking_locks.tuple IS NOT DISTINCT FROM blocked_locks.tuple AND blocking_locks.virtualxid IS NOT DISTINCT FROM blocked_locks.virtualxid AND blocking_locks.transactionid IS NOT DISTINCT FROM blocked_locks.transactionid AND blocking_locks.classid IS NOT DISTINCT FROM blocked_locks.classid AND blocking_locks.objid IS NOT DISTINCT FROM blocked_locks.objid AND blocking_locks.objsubid IS NOT DISTINCT FROM blocked_locks.objsubid AND blocking_locks.pid != blocked_locks.pid WHERE NOT blocked_locks.granted; - autovacuum 可被中断(如被
pg_terminate_backend()杀掉),但 manual VACUUM 一旦开始,只能等完或强制 cancel(可能留下不一致状态) - 高频手动干预通常说明 autovacuum 配置不合理,而不是“它不行”
IO 影响到底该怎么压住不爆
核心不是“少 vacuum”,而是让 vacuum 的 IO 更可预测、更分散。autovacuum 的节流机制本质是模拟一个“IO 预算”,但默认配置对 SSD 或高 IOPS 环境过于保守。
- 调低
autovacuum_vacuum_cost_delay(比如从 20ms 改成 2ms)比调高autovacuum_vacuum_cost_limit(比如从 200 到 2000)更安全——前者控制节奏,后者只放大单次吞吐 - 对写入热点表单独设置:使用
ALTER TABLE t SET (autovacuum_vacuum_scale_factor = 0.001);,比全局调参影响更精准 - 监控真实 IO 压力看
pg_stat_bgwriter的buffers_clean和maxwritten_clean:如果后者频繁接近bgwriter_lru_maxpages,说明后台写进程已在拼命刷脏页,vacuum 再加码容易雪上加霜
pg_stat_all_tables.n_dead_tup 趋势和磁盘 await、%util 指标来看——光看 autovacuum 日志里“finished”不代表 IO 没打穿。










