Oracle 阻塞(blocking blocked)介绍和实例演示 |
|
阻塞是DBA经常碰到的情形,尤其是不良的应用程序设计的阻塞将导致性能严重下降直至数据库崩溃 。对DBA而言,有必要知道如何定位到当前系统有哪些阻塞,到底谁是阻塞者,谁是被阻塞者 。本文对此给出了描述并做了相关演示 。 1、阻塞及其类型 a、什么是阻塞 2、几种不同类型阻塞的处理办法 a、INSERT阻塞主要是由于有一个带主键的表,或者表上有惟一的约束,在两个会话试图用同样的值插入一行时引发阻塞 。多表通过引用完整性约束相互链接时,在其依赖的父表正在创建或删除期间,对子表的插入可能会阻塞 。对于该类情形建议使用序列来生成主键/惟一列值 。 3、演示阻塞 --更新表,注,提示符scott@CNMMBO表明用户为scott的session,用户名不同,session不同 。 scott@CNMMBO> update emp set sal=sal*1.1 where empno=7788; 1 row updated. scott@CNMMBO> @my_env SPID SID SERIAL# USERNAME PROGRAM ------------ ---------- ---------- --------------- ------------------------------------------------ 11205 1073 4642 robin oracle@SZDB (TNS V1-V3) --另起两个session更新同样的行,这两个session都会处于等待,直到第一个session提交或回滚 leshami@CNMMBO> update scott.emp set sal=sal+100 where empno=7788; goex_admin@CNMMBO> update scott.emp set sal=sal-50 where empno=7788; --下面在第一个session 查询阻塞情况 scott@CNMMBO> @blocker BLOCK_MSG BLOCK -------------------------------------------------- ---------- pts/5 (1073,4642) is blocking 1067,10438 1 pts/5 (1073,4642) is blocking 1065,4464 1 --上面的结果表明session 1073,4642 阻塞了后面的2个 --即session 1073,4642是阻塞者,后面2个session是被阻塞者 --Author : Leshami --Blog : http://blog.csdn.net/leshami --下面查询正在阻塞的session id,SQL语句以及被阻塞的时间 scott@CNMMBO> @blocking_session_detail.sql SID=||A.SID||WAITCLASS=||A.WAIT_CLASS||TIME=||A.SECONDS_IN_WAIT||CHR(10)||QUERY=||B.SQL_TEXT ------------------------------------------------------------------------------------------------------- sid=1067 Wait Class=Application Time=5995 Query=update scott.emp set sal=sal+100 where empno=7788 sid=1065 Wait Class=Application Time=225 Query=update scott.emp set sal=sal-50 where empno=7788 --下面的查询阻塞时锁的持有情况 scott@CNMMBO> @request_lock_type USERNAME SID TY LMODE REQUEST ID1 ID2 ------------------------------ ---------- -- ----------- ----------- ---------- ---------- SCOTT 1073 TX Exclusive None 524319 27412 LESHAMI 1067 TX None Exclusive 524319 27412 GOEX_ADMIN 1065 TX None Exclusive 524319 27412 --可以看到LESHAMI,GOEX_ADMIN 2个用户都在请求524319/27412上的Exclusive锁,而此时已经被SCOTT加了Exclusive锁 --查询阻塞时锁的持有详细信息 scott@CNMMBO> @request_lock_detail SID USERNAME OSUSER TERMINAL OBJECT_NAME TY Lock Mode Req_Mode ---------- -------------------- --------------- ------------------------- -------------------- -- ----------- -------------------- 1065 GOEX_ADMIN robin pts/1 EMP TM Row Excl 1065 GOEX_ADMIN robin pts/1 Trans-524319 TX --Waiting-- Exclusive 1067 LESHAMI robin pts/0 EMP TM Row Excl 1067 LESHAMI robin pts/0 Trans-524319 TX --Waiting-- Exclusive 1073 SCOTT robin pts/5 EMP TM Row Excl 1073 SCOTT robin pts/5 Trans-524319 TX Exclusive 文中涉及到的相关脚本如下:
robin@SZDB:'/dba_scripts/custom/sql> more my_env.sql
SELECT spid, s.sid, s.serial#, p.username, p.program
FROM v$process p, v$session s
WHERE p.addr = s.paddr
AND s.sid = (SELECT sid
FROM v$mystat
WHERE rownum = 1);
robin@SZDB:'/dba_scripts/custom/sql> more blocker.sql
col block_msg format a50;
select c.terminal|| (||a.sid||,||c.serial#||) is blocking ||b.sid||,||d.serial# block_msg, a.block
from v$lock a,v$lock b,v$session c,v$session d
where a.id1=b.id1
and a.id2=b.id2
and a.block>0
and a.sid <>b.sid
and a.sid=c.sid
and b.sid=d.SID;
robin@SZDB:'/dba_scripts/custom/sql> more blocking_session_detail.sql
--To find the query for blocking session
--Access Privileges: SELECT on v$session, v$sqlarea
SELECT sid=
|| a.SID
|| Wait Class=
|| a.wait_class
|| Time=
|| a.seconds_in_wait
|| CHR (10)
|| Query=
|| b.sql_text
FROM v$session a, v$sqlarea b
WHERE a.blocking_session IS NOT NULL AND a.sql_address = b.address
ORDER BY a.blocking_session
/
robin@SZDB:'/dba_scripts/custom/sql> more request_lock_type.sql
--This script generates a report of users waiting for locks.
--Access Privileges: SELECT on v$session, v$lock
SELECT sn.username, m.sid, m.type,
DECODE(m.lmode, 0, None,
1, Null,
2, Row Share,
3, Row Excl.,
4, Share,
5, S/Row Excl.,
6, Exclusive,
lmode, ltrim(to_char(lmode,990))) lmode,
DECODE(m.request,0, None,
1, Null,
2, Row Share,
3, Row Excl.,
4, Share,
5, S/Row Excl.,
6, Exclusive,
request, ltrim(to_char(m.request,
990))) request, m.id1, m.id2
FROM v$session sn, v$lock m
WHERE (sn.sid = m.sid AND m.request != 0)
OR (sn.sid = m.sid
AND m.request = 0 AND lmode != 4
AND (id1, id2) IN (SELECT s.id1, s.id2
FROM v$lock s
WHERE request != 0
AND s.id1 = m.id1
AND s.id2 = m.id2)
)
ORDER BY id1, id2, m.request;
robin@SZDB:'/dba_scripts/custom/sql> more request_lock_detail.sql
set linesize 190
col osuser format a15
col username format a20 wrap
col object_name format a20 wrap
col terminal format a25 wrap
col Req_Mode format a20
select B.SID, C.USERNAME, C.OSUSER, C.TERMINAL,
DECODE(B.ID2, 0, A.OBJECT_NAME,
Trans-||to_char(B.ID1)) OBJECT_NAME,
B.TYPE,
DECODE(B.LMODE,0,--Waiting--,
1,Null,
2,Row Share,
3,Row Excl,
4,Share,
5,Sha Row Exc,
6,Exclusive,
Other) "Lock Mode",
DECODE(B.REQUEST,0, ,
1,Null,
2,Row Share,
3,Row Excl,
4,Share,
5,Sha Row Exc,
6,Exclusive,
Other) "Req_Mode"
from DBA_OBJECTS A, V$LOCK B, V$SESSION C
where A.OBJECT_ID(+) = B.ID1
and B.SID = C.SID
and C.USERNAME is not null
order by B.SID, B.ID2;
|