Skip to content

Commit 74876cb

Browse files
authored
Merge pull request #11 from NikolayS/tablespaces_and_load_profiles
New report: Load Profile + tablespaces info for Table Sizes report
2 parents 6dfa998 + 93f16cf commit 74876cb

File tree

6 files changed

+137
-14
lines changed

6 files changed

+137
-14
lines changed

sql/1_basic.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
--Basic Node Information (master/replica, lag, DB size, tmp files)
1+
--Node Information: master/replica, lag, DB size, tmp files, etc
22
with data as (
33
select s.*
44
from pg_stat_database s

sql/2_table_sizes.sql

Lines changed: 25 additions & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -1,8 +1,9 @@
1-
--General Table Size Information
1+
--Table Size
22

33
with data as (
44
select
55
c.oid,
6+
(select spcname from pg_tablespace where oid = reltablespace) as tblspace,
67
nspname as schema_name,
78
relname as table_name,
89
c.reltuples as row_estimate,
@@ -12,10 +13,11 @@ with data as (
1213
pg_total_relation_size(c.oid) - pg_indexes_size(c.oid) - coalesce(pg_total_relation_size(reltoastrelid), 0) as table_bytes
1314
from pg_class c
1415
left join pg_namespace n on n.oid = c.relnamespace
15-
where relkind = 'r'
16+
where relkind = 'r' and nspname <> 'pg_catalog'
1617
), data2 as (
1718
select
1819
null::oid as oid,
20+
null as tblspace,
1921
null as schema_name,
2022
'*** TOTAL ***' as table_name,
2123
sum(row_estimate) as row_estimate,
@@ -25,23 +27,37 @@ with data as (
2527
sum(table_bytes) as table_bytes
2628
from data
2729
union all
28-
select null::oid, null, null, null, null, null, null, null
30+
select
31+
null::oid as oid,
32+
null,
33+
null as schema_name,
34+
' tablespace: [' || coalesce(tblspace, 'pg_default') || ']' as table_name,
35+
sum(row_estimate) as row_estimate,
36+
sum(total_bytes) as total_bytes,
37+
sum(index_bytes) as index_bytes,
38+
sum(toast_bytes) as toast_bytes,
39+
sum(table_bytes) as table_bytes
40+
from data
41+
where (select count(distinct coalesce(tblspace, 'pg_default')) from data) > 1 -- don't show this part if there are no custom tablespaces
42+
group by tblspace
43+
union all
44+
select null::oid, null, null, null, null, null, null, null, null
2945
union all
3046
select * from data
3147
)
3248
select
33-
coalesce(nullif(schema_name, 'public') || '.', '') || table_name as "Table",
49+
coalesce(nullif(schema_name, 'public') || '.', '') || table_name || coalesce(' [' || tblspace || ']', '') as "Table",
3450
'~' || case
3551
when row_estimate > 10^12 then round(row_estimate::numeric / 10^12::numeric, 0)::text || 'T'
3652
when row_estimate > 10^9 then round(row_estimate::numeric / 10^9::numeric, 0)::text || 'B'
3753
when row_estimate > 10^6 then round(row_estimate::numeric / 10^6::numeric, 0)::text || 'M'
3854
when row_estimate > 10^3 then round(row_estimate::numeric / 10^3::numeric, 0)::text || 'k'
3955
else row_estimate::text
4056
end as "Rows",
41-
pg_size_pretty(total_bytes) || ' (' || round(100 * total_bytes::numeric / sum(total_bytes) over (partition by (schema_name is null)), 2)::text || '%)' as "Total Size",
42-
pg_size_pretty(table_bytes) || ' (' || round(100 * table_bytes::numeric / sum(table_bytes) over (partition by (schema_name is null)), 2)::text || '%)' as "Table Size",
43-
pg_size_pretty(index_bytes) || ' (' || round(100 * index_bytes::numeric / sum(index_bytes) over (partition by (schema_name is null)), 2)::text || '%)' as "Index(es) Size",
44-
pg_size_pretty(toast_bytes) || ' (' || round(100 * toast_bytes::numeric / sum(toast_bytes) over (partition by (schema_name is null)), 2)::text || '%)' as "TOAST Size"
57+
pg_size_pretty(total_bytes) || ' (' || round(100 * total_bytes::numeric / sum(total_bytes) over (partition by (schema_name is null), left(table_name, 3) = '***'), 2)::text || '%)' as "Total Size",
58+
pg_size_pretty(table_bytes) || ' (' || round(100 * table_bytes::numeric / sum(table_bytes) over (partition by (schema_name is null), left(table_name, 3) = '***'), 2)::text || '%)' as "Table Size",
59+
pg_size_pretty(index_bytes) || ' (' || round(100 * index_bytes::numeric / sum(index_bytes) over (partition by (schema_name is null), left(table_name, 3) = '***'), 2)::text || '%)' as "Index(es) Size",
60+
pg_size_pretty(toast_bytes) || ' (' || round(100 * toast_bytes::numeric / sum(toast_bytes) over (partition by (schema_name is null), left(table_name, 3) = '***'), 2)::text || '%)' as "TOAST Size"
4561
\if :postgres_dba_wide
4662
,
4763
row_estimate,
@@ -51,6 +67,7 @@ select
5167
toast_bytes,
5268
schema_name,
5369
table_name,
70+
tblspace,
5471
oid
5572
\endif
5673
from data2

sql/3_load_profiles.sql

Lines changed: 100 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,100 @@
1+
--Load Profile
2+
3+
with data as (
4+
select
5+
s.relname as table_name,
6+
s.schemaname as schema_name,
7+
(select spcname from pg_tablespace where oid = reltablespace) as tblspace,
8+
*,
9+
case when n_tup_upd = 0 then null else n_tup_hot_upd::numeric / n_tup_upd end as upd_hot_ratio,
10+
seq_tup_read + coalesce(idx_tup_fetch, 0) - n_tup_del - n_tup_upd as tuples_selected,
11+
seq_tup_read + coalesce(idx_tup_fetch, 0) + n_tup_ins as processed_tup_total -- we don't add _del and _upd here (already counted via seq_ & idx_)
12+
from pg_stat_user_tables s
13+
join pg_class c on c.oid = relid
14+
), data2 as (
15+
select
16+
0 as ord,
17+
'*** TOTAL ***' as table_name,
18+
null as schema_name,
19+
null as tblspace,
20+
sum(seq_tup_read) as seq_tup_read,
21+
sum(idx_tup_fetch) as idx_tup_fetch,
22+
sum(tuples_selected) as tuples_selected,
23+
sum(n_tup_ins) as n_tup_ins,
24+
sum(n_tup_del) as n_tup_del,
25+
sum(n_tup_upd) as n_tup_upd,
26+
sum(n_tup_hot_upd) as n_tup_hot_upd,
27+
avg(upd_hot_ratio) as upd_hot_ratio,
28+
sum(processed_tup_total) as processed_tup_total
29+
from data
30+
union all
31+
select
32+
1 as ord,
33+
' tablespace: [' || coalesce(tblspace, 'pg_default') || ']' as table_name,
34+
null as schema_name,
35+
null, -- we don't need to pass real tblspace value for this aggregated record further
36+
sum(seq_tup_read) as seq_tup_read,
37+
sum(idx_tup_fetch) as idx_tup_fetch,
38+
sum(tuples_selected) as tuples_selected,
39+
sum(n_tup_ins) as n_tup_ins,
40+
sum(n_tup_del) as n_tup_del,
41+
sum(n_tup_upd) as n_tup_upd,
42+
sum(n_tup_hot_upd) as n_tup_hot_upd,
43+
avg(upd_hot_ratio) as upd_hot_ratio,
44+
sum(processed_tup_total) as processed_tup_total
45+
from data
46+
where (select count(distinct coalesce(tblspace, 'pg_default')) from data) > 1 -- don't show this part if there are no custom tablespaces
47+
group by tblspace
48+
union all
49+
select 3, null, null, null, null, null, null, null, null, null, null, null, null
50+
union all
51+
select 4, table_name, schema_name, tblspace, seq_tup_read, idx_tup_fetch, tuples_selected, n_tup_ins, n_tup_del, n_tup_upd, n_tup_hot_upd, upd_hot_ratio, processed_tup_total
52+
from data
53+
)
54+
select
55+
coalesce(nullif(schema_name, 'public') || '.', '') || table_name || coalesce(' [' || tblspace || ']', '') as "Table",
56+
(
57+
with ops as (
58+
select * from data2 d2 where d2.schema_name is not distinct from data2.schema_name and d2.table_name = data2.table_name
59+
), ops_ratios(opname, ratio) as (
60+
select
61+
'select',
62+
case when processed_tup_total > 0 then tuples_selected::numeric / processed_tup_total else 0 end
63+
from ops
64+
union all
65+
select
66+
'insert',
67+
case when processed_tup_total > 0 then n_tup_ins::numeric / processed_tup_total else 0 end
68+
from ops
69+
union all
70+
select
71+
'delete',
72+
case when processed_tup_total > 0 then n_tup_del::numeric / processed_tup_total else 0 end
73+
from ops
74+
union all
75+
select
76+
'update',
77+
case when processed_tup_total > 0 then n_tup_upd::numeric / processed_tup_total else 0 end
78+
from ops
79+
)
80+
select
81+
case
82+
when ratio > .7 then upper(opname) || ' ~' || round(100 * ratio, 2)::text || '%'
83+
else 'Mixed: ' || (
84+
select string_agg(upper(left(opname, 1)) || ' ~' || round(100 * ratio, 2)::text || '%', ', ' order by ratio desc)
85+
from (select * from ops_ratios where ratio > .2) _
86+
)
87+
end
88+
from ops_ratios
89+
order by ratio desc
90+
limit 1
91+
) as "Load Type",
92+
processed_tup_total as "Total (S+I+D+U)",
93+
tuples_selected as "SELECTed",
94+
n_tup_ins as "INSERTed",
95+
n_tup_del as "DELETEd",
96+
n_tup_upd as "UPDATEd",
97+
round(100 * upd_hot_ratio, 2) as "HOT-updated, %",
98+
case when seq_tup_read + coalesce(idx_tup_fetch, 0) > 0 then round(100 * seq_tup_read::numeric / (seq_tup_read + coalesce(idx_tup_fetch, 0)), 2) else 0 end as "SeqScan, %"
99+
from data2
100+
order by ord, processed_tup_total desc;

sql/a1_alignment_padding.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
--Alignmet Padding Analysis: how many bytes can be saved if columns are ordered better?
1+
--[EXPERIMENTAL] Alignment Padding. How many bytes can be saved if columns are ordered better?
22

33
-- TODO: not-yet-analyzed tables – show a warning (cannot get n_live_tup -> cannot get total bytes)
44
-- TODO: NULLs

sql/s1_pg_stat_statements_top_total.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -20,7 +20,7 @@ select
2020
min(min_time) as min_time,
2121
-- stddev_time, -- https://stats.stackexchange.com/questions/55999/is-it-possible-to-find-the-combined-standard-deviation
2222
sum(rows) as rows,
23-
userid,
23+
(select usename from pg_user where usesysid = userid) as usr,
2424
(select datname from pg_database where oid = dbid) as db,
2525
query,
2626
sum(shared_blks_hit) as shared_blks_hit,

start.psql

Lines changed: 9 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -14,9 +14,10 @@ select regexp_replace(version(), '^PostgreSQL (\d+\.\d+).*$', e'\\1')::numeric >
1414
reset client_min_messages;
1515
\endif
1616
\echo '\033[1;35mMenu:\033[0m'
17-
\echo ' 1 – Basic Node Information (master/replica, lag, DB size, tmp files)'
18-
\echo ' 2 – General Table Size Information'
19-
\echo ' a1 – Alignment Padding Analysis: how many bytes can be saved if columns are ordered better?'
17+
\echo ' 1 – Node Information: master/replica, lag, DB size, tmp files, etc'
18+
\echo ' 2 – Table Size'
19+
\echo ' 3 – Load Profile'
20+
\echo ' a1 – [EXPERIMENTAL] Alignment Padding. How many bytes can be saved if columns are ordered better?'
2021
\echo ' b1 – Tables Bloat, rough estimation'
2122
\echo ' b2 – B-tree Indexes Bloat, rough estimation'
2223
\echo ' b3 – Tables Bloat, more precise (requires pgstattuple extension; expensive)'
@@ -40,6 +41,7 @@ select regexp_replace(version(), '^PostgreSQL (\d+\.\d+).*$', e'\\1')::numeric >
4041
select
4142
:d_stp::text = '1' as d_step_is_1,
4243
:d_stp::text = '2' as d_step_is_2,
44+
:d_stp::text = '3' as d_step_is_3,
4345
:d_stp::text = 'a1' as d_step_is_a1,
4446
:d_stp::text = 'b1' as d_step_is_b1,
4547
:d_stp::text = 'b2' as d_step_is_b2,
@@ -75,6 +77,10 @@ set postgres_dba.wide = 'on';
7577
\ir ./sql/2_table_sizes.sql
7678
\prompt 'Press <Enter> to continue…' d_dummy
7779
\ir ./start.psql
80+
\elif :d_step_is_3
81+
\ir ./sql/3_load_profiles.sql
82+
\prompt 'Press <Enter> to continue…' d_dummy
83+
\ir ./start.psql
7884
\elif :d_step_is_a1
7985
\ir ./sql/a1_alignment_padding.sql
8086
\prompt 'Press <Enter> to continue…' d_dummy

0 commit comments

Comments
 (0)