Find out which next extents will fail

This script will give you information about which Oracle next extents are going to fail.

This tip is useful for DBAs to find out which next extents are going to fail when Oracle allocates them. There are many tips available that give similar information so you may ask what is unique about this tip. It takes into account Dictionary Managed Tablespaces as well as Locally Managed Tablespaces. This tip also takes into account whether a datafile is set to Autoextent ON. Oracle versions tested: 8.1.6,8.1.7 and 9.0.1, and it will...

also work on 9.2.

Set Linesize 130
Set Trims on
Column Tablespace             Format A30
Column SegmentType            Format A12
Column Owner                  Format A12
Column Segment                Format A30
Column "Required Extent(KB)"  Format 999,999,999.99
Column "MaxAvail(KB)"         Format 999,999,999.99
    


SELECT    /*+ RULE */ 
          SEG.tablespace_name "Tablespace",
          SEG.segment_type "SegmentType",
          EXT.OWNER,
          EXT.segment_name "Segment",
          decode(freespace.Extent_Management,'DICTIONARY',decode(SEG.extents,1,SEG.next_extent,
          ext.bytes * (1+SEG.pct_increase/100))
          ,'LOCAL',decode(freespace.Allocation_Type,'UNIFORM',freespace.INITIAL_EXTENT,'SYSTEM',EXT.bytes))/1024 as "Required Extent(KB)",
          freespace.largest/1024 "MaxAvail(KB)"
FROM      DBA_EXTENTS EXT,DBA_SEGMENTS SEG,
         (
           Select     /*+ RULE */ 
                     MaxSize_PerFile.Tablespace_name, TBS.Extent_Management, TBS.Allocation_Type, TBS.INITIAL_EXTENT,
                     TBS.NEXT_EXTENT, Max(MaxSize_PerFile.MaxSizeBytes) As Largest
           FROM
               (
                  SELECT     /*+ RULE */ 
                             DDF.TABLESPACE_NAME, DDF.File_Id,
                             decode(AUTOEXTENSIBLE,'YES',(DDF.MAXBYTES-DDF.BYTES),0) + Nvl(Max (DFS.bytes ),0) as MaxSizeBytes, 
                      Nvl(Max (DFS.bytes ),0) as MaxFreeExtentSizeBytes
                  FROM       Dba_Free_Space DFS, DBA_DATA_FILES DDF , DBA_TABLESPACES TBSP
                  WHERE      DFS.File_Id (+)            = DDF.File_Id
                  AND        TBSP.Tablespace_Name       = DDF.TABLESPACE_NAME
                  AND        TBSP.CONTENTS              = 'PERMANENT'
                  AND        TBSP.STATUS                = 'ONLINE'
                  Group By   DDF.TABLESPACE_NAME, DDF.File_Id,decode(AUTOEXTENSIBLE,'YES',(DDF.MAXBYTES-DDF.BYTES),0)
               )   MaxSize_PerFile, dba_tablespaces TBS
          WHERE    MaxSize_PerFile.Tablespace_Name      = TBS.Tablespace_Name
          AND      TBS.Status                           = 'ONLINE'
          GROUP BY MaxSize_PerFile.Tablespace_Name, TBS.Extent_Management, TBS.Allocation_Type, 
                   TBS.INITIAL_EXTENT, TBS.NEXT_EXTENT
        ) FREESPACE
WHERE
        SEG.owner            =     EXT.owner 
AND     SEG.segment_type     =     EXT.segment_type 
AND     SEG.segment_name     =     EXT.segment_name 
AND     SEG.tablespace_name  =     EXT.tablespace_name 
AND    (SEG.extents-1)       =     EXT.extent_id 
AND    SEG.tablespace_name   =     FREESPACE.tablespace_name
AND    decode(freespace.Extent_Management,'DICTIONARY',
       decode(SEG.extents,1,(SEG.next_extent),ext.bytes*(1+SEG.pct_increase/100))
       ,'LOCAL',decode(freespace.Allocation_Type,'UNIFORM',freespace.INITIAL_EXTENT,'SYSTEM',EXT.bytes)) > freespace.largest
ORDER BY SEG.Tablespace_Name,SEG.Segment_Type,SEG.Segment_Name
/

Reader Feedback

Kevin Y. writes: This script is wrong on this line:

decode(freespace.Allocation_Type,'UNIFORM',freespace.INITIAL_EXTENT,'SYSTEM',EXT.bytes)

When the allocation_type is 'SYSTEM' it uses DBA_EXTENTS.BYTES as next extent -- this is definitely wrong! When the DBA finds the failed extent, he changes the storage (next blah) for this object to a smaller size, to let it grow. But this script still shows the object!

The author responds: Kevin Y. writes that when allocation_type is SYSTEM then it does not give a correct result. He is right about this. When you are using LMT tablespaces with Allocation_Type set to SYSTEM, there is no Oracle-published algorithm about what is going to be your next extent. My script assumes that the next extent would be the same as the previous extent as the method of calculation. Even you can figure out by doing some research how Oracle is allocating extents in case of Autoallocate extent, that logic could change in a different version of Oracle. Though, as a DBA, I would not advise you to create LMT tablespace with Autoallocate Allocation Type.

You can replace the below line from the script (in the Select and Where clauses) as follows:

decode(freespace.Extent_Management,'DICTIONARY',decode(SEG.extents,1,SEG.next_extent,ext.bytes * (1+SEG.pct_increase/100)),
'LOCAL',decode(freespace.Allocation_Type,'UNIFORM',freespace.INITIAL_EXTENT,
'SYSTEM',EXT.bytes))/1024 as "Required Extent(KB)",

With:

decode(freespace.Extent_Management,'DICTIONARY',SEG.next_extent,'LOCAL',
decode(freespace.Allocation_Type,'UNIFORM',freespace.INITIAL_EXTENT,
'SYSTEM',EXT.bytes))/1024 as "Required Extent(KB)",

Finally, for Dictionary Managed Tablespaces, Oracle keeps the calculated value of Next Extent in DBA_SEGMENTS -- that's why there is no need to calculate it.

For More Information

  • Feedback: E-mail the editor with your thoughts about this tip.
  • More tips: Hundreds of free Oracle tips and scripts.
  • Tip contest: Have an Oracle tip to offer your fellow DBAs and developers? The best tips submitted will receive a cool prize -- submit your tip today!
  • Ask the Experts: Our SQL, database design, Oracle, SQL Server, DB2, metadata, and data warehousing gurus are waiting to answer your toughest questions.
  • Forums: Ask your technical Oracle questions--or help out your peers by answering them--in our active forums.
  • Best Web Links: Oracle tips, tutorials, and scripts from around the Web.

This was first published in April 2003

Dig deeper on Oracle database backup and recovery

Pro+

Features

Enjoy the benefits of Pro+ membership, learn more and join.

0 comments

Oldest 

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to:

-ADS BY GOOGLE

SearchDataManagement

SearchBusinessAnalytics

SearchSAP

SearchSQLServer

TheServerSide

SearchDataCenter

SearchContentManagement

SearchFinancialApplications

Close