Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> RE: Estimating space needed for UNDO tablespaces

RE: Estimating space needed for UNDO tablespaces

From: Thomas Jeff <jeff.thomas_at_thomson.net>
Date: Mon, 29 Sep 2003 10:59:39 -0800
Message-ID: <F001.005D1625.20030929105939@fatcity.com>


Kirti,

Thanks for this information. I've implemented AUM in a number of our development
databases. One of the things I have to do is write up a monitoring policy to hand
to our contracted production DBAs -- guidelines on how to address certain scenarios
and so forth -- otherwise, they will simply resort to adding 'more' of whatever they
presume is in short supply in event of a production crisis.

For example, I'm seeing some steal counts in v$undostat, implying that the undo
tablespace needs more space. However, from what you are saying, it seems that if
undo_retention is consistently larger then maxquerylen during the period of time when
the steal counts occur, that maybe the smarter thing to do is simply reduce the
undo_retention parameter before considering adding more space?

Jeff

-----Original Message-----
Sent: Friday, September 26, 2003 11:50 PM To: Multiple recipients of list ORACLE-L

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.


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: kirtikumar_deshpande_at_yahoo.com

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: ListGuru_at_fatcity.com (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.net
-- 
Author: Thomas Jeff
  INET: jeff.thomas_at_thomson.net

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: ListGuru_at_fatcity.com (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).
Received on Mon Sep 29 2003 - 13:59:39 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US