Last active
February 1, 2022 17:42
-
-
Save genslein/0163443b514af268e69a22d5167934a9 to your computer and use it in GitHub Desktop.
Get more robust autovacuum stas
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
WITH table_opts AS ( | |
SELECT | |
pg_class.oid, relname, nspname, array_to_string(reloptions, '') AS relopts | |
FROM | |
pg_class INNER JOIN pg_namespace ns ON relnamespace = ns.oid | |
), vacuum_settings AS ( | |
SELECT | |
oid, relname, nspname, | |
CASE | |
WHEN relopts LIKE '%autovacuum_vacuum_threshold%' | |
THEN substring(relopts, '.*autovacuum_vacuum_threshold=([0-9.]+).*')::integer | |
ELSE current_setting('autovacuum_vacuum_threshold')::integer | |
END AS autovacuum_vacuum_threshold, | |
CASE | |
WHEN relopts LIKE '%autovacuum_vacuum_scale_factor%' | |
THEN substring(relopts, '.*autovacuum_vacuum_scale_factor=([0-9.]+).*')::real | |
ELSE current_setting('autovacuum_vacuum_scale_factor')::real | |
END AS autovacuum_vacuum_scale_factor | |
FROM | |
table_opts | |
) | |
SELECT | |
vacuum_settings.nspname AS schema, | |
vacuum_settings.relname AS table, | |
to_char(psut.last_vacuum, 'YYYY-MM-DD HH24:MI') AS last_vacuum, | |
to_char(psut.last_autovacuum, 'YYYY-MM-DD HH24:MI') AS last_autovacuum, | |
to_char(pg_class.reltuples, '9G999G999G999') AS rowcount, | |
to_char(psut.n_dead_tup, '9G999G999G999') AS dead_rowcount, | |
to_char(autovacuum_vacuum_threshold | |
+ (autovacuum_vacuum_scale_factor::numeric * pg_class.reltuples), '9G999G999G999') AS autovacuum_threshold, | |
CASE | |
WHEN autovacuum_vacuum_threshold + (autovacuum_vacuum_scale_factor::numeric * pg_class.reltuples) < psut.n_dead_tup | |
THEN 'yes' | |
END AS expect_autovacuum | |
FROM | |
pg_stat_all_tables psut INNER JOIN pg_class ON psut.relid = pg_class.oid | |
INNER JOIN vacuum_settings ON pg_class.oid = vacuum_settings.oid | |
ORDER BY 1; | |
-- pg_toast table ID from name in relation e.g. pg_toast_1475348394 | |
select '[some-toast-id]'::regclass; |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment