Thanks John.  Good point.  We are on 9.0.1.3 and we have turned on the
monitoring flag for our tables.  But the info that I am really looking for is
the amount of selects against the tables.  I just think that it would be nice to
know the top 5% of the tables that the users are selecting from (statspack
perhaps?).

Tom  

-----Original Message-----
Sent: Thursday, July 25, 2002 2:39 PM
To: Multiple recipients of list ORACLE-L


Tom,
 
If you are on 8i, how about using an ALTER TABLE <tab> MONITORING on all user
tables - schema by schema if you prefer - and looking at DBA_TAB_MODIFICATIONS
after a predefined period. My understanding from the Guru (Steve Adams that is!)
is that this tracking is achieved in memory via unlatched activity so there is
(should) be no performance overhead for turning on this monitoring - this
structure is flushed to disk once in 3 hours apparently. 9i takes this further
by allowing Indexes to be montored too (haven't tried that yet!)
 
Oh-Boy! It is nice to have On-topic queries after all those looooong OT threads.
 
Hth,
John Kanagaraj
Oracle Applications DBA
DBSoft Inc
(W): 408-970-7002

Want to know about a carpenter who built a bridge with two sticks and three
nails? Write me for details!

** The opinions and statements above are entirely my own and not those of my
employer or clients **


-----Original Message-----
Sent: Thursday, July 25, 2002 5:48 AM
To: Multiple recipients of list ORACLE-L


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 
/ 


 

 

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: John Kanagaraj
  INET: [EMAIL PROTECTED]

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in the message
BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you
want to be removed from).  You may also send the HELP command for other
information (like subscribing).
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Terrian, Tom
  INET: [EMAIL PROTECTED]

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).

Reply via email to