Skip to content

Commit 0b6e2cc

Browse files
committed
feat(t2): add storage parameters (reloptions) query
Add new t2 query to list tables, indexes, and materialized views with custom storage parameters (reloptions). This helps DBAs: - Audit custom table/index settings - Find tables with disabled autovacuum - Identify low fillfactor settings - See partition relationships and their individual settings Features: - Shows all objects with reloptions - Includes partition hierarchy (shows parent table for partitions) - Provides warnings for potentially problematic settings: - Autovacuum disabled on tables > 10 MiB - Low fillfactor (< 50%) - Aggressive autovacuum (very low scale factor) - Sorted by size (largest first) and partition relationships Closes #61
1 parent ac864a2 commit 0b6e2cc

File tree

2 files changed

+60
-0
lines changed

2 files changed

+60
-0
lines changed

sql/t2_storage_parameters.sql

Lines changed: 54 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,54 @@
1+
--Storage parameters (reloptions)
2+
3+
with rel_with_options as (
4+
select
5+
n.nspname as schema,
6+
c.relname as object_name,
7+
case c.relkind
8+
when 'r' then 'table'
9+
when 'i' then 'index'
10+
when 'm' then 'materialized view'
11+
when 'p' then 'partitioned table'
12+
when 'I' then 'partitioned index'
13+
end as object_type,
14+
pg_size_pretty(pg_relation_size(c.oid)) as size,
15+
pg_relation_size(c.oid) as size_bytes,
16+
c.reloptions,
17+
unnest(c.reloptions) as option,
18+
c.relispartition,
19+
(select n2.nspname || '.' || c2.relname
20+
from pg_inherits i
21+
join pg_class c2 on i.inhparent = c2.oid
22+
join pg_namespace n2 on c2.relnamespace = n2.oid
23+
where i.inhrelid = c.oid
24+
) as parent_table
25+
from pg_class c
26+
join pg_namespace n on c.relnamespace = n.oid
27+
where c.reloptions is not null
28+
and n.nspname not in ('pg_catalog', 'information_schema')
29+
and c.relname != 'pg_stats'
30+
)
31+
select
32+
schema,
33+
object_name,
34+
object_type,
35+
case
36+
when relispartition then 'partition of ' || parent_table
37+
else null
38+
end as partition_info,
39+
size,
40+
option,
41+
case
42+
when option ~ 'autovacuum_enabled=(false|off)' and size_bytes > 10485760 then 'WARNING: autovacuum disabled on table > 10 MiB'
43+
when option ~ 'autovacuum_enabled=(false|off)' then 'autovacuum disabled'
44+
when option ~ 'fillfactor=([1-4][0-9]|50)' then 'low fillfactor (< 50%)'
45+
when option ~ 'autovacuum_vacuum_scale_factor=0\.0*[1-9]' then 'aggressive autovacuum (low scale factor)'
46+
else null
47+
end as note
48+
from rel_with_options
49+
order by
50+
parent_table nulls first,
51+
size_bytes desc,
52+
object_type,
53+
schema,
54+
object_name;

start.psql

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -24,6 +24,7 @@
2424
\echo ' s1 – Slowest queries, by total time (requires pg_stat_statements)'
2525
\echo ' s2 – Slowest queries report (requires pg_stat_statements)'
2626
\echo ' t1 – Postgres parameters tuning'
27+
\echo ' t2 – Storage parameters (reloptions)'
2728
\echo ' v1 – Vacuum: current activity'
2829
\echo ' v2 – VACUUM progress and autovacuum queue'
2930
\echo ' q – Quit'
@@ -56,6 +57,7 @@ select
5657
:d_stp::text = 's1' as d_step_is_s1,
5758
:d_stp::text = 's2' as d_step_is_s2,
5859
:d_stp::text = 't1' as d_step_is_t1,
60+
:d_stp::text = 't2' as d_step_is_t2,
5961
:d_stp::text = 'v1' as d_step_is_v1,
6062
:d_stp::text = 'v2' as d_step_is_v2,
6163
:d_stp::text = 'q' as d_step_is_q \gset
@@ -158,6 +160,10 @@ select
158160
\ir ./sql/t1_tuning.sql
159161
\prompt 'Press <Enter> to continue…' d_dummy
160162
\ir ./start.psql
163+
\elif :d_step_is_t2
164+
\ir ./sql/t2_storage_parameters.sql
165+
\prompt 'Press <Enter> to continue…' d_dummy
166+
\ir ./start.psql
161167
\elif :d_step_is_v1
162168
\ir ./sql/v1_vacuum_activity.sql
163169
\prompt 'Press <Enter> to continue…' d_dummy

0 commit comments

Comments
 (0)