在数据库中,通过锁机制以及多版本并发控制(MVCC)可以保护数据的一致性。例如,会话A正在查询数据,会话B就无法对会话A访问的对象执行DDL。会话A正在更新某条记录,会话B就不能删除或更新这条记录。
锁是由数据库自动控制的,如果应用程序或者SQL脚本设计不当,就可能导致长时间的锁等待或者死锁。AnalyticDB for PostgreSQL提供了两种统计视图,用户可通过这两个视图查询锁等待或者死锁的情况。
- pg_locks:用于展示锁信息,每个被锁的对象或等待锁的对象为一条记录。
- pg_stat_activity:显示所有会话的信息,每个会话为一条记录。
创建锁监控视图
具体如何查询当前的锁等待和持锁信息,您可以通过如下SQL语句创建锁监控视图。
说明 本文的所有SQL命令均在psql客户端中执行,请使用psql连接数据库。
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;
查询锁信息
当发生锁等待或者死锁时,使用如下SQL语句查询v_locks_monitor的信息。
postgres=# \x
postgres=# select * from v_locks_monitor;
处理方法
前面SQL查询语句可以清晰地显示目前数据库系统发生的锁的情况,使用如下语句终止对应的进程。
postgres=# select pg_terminate_backend(PID);
其中PID为v_locks_monitor查询结果中Lock_Granted值为t的记录的Pid,如下图所示。
执行如下语句,如果返回结果为0 rows
表示锁已经清除,如果查询结果还有记录,请再次执行select pg_terminate_backend(PID);
终止对应的PID。
postgres=# select * from v_locks_monitor;