詳解Oracle數(shù)據(jù)庫并行操作常見等待事件及腳本
今天主要介紹Oracle數(shù)據(jù)庫在并行操作過程中 slave 進(jìn)程和 QC 進(jìn)程經(jīng)常遇到的等待事件及常用腳本。
一、PX Deq: Execution Msg,PX Deq: Execute Reply等待事件
1. PX Deq: Execution Msg
Occurs when a parallel slave is waiting to be told what to do. This is normally considered an idle event, but can cause excessive CPU in some cases. |
該事件是并行查詢中的常見事件。當(dāng)PQ slave進(jìn)程在等待QC告訴它要做什么的時(shí)候就會(huì)出現(xiàn)此事件(eg: when waiting to be told parse / execute / fetch etc..)
v$session_wait 中該等待事件對(duì)應(yīng)的參數(shù):
- P1 = sleeptime/senderid
- P2 = passes
- P3 = not used
我們可以使用如下語句獲取轉(zhuǎn)換sleeptime/senderid的相關(guān)信息:
- set SERVEROUTPUT on
- undef p1
- declare
- inst varchar(20);
- sender varchar(20);
- begin
- select bitand(&&p1, 16711680) - 65535 as SNDRINST,
- decode(bitand(&&p1, 65535),65535, 'QC', 'P'||to_char(bitand(&&p1, 65535),'fm000') ) as SNDR
- into inst , sender
- from dual
- where bitand(&&p1, 268435456) = 268435456;
- dbms_output.put_line('Instance = '||inst);
- dbms_output.put_line('Sender = '||sender );
- end;
- /
如果P1的值為空,則意味slave 不需要等待任何進(jìn)程
比如p1的值為268501004,則上面的sql會(huì)返回:
- Instance = 1
- Sender = P012
passes 進(jìn)程在得到信息之前循環(huán)輪轉(zhuǎn)等待的次數(shù)
該等待事件是一個(gè)空閑等待事件,當(dāng)此等待事件出現(xiàn),進(jìn)程會(huì)持續(xù)等待并逐漸增加等待次數(shù)直到獲取信息!
解決方法:
作為 Coordinator 的 Process 在獲取 Slave 進(jìn)程的數(shù)據(jù)時(shí),反應(yīng)太慢了,導(dǎo)致某些 Slave進(jìn)行因?yàn)?Queue 滿而不得不等待,進(jìn)而拖慢了整個(gè)并行執(zhí)行的速度。
這常常是由于 CPU 數(shù)目不足或者 系統(tǒng)中運(yùn)行的 進(jìn)程太多導(dǎo)致。可考慮 減小并行度。
2. PX Deq: Execute Reply
Occurs when the query coordinator is waiting for a response from a parallel slave. This is normally considered an idle event, but can cause excessive CPU in some cases.
Waiting Process: QC |
協(xié)調(diào)器正在等待一個(gè) 從slaves 進(jìn)程對(duì)控制信息的響應(yīng)(確認(rèn)通知)或者期望從slave進(jìn)程集中獲取數(shù)據(jù)。這個(gè)等待事件意味著QC等待slaves結(jié)束執(zhí)行sql 并且將結(jié)果集發(fā)送給QC
v$session_wait 中該等待事件對(duì)應(yīng)的參數(shù):
- P1 = sleeptime/senderid
- P2 = passes
- P3 = not used
我們可以使用如下語句獲取轉(zhuǎn)換sleeptime/senderid的相關(guān)信息:
- set SERVEROUTPUT on
- undef p1
- declare
- inst varchar(20);
- sender varchar(20);
- begin
- select bitand(&&p1, 16711680) - 65535 as SNDRINST,
- decode(bitand(&&p1, 65535),65535, 'QC', 'P'||to_char(bitand(&&p1, 65535),'fm000') ) as SNDR
- into inst , sender
- from dual
- where bitand(&&p1, 268435456) = 268435456;
- dbms_output.put_line('Instance = '||inst);
- dbms_output.put_line('Sender = '||sender );
- end;
- /
如果P1的值為空,則意味slave 不需要等待任何進(jìn)程
比如p1的值為268501004,則上面的sql會(huì)返回:
- Instance = 1
- Sender = P012
等待時(shí)間:這是非空閑等待時(shí)間,QC 等待從slave 的響應(yīng)或者查詢的數(shù)據(jù)結(jié)果
解決辦法:非優(yōu)化的sql語句肯能是導(dǎo)致此等待事件的原因:slaves 需要花費(fèi)很長(zhǎng)時(shí)間來執(zhí)行sql 語句而qc又在等待slave返回?cái)?shù)據(jù)。
優(yōu)化sql,查看slave 在執(zhí)行的語句以及其執(zhí)行計(jì)劃,并做出盡量的優(yōu)化,以便減少slave執(zhí)行sql語句的時(shí)間!
二、相關(guān)腳本
1. gives an overview of all running parallel queries with all slaves.It shows the if a slave is waiting and for what event it waits.
- select decode(px.qcinst_id,
- NULL,
- username,
- ' - ' ||
- lower(substr(pp.SERVER_NAME, length(pp.SERVER_NAME) - 4, 4))) "Username",
- decode(px.qcinst_id, NULL, 'QC', '(Slave)') "QC/Slave",
- to_char(px.server_set) "SlaveSet",
- to_char(s.sid) "SID",
- to_char(px.inst_id) "Slave INST",
- decode(sw.state, 'WAITING', 'WAIT', 'NOT WAIT') as STATE,
- case sw.state
- WHEN 'WAITING' THEN
- substr(sw.event, 1, 30)
- ELSE
- NULL
- end as wait_event,
- decode(px.qcinst_id, NULL, to_char(s.sid), px.qcsid) "QC SID",
- to_char(px.qcinst_id) "QC INST",
- px.req_degree "Req. DOP",
- px.degree "Actual DOP"
- from gv$px_session px, gv$session s, gv$px_process pp, gv$session_wait sw
- where px.sid = s.sid(+)
- and px.serial# = s.serial#(+)
- and px.inst_id = s.inst_id(+)
- and px.sid = pp.sid(+)
- and px.serial# = pp.serial#(+)
- and ssw.sid = s.sid
- and ssw.inst_id = s.inst_id
- order by decode(px.QCINST_ID, NULL, px.INST_ID, px.QCINST_ID),
- px.QCSID,
- decode(px.SERVER_GROUP, NULL, 0, px.SERVER_GROUP),
- px.SERVER_SET,
- px.INST_ID /
2. shows for the PX Deq events the processes that are exchange data.
- select sw.SID as RCVSID,
- decode(pp.server_name, NULL, 'A QC', pp.server_name) as RCVR,
- sw.inst_id as RCVRINST,
- case sw.state
- WHEN 'WAITING' THEN
- substr(sw.event, 1, 30)
- ELSE
- NULL
- end as wait_event,
- decode(bitand(p1, 65535),
- 65535,
- 'QC',
- 'P' || to_char(bitand(p1, 65535), 'fm000')) as SNDR,
- bitand(p1, 16711680) - 65535 as SNDRINST,
- decode(bitand(p1, 65535),
- 65535,
- ps.qcsid,
- (select sid
- from gv$px_process
- where server_name =
- 'P' || to_char(bitand(sw.p1, 65535), 'fm000')
- and inst_id = bitand(sw.p1, 16711680) - 65535)) as SNDRSID,
- decode(sw.state, 'WAITING', 'WAIT', 'NOT WAIT') as STATE
- from gv$session_wait sw, gv$px_process pp, gv$px_session ps
- where sw.sid = pp.sid(+)
- and sw.inst_id = pp.inst_id(+)
- and sw.sid = ps.sid(+)
- and sw.inst_id = ps.inst_id(+)
- and p1text = 'sleeptime/senderid'
- and bitand(p1, 268435456) = 268435456
- order by decode(ps.QCINST_ID, NULL, ps.INST_ID, ps.QCINST_ID),
- ps.QCSID,
- decode(ps.SERVER_GROUP, NULL, 0, ps.SERVER_GROUP),
- ps.SERVER_SET,
- ps.INST_ID
3. shows for long running processes what are the slaves do.
- select decode(px.qcinst_id,
- NULL,
- username,
- ' - ' ||
- lower(substr(pp.SERVER_NAME, length(pp.SERVER_NAME) - 4, 4))) "Username",
- decode(px.qcinst_id, NULL, 'QC', '(Slave)') "QC/Slave",
- to_char(px.server_set) "SlaveSet",
- to_char(px.inst_id) "Slave INST",
- substr(opname, 1, 30) operation_name,
- substr(target, 1, 30) target,
- sofar,
- totalwork,
- units,
- start_time,
- timestamp,
- decode(px.qcinst_id, NULL, to_char(s.sid), px.qcsid) "QC SID",
- to_char(px.qcinst_id) "QC INST"
- from gv$px_session px, gv$px_process pp, gv$session_longops s
- where px.sid = s.sid
- and px.serial# = s.serial#
- and px.inst_id = s.inst_id
- and px.sid = pp.sid(+)
- and px.serial# = pp.serial#(+)
- order by decode(px.QCINST_ID, NULL, px.INST_ID, px.QCINST_ID),
- px.QCSID,
- decode(px.SERVER_GROUP, NULL, 0, px.SERVER_GROUP),
- px.SERVER_SET,
- px.INST_ID