Skip to content

Commit 7da9d57

Browse files
authored
Merge pull request #46 from NikolayS/more-reports
2 new reports: lock trees and autovacuum queue
2 parents 24a5f66 + 361bba2 commit 7da9d57

5 files changed

+143
-6
lines changed

sql/i2_redundant_indexes.sql

+1-1
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
-- List of redundant indexes
1+
--List of redundant indexes
22

33
-- Use it to see redundant indexes list
44

sql/i4_invalid_indexes.sql

+2-2
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
-- List of invalid indexes
1+
--List of invalid indexes
22

33
-- Use it to see invalid indexes list
44

@@ -29,4 +29,4 @@ from pg_index pidx
2929
join pg_class as pci on pci.oid = pidx.indexrelid
3030
join pg_class as pct on pct.oid = pidx.indrelid
3131
left join pg_namespace pn on pn.oid = pct.relnamespace
32-
where pidx.indisvalid = false;
32+
where pidx.indisvalid = false;

sql/l1_lock_trees.sql

+53
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,53 @@
1+
--Locks: analysis of "locking trees"
2+
3+
-- Based on: https://gitlab.com/snippets/1890428
4+
with recursive l as (
5+
select
6+
pid, locktype, granted,
7+
array_position(array['AccessShare','RowShare','RowExclusive','ShareUpdateExclusive','Share','ShareRowExclusive','Exclusive','AccessExclusive'], left(mode, -4)) m,
8+
row(locktype, database, relation, page, tuple, virtualxid, transactionid, classid, objid, objsubid) obj
9+
from pg_locks
10+
), pairs as (
11+
select w.pid waiter, l.pid locker, l.obj, l.m
12+
from l w join l on l.obj is not distinct from w.obj and l.locktype = w.locktype and not l.pid = w.pid and l.granted
13+
where not w.granted
14+
and not exists (select from l i where i.pid=l.pid and i.locktype = l.locktype and i.obj is not distinct from l.obj and i.m > l.m)
15+
), leads as (
16+
select o.locker, 1::int lvl, count(*) q, array[locker] track, false as cycle
17+
from pairs o
18+
group by o.locker
19+
union all
20+
select i.locker, leads.lvl + 1, (select count(*) from pairs q where q.locker = i.locker), leads.track || i.locker, i.locker = any(leads.track)
21+
from pairs i, leads
22+
where i.waiter=leads.locker and not cycle
23+
), tree as (
24+
select locker pid,locker dad,locker root,case when cycle then track end dl, null::record obj,0 lvl, locker::text path, array_agg(locker) over () all_pids
25+
from leads o
26+
where
27+
(cycle and not exists (select from leads i where i.locker=any(o.track) and (i.lvl>o.lvl or i.q<o.q)))
28+
or (not cycle and not exists (select from pairs where waiter=o.locker) and not exists (select from leads i where i.locker=o.locker and i.lvl>o.lvl))
29+
union all
30+
select w.waiter pid,tree.pid,tree.root,case when w.waiter=any(tree.dl) then tree.dl end,w.obj,tree.lvl+1,tree.path||'.'||w.waiter,all_pids || array_agg(w.waiter) over ()
31+
from tree
32+
join pairs w on tree.pid=w.locker and not w.waiter = any (all_pids)
33+
)
34+
select (clock_timestamp() - a.xact_start)::interval(0) as transaction_age,
35+
(clock_timestamp() - a.state_change)::interval(0) as change_age,
36+
a.datname,
37+
a.usename,
38+
a.client_addr,
39+
--w.obj wait_on_object,
40+
tree.pid,
41+
--(select array_to_json(array_agg(json_build_object(mode, granted))) from pg_locks pl where pl.pid = tree.pid) as locks,
42+
a.wait_event_type,
43+
a.wait_event,
44+
pg_blocking_pids(tree.pid) blocked_by_pids,
45+
replace(a.state, 'idle in transaction', 'idletx') state,
46+
lvl,
47+
(select count(*) from tree p where p.path ~ ('^'||tree.path) and not p.path=tree.path) blocking_others,
48+
case when tree.pid=any(tree.dl) then '!>' else repeat(' .', lvl) end||' '||trim(left(regexp_replace(a.query, e'\\s+', ' ', 'g'),300)) latest_query_in_tx
49+
from tree
50+
left join pairs w on w.waiter = tree.pid and w.locker = tree.dad
51+
join pg_stat_activity a using (pid)
52+
join pg_stat_activity r on r.pid=tree.root
53+
order by (now() - r.xact_start), path;
+73
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,73 @@
1+
--Vacuum: VACUUM progress and autovacuum queue
2+
3+
-- Based on: https://gitlab.com/snippets/1889668
4+
5+
with table_opts as (
6+
select
7+
pg_class.oid,
8+
relname,
9+
nspname,
10+
array_to_string(reloptions, '') as relopts
11+
from pg_class
12+
join pg_namespace ns on relnamespace = ns.oid
13+
), vacuum_settings as (
14+
select
15+
oid,
16+
relname,
17+
nspname,
18+
case
19+
when relopts like '%autovacuum_vacuum_threshold%' then regexp_replace(relopts, '.*autovacuum_vacuum_threshold=([0-9.]+).*', E'\\1')::int8
20+
else current_setting('autovacuum_vacuum_threshold')::int8
21+
end as autovacuum_vacuum_threshold,
22+
case
23+
when relopts like '%autovacuum_vacuum_scale_factor%' then regexp_replace(relopts, '.*autovacuum_vacuum_scale_factor=([0-9.]+).*', E'\\1')::numeric
24+
else current_setting('autovacuum_vacuum_scale_factor')::numeric
25+
end as autovacuum_vacuum_scale_factor,
26+
case when relopts ~ 'autovacuum_enabled=(false|off)' then false else true end as autovacuum_enabled
27+
from table_opts
28+
), p as (
29+
select *
30+
from pg_stat_progress_vacuum
31+
)
32+
select
33+
--vacuum_settings.oid,
34+
coalesce(
35+
coalesce(nullif(vacuum_settings.nspname, 'public') || '.', '') || vacuum_settings.relname, -- current DB
36+
format('[something in "%I"]', p.datname)
37+
) as table,
38+
round((100 * psat.n_dead_tup::numeric / nullif(pg_class.reltuples, 0))::numeric, 2) as dead_tup_pct,
39+
pg_class.reltuples::numeric,
40+
psat.n_dead_tup,
41+
'vt: ' || vacuum_settings.autovacuum_vacuum_threshold
42+
|| ', vsf: ' || vacuum_settings.autovacuum_vacuum_scale_factor
43+
|| case when not autovacuum_enabled then ', DISABLED' else ', enabled' end as "effective_settings",
44+
case
45+
when last_autovacuum > coalesce(last_vacuum, '0001-01-01') then left(last_autovacuum::text, 19) || ' (auto)'
46+
when last_vacuum is not null then left(last_vacuum::text, 19) || ' (manual)'
47+
else null
48+
end as "last_vacuumed",
49+
coalesce(p.phase, '~~~ in queue ~~~') as status,
50+
p.pid as pid,
51+
case
52+
when a.query ~ '^autovacuum.*to prevent wraparound' then 'wraparound'
53+
when a.query ~ '^vacuum' then 'user'
54+
when a.pid is null then null
55+
else 'regular'
56+
end as mode,
57+
case when a.pid is null then null else coalesce(wait_event_type ||'.'|| wait_event, 'f') end as waiting,
58+
round(100.0 * p.heap_blks_scanned / nullif(p.heap_blks_total, 0), 1) AS scanned_pct,
59+
round(100.0 * p.heap_blks_vacuumed / nullif(p.heap_blks_total, 0), 1) AS vacuumed_pct,
60+
p.index_vacuum_count,
61+
case
62+
when psat.relid is not null and p.relid is not null then
63+
(select count(*) from pg_index where indrelid = psat.relid)
64+
else null
65+
end as index_count
66+
from pg_stat_all_tables psat
67+
join pg_class on psat.relid = pg_class.oid
68+
join vacuum_settings on pg_class.oid = vacuum_settings.oid
69+
full outer join p on p.relid = psat.relid and p.datname = current_database()
70+
left join pg_stat_activity a using (pid)
71+
where
72+
psat.relid is null
73+
or autovacuum_vacuum_threshold + (autovacuum_vacuum_scale_factor::numeric * pg_class.reltuples) < psat.n_dead_tup;

start.psql

+14-3
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,3 @@
1-
\set postgres_dba_interactive_mode true
21
\ir warmup.psql
32
\echo '\033[1;35mMenu:\033[0m'
43
\echo ' 0 – Node & Current DB Information: master/replica, lag, DB size, tmp files, etc'
@@ -13,15 +12,17 @@
1312
\echo ' b5 – Tables and Columns Without Stats (so bloat cannot be estimated)'
1413
\echo ' e1 – List of extensions installed in the current DB'
1514
\echo ' i1 – Unused/Rarely Used Indexes'
16-
\echo ' i2 – Redundant Indexes'
15+
\echo ' i2 – List of redundant indexes'
1716
\echo ' i3 – FKs with Missing/Bad Indexes'
18-
\echo ' i4 – Invalid Indexes'
17+
\echo ' i4 – List of invalid indexes'
1918
\echo ' i5 – Unused/Redundant Indexes Do & Undo Migration DDL'
19+
\echo ' l1 – Locks: analysis of "locking trees"'
2020
\echo ' p1 – [EXPERIMENTAL] Alignment Padding. How many bytes can be saved if columns are ordered better?'
2121
\echo ' s1 – Slowest Queries, by Total Time (requires pg_stat_statements extension)'
2222
\echo ' s2 – Slowest Queries Report (requires pg_stat_statements)'
2323
\echo ' t1 – Postgres parameters tuning'
2424
\echo ' v1 – Vacuum: Current Activity'
25+
\echo ' v2 – Vacuum: VACUUM progress and autovacuum queue'
2526
\echo ' q – Quit'
2627
\echo
2728
\echo Type your choice and press <Enter>:
@@ -44,11 +45,13 @@ select
4445
:d_stp::text = 'i3' as d_step_is_i3,
4546
:d_stp::text = 'i4' as d_step_is_i4,
4647
:d_stp::text = 'i5' as d_step_is_i5,
48+
:d_stp::text = 'l1' as d_step_is_l1,
4749
:d_stp::text = 'p1' as d_step_is_p1,
4850
:d_stp::text = 's1' as d_step_is_s1,
4951
:d_stp::text = 's2' as d_step_is_s2,
5052
:d_stp::text = 't1' as d_step_is_t1,
5153
:d_stp::text = 'v1' as d_step_is_v1,
54+
:d_stp::text = 'v2' as d_step_is_v2,
5255
:d_stp::text = 'q' as d_step_is_q \gset
5356
\if :d_step_is_q
5457
\echo 'Bye!'
@@ -117,6 +120,10 @@ select
117120
\ir ./sql/i5_indexes_migration.sql
118121
\prompt 'Press <Enter> to continue…' d_dummy
119122
\ir ./start.psql
123+
\elif :d_step_is_l1
124+
\ir ./sql/l1_lock_trees.sql
125+
\prompt 'Press <Enter> to continue…' d_dummy
126+
\ir ./start.psql
120127
\elif :d_step_is_p1
121128
\ir ./sql/p1_alignment_padding.sql
122129
\prompt 'Press <Enter> to continue…' d_dummy
@@ -137,6 +144,10 @@ select
137144
\ir ./sql/v1_vacuum_activity.sql
138145
\prompt 'Press <Enter> to continue…' d_dummy
139146
\ir ./start.psql
147+
\elif :d_step_is_v2
148+
\ir ./sql/v2_autovacuum_progress_and_queue.sql
149+
\prompt 'Press <Enter> to continue…' d_dummy
150+
\ir ./start.psql
140151
\else
141152
\echo
142153
\echo '\033[1;31mError:\033[0m Unknown option! Try again.'

0 commit comments

Comments
 (0)