Skip to content

2 new reports: lock trees and autovacuum queue #46

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 1 commit into from
May 25, 2020
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 1 addition & 1 deletion sql/i2_redundant_indexes.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
-- List of redundant indexes
--List of redundant indexes

-- Use it to see redundant indexes list

Expand Down
4 changes: 2 additions & 2 deletions sql/i4_invalid_indexes.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
-- List of invalid indexes
--List of invalid indexes

-- Use it to see invalid indexes list

Expand Down Expand Up @@ -29,4 +29,4 @@ from pg_index pidx
join pg_class as pci on pci.oid = pidx.indexrelid
join pg_class as pct on pct.oid = pidx.indrelid
left join pg_namespace pn on pn.oid = pct.relnamespace
where pidx.indisvalid = false;
where pidx.indisvalid = false;
53 changes: 53 additions & 0 deletions sql/l1_lock_trees.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,53 @@
--Locks: analysis of "locking trees"

-- Based on: https://gitlab.com/snippets/1890428
with recursive l as (
select
pid, locktype, granted,
array_position(array['AccessShare','RowShare','RowExclusive','ShareUpdateExclusive','Share','ShareRowExclusive','Exclusive','AccessExclusive'], left(mode, -4)) m,
row(locktype, database, relation, page, tuple, virtualxid, transactionid, classid, objid, objsubid) obj
from pg_locks
), pairs as (
select w.pid waiter, l.pid locker, l.obj, l.m
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
where not w.granted
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)
), leads as (
select o.locker, 1::int lvl, count(*) q, array[locker] track, false as cycle
from pairs o
group by o.locker
union all
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)
from pairs i, leads
where i.waiter=leads.locker and not cycle
), tree as (
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
from leads o
where
(cycle and not exists (select from leads i where i.locker=any(o.track) and (i.lvl>o.lvl or i.q<o.q)))
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))
union all
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 ()
from tree
join pairs w on tree.pid=w.locker and not w.waiter = any (all_pids)
)
select (clock_timestamp() - a.xact_start)::interval(0) as transaction_age,
(clock_timestamp() - a.state_change)::interval(0) as change_age,
a.datname,
a.usename,
a.client_addr,
--w.obj wait_on_object,
tree.pid,
--(select array_to_json(array_agg(json_build_object(mode, granted))) from pg_locks pl where pl.pid = tree.pid) as locks,
a.wait_event_type,
a.wait_event,
pg_blocking_pids(tree.pid) blocked_by_pids,
replace(a.state, 'idle in transaction', 'idletx') state,
lvl,
(select count(*) from tree p where p.path ~ ('^'||tree.path) and not p.path=tree.path) blocking_others,
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
from tree
left join pairs w on w.waiter = tree.pid and w.locker = tree.dad
join pg_stat_activity a using (pid)
join pg_stat_activity r on r.pid=tree.root
order by (now() - r.xact_start), path;
73 changes: 73 additions & 0 deletions sql/v2_autovacuum_progress_and_queue.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,73 @@
--Vacuum: VACUUM progress and autovacuum queue

-- Based on: https://gitlab.com/snippets/1889668

with table_opts as (
select
pg_class.oid,
relname,
nspname,
array_to_string(reloptions, '') as relopts
from pg_class
join pg_namespace ns on relnamespace = ns.oid
), vacuum_settings as (
select
oid,
relname,
nspname,
case
when relopts like '%autovacuum_vacuum_threshold%' then regexp_replace(relopts, '.*autovacuum_vacuum_threshold=([0-9.]+).*', E'\\1')::int8
else current_setting('autovacuum_vacuum_threshold')::int8
end as autovacuum_vacuum_threshold,
case
when relopts like '%autovacuum_vacuum_scale_factor%' then regexp_replace(relopts, '.*autovacuum_vacuum_scale_factor=([0-9.]+).*', E'\\1')::numeric
else current_setting('autovacuum_vacuum_scale_factor')::numeric
end as autovacuum_vacuum_scale_factor,
case when relopts ~ 'autovacuum_enabled=(false|off)' then false else true end as autovacuum_enabled
from table_opts
), p as (
select *
from pg_stat_progress_vacuum
)
select
--vacuum_settings.oid,
coalesce(
coalesce(nullif(vacuum_settings.nspname, 'public') || '.', '') || vacuum_settings.relname, -- current DB
format('[something in "%I"]', p.datname)
) as table,
round((100 * psat.n_dead_tup::numeric / nullif(pg_class.reltuples, 0))::numeric, 2) as dead_tup_pct,
pg_class.reltuples::numeric,
psat.n_dead_tup,
'vt: ' || vacuum_settings.autovacuum_vacuum_threshold
|| ', vsf: ' || vacuum_settings.autovacuum_vacuum_scale_factor
|| case when not autovacuum_enabled then ', DISABLED' else ', enabled' end as "effective_settings",
case
when last_autovacuum > coalesce(last_vacuum, '0001-01-01') then left(last_autovacuum::text, 19) || ' (auto)'
when last_vacuum is not null then left(last_vacuum::text, 19) || ' (manual)'
else null
end as "last_vacuumed",
coalesce(p.phase, '~~~ in queue ~~~') as status,
p.pid as pid,
case
when a.query ~ '^autovacuum.*to prevent wraparound' then 'wraparound'
when a.query ~ '^vacuum' then 'user'
when a.pid is null then null
else 'regular'
end as mode,
case when a.pid is null then null else coalesce(wait_event_type ||'.'|| wait_event, 'f') end as waiting,
round(100.0 * p.heap_blks_scanned / nullif(p.heap_blks_total, 0), 1) AS scanned_pct,
round(100.0 * p.heap_blks_vacuumed / nullif(p.heap_blks_total, 0), 1) AS vacuumed_pct,
p.index_vacuum_count,
case
when psat.relid is not null and p.relid is not null then
(select count(*) from pg_index where indrelid = psat.relid)
else null
end as index_count
from pg_stat_all_tables psat
join pg_class on psat.relid = pg_class.oid
join vacuum_settings on pg_class.oid = vacuum_settings.oid
full outer join p on p.relid = psat.relid and p.datname = current_database()
left join pg_stat_activity a using (pid)
where
psat.relid is null
or autovacuum_vacuum_threshold + (autovacuum_vacuum_scale_factor::numeric * pg_class.reltuples) < psat.n_dead_tup;
17 changes: 14 additions & 3 deletions start.psql
Original file line number Diff line number Diff line change
@@ -1,4 +1,3 @@
\set postgres_dba_interactive_mode true
\ir warmup.psql
\echo '\033[1;35mMenu:\033[0m'
\echo ' 0 – Node & Current DB Information: master/replica, lag, DB size, tmp files, etc'
Expand All @@ -13,15 +12,17 @@
\echo ' b5 – Tables and Columns Without Stats (so bloat cannot be estimated)'
\echo ' e1 – List of extensions installed in the current DB'
\echo ' i1 – Unused/Rarely Used Indexes'
\echo ' i2 – Redundant Indexes'
\echo ' i2 – List of redundant indexes'
\echo ' i3 – FKs with Missing/Bad Indexes'
\echo ' i4 – Invalid Indexes'
\echo ' i4 – List of invalid indexes'
\echo ' i5 – Unused/Redundant Indexes Do & Undo Migration DDL'
\echo ' l1 – Locks: analysis of "locking trees"'
\echo ' p1 – [EXPERIMENTAL] Alignment Padding. How many bytes can be saved if columns are ordered better?'
\echo ' s1 – Slowest Queries, by Total Time (requires pg_stat_statements extension)'
\echo ' s2 – Slowest Queries Report (requires pg_stat_statements)'
\echo ' t1 – Postgres parameters tuning'
\echo ' v1 – Vacuum: Current Activity'
\echo ' v2 – Vacuum: VACUUM progress and autovacuum queue'
\echo ' q – Quit'
\echo
\echo Type your choice and press <Enter>:
Expand All @@ -44,11 +45,13 @@ select
:d_stp::text = 'i3' as d_step_is_i3,
:d_stp::text = 'i4' as d_step_is_i4,
:d_stp::text = 'i5' as d_step_is_i5,
:d_stp::text = 'l1' as d_step_is_l1,
:d_stp::text = 'p1' as d_step_is_p1,
:d_stp::text = 's1' as d_step_is_s1,
:d_stp::text = 's2' as d_step_is_s2,
:d_stp::text = 't1' as d_step_is_t1,
:d_stp::text = 'v1' as d_step_is_v1,
:d_stp::text = 'v2' as d_step_is_v2,
:d_stp::text = 'q' as d_step_is_q \gset
\if :d_step_is_q
\echo 'Bye!'
Expand Down Expand Up @@ -117,6 +120,10 @@ select
\ir ./sql/i5_indexes_migration.sql
\prompt 'Press <Enter> to continue…' d_dummy
\ir ./start.psql
\elif :d_step_is_l1
\ir ./sql/l1_lock_trees.sql
\prompt 'Press <Enter> to continue…' d_dummy
\ir ./start.psql
\elif :d_step_is_p1
\ir ./sql/p1_alignment_padding.sql
\prompt 'Press <Enter> to continue…' d_dummy
Expand All @@ -137,6 +144,10 @@ select
\ir ./sql/v1_vacuum_activity.sql
\prompt 'Press <Enter> to continue…' d_dummy
\ir ./start.psql
\elif :d_step_is_v2
\ir ./sql/v2_autovacuum_progress_and_queue.sql
\prompt 'Press <Enter> to continue…' d_dummy
\ir ./start.psql
\else
\echo
\echo '\033[1;31mError:\033[0m Unknown option! Try again.'
Expand Down