현재 Autovacuum을 수행할 수 있는 테이블 결정 - Amazon Relational Database Service

현재 Autovacuum을 수행할 수 있는 테이블 결정

vacuum을 수행해야 하는 테이블이 하나이거나 두 개인 경우가 많습니다. relfrozenxid 값이 autovacuum_freeze_max_age의 트랜잭션 수보다 큰 테이블은 항상 Autovacuum의 대상이 됩니다. 그렇지 않은 경우 VACUUM이 "vacuum 임계값"을 초과하여 튜플 수가 더 이상 사용되지 않는 경우 테이블이 vacuum됩니다.

autovacuum 임계값은 다음과 같이 정의되어 있습니다.

Vacuum-threshold = vacuum-base-threshold + vacuum-scale-factor * number-of-tuples

여기서 vacuum base thresholdautovacuum_vacuum_threshold이고, vacuum scale factorautovacuum_vacuum_scale_factor이며, number of tuplespg_class.reltuples입니다.

데이터베이스에 연결되어 있는 상태에서 다음 쿼리를 실행하여 autovacuum이 vacuum 가능한 대상으로 분류하는 테이블 목록을 확인합니다.

WITH vbt AS (SELECT setting AS autovacuum_vacuum_threshold FROM pg_settings WHERE name = 'autovacuum_vacuum_threshold'), vsf AS (SELECT setting AS autovacuum_vacuum_scale_factor FROM pg_settings WHERE name = 'autovacuum_vacuum_scale_factor'), fma AS (SELECT setting AS autovacuum_freeze_max_age FROM pg_settings WHERE name = 'autovacuum_freeze_max_age'), sto AS (select opt_oid, split_part(setting, '=', 1) as param, split_part(setting, '=', 2) as value from (select oid opt_oid, unnest(reloptions) setting from pg_class) opt) SELECT '"'||ns.nspname||'"."'||c.relname||'"' as relation, pg_size_pretty(pg_table_size(c.oid)) as table_size, age(relfrozenxid) as xid_age, coalesce(cfma.value::float, autovacuum_freeze_max_age::float) autovacuum_freeze_max_age, (coalesce(cvbt.value::float, autovacuum_vacuum_threshold::float) + coalesce(cvsf.value::float,autovacuum_vacuum_scale_factor::float) * c.reltuples) AS autovacuum_vacuum_tuples, n_dead_tup as dead_tuples FROM pg_class c join pg_namespace ns on ns.oid = c.relnamespace join pg_stat_all_tables stat on stat.relid = c.oid join vbt on (1=1) join vsf on (1=1) join fma on (1=1) left join sto cvbt on cvbt.param = 'autovacuum_vacuum_threshold' and c.oid = cvbt.opt_oid left join sto cvsf on cvsf.param = 'autovacuum_vacuum_scale_factor' and c.oid = cvsf.opt_oid left join sto cfma on cfma.param = 'autovacuum_freeze_max_age' and c.oid = cfma.opt_oid WHERE c.relkind = 'r' and nspname <> 'pg_catalog' AND (age(relfrozenxid) >= coalesce(cfma.value::float, autovacuum_freeze_max_age::float) OR coalesce(cvbt.value::float, autovacuum_vacuum_threshold::float) + coalesce(cvsf.value::float,autovacuum_vacuum_scale_factor::float) * c.reltuples <= n_dead_tup) ORDER BY age(relfrozenxid) DESC LIMIT 50;