Permalink
Browse files

added ash_io_top_obj_advanced

  • Loading branch information...
khailey committed Jan 11, 2013
1 parent b01fd99 commit ecb2ed2e635d6e8a3093a3f0324e3737964fc77e
Showing with 107 additions and 1 deletion.
  1. +15 −1 ash_io_top_obj.sql
  2. +92 −0 ash_io_top_obj_advanced.sql
View
@@ -1,6 +1,20 @@
-col objn for a28
+/*
+
+results look like:
+
+CNT OBJN OTYPE
+---- ------------------------- ---------------
+ 79 52949 ORDER_ITEMS TABLE PARTITION
+ 97 -1
+ 130 53117 ORD_STATUS_IX INDEX
+ 498 53120 CUST_EMAIL_IX INDEX
+ 512 0
+1632 53112 ITEM_ORDER_IX INDEX
+*/
+
+col objn for a28
select
count(*) cnt,
@@ -0,0 +1,92 @@
+
+
+/*
+
+
+Notice the 3rd row final column, it's UNDO. 1/2 of the query data is coming from UNDO
+Seeing sequential read waits on a full table scan that shoul normally
+be scattered read waits is a good flag that it might be undo coming from
+an uncommited transaction.
+
+This query can help identify that
+
+AAS SQL_ID PCT OBJ SUB_OBJ OTYPE EVENT F# TABLESPAC CONTENTS
+---- ----------------- ----------- ------- ---------- ---------- -- --------- ---------
+.00 f9u2k84v884y7 33 CUSTOMERS SYS_P27 TABLE PART sequentia 1 SYSTEM PERMANENT
+ 33 ORDER_PK INDEX sequentia 4 USERS PERMANENT
+ 33 sequentia 2 UNDOTBS1 UNDO
+.01 0tvtamt770hqz 100 TOTO1 TABLE scattered 7 NO_ASSM PERMANENT
+.06 75621g9y3xmvd 3 CUSTOMERS SYS_P36 TABLE PART sequentia 4 USERS PERMANENT
+ 3 CUSTOMERS SYS_P25 TABLE PART sequentia 4 USERS PERMANENT
+ 3 CUSTOMERS SYS_P22 TABLE PART sequentia 4 USERS PERMANENT
+ 3 CUSTOMERS SYS_P29 TABLE PART sequentia 4 USERS PERMANENT
+ 3 CUSTOMERS SYS_P21 TABLE PART sequentia 4 USERS PERMANENT
+
+
+*/
+
+
+col tcnt for 9999
+col aas for 999.99
+col sql_id for a14
+col cnt for 999
+col pct for 999
+col obj for a20
+col sub_obj for a10
+col otype for a15
+col event for a15
+col file# for 9999
+col tablespace_name for a15
+
+col f_minutes new_value v_minutes
+select &minutes f_minutes from dual;
+
+break on sql_id on aas on tcnt
+
+select
+ -- sum(cnt) over ( partition by io.sql_id order by sql_id ) tcnt,
+ round(sum(cnt) over ( partition by io.sql_id order by sql_id ) / (&v_minutes*60),2) aas,
+ io.sql_id,
+ -- io.cnt cnt,
+ 100*cnt/sum(cnt) over ( partition by io.sql_id order by sql_id ) pct,
+ --CURRENT_OBJ# obj#,
+ o.object_name obj,
+ o.subobject_name sub_obj,
+ o.object_type otype,
+ substr(io.event,8,10) event,
+ io.p1 file#,
+ f.tablespace_name tablespace_name,
+ tbs.contents
+from
+(
+ select
+ sql_id,
+ event,
+ count(*) cnt,
+ count(*) / (&v_minutes*60) aas,
+ CURRENT_OBJ# ,
+ ash.p1
+ from v$active_session_history ash
+ where ( event like 'db file s%' or event like 'direct%' )
+ and sample_time > sysdate - &v_minutes/(60*24)
+ group by
+ CURRENT_OBJ#,
+ event,
+ --o.object_name ,
+ --o.object_type ,
+ ash.p1,
+ sql_id
+) io
+ , dba_data_files f
+ , all_objects o
+ , dba_tablespaces tbs
+where
+ f.file_id = io.p1
+ and o.object_id (+)= io.CURRENT_OBJ#
+ and tbs.tablespace_name= f.tablespace_name
+Order by tcnt, sql_id, cnt
+/
+
+clear breaks
+
+

0 comments on commit ecb2ed2

Please sign in to comment.