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;
0 commit comments