Title: Message
You already have paret of what you need from the stats$sql_summary table which tells you how often a statement has been executed.  Bear in mind this table will truncate any statement to 1000 bytes.   You will probably also need the stats$sqltext table.  This table was added to statspack in Oracle 8.1.7.   What you need to do is to parse the statements to find the tables they access.  The easiest way of doing that  is to explain them.  This will  also tell you the type of access; e.g. FTS  or some type of index.  In Oracle 9i there is a V$SQL_Plan  table which could be added to the statspack "snapshots".   I have not fooled with the 9i version of statspack.  Perhaps it is already there. 
 
With this information you can say, for instance, the personnel table was accessed 35 times via an FTS in the past hour, and you would  know which statements caused that access.  What would be nice to know is how many I/0's it took to accomplish those scans.  The numbers present in stats$sql_summary  are for the entire statement and not for the individual tables.  The costs figures produced by explain are estimates.  It may seem that you could get the number of I/O's by knopwing the number of blocks below the highwater mark and the size of each db_file_scattered_read.  However  a read for various reasons may not fetch the maximum number of blocks.  I'm not sure how to get an accurate per segment I/O count.
 
Also missing would be  any waits associated with accessing the tables.
 
Ian MacGregor
Stanford Linear Accelerator Center
-----Original Message-----
From: Terrian, Tom [mailto:[EMAIL PROTECTED]]
Sent: Thursday, July 25, 2002 5:48 AM
To: Multiple recipients of list ORACLE-L
Subject: Hot tables

How is everyone identifying hot tables?  In my tool box I have the following two scripts but I am looking for other options.  How do you track frequently accessed tables?
 
Script #1 - Author unknown:
select obj_name, sum(decode(action_name,'SELECT',1,0)) sel  ,sum(decode(action_name,'INSERT',1,0)) inserts,
                            sum(decode(action_name,'UPDATE',1,0)) updates,
                            sum(decode(action_name,'DELETE',1,0)) deletes
from dba_audit_trail
having sum(decode(action_name,'SELECT' , 1, 'INSERT',1, 'DELETE',1,'UPDATE',1,0)) > 0
group by obj_name;

Script #2 - Dave Ensor (BMC):
set verify off
col CTYP heading 'Command Type'
col OBJ  format a32 wrap   heading 'Table'
col EXES format 999,990    heading 'Execs'
col GETS format 99,999,990 heading 'Buff Gets'
col ROWP format 99,999,990 heading 'Rows Proc'

select CTYP
     , OBJ
     , 0 - EXEM  EXES
     , GETS
     , ROWP
  from (select distinct EXEM, CTYP, OBJ, GETS, ROWP
          from ( select decode (S.COMMAND_TYPE
                                  ,  2, 'Insert into '
                                  ,  3, 'Select from '
                                  ,  6, 'Update  of  '
                                  ,  7, 'Delete from '
                                  , 26, 'Lock    of  ') CTYP
                         , O.OWNER || '.' || O.NAME    OBJ
                         , sum(0 - S.EXECUTIONS)       EXEM
                         , sum(S.BUFFER_GETS)          GETS
                         , sum(S.ROWS_PROCESSED)       ROWP
                    from V$SQL               S
                       , V$OBJECT_DEPENDENCY D
                       , V$DB_OBJECT_CACHE   O
                   where S.COMMAND_TYPE in (2,3,6,7,26)
                     and D.FROM_ADDRESS = S.ADDRESS
                     and D.TO_OWNER     = O.OWNER
                     and D.TO_NAME      = O.NAME
                     and O.TYPE         = 'TABLE'
                group by S.COMMAND_TYPE
                       , O.OWNER
                       , O.NAME )  )
 where ROWNUM <= &1
/

 

 

Reply via email to