You can run following query to get an idea of undo generation rate and max query 
length: 

SELECT 
      to_char(min(begin_time),'MM/DD/YYYY HH24:MI:SS') "Begin Time",
      to_char(max(end_time),'MM/DD/YYYY HH24:MI:SS') "End Time",
      (max(end_time)-min(begin_time))*24*60*60 "Seconds",
      sum(undoblks) "UndoBlks",
      sum(undoblks)/((max(end_time)-min(begin_time))*24*60*60) "UndoBlksPerSec",
      max(maxquerylen) "MaxQueryLenSecs"
 FROM 
        v$undostat;

Unfortunately, the TXNCOUNT column in v$undostat view in Oracle 9.2.0.x is screwed up. 
It does not
correctly report the transaction count for the sample interval. Instead it keeps 
accumulating. One
needs to do the math to get the correct count for the desired sample interval. It will 
show the
time of high transaction activity with related undo generation.

Oracle recommends setting undo_retention to the max(maxquerylen), but use your 
judgement. If data
loads and queries accessing same tables, do not run at the same time (in DW, for 
example), setting
undo_retention to a high number (maxquerylen) will simply waste disk space. 

If undo_retention is not set appropriately, you will get ORA-1555, and it will be 
reported in
alert.log along with the affected SQL statement. The log entry will also contain the 
query time,
in seconds, before it got aborted due to ORA-1555. 

Also, the above query works only when the database is using AUM. V$undostat does not 
report
anything in 9.2.0.x when using MUM (manual undo mode). In 9.0.1, it returns one 
useless row when
using MUM! 

BTW, you can also use the OEM to see the undo generation rate. It is one of the few 
things in OEM
(standalone mode) I use. 


Hth. 

- Kirti 



--- Daniel Fink <[EMAIL PROTECTED]> wrote:
> That sounds very reasonable. You can check that number against the values in
> v$undostat as it runs. Remember, UNDO_RETENTION is not guaranteed. If the
> space is needed by another segment, it may be taken even if the expire time
> has not been reached.
> 
> Daniel
> 
> Thomas Jeff wrote:
> 
> > Thanks for the reply Dan.
> >
> > Would you suggest setting UNDO_RETENTION to roughly the length of time of
> > the longest
> > running job in the database?   For example, in our DW, our BI analysts tell
> > me that their
> > longest batch run is about 1 hr 45 minutes.   My uneducated guess is to
> > accordingly
> > set the parameter to approx 2 hours.
> >
> > -----Original Message-----
> > Sent: Friday, September 26, 2003 4:15 PM
> > To: Multiple recipients of list ORACLE-L
> >
> > That is a good place to start. You might consider adding a little if you
> > have many concurrent transactions or want to increase the undo_retention
> > to a high number. Once you are using AUM, keep a close eye on
> > v$undostat, though there are some known issues with it not populating
> > properly, keep an eye on the begin_time and end_time. However, for
> > estimation purposes it should work.
> >
> > Daniel Fink
> >
> > Thomas Jeff wrote:
> >
> > > I'm beginning the process of converting over to automatic
> > > undo management.  I'm wondering as to exactly how large to
> > > initially build the UNDO tablespace.    Make it roughly
> > > the same size as the sum of the current rollback
> > > tablespaces?    Or has your experience been different,
> > > i.e., you've found you've generally needed more or less
> > > space with respect to the previous allocation for rollback
> > > segments (manual undo)?
> > >
> > > Thanks.
> > >
> > > --------------------------------------------
> > > Jeffery D Thomas
> > > DBA
> > > Thomson Information Services
> > > Thomson, Inc.
> > >
>


__________________________________
Do you Yahoo!?
The New Yahoo! Shopping - with improved product search
http://shopping.yahoo.com
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Kirtikumar Deshpande
  INET: [EMAIL PROTECTED]

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
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