In a database system, locking works with multiversion concurrency control (MVCC) to ensure data consistency. Assume that there are two sessions: A and B. If session A is querying data from a specific object, session B cannot perform data definition language (DDL) operations on that object. Similarly, if session A is updating a data record, session B cannot update or delete that data record.

Locks are controlled by the database system. If an application or SQL script is incorrectly designed, a transaction may remain in a LOCK WAIT state. If a transaction waits indefinitely, a deadlock occurs. AnalyticDB for PostgreSQL provides the following two views from which you can obtain information about lock waits and deadlocks:

  • pg_locks: shows lock statistics. Each data record represents a process that holds a lock or is waiting for a lock.
  • pg_stat_activity: shows session statistics. Each data record represents a session.

Create a lock monitoring view

Execute the following statements to create the v_locks_monitor view and query the processes that hold locks or are waiting for locks:

Note All SQL statements described in this topic are executed on the psql CLI client. You must connect to your AnalyticDB for PostgreSQL database by using the psql CLI client.

create view v_locks_monitor as
with
t_wait as
(
select a.mode,a.locktype,a.database,a.relation,a.page,a.tuple,a.classid,a.granted,
a.objid,a.objsubid,a.pid,a.transactionid,
b.xact_start,b.query_start,b.usename,b.datname,b.client_addr,b.client_port,b.application_name
from pg_locks a,pg_stat_activity b where a.pid=b.pid and not a.granted
),
t_run as
(
select a.mode,a.locktype,a.database,a.relation,a.page,a.tuple,a.classid,a.granted,
a.objid,a.objsubid,a.pid,a.transactionid,
b.xact_start,b.query_start,b.usename,b.datname,b.client_addr,b.client_port,b.application_name
from pg_locks a,pg_stat_activity b where a.pid=b.pid and a.granted
),
t_overlap as
(
select r.* from t_wait w join t_run r on
(
r.locktype is not distinct from w.locktype and
r.database is not distinct from w.database and
r.relation is not distinct from w.relation and
r.page is not distinct from w.page and
r.tuple is not distinct from w.tuple and

r.transactionid is not distinct from w.transactionid and
r.classid is not distinct from w.classid and
r.objid is not distinct from w.objid and
r.objsubid is not distinct from w.objsubid and
r.pid <> w.pid
)
),
t_unionall as
(
select r.* from t_overlap r
union all
select w.* from t_wait w
)
select locktype,datname,relation::regclass,page,tuple,transactionid::text,classid::regclass,objid,objsubid,
string_agg(
'Pid: '||case when pid is null then 'NULL' else pid::text end||chr(10)||
'Lock_Granted: '||case when granted is null then 'NULL' else granted::text end||
' , Mode: '||case when mode is null then 'NULL' else mode::text end||
' , Username: '||case when usename is null then 'NULL' else usename::text end||
' , Database: '||case when datname is null then 'NULL' else datname::text end||
' , Client_Addr: '||case when client_addr is null then 'NULL' else client_addr::text end||
' , Client_Port: '||case when client_port is null then 'NULL' else client_port::text end||
' , Application_Name: '||case when application_name is null then 'NULL' else application_name::text end||chr(10)||
' , Xact_Start: '||case when xact_start is null then 'NULL' else xact_start::text end||
' , Query_Start: '||case when query_start is null then 'NULL' else query_start::text end||
' , Xact_Elapse: '||case when (now()-xact_start) is null then 'NULL' else (now()-xact_start)::text end||
chr(10)||'--------'||chr(10), (case when granted then '0' else '1' end)
order by
( case mode
when 'INVALID' then 0
when 'AccessShareLock' then 1
when 'RowShareLock' then 2
when 'RowExclusiveLock' then 3
when 'ShareUpdateExclusiveLock' then 4
when 'ShareLock' then 5
when 'ShareRowExclusiveLock' then 6
when 'ExclusiveLock' then 7
when 'AccessExclusiveLock' then 8
else 0
end ) desc )
as lock_conflict
from t_unionall
group by
locktype,datname,relation,page,tuple,transactionid::text,classid,objid,objsubid;

            

Query locks

If a lock wait or deadlock occurs, execute the following SQL statement to query the v_locks_monitor view:



postgres=# \x

postgres=# select * from v_locks_monitor;

            

Solution

From the v_locks_monitor view, you can obtain the locks in your database system. Execute the following statement to terminate the process used to run the transactions that triggered the locks:

postgres=# select pg_terminate_backend(PID);
In this example, PID is the Pid value for the data record whose Lock_Granted value is t in the v_locks_monitor view.

Execute the following statement. If the return result is "0 rows", the locks are released. If the return result contains a data record, execute the select pg_terminate_backend(PID); statement again to terminate the corresponding process.

postgres=# select * from v_locks_monitor; 
            

References

SQL statements to monitor PostgreSQL lock waits - who blocked whom