Oracle動(dòng)態(tài)視圖v$active_session_history實(shí)戰(zhàn)示例
Oracle動(dòng)態(tài)視圖實(shí)戰(zhàn)之v$active_session_history
先看下官方解釋
- Samples of wait event information are taken once per second and made available using the V$ACTIVE_SESSION_HISTORY view. An active session is one that is waiting on CPU or any event that does not belong to the "Idle" wait class at the time of the sample. The sample information is written to a circular buffer in the SGA, so the greater the database activity, the less time the information will remain available for.
- 有幾個(gè)關(guān)鍵點(diǎn):1秒采集一次,執(zhí)行時(shí)間很快遠(yuǎn)小于1秒的SQL基本不會(huì)采集到,只寫入非空閑狀態(tài)的事件,循環(huán)存放活動(dòng)越多保存的時(shí)間就越短。
實(shí)際工作中主要應(yīng)用
v$active_session_history的字段非常豐富,實(shí)際工作中主要應(yīng)用在下面這些情況:
a.應(yīng)用場(chǎng)景:開(kāi)發(fā)反應(yīng)2023-03-02 00:22至00:35,數(shù)據(jù)落盤慢,根據(jù)情況查看此時(shí)間段的主要活動(dòng)事件,數(shù)量,與sql_id(全局)
select count(*), sql_id, event, blocking_session
from gv$active_session_history
where sample_time between
to_date('2023-03-02 00:22:00', 'yyyy-mm-dd hh24:mi:ss') and
to_date('2023-03-02 00:35:00', 'yyyy-mm-dd hh24:mi:ss')
group by sql_id, event, blocking_session
order by 1;
(非全局)BLOCKING_INST_ID--被阻塞者, blocking_session--阻塞者
select count(*), sql_id, event, BLOCKING_INST_ID, blocking_session
from v$active_session_history
where sample_time between
to_date('2023-03-02 00:20:00', 'yyyy-mm-dd hh24:mi:ss') and
to_date('2023-03-02 00:35:00', 'yyyy-mm-dd hh24:mi:ss')
group by sql_id, event, BLOCKING_INST_ID, blocking_session
order by 1;
b.現(xiàn)在我們已經(jīng)得到兩個(gè)關(guān)鍵信息:sql_id與阻塞事件,首先根據(jù)sql_id我們可以再進(jìn)一步使用此視圖,實(shí)際中可以多調(diào)整幾個(gè)較小的時(shí)間段,以突出最有代表的信息
select count(*),
session_id,
session_serial#,
sql_id,
event,
BLOCKING_INST_ID,
blocking_session
from v$active_session_history
where sample_time between
to_date('2023-03-02 00:24:00', 'yyyy-mm-dd hh24:mi:ss') and
to_date('2023-03-02 00:25:00', 'yyyy-mm-dd hh24:mi:ss')
and sql_id = '1xfbtdvu3xb67'
group by session_id,
session_serial#,
sql_id,
event,
BLOCKING_INST_ID,
blocking_session
order by 3;
c.加入等待事件后更清晰
select count(*),
session_id,
sql_id,
event,
BLOCKING_INST_ID,
blocking_session
from v$active_session_history
where sample_time between
to_date('2023-03-02 00:25:00', 'yyyy-mm-dd hh24:mi:ss') and
to_date('2023-03-02 00:35:00', 'yyyy-mm-dd hh24:mi:ss')
and event = 'library cache lock'
and sql_id = '1j47z0mc6k02b'
group by session_id, sql_id, event, BLOCKING_INST_ID, blocking_session
order by 1;
結(jié)論:可以看出大量并發(fā)等待,最終是發(fā)現(xiàn)有什么阻塞了此SQL語(yǔ)句
結(jié)合我們的AWR報(bào)告
當(dāng)然也要結(jié)合我們的AWR報(bào)告:(兩份為同時(shí)間段,上一份為有爭(zhēng)用,下一份為正常情況,報(bào)告太長(zhǎng),只截取了關(guān)鍵點(diǎn))








關(guān)鍵點(diǎn)
最后關(guān)鍵點(diǎn)a:下面報(bào)告里的sql_id與事件與v$active_session_history里查出來(lái)的結(jié)果相同,進(jìn)一步證明事件與此SQL的關(guān)聯(lián)性。


- 總結(jié)時(shí)間:
我們根據(jù)SQL_ID找到相應(yīng)的SQL語(yǔ)句,從而找到對(duì)應(yīng)的TABLE,最終對(duì)應(yīng)到兩張分區(qū)表,分別為:AA_BBB_CCCC_DDDD_OUT,AA_BBB_CCCC_DDDD_IN。
在對(duì)開(kāi)發(fā)進(jìn)行嚴(yán)刑拷打逼問(wèn)后(如果開(kāi)發(fā)小哥不松口怎么辦?下節(jié)預(yù)告:可以直接查詢時(shí)間段的DDL語(yǔ)句執(zhí)行情況),終于告訴我當(dāng)天晚上時(shí)間點(diǎn)上對(duì)這兩張表做了大量新建分區(qū)表的操作,至此基本水落石出。
#根據(jù)dba_objects確定創(chuàng)建時(shí)間是否匹配
select owner,
object_name,
object_type,
to_char(created, 'yyyy-mm-dd hh24:mi:ss')
from dba_objects
where object_name = 'AA_BBB_CCCC_DDDD_OUT'
and created > to_date('2023-03-01', 'yyyy-mm-dd')
order by 4;
select owner,
object_name,
object_type,
to_char(created, 'yyyy-mm-dd hh24:mi:ss')
from dba_objects
where object_name = 'AA_BBB_CCCC_DDDD_IN'
and created > to_date('2023-03-01', 'yyyy-mm-dd')
order by 4;
最后關(guān)鍵點(diǎn)b:我一定要記住,應(yīng)該最先查看OSWatch的數(shù)據(jù),排除OS的問(wèn)題。至于OSW怎么部署,運(yùn)行和查看以后章節(jié)再補(bǔ)充。同時(shí)也得查看database的alert.log日志,有驚喜╰(°▽°)╯
以上就是Oracle動(dòng)態(tài)視圖v$active_session_history實(shí)戰(zhàn)示例的詳細(xì)內(nèi)容,更多關(guān)于Oracle動(dòng)態(tài)視圖的資料請(qǐng)關(guān)注腳本之家其它相關(guān)文章!
相關(guān)文章
IntelliJ DataGrip Oracle 11g遠(yuǎn)程連接的方法步驟
本文主要介紹了IntelliJ DataGrip Oracle 11g遠(yuǎn)程連接的方法步驟,文中通過(guò)示例代碼介紹的非常詳細(xì),具有一定的參考價(jià)值,感興趣的小伙伴們可以參考一下2021-09-09
Oracle內(nèi)存分配不足的過(guò)程解析(業(yè)務(wù)干掛數(shù)據(jù)庫(kù))
本文介紹了Oracle數(shù)據(jù)庫(kù)內(nèi)存分配不足的問(wèn)題,原因主要是業(yè)務(wù)劇增導(dǎo)致的內(nèi)存不足,通過(guò)分析AAS負(fù)載、等待事件、transactions和阻塞情況,發(fā)現(xiàn)PGA內(nèi)存出現(xiàn)了嚴(yán)重抖動(dòng),感興趣的朋友一起看看吧2025-02-02
Oracle數(shù)據(jù)庫(kù)的備份與恢復(fù)
Oracle數(shù)據(jù)庫(kù)的備份與恢復(fù)...2007-03-03
Oracle安裝過(guò)程中物理內(nèi)存檢查及臨時(shí)temp空間不足問(wèn)題解決
Oracle安裝過(guò)程物理內(nèi)存檢查及臨時(shí)temp空間不足的情況,想必有很多的朋友都有遇到過(guò)吧,下面與大家分享下具體的解決方法,感興趣的朋友可以參考下哈2013-07-07
深入淺析Oracle數(shù)據(jù)庫(kù)管理之創(chuàng)建和刪除數(shù)據(jù)庫(kù)
本篇文章給大家介紹oracle數(shù)據(jù)庫(kù)管理之創(chuàng)建和刪除數(shù)據(jù)庫(kù),本文從數(shù)據(jù)庫(kù)管理概述、數(shù)據(jù)庫(kù)管理方法、數(shù)據(jù)庫(kù)的準(zhǔn)則、使用dbca創(chuàng)建數(shù)據(jù)庫(kù)、使用dbca刪除數(shù)據(jù)庫(kù)等五大方面展開(kāi)話題,需要的朋友一起學(xué)習(xí)吧2015-10-10
oracle數(shù)據(jù)庫(kù)實(shí)現(xiàn)按多個(gè)字段排序
這篇文章主要介紹了oracle數(shù)據(jù)庫(kù)實(shí)現(xiàn)按多個(gè)字段排序方式,具有很好的參考價(jià)值,希望對(duì)大家有所幫助,如有錯(cuò)誤或未考慮完全的地方,望不吝賜教2024-06-06

