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