代码拉取完成,页面将自动刷新
/*
TOP SQL from dba_hist_active_sess_history no v$active_session_history
filter by DBID
output looks like
SQL_ID PLAN_HASH TYPE CPU WAIT IO TOTAL
------------- ---------- ---------------- --------- ---------- --------- ----------
fgzp9yqqjcjvm 707845071 UPDATE 25.0 95 4081.0 4201
8u8y8mc1qxd98 131695425 SELECT 18.0 57 3754.0 3829
cfk8gy594h42s 3743737989 SELECT 2021.0 17 82.0 2120
cnx6ht8bdmf4c 0 PL/SQL EXECUTE 546.0 367 868.0 1781
gyj8wh7vx960y 1736948211 SELECT 197.0 11 1227.0 1435
1wmz1trqkzhzq 1384060092 SELECT 639.0 20 679.0 1338
5vjzz8f5ydqm7 1375932572 SELECT 538.0 0 541.0 1079
8w08jp8urfj6t 3134135242 SELECT 118.0 10 945.0 1073
*/
col type for a10
col "CPU" for 999999.9
col "IO" for 999999.9
select * from (
select
ash.SQL_ID , ash.SQL_PLAN_HASH_VALUE Plan_hash, aud.name type,
sum(decode(ash.session_state,'ON CPU',1,0)) "CPU",
sum(decode(ash.session_state,'WAITING',1,0)) -
sum(decode(ash.session_state,'WAITING', decode(wait_class, 'User I/O',1,0),0)) "WAIT" ,
sum(decode(ash.session_state,'WAITING', decode(wait_class, 'User I/O',1,0),0)) "IO" ,
sum(decode(ash.session_state,'ON CPU',1,1)) "TOTAL"
from dba_hist_active_sess_history ash,
audit_actions aud
where SQL_ID is not NULL
and ash.dbid=&DBID
and ash.sql_opcode=aud.action
-- and ash.sample_time > sysdate - &minutes /( 60*24)
group by sql_id, SQL_PLAN_HASH_VALUE , aud.name
order by sum(decode(session_state,'ON CPU',1,1)) desc
) where rownum < 10
/
此处可能存在不合适展示的内容,页面不予展示。您可通过相关编辑功能自查并修改。
如您确认内容无涉及 不当用语 / 纯广告导流 / 暴力 / 低俗色情 / 侵权 / 盗版 / 虚假 / 无价值内容或违法国家有关法律法规的内容,可点击提交进行申诉,我们将尽快为您处理。