Oracle RAC環(huán)境下的阻塞(blocking blocked)介紹和實(shí)例演示
RAC環(huán)境下的阻塞不同于單實(shí)例情形,因?yàn)槲覀冃枰紤]到位于不同實(shí)例的session。也就是說(shuō)之前查詢的v$session,v$lock相應(yīng)的應(yīng)變化為全局范圍來(lái)查找。本文提供了2個(gè)查詢腳本,并給出實(shí)例演示那些session為阻塞者,哪些為被阻塞者。有關(guān)阻塞的概念以及單實(shí)例環(huán)境下的阻塞請(qǐng)參考:Oracle 阻塞(blocking blocked)
1、演示環(huán)境
scott@DEVDB> select * from v$version where rownum<2; BANNER -------------------------------------------------------------------------------- Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production --在scott session中發(fā)布SQL語(yǔ)句,并未提交 scott@DEVDB> begin 2 update emp set sal=sal+100 where empno=7788; 3 update dept set dname='DBA' where deptno=10; 4 end; 5 / PL/SQL procedure successfully completed. --在leshami session中更新emp對(duì)象 leshami@DEVDB> update scott.emp set sal=sal-200 where empno=7788; --在usr1 session中更新emp對(duì)象 usr1@DEVDB> update scott.dept set dname='DEV' where deptno=10;
2、尋找阻塞
scott@DEVDB> @block_session_rac USER_STATUS SID_SERIAL CONN_INSTANCE SID PROGRAM OSUSER MACHINE LOCK_TYPE LOCK_MODE CTIME OBJECT_NAME --------------- --------------- ---------------- ---- ------------------------------ ------- --------------- --------------- ----------- ---------- ------------------------- Blocking -> '20,1545' devdb1 20 sqlplus@Linux-01 (TNS V1-V3) oracle Linux-01 Transaction Exclusive 666 DEPT Blocking -> '20,1545' devdb1 20 sqlplus@Linux-01 (TNS V1-V3) oracle Linux-01 Transaction Exclusive 666 EMP Waiting '49,1007' devdb1 49 sqlplus@Linux-01 (TNS V1-V3) oracle Linux-01 Transaction None 618 EMP Waiting '933,11691' devdb2 933 sqlplus@Linux-02 (TNS V1-V3) oracle Linux-02 Transaction None 558 DEPT --通過(guò)上述腳本我們可以看到session '20,1545' 鎖住了對(duì)象DEPT以及EMP,而此時(shí)session '49,1007'與'933,11691'處于等待狀態(tài)。 --下面是另外的一種方式來(lái)獲取阻塞的情形 scott@DEVDB> @block_session_rac2 BLOCKING_STATUS ---------------------------------------------------------------------------------------------------------------------------- SCOTT@Linux-01 ( INST=1 SID=20 Serail#=1545 ) IS BLOCKING USR1@Linux-02 ( INST=2 SID=933 Serial#=11691 ) SCOTT@Linux-01 ( INST=1 SID=20 Serail#=1545 ) IS BLOCKING LESHAMI@Linux-01 ( INST=1 SID=49 Serial#=1007 ) --Author : Leshami --Blog : http://blog.csdn.net/leshami
3、演示中用到的腳本
[oracle@Linux-01 ~]$ more block_session_rac.sql
set linesize 180
col user_status format a15
col sid_serial format a15
col program format a30 wrapped
col machine format a15 wrapped
col osuser format a15 wrapped
col conn_instance format a15
col object_name format a25 wrapped
SELECT DECODE (l.block, 0, 'Waiting', 'Blocking ->') user_status,
CHR (39) || s.sid || ',' || s.serial# || CHR (39) sid_serial,
(SELECT instance_name
FROM gv$instance
WHERE inst_id = l.inst_id)
conn_instance,
s.sid,
s.program,
s.osuser,
s.machine,
DECODE (l.TYPE,
'RT', 'Redo Log Buffer',
'TD', 'Dictionary',
'TM', 'DML',
'TS', 'Temp Segments',
'TX', 'Transaction',
'UL', 'User',
'RW', 'Row Wait',
l.TYPE)
lock_type--,id1
--,id2
,
DECODE (l.lmode,
0, 'None',
1, 'Null',
2, 'Row Share',
3, 'Row Excl.',
4, 'Share',
5, 'S/Row Excl.',
6, 'Exclusive',
LTRIM (TO_CHAR (lmode, '990')))
lock_mode,
ctime--,DECODE(l.BLOCK, 0, 'Not Blocking', 1, 'Blocking', 2, 'Global') lock_status
,
object_name
FROM gv$lock l
JOIN gv$session s ON (l.inst_id = s.inst_id AND l.sid = s.sid)
JOIN gv$locked_object o
ON (o.inst_id = s.inst_id AND s.sid = o.session_id)
JOIN dba_objects d ON (d.object_id = o.object_id)
WHERE (l.id1, l.id2, l.TYPE) IN (SELECT id1, id2, TYPE
FROM gv$lock
WHERE request > 0)
ORDER BY id1, id2, ctime DESC;
[oracle@Linux-01 ~]$ more block_session_rac2.sql
SELECT DISTINCT
s1.username
|| '@'
|| s1.machine
|| ' ( INST='
|| s1.inst_id
|| ' SID='
|| s1.sid
|| ' Serail#='
|| s1.serial#
|| ' ) IS BLOCKING '
|| s2.username
|| '@'
|| s2.machine
|| ' ( INST='
|| s2.inst_id
|| ' SID='
|| s2.sid
|| ' Serial#='
|| s2.serial#
|| ' ) '
AS blocking_status
FROM gv$lock l1,
gv$session s1,
gv$lock l2,
gv$session s2
WHERE s1.sid = l1.sid
AND s2.sid = l2.sid
AND s1.inst_id = l1.inst_id
AND s2.inst_id = l2.inst_id
AND l1.block > 0
AND l2.request > 0
AND l1.id1 = l2.id1
AND l1.id2 = l2.id2;
相關(guān)文章
pl/sql連接遠(yuǎn)程oracle服務(wù)器的配置教程
這篇文章主要為大家詳細(xì)介紹了pl/sql連接遠(yuǎn)程oracle服務(wù)器的配置教程,具有一定的參考價(jià)值,感興趣的小伙伴們可以參考一下2017-07-07
Oracle存儲(chǔ)過(guò)程與函數(shù)的詳細(xì)使用教程
存儲(chǔ)過(guò)程和函數(shù)在Oracle中被稱為子程序,是指被命名的PL/SQL塊,這種塊可以帶有參數(shù),可以被多次調(diào)用,下面這篇文章主要給大家介紹了關(guān)于Oracle存儲(chǔ)過(guò)程與函數(shù)的詳細(xì)使用,文中通過(guò)實(shí)例代碼介紹的非常詳細(xì),需要的朋友可以參考下2022-07-07
Oracle捕獲問(wèn)題SQL解決CPU過(guò)渡消耗
本文通過(guò)實(shí)際業(yè)務(wù)系統(tǒng)中調(diào)整的一個(gè)案例,試圖給出一個(gè)常見(jiàn)CPU消耗問(wèn)題的一個(gè)診斷方法.2007-03-03
Oracle中TIMESTAMP的幾種類型介紹與實(shí)例
我們都知道date和timestamp都是對(duì)日期和時(shí)間的表示,只是兩種類型的精確度不同,前者精確到秒,后者精確到小數(shù)秒(fractional_seconds_precision),可以是 0 to 9,缺省是6。這篇文章主要介紹了Oralce中TIMESTAMP的幾種類型。有需要的朋友們可以參考借鑒。2016-12-12
oracle 服務(wù)啟動(dòng),關(guān)閉腳本(windows系統(tǒng)下)
Windows下的批出理程序,就是dos命令的集合,我們也可以通過(guò)運(yùn)行程序里的命令來(lái)開(kāi)啟服務(wù).2009-07-07
Oracle數(shù)據(jù)庫(kù)時(shí)間格式轉(zhuǎn)換的常見(jiàn)示例
這篇文章主要給大家介紹了關(guān)于Oracle數(shù)據(jù)庫(kù)時(shí)間格式轉(zhuǎn)換的常見(jiàn)示例,在實(shí)際的工作中會(huì)經(jīng)常會(huì)用到to_char()、to_date()函數(shù)來(lái)對(duì)時(shí)間、日期進(jìn)行處理,文中給出了詳細(xì)的代碼示例,需要的朋友可以參考下2024-02-02

