PostgreSQL Vacuum 수행 필요 대상 추출 스크립트
- Vacuum threshold(autovacuum 임계값) = vacuum base threshold + vacuum scale factor * number of tuples
WITH avt 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) as autovacuum_freeze_max_age
, (coalesce(cavt.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 avt
on (1=1) join vsf
on (1=1) join fma
on (1=1)
left join sto cavt
on cavt.param = 'autovacuum_vacuum_threshold'
and c.oid = cavt.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(cavt.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;
'1. IT Story > Scripts' 카테고리의 다른 글
MySQL Session Lock 관리 스크립트 (0) | 2019.03.20 |
---|---|
MySQL 테이블/인덱스 사이즈 조회 스크립트 (0) | 2019.03.19 |
PostgreSQL 10, Export/Import (0) | 2019.03.18 |
PostgreSQL Object 접근 권한 조회 스크립트 (0) | 2019.03.17 |
Oracle TEMP / UNDO 재생성 스크립트 (0) | 2019.03.15 |
6 sigma (무결점 수준의 결함을 통한 고객만족의 극대화) (0) | 2019.03.14 |
Oracle 락 홀더(Locks Holders) 조회 스크립트 (0) | 2019.03.12 |
PostgreSQL 인덱스 관리 스크립트 (0) | 2019.03.10 |