diff --git a/sql/t2_storage_parameters.sql b/sql/t2_storage_parameters.sql new file mode 100644 index 0000000..0946f01 --- /dev/null +++ b/sql/t2_storage_parameters.sql @@ -0,0 +1,54 @@ +--Objects with custom storage parameters + +with rel_with_options as ( + select + n.nspname as schema, + c.relname as object_name, + case c.relkind + when 'r' then 'table' + when 'i' then 'index' + when 'm' then 'materialized view' + when 'p' then 'partitioned table' + when 'I' then 'partitioned index' + end as object_type, + pg_size_pretty(pg_relation_size(c.oid)) as size, + pg_relation_size(c.oid) as size_bytes, + c.reloptions, + unnest(c.reloptions) as option, + c.relispartition, + (select n2.nspname || '.' || c2.relname + from pg_inherits i + join pg_class c2 on i.inhparent = c2.oid + join pg_namespace n2 on c2.relnamespace = n2.oid + where i.inhrelid = c.oid + ) as parent_table + from pg_class c + join pg_namespace n on c.relnamespace = n.oid + where c.reloptions is not null + and n.nspname not in ('pg_catalog', 'information_schema') + and c.relname != 'pg_stats' +) +select + schema, + object_name, + object_type, + case + when relispartition then 'partition of ' || parent_table + else null + end as partition_info, + size, + option, + case + when option ~ 'autovacuum_enabled=(false|off)' and size_bytes > 10485760 then 'WARNING: autovacuum disabled on table > 10 MiB' + when option ~ 'autovacuum_enabled=(false|off)' then 'autovacuum disabled' + when option ~ 'fillfactor=([1-4][0-9]|50)' then 'low fillfactor (< 50%)' + when option ~ 'autovacuum_vacuum_scale_factor=0\.0*[1-9]' then 'aggressive autovacuum (low scale factor)' + else null + end as note +from rel_with_options +order by + parent_table nulls first, + size_bytes desc, + object_type, + schema, + object_name; \ No newline at end of file diff --git a/start.psql b/start.psql index aa7d0ae..4136933 100644 --- a/start.psql +++ b/start.psql @@ -24,6 +24,7 @@ \echo ' s1 – Slowest queries, by total time (requires pg_stat_statements)' \echo ' s2 – Slowest queries report (requires pg_stat_statements)' \echo ' t1 – Postgres parameters tuning' +\echo ' t2 – Objects with custom storage parameters' \echo ' v1 – Vacuum: current activity' \echo ' v2 – VACUUM progress and autovacuum queue' \echo ' q – Quit' @@ -56,6 +57,7 @@ select :d_stp::text = 's1' as d_step_is_s1, :d_stp::text = 's2' as d_step_is_s2, :d_stp::text = 't1' as d_step_is_t1, +:d_stp::text = 't2' as d_step_is_t2, :d_stp::text = 'v1' as d_step_is_v1, :d_stp::text = 'v2' as d_step_is_v2, :d_stp::text = 'q' as d_step_is_q \gset @@ -158,6 +160,10 @@ select \ir ./sql/t1_tuning.sql \prompt 'Press to continue…' d_dummy \ir ./start.psql +\elif :d_step_is_t2 + \ir ./sql/t2_storage_parameters.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql \elif :d_step_is_v1 \ir ./sql/v1_vacuum_activity.sql \prompt 'Press to continue…' d_dummy