oracle阻塞(blockingblocked)實(shí)例詳解

字號(hào):


    一、概述:
    阻塞是dba經(jīng)常碰到的情形,尤其是不良的應(yīng)用程序設(shè)計(jì)所造成的阻塞將導(dǎo)致數(shù)據(jù)庫(kù)性能的嚴(yán)重下降,直至數(shù)據(jù)庫(kù)崩潰。對(duì)dba而言,有必要知道如何定位到當(dāng)前系統(tǒng)有哪些阻塞,到底誰(shuí)是阻塞者,誰(shuí)是被阻塞者。本文對(duì)此給出了描述并做了相關(guān)演示。
    二、演示阻塞:
    --更新表,注,提示符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)
    --另起兩個(gè)session更新同樣的行,這兩個(gè)session都會(huì)處于等待,直到第一個(gè)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;
    --下面在第一個(gè)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
    --上面的結(jié)果表明session 1073,4642 阻塞了后面的2個(gè)
    --即session 1073,4642是阻塞者,后面2個(gè)session是被阻塞者
    --author : leshami
    --blog  : http://blog.csdn.net/leshami
    --下面查詢正在阻塞的session id,sql語(yǔ)句以及被阻塞的時(shí)間
    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
    --下面的查詢阻塞時(shí)鎖的持有情況
    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個(gè)用戶都在請(qǐng)求524319/27412上的exclusive鎖,而此時(shí)已經(jīng)被scott加了exclusive鎖
    --查詢阻塞時(shí)鎖的持有詳細(xì)信息
    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
    三、文中涉及到的相關(guān)sql腳本完整代碼如下:
    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;