Skip to content

Instantly share code, notes, and snippets.

@VincentAntoine
Last active November 26, 2024 13:04
Show Gist options
  • Select an option

  • Save VincentAntoine/43858a6023aa04ee274e20255fa91a1e to your computer and use it in GitHub Desktop.

Select an option

Save VincentAntoine/43858a6023aa04ee274e20255fa91a1e to your computer and use it in GitHub Desktop.
Postgresql - Analyse du bloat des tables du schéma `public` avec `pgstattuple`
WITH t AS (
SELECT
s.relid,
s.relname,
last_autovacuum,
last_vacuum
FROM pg_stat_user_tables s
WHERE s.schemaname = 'public'
)
SELECT
--COALESCE(chunk_catalog.hypertable_name, s.relname) as table,
s.relname as table,
pg_size_pretty(table_len) AS table_size_on_disk,
pg_size_pretty(tuple_len) AS live_data_size,
pg_size_pretty(dead_tuple_len) AS dead_data_size,
pg_size_pretty(free_space) AS free_space_size,
pg_size_pretty(dead_tuple_len + free_space) AS total_wasted_space,
dead_tuple_len + free_space AS total_wasted_space_,
tuple_len::DOUBLE PRECISION / table_len::DOUBLE PRECISION AS live_percent,
dead_tuple_len::DOUBLE PRECISION / table_len::DOUBLE PRECISION AS dead_percent,
free_space::DOUBLE PRECISION / table_len::DOUBLE PRECISION AS free_percent,
s.last_autovacuum,
s.last_vacuum
FROM t s
LEFT JOIN LATERAL pgstattuple(s.relid::regclass) stup ON true
-- LEFT JOIN chunk_catalog
-- ON chunk_catalog.chunk_regclass = s.relid::regclass
WHERE table_len > 8192
ORDER BY dead_tuple_len + free_space DESC
--GROUP BY 1
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment