enq: TX - row lock contention 通常是application级别的问题。
enq是一种保护共享资源的锁定机制,一个排队机制,先进先出(FIFO)。
enq: TX - row lock contention 的产生有几种情况。
<1>Waits for TX in mode 6 :A 会话持有row level lock,B会话等待这个lock释放。
不同的session更新或删除同一个记录。(This occurs when one application is updating or deleting a row that another session is also trying to update or delete. )
解决办法:持有锁的会话commit或者rollback。
<2>In mode 4,唯一索引
表上存在唯一索引,A会话插入一个值(未提交),B会话随后也插入同样的值;A会话提交后,enq: TX - row lock contention消失。
解决办法:持有锁的会话commit或者rollback。
<3>in mode 4 :bitmap
源于bitmap的特性:位图索引的一个键值,会指向多行记录,所以更新一行就会把该键值指向的所有行锁定。
解决办法:commit或者rollback。
<4>其他原因
It could be a primary key problem; a trigger firing attempting to insert, delete, or update a row; a problem with initrans; waiting for an index split to complete; problems with bitmap indexes;updating a row already updated by another session; or something else.
()
下面用实验证明:
<1>Waits for TX in mode 6 :A 会话持有row level lock,B会话等待这个lock释放。
170 session:
SQL> create table t1(id number,name varchar2(10));
SQL> insert into t1 values(1,'tom');
SQL> commit;
SQL> update t1 set name='jack' where id=1;
session 128:
SQL> update t1 set name='john' where id=1;
此时session 128处在等待状态。
打开一个新会话
会话128等待会话170的 enq: TX - row lock contention锁释放。
set linesize 200
col event for a40
col username for a10
col SQL_FULLTEXT for a60
select g.Inst_id,g.sid,g.serial#,g.event,g.username, g.sql_hash_value,s.SQL_FULLTEXT
from gv$session g,v$sql s
where g.Wait_class <> 'Idle' and g.sql_hash_value=s.HASH_VALUE;
INST_ID SID SERIAL# EVENT USERNAME SQL_HASH_VALUE SQL_FULLTEXT
---------- ---------- ---------- ---------------------------------------- ---------- -------------- ------------------------------------------------------------
1 128 2154 enq: TX - row lock contention DOWNLOAD 4124578373 update t1 set name='john' where id=1
查看,可以看到170会话正在阻塞128
select
blocking_session,
sid, serial#,
wait_class,
seconds_in_wait
from
v$session
where
blocking_session is not NULL
order by
blocking_session;
BLOCKING_SESSION SID SERIAL# WAIT_CLASS SECONDS_IN_WAIT
---------------- ---------- ---------- ---------------------------------------------------------------- ---------------
170 128 2154 Application 140
session 170阻塞128,128请求LMODE=6的锁。
SQL> select sid,type,id1,id2 ,lmode,request,block from v$lock where type='TX';
SID TY ID1 ID2 LMODE REQUEST BLOCK
---------- -- ---------- ---------- ---------- ---------- ----------
128 TX 393218 1623 0 6 0
170 TX 393218 1623 6 0 1
session 170 commit后,enq: TX - row lock contention的等待事件消失。
由于170会话没有提交,那么170持有LMODE=7的锁。170会话提交后,锁被释放。
SQL> select sid,type,id1,id2 ,lmode,request,block from v$lock where type='TX';
SID TY ID1 ID2 LMODE REQUEST BLOCK
---------- -- ---------- ---------- ---------- ---------- ----------
128 TX 458756 1306 6 0 0
<2>In mode 4,唯一索引
session 170:
SQL> create table t2(a number primary key);
SQL> insert into t2 values(1);
session 128:
SQL> insert into t2 values(1); --处于等待状态
打开一个新会话:
会话128等待会话170的 enq: TX - row lock contention锁释放。
set linesize 200
col event for a40
col username for a10
col SQL_FULLTEXT for a60
select g.Inst_id,g.sid,g.serial#,g.event,g.username, g.sql_hash_value,s.SQL_FULLTEXT
from gv$session g,v$sql s
where g.Wait_class <> 'Idle' and g.sql_hash_value=s.HASH_VALUE;
INST_ID SID SERIAL# EVENT USERNAME SQL_HASH_VALUE SQL_FULLTEXT
---------- ---------- ---------- ---------------------------------------- ---------- -------------- ------------------------------------------------------------
1 128 2154 enq: TX - row lock contention DOWNLOAD 1678275016 insert into t2 values(1)
查看,可以看到170会话正在阻塞128
select
blocking_session,
sid, serial#,
wait_class,
seconds_in_wait
from
v$session
where
blocking_session is not NULL
order by
blocking_session;
BLOCKING_SESSION SID SERIAL# WAIT_CLASS SECONDS_IN_WAIT
---------------- ---------- ---------- ---------------------------------------------------------------- ---------------
170 128 2154 Application 117
session 128正在请求LMODE=4的锁。
SQL> select sid,type,id1,id2 ,lmode,request,block from v$lock where type='TX';
SID TY ID1 ID2 LMODE REQUEST BLOCK
---------- -- ---------- ---------- ---------- ---------- ----------
128 TX 524302 1714 0 4 0
128 TX 458784 1311 6 0 0
170 TX 524302 1714 6 0 1
session 170 commit 128获lmode=4的锁,可以继续执行,但是会报错
ERROR at line 1:
ORA-00001: unique constraint (DOWNLOAD.SYS_C009683) violated
<3>in mode 4 :bitmap
SQL> create table t3(id number,name varchar2(10));
SQL> create bitmap index bit_ind_id on t3(id);
session 170:
SQL> insert into t3 values(1,'tom');
session 128:
SQL> insert into t3 values(1,'lily'); --处于等待
打开一个新会话:
会话128等待 enq: TX - row lock contention锁。
set linesize 200
col event for a40
col username for a10
col SQL_FULLTEXT for a60
select g.Inst_id,g.sid,g.serial#,g.event,g.username, g.sql_hash_value,s.SQL_FULLTEXT
from gv$session g,v$sql s
where g.Wait_class <> 'Idle' and g.sql_hash_value=s.HASH_VALUE;
INST_ID SID SERIAL# EVENT USERNAME SQL_HASH_VALUE SQL_FULLTEXT
---------- ---------- ---------- ---------------------------------------- ---------- -------------- ------------------------------------------------------------
1 128 2154 enq: TX - row lock contention DOWNLOAD 1423993589 insert into t3 values(1,'lily')
查看,可以看到170会话正在阻塞128
select
blocking_session,
sid, serial#,
wait_class,
seconds_in_wait
from
v$session
where
blocking_session is not NULL
order by
blocking_session;
BLOCKING_SESSION SID SERIAL# WAIT_CLASS SECONDS_IN_WAIT
---------------- ---------- ---------- ---------------------------------------------------------------- ---------------
170 128 2154 Application 139
session 128正在请求LMODE=4的锁。
SQL> select sid,type,id1,id2 ,lmode,request,block from v$lock where type='TX';
SID TY ID1 ID2 LMODE REQUEST BLOCK
---------- -- ---------- ---------- ---------- ---------- ----------
128 TX 131082 1622 0 4 0
128 TX 65537 1329 6 0 0
170 TX 131082 1622 6 0 1
session 170 commit 128获lmode=4的锁。
实验结束。
参考文档:
阅读(10860) | 评论(0) | 转发(2) |