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: Rollback Segment Problem

RE: Rollback Segment Problem

From: Mohammad Rafiq <rafiq9857_at_hotmail.com>
Date: Wed, 13 Feb 2002 09:59:37 -0800
Message-ID: <F001.0040E2DF.20020213092840@fatcity.com>

Samir,

For a long term solution, it is better to reorg rbs tablespace and rollback segments with correct sizing based on usage... You may use following script to get better info about rollback segments usage

1 set linesize 120
  2 column name format A15
  3 column status format A7
  4 column ext format 999
  5 column MB format 9990.0
  6 column HWMSIZE heading "HIGH|WATER" justify center format 9990.0   7 column AVEACT heading "AVERAGE|ACTIVE" justify center format 9990.0   8 column optsize format 999990
  9 column shrinks format 9990
10 column waits format 99999
11 set numwidth 8
12 select ud.name,

13         sg.extents ext,
14         round(sg.blocks * ts.blocksize / 1048576, 2) MB,
15         round(s.optsize / 1048576, 1) optsize,
16         round(s.aveactive / 1048576, 1) AVEACT,
17         round(s.hwmsize / 1048576, 1) HWMSIZE,
18         s.shrinks,
19         s.wraps,
20         s.waits,
21         nvl(s.status, 'OFFLINE') status
22  from v$rollstat s,
23       sys.undo$ ud,
24       sys.seg$ sg,
25       sys.ts$ ts
26  where ud.us# = s.usn (+)
27    and ud.file# = sg.file#

28 and ud.block# = sg.block#
29* and sg.ts# = ts.ts#

Regards

Rafiq

To: "'ORACLE-L_at_fatcity.com'" <ORACLE-L_at_fatcity.com> CC: "'rafiq9857_at_hotmail.com'" <rafiq9857_at_hotmail.com> Date: Wed, 13 Feb 2002 16:50:37 -0000

Thanks a lot, Rafiq....the output from ur query after running it on the database
showed the rollback segment to be highly fragmented.....the total extents were
7490 and the extents coalesced were only 440. The initial and next extents have been set at 409K which seems to me as quite small.

Regards,
Samir

Samir Sarkar
Oracle DBA - Lennon Team
SchlumbergerSema
Email : samir.sarkar_at_nottingham.sema.slb.com

             samir.sarkar_at_sema.co.uk
Phone : +44 (0) 115 - 957 6217
EPABX : +44 (0) 115 - 957 6418 Ext. 76217 Fax : +44 (0) 115 - 957 6018

-----Original Message-----

Sent: 13 February 2002 16:03
To: Multiple recipients of list ORACLE-L

Samir,
It is not coalesced automatically at shutdown and startup. It is to be coalesced manually. It applies to any tablespace with pctincrease set as 0(zero). I have no idea of 9i but this is normal behaviour of ver 7.3.4 to 8.1.7...

Regards
Rafiq

Reply-To: ORACLE-L_at_fatcity.com
To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> Date: Wed, 13 Feb 2002 05:48:28 -0800

Rafiq,

Just a small question....r the rollback segment extents in the rollback segment tablespace de-allocated when the database is shut down ?? In that case, does the fragmentation remain when the database is restarted or r the blocks coalesced automatically ??

Regards,
Samir

Samir Sarkar
Oracle DBA - Lennon Team
SchlumbergerSema
Email : samir.sarkar_at_nottingham.sema.slb.com

              samir.sarkar_at_sema.co.uk
Phone : +44 (0) 115 - 957 6217
EPABX : +44 (0) 115 - 957 6418 Ext. 76217 Fax : +44 (0) 115 - 957 6018

-----Original Message-----

Sent: 12 February 2002 17:49
To: Multiple recipients of list ORACLE-L

Is your tablespace fragmented as it is not finding contingous extent .. TRy to coalesce your subject tablespace and try...

you can use following script to check whether coalesing is required or not.. If percent is < 100 then coalesce it..

select substr(tablespace_name,1,10)TS_NAME,total_extents "Total_Extnts",extents_coalesced,round(percent_extents_coalesced,0) from dba_free_space_coalesced
order by tablespace_name
/

HTH
Regards
Rafiq

Reply-To: ORACLE-L_at_fatcity.com
To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> Date: Tue, 12 Feb 2002 02:33:19 -0800

All,

The following is the pitiable scenario I am in and would really appreciate a bit of help :

    We were running a long running delete job which gave the following error :

                                 Oracle8 Enterprise Edition Release
8.0.5.2.1 - Production
                                PL/SQL Release 8.0.5.2.0 - Production
                                SQLWKS> EXECUTE
PKG_PAS_AnnualDataMaintenance.Delete_OldData (2000, '/home/sqribe/work/live', '2000AnnualDataDelete.log');
                                ORA-01562: failed to extend rollback segment
number 8
                                ORA-01650: unable to extend rollback segment
RSUNDB08 by 50 in tablespace RSUN425
                                ORA-06512: at
"PAS.PKG_PAS_ANNUALDATAMAINTENANCE", line 66
                                ORA-06512: at line 2


    I don't understand why it ran out of rollback space. The rollback segment
has a virtually unlimited number of extents, so the only explanation I can see is that this particular rollback segment expanded until it exceeded the space allocation for the whole tablespace RSUN425, which is 3,000M. However, Oracle Storage Manager shows only 200M of the tablespace used, and it also shows high water marks against each rollback segment, none of which exceeds 400M. This would suggest to me that none of the previous month's deletions exceeded 400M per month, so why should it fail on this particular one when it had nearly 3,000M available?

Is there something I am not understanding about rollback segments ??

Thanks and Regards,
Samir

Samir Sarkar
Oracle DBA - Lennon Team
SchlumbergerSema
Email : samir.sarkar_at_nottingham.sema.slb.com

               samir.sarkar_at_sema.co.uk
Phone : +44 (0) 115 - 957 6217
EPABX : +44 (0) 115 - 957 6418 Ext. 76217 Fax : +44 (0) 115 - 957 6018



This email is confidential and intended solely for the use of the individual to whom it is addressed. Any views or opinions presented are solely those of the author and do not necessarily represent those of SchlumbergerSema.
If you are not the intended recipient, be advised that you have received this
email in error and that any use, dissemination, forwarding, printing, or copying of this email is strictly prohibited.

If you have received this email in error please notify the SchlumbergerSema Helpdesk by telephone on +44 (0) 121 627 5600.


--

Please see the official ORACLE-L FAQ: http://www.orafaq.com
--

Author: SARKAR, Samir

     INET: Samir.SARKAR_at_nottingham.sema.slb.com

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: 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).

MOHAMMAD RAFIQ



Chat with friends online, try MSN Messenger: http://messenger.msn.com

--

Please see the official ORACLE-L FAQ: http://www.orafaq.com
--

Author: Mohammad Rafiq

    INET: rafiq9857_at_hotmail.com

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

Author: SARKAR, Samir

    INET: Samir.SARKAR_at_nottingham.sema.slb.com

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: 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).

MOHAMMAD RAFIQ



Send and receive Hotmail on your mobile device: http://mobile.msn.com

--

Please see the official ORACLE-L FAQ: http://www.orafaq.com
--

Author: Mohammad Rafiq

   INET: rafiq9857_at_hotmail.com

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: 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).

MOHAMMAD RAFIQ



Send and receive Hotmail on your mobile device: http://mobile.msn.com

--

Please see the official ORACLE-L FAQ: http://www.orafaq.com
--

Author: Mohammad Rafiq
  INET: rafiq9857_at_hotmail.com

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: 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 Wed Feb 13 2002 - 11:59:37 CST

Original text of this message

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