Skip to content

Commit d2b6db3

Browse files
author
Josh Berkus
committed
Added query and shell script to log transaction locks.
1 parent 0a9a431 commit d2b6db3

File tree

4 files changed

+212
-1
lines changed

4 files changed

+212
-1
lines changed

README.md

Lines changed: 17 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -26,6 +26,21 @@ table_bloat_check.sql
2626

2727
An overhauled table bloat check. Lists tables which are likely to be bloated and estimates bloat amounts. Requires PostgreSQL >= 8.4, superuser access, and a 64-bit compile.
2828

29+
Locks
30+
=====
31+
32+
Tools and a set of queries to analyze lock-blocking.
33+
34+
transaction_locks.sql
35+
---------------------
36+
37+
Requires: Postgres 9.2+
38+
39+
Lists waiting transaction locks and what they're waiting on, if possible.
40+
Includes relation and query information, but realistically needs to be
41+
accompanied by full query logging to be useful. Needs to be run
42+
per active database.
43+
2944

3045
Additional Contributors
3146
=======================
@@ -34,4 +49,5 @@ In addition to the staff of PostgreSQL Experts, we are indebted
3449
to:
3550

3651
* The authors of the check_postgres.pl script for supplying the
37-
original bloat queries on which our bloat queries are based.
52+
original bloat queries on which our bloat queries are based.
53+
* Andrew Gierth for help on various system queries.

locks/log_transaction_locks.sh

Lines changed: 18 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,18 @@
1+
#!/bin/bash
2+
3+
# simple script to log transaction locks to a table
4+
# assumes that you're running it as the postgres user and don't need a password
5+
6+
# change to path of psql
7+
PSQL='/usr/lib/postgresql/9.3/bin/psql'
8+
9+
# change to database you're targeting
10+
DBNAME='somedb'
11+
12+
# modify if required
13+
DBPORT='-p 5432'
14+
DBHOST='-h 127.0.0.1'
15+
16+
$PSQL -c "INSERT INTO log_transaction_locks SELECT * FROM log_transaction_locks_view" -U postgres $DBNAME $DBPORT $DBHOST
17+
18+
exit 0

locks/transaction_locks.sql

Lines changed: 80 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,80 @@
1+
-- query to analyze waiting transaction locks
2+
-- requires Postgres 9.2 or greater
3+
4+
WITH table_locks AS (
5+
select pid,
6+
relation::regclass as lockobj,
7+
case when page is not null and tuple is not null then
8+
mode || ' on ' || page::text || ':' || tuple::text
9+
else
10+
mode
11+
end as lock_mode,
12+
locktype
13+
from pg_locks
14+
join pg_database
15+
ON pg_locks.database = pg_database.oid
16+
where relation is not null
17+
and pg_database.datname = current_database()
18+
order by lockobj
19+
),
20+
locked_list AS (
21+
select pid,
22+
array_agg(lockobj) as lock_relations,
23+
array_agg(lock_mode) as lock_modes,
24+
array_agg(locktype) as lock_types
25+
from table_locks
26+
group by pid
27+
),
28+
txn_locks AS (
29+
select pid, transactionid::text as lxid, granted
30+
from pg_locks
31+
where locktype = 'transactionid'
32+
union all
33+
select pid, virtualxid::text as lxid, granted
34+
from pg_locks
35+
where locktype = 'virtualxid'
36+
),
37+
txn_granted AS (
38+
select pid, lxid from txn_locks
39+
where granted
40+
),
41+
txn_waiting AS (
42+
select pid, lxid from txn_locks
43+
where not granted
44+
)
45+
select now() as lock_ts,
46+
txn_waiting.pid as waiting_pid,
47+
txn_waiting.lxid as wait_xid,
48+
txn_granted.pid as locked_pid,
49+
waiting_proc.application_name as waiting_app,
50+
waiting_proc.client_addr as waiting_addr,
51+
waiting_proc.xact_start as waiting_xact_start,
52+
waiting_proc.query_start as waiting_query_start,
53+
waiting_proc.state_change as waiting_start,
54+
waiting_proc.query as waiting_query,
55+
locked_proc.application_name as locked_app,
56+
locked_proc.client_addr as locked_addr,
57+
locked_proc.xact_start as locked_xact_start,
58+
locked_proc.query_start as locked_query_start,
59+
locked_proc.state as locked_state,
60+
locked_proc.state_change as locked_state_start,
61+
locked_proc.query as locked_last_query,
62+
waiting_locks.lock_relations as waiting_relations,
63+
waiting_locks.lock_modes as waiting_modes,
64+
waiting_locks.lock_types as waiting_lock_types,
65+
locked_locks.lock_relations as locked_relations,
66+
locked_locks.lock_modes as locked_modes,
67+
locked_locks.lock_types as locked_lock_types
68+
from txn_waiting
69+
JOIN pg_stat_activity as waiting_proc
70+
ON txn_waiting.pid = waiting_proc.pid
71+
LEFT OUTER JOIN txn_granted
72+
ON txn_waiting.lxid = txn_granted.lxid
73+
LEFT OUTER JOIN pg_stat_activity as locked_proc
74+
ON txn_granted.pid = locked_proc.pid
75+
LEFT OUTER JOIN locked_list AS waiting_locks
76+
ON txn_waiting.pid = waiting_locks.pid
77+
LEFT OUTER JOIN locked_list AS locked_locks
78+
ON txn_granted.pid = locked_locks.pid
79+
order by waiting_pid;
80+

locks/transaction_locks_setup.sql

Lines changed: 97 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,97 @@
1+
-- do statement to set things up for transaction lock logging
2+
-- written so that it can be run repeatedly
3+
4+
DO $f$
5+
BEGIN
6+
PERFORM 1
7+
FROM pg_stat_user_tables
8+
WHERE relname = 'log_transaction_locks';
9+
10+
IF NOT FOUND THEN
11+
12+
CREATE VIEW log_transaction_locks_view
13+
AS
14+
WITH table_locks AS (
15+
select pid,
16+
relation::regclass as lockobj,
17+
case when page is not null and tuple is not null then
18+
mode || ' on ' || page::text || ':' || tuple::text
19+
else
20+
mode
21+
end as lock_mode,
22+
locktype
23+
from pg_locks
24+
join pg_database
25+
ON pg_locks.database = pg_database.oid
26+
where relation is not null
27+
and pg_database.datname = current_database()
28+
order by lockobj
29+
),
30+
locked_list AS (
31+
select pid,
32+
array_agg(lockobj) as lock_relations,
33+
array_agg(lock_mode) as lock_modes,
34+
array_agg(locktype) as lock_types
35+
from table_locks
36+
group by pid
37+
),
38+
txn_locks AS (
39+
select pid, transactionid::text as lxid, granted
40+
from pg_locks
41+
where locktype = 'transactionid'
42+
union all
43+
select pid, virtualxid::text as lxid, granted
44+
from pg_locks
45+
where locktype = 'virtualxid'
46+
),
47+
txn_granted AS (
48+
select pid, lxid from txn_locks
49+
where granted
50+
),
51+
txn_waiting AS (
52+
select pid, lxid from txn_locks
53+
where not granted
54+
)
55+
select now() as lock_ts,
56+
txn_waiting.pid as waiting_pid,
57+
txn_waiting.lxid as wait_xid,
58+
txn_granted.pid as locked_pid,
59+
waiting_proc.application_name as waiting_app,
60+
waiting_proc.client_addr as waiting_addr,
61+
waiting_proc.xact_start as waiting_xact_start,
62+
waiting_proc.query_start as waiting_query_start,
63+
waiting_proc.state_change as waiting_start,
64+
waiting_proc.query as waiting_query,
65+
locked_proc.application_name as locked_app,
66+
locked_proc.client_addr as locked_addr,
67+
locked_proc.xact_start as locked_xact_start,
68+
locked_proc.query_start as locked_query_start,
69+
locked_proc.state as locked_state,
70+
locked_proc.state_change as locked_state_start,
71+
locked_proc.query as locked_last_query,
72+
waiting_locks.lock_relations as waiting_relations,
73+
waiting_locks.lock_modes as waiting_modes,
74+
waiting_locks.lock_types as waiting_lock_types,
75+
locked_locks.lock_relations as locked_relations,
76+
locked_locks.lock_modes as locked_modes,
77+
locked_locks.lock_types as locked_lock_types
78+
from txn_waiting
79+
JOIN pg_stat_activity as waiting_proc
80+
ON txn_waiting.pid = waiting_proc.pid
81+
LEFT OUTER JOIN txn_granted
82+
ON txn_waiting.lxid = txn_granted.lxid
83+
LEFT OUTER JOIN pg_stat_activity as locked_proc
84+
ON txn_granted.pid = locked_proc.pid
85+
LEFT OUTER JOIN locked_list AS waiting_locks
86+
ON txn_waiting.pid = waiting_locks.pid
87+
LEFT OUTER JOIN locked_list AS locked_locks
88+
ON txn_granted.pid = locked_locks.pid
89+
order by waiting_pid;
90+
91+
CREATE TABLE log_transaction_locks AS
92+
SELECT * FROM log_transaction_locks_view
93+
WHERE FALSE;
94+
95+
END IF;
96+
END;
97+
$f$;

0 commit comments

Comments
 (0)