Skip to content

Commit 717080c

Browse files
committed
Merge branch 'master' of github.com:NikolayS/postgres_dba into postgres10
Conflicts: start.psql
2 parents a3c4aa3 + cd96057 commit 717080c

File tree

6 files changed

+116
-9
lines changed

6 files changed

+116
-9
lines changed

README.md

Lines changed: 3 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -4,9 +4,11 @@ The missing set of useful tools for Postgres DBA and mere mortals.
44

55
:warning: The project is in its very early stage. If you have great ideas, feel free to create a pull request or open an issue.
66

7+
<img width="709" alt="screen shot 2018-03-17 at 14 34 04" src="https://user-images.githubusercontent.com/1345402/37560150-78b4b24e-29f0-11e8-9b3f-7d68b13631e1.png">
8+
79
## Questions?
810

9-
Questions? Ideas? Write me: samokhvalov@gmail.com, Nikolay Samokhvalov.
11+
Questions? Ideas? Contact me: samokhvalov@gmail.com, Nikolay Samokhvalov.
1012

1113
## Credits
1214

@@ -45,8 +47,6 @@ And type `:dba <Enter>` in psql. (Or `\i /path/to/postgres_dba/start.psql` if yo
4547

4648
– it will open interactive menu.
4749

48-
<img width="779" alt="screen shot 2018-01-05 at 13 14 30" src="https://user-images.githubusercontent.com/1345402/34628761-6b98b988-f21a-11e7-8e5c-ab2580389a5c.png">
49-
5050
### Connect to Remote Postgres Server
5151
What to do if you need to connect to a remote Postgres server? Usually, Postgres is behind a firewall and/or doesn't listen to a public network interface. So you need to be able to connect to the server using SSH. If you can do it, then just create SSH tunnel (assuming that Postgres listens to default port 5432 on that server:
5252

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: 2 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
--General Table Size Information
1+
--Table Size
22

33
with data as (
44
select
@@ -38,6 +38,7 @@ with data as (
3838
sum(toast_bytes) as toast_bytes,
3939
sum(table_bytes) as table_bytes
4040
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
4142
group by tblspace
4243
union all
4344
select null::oid, null, null, null, null, null, null, null, null

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

start.psql

Lines changed: 9 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -27,9 +27,10 @@ select regexp_replace(version(), '^PostgreSQL (\d+\.\d+).*$', e'\\1')::numeric >
2727
reset client_min_messages;
2828
\endif
2929
\echo '\033[1;35mMenu:\033[0m'
30-
\echo ' 1 – Basic Node Information (master/replica, lag, DB size, tmp files)'
31-
\echo ' 2 – General Table Size Information'
32-
\echo ' a1 – Alignmet Padding Analysis: how many bytes can be saved if columns are ordered better?'
30+
\echo ' 1 – Node Information: master/replica, lag, DB size, tmp files, etc'
31+
\echo ' 2 – Table Size'
32+
\echo ' 3 – Load Profile'
33+
\echo ' a1 – [EXPERIMENTAL] Alignment Padding. How many bytes can be saved if columns are ordered better?'
3334
\echo ' b1 – Tables Bloat, rough estimation'
3435
\echo ' b2 – B-tree Indexes Bloat, rough estimation'
3536
\echo ' b3 – Tables Bloat, more precise (requires pgstattuple extension; expensive)'
@@ -53,6 +54,7 @@ select regexp_replace(version(), '^PostgreSQL (\d+\.\d+).*$', e'\\1')::numeric >
5354
select
5455
:d_stp::text = '1' as d_step_is_1,
5556
:d_stp::text = '2' as d_step_is_2,
57+
:d_stp::text = '3' as d_step_is_3,
5658
:d_stp::text = 'a1' as d_step_is_a1,
5759
:d_stp::text = 'b1' as d_step_is_b1,
5860
:d_stp::text = 'b2' as d_step_is_b2,
@@ -88,6 +90,10 @@ set postgres_dba.wide = 'on';
8890
\ir ./sql/2_table_sizes.sql
8991
\prompt 'Press <Enter> to continue…' d_dummy
9092
\ir ./start.psql
93+
\elif :d_step_is_3
94+
\ir ./sql/3_load_profiles.sql
95+
\prompt 'Press <Enter> to continue…' d_dummy
96+
\ir ./start.psql
9197
\elif :d_step_is_a1
9298
\ir ./sql/a1_alignment_padding.sql
9399
\prompt 'Press <Enter> to continue…' d_dummy

0 commit comments

Comments
 (0)