Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 

Online Table Reorganization

Oracle Tips by Burleson Consulting

Online Segment Reorganization

An Oracle10g database can reclaim space within data segments online without affecting the ability of end users to access their data. The only thing that must be ensured before using online segment reorganization capability is that the tablespaces have the Automatic Segment Space Management (ASSM) and row movement features enabled. Oracle10g introduces the ability to reclaim space from a segment by shrinking of the segment. Shrinking a segment will make unused space available to other segments in the tablespace and may improve the performance of queries and DML operations.

 

With the introduction of the alter table xxx shrink space compact syntax, the DBA gets a powerful tool for effective and easy database space management. However, the DBA needs to know what data segments experience high space waste in order to reclaim free space to the database and shrink segments. The awr_list_seg_block_space.sql script below reports percentages of free space for data segments:

 

<      awr_list_seg_block_space.sql

 

-- *************************************************

-- Copyright © 2007 by Rampant TechPress

-- *************************************************

 

drop type BlckFreeSpaceSet;

drop type BlckFreeSpace;

 

create type BlckFreeSpace as object

(

 seg_owner varchar2(30),

 seg_type varchar2(30),

 seg_name varchar2(100),

 fs1 number,

 fs2 number,

 fs3 number,

 fs4 number,

 fb  number

 );

 

create type BlckFreeSpaceSet as table of  BlckFreeSpace;

 

create or replace function BlckFreeSpaceFunc (seg_owner IN varchar2, seg_type in varchar2 default null) return BlckFreeSpaceSet

pipelined

is

   outRec BlckFreeSpace := BlckFreeSpace(null,null,null,null,null,null,null,null);

   fs1_b number;

   fs2_b number;

   fs3_b number;

   fs4_b number;

   fs1_bl number;

   fs2_bl number;

   fs3_bl number;

   fs4_bl number;

   fulb number;

   fulbl number;

   u_b number;

   u_bl number;

begin

  for rec in (select s.owner,s.segment_name,s.segment_type from dba_segments s where owner = seg_owner and segment_type = nvl(seg_type,segment_type) )

  loop

    dbms_space.space_usage(

      segment_owner      => rec.owner,

      segment_name       => rec.segment_name,

      segment_type       => rec.segment_type,

      fs1_bytes          => fs1_b,

      fs1_blocks         => fs1_bl,

      fs2_bytes          => fs2_b,

      fs2_blocks         => fs2_bl,

      fs3_bytes          => fs3_b,

      fs3_blocks         => fs3_bl,

      fs4_bytes          => fs4_b,

      fs4_blocks         => fs4_bl,

      full_bytes         => fulb,

      full_blocks        => fulbl,

      unformatted_blocks => u_bl,

SEE CODE DEPOT FOR FULL SCRIPT

   );

 

   outRec.seg_owner := rec.owner;

   outRec.seg_type := rec.segment_type;

   outRec.seg_name := rec.segment_name;

  

   outRec.fs1 := fs1_bl;

   outRec.fs2 := fs2_bl;

   outRec.fs3 := fs3_bl;

   outRec.fs4 := fs4_bl;

   outRec.fb  := fulbl;

 

   Pipe Row (outRec);

 

  end loop;

  return;

end;

/

 

The following script can be used to quickly generate a report showing which data segments are good candidates for segment shrinking, thus restoring the wasted space to the tablespace:

 

<      free_space_by_segment.sql

 

col seg_owner heading 'Segment|Owner' format a10

col seg_type heading 'Segment|Type'   format a10

col seg_name heading 'Segment|Name'   format a30

 

col fs1 heading '0-25%|Free Space'    format 9,999

col fs2 heading '25-50%|Free Space'   format 9,999

col fs3 heading '50-75%|Free Space'   format 9,999

col fs4 heading '75-100%|Free Space'  format 9,999

col fb  heading 'Full|Blocks'         format 9,999

 

accept user_name prompt ‘Enter Segment Owner: ‘

 

break on seg_owner

 

select

  *

from

  Table ( BlckFreeSpaceFunc ('&user_name', 'TABLE' ) )

order by

  fs4 desc

;

 

The following is the sample output of the above script for the PERFSTAT schema that owns STATSPACK utility:

 

Segment    Segment    Segment                             0-25%     25-50%     50-75%    75-100%   Full

Owner      Type       Name                           Free Space Free Space Free Space Free Space Blocks

---------- ---------- ------------------------------ ---------- ---------- ---------- ---------- ---

PERFSTAT   TABLE      STATS$EVENT_HISTOGRAM                   0          0          2         47    321

           TABLE      STATS$LATCH                             0          0          1         35    522

           TABLE      STATS$SQL_SUMMARY                       0          1          0         28  1,285

           TABLE      STATS$SYSSTAT                           1          0          1         13    355

           TABLE      STATS$LIBRARYCACHE                      0          0          0          7     13

           TABLE      STATS$SQL_WORKAREA_HISTOGRAM            0          0          1          7      5

           TABLE      STATS$ROWCACHE_SUMMARY                  0          0          1          6     43

           TABLE      STATS$ENQUEUE_STATISTICS                0          0          1          6     66

           TABLE      STATS$RESOURCE_LIMIT                    1          0          1          6      5

           TABLE      STATS$TIME_MODEL_STATNAME               0          0          0          5      0

           TABLE      STATS$DATABASE_INSTANCE                 0          0          0          5      0

           TABLE      STATS$LEVEL_DESCRIPTION                 0          0          0          5      0

           TABLE      STATS$IDLE_EVENT                        0          0          0          5      0

           TABLE      STATS$WAITSTAT                          1          0          1          5     13

           TABLE      STATS$STATSPACK_PARAMETER               0          0          0          5      0

           TABLE      STATS$TEMP_HISTOGRAM                    0          1          0          4      0

           TABLE      STATS$INSTANCE_RECOVERY                 0          1          0          4      0

           TABLE      STATS$SQL_STATISTICS                    0          0          1          4      0

           TABLE      STATS$SGASTAT                           0          0          2          4     44

           TABLE      STATS$THREAD                            0          0          1          4      0

           TABLE      STATS$ROLLSTAT                          0          1          1          4     14

           TABLE      STATS$PARAMETER                         1          0          0          4    301

 

Based on the 75-100% freespace numbers in the above output, one can see that tables stats$event_histogram, stats$latch, stats$sql_summary, and stats$sysstat are good candidates for segment shrinking. The following alter table enable row movement and alter table shrink space compact statements can be issued to shrink the segments mentioned:

 

SQL> alter table stats$event_histogram enable row movement;

Table altered.

 

SQL> alter table stats$event_histogram shrink space compact;

Table altered.

 

SQL> alter table stats$latch enable row movement;

Table altered.

 

SQL> alter table stats$latch shrink space compact;

Table altered.

 

SQL> alter table stats$sql_summary enable row movement;

Table altered.

 

SQL> alter table stats$sql_summary shrink space compact;

Table altered.

 

SQL> alter table stats$sysstat enable row movement;

Table altered.

 

SQL> alter table stats$sysstat shrink space compact;

Table altered.

 

In order to verify that Oracle reclaimed the space, the report script shown above should be issued again to yield the following result.

 

SQL> @ awr_report_seg_block_space.sql

 

Segment    Segment    Segment                             0-25%     25-50%     50-75%    75-100%   Full

Owner      Type       Name                           Free Space Free Space Free Space Free Space Blocks

---------- ---------- ------------------------------ ---------- ---------- ---------- ---------- ---

PERFSTAT   TABLE      STATS$LIBRARYCACHE                      0          0          0          7     13

           TABLE      STATS$SQL_WORKAREA_HISTOGRAM            0          0          1          7      5

           TABLE      STATS$ROWCACHE_SUMMARY                  0          0          1          6     43

           TABLE      STATS$RESOURCE_LIMIT                    1          0          1          6      5

           TABLE      STATS$ENQUEUE_STATISTICS                0          0          1          6     66

…….

           TABLE      STATS$SHARED_POOL_ADVICE                1          0          0          2     17

           TABLE      STATS$BUFFER_POOL_STATISTICS            0          0          2          2      1

           TABLE      STATS$EVENT_HISTOGRAM                   0          1          0          1    320

           TABLE      STATS$SYSSTAT                           0          0          1          1    356

           TABLE      STATS$SGA                               0          1          1          1      2

           TABLE      STATS$BUFFERED_QUEUES                   0          1          2          1      1

           TABLE      STATS$PGASTAT                           1          1          1          1      9

           TABLE      STATS$SYS_TIME_MODEL                    0          1          1          1     10

…..

           TABLE      STATS$PGA_TARGET_ADVICE                 1          0          1          0     11

           TABLE      STATS$LATCH_PARENT                      0          0          0          0      0

           TABLE      STATS$LATCH_CHILDREN                    0          0          0          0      0

           TABLE      STATS$LATCH                             0          1          1          0    521

           TABLE      STATS$DB_CACHE_ADVICE                   0          1          0          0     27

           TABLE      STATS$SQL_SUMMARY                       1          0          0          0  1,284

           TABLE      STATS$SEG_STAT_OBJ                      0          0          0          0      0

           TABLE      STATS$SQL_PLAN                          0          0          0          0      0

           TABLE      STATS$SESS_TIME_MODEL                   0          0          0          0      0

           TABLE      STATS$DLM_MISC                          0          0          0          0      0

           TABLE      STATS$CR_BLOCK_SERVER                   0          0          0          0      0

           TABLE      STATS$CURRENT_BLOCK_SERVER              0          0          0          0      0

           TABLE      STATS$CLASS_CACHE_TRANSFER              0          0          0          0      0

 

From the listing above, it is apparent that the tables that underwent the shrink operation consume much less space than they did previously. The HWM for tables can be reset using a SQL statement like ALTER TABLE SHRINK SPACE. The shrink operation is performed completely online without affecting end users. If the CASCADE option is added to the SHRINK clause, Oracle will also compact indexes created on the target table.

 

Figure 17.7:  Database objects that support the SHRINK SPACE operation.

 

Figure 17.7 shows database objects that support the SHRINK SPACE operation. Oracle10g provides the ability to perform an in-place reorganization of data for optimal space utilization by shrinking it. This feature also provides the ability to both compact the space used in a segment and then deallocate it from the segment. The deallocated space is returned to the tablespace and is available to other objects in the tablespace. Sparsely populated tables may cause a performance problem for full-table scans. By performing SHRINK, data in the table is compacted and the high water mark of the segment is pushed down. This makes full-table scans read less blocks and hence, run faster. Also, during compaction, row chaining is eliminated whenever possible.

 

Segment shrink is an online operation where the table being shrunk is open to queries and DML while the segment is being shrunk. Additionally, segment shrink is performed in place. This is a key advantage over performing Online Table Redefinition for compaction and reclaiming space. The DBA may schedule segment shrink for one or all the objects in the database as nightly jobs without requiring any additional space to be provided to the database. Segment shrink works on heaps, IOTs, LOBs, Materialized Views and Indexes with row movement enabled in tablespaces with Automatic Segment Space Management.

 

When segment shrink is performed on tables with indexes on them, the indexes are automatically maintained when rows are moved around for compaction. User defined triggers are not fired, however, because compaction is a purely physical operation and does not impact the application.

 

The dbms_space package allows the DBA to also estimate sizes of indexes intended for creation on a table. The create_index_cost procedure from the dbms_space package allows users to get estimate for space usage of the future index, and the following SQL script can be used to accomplish this:

 

declare

   u_bytes number;

   a_bytes number;

begin

   dbms_space.create_index_cost (

      ddl => 'create index stats$sysstat_idx on stats$sysstat '||

        '(value) tablespace sysaux',

      used_bytes => u_bytes,

      alloc_bytes => a_bytes

   );

   dbms_output.put_line ('Used Bytes      = '|| u_bytes);

   dbms_output.put_line ('Allocated Bytes = '|| a_bytes);

end;

/  

 

The result of this PL/SQL block looks like:

 

SQL>

  1  declare

  2     u_bytes number;

  3     a_bytes number;

  4  begin

  5     dbms_space.create_index_cost  (

  6        ddl => 'create index stats$sysstat_idx on stats$sysstat '||

  7          '(value) tablespace sysaux',

  8        used_bytes => u_bytes,

  9        alloc_bytes => a_bytes

 10     );

 11     dbms_output.put_line ('Used Bytes      = '|| u_bytes);

 12     dbms_output.put_line ('Allocated Bytes = '|| a_bytes);

 13* end;


SQL> /

Used Bytes      = 392886

Allocated Bytes = 851968

 

PL/SQL procedure successfully completed.

 

This approach is useful because it allows the DBA to adjust some storage parameters before creating an index. The create_table_cost procedure for table space size estimates is also available within the dbms_space package.

 

SEE CODE DEPOT FOR FULL SCRIPTS


This is an excerpt from my latest book "Oracle Tuning: The Definitive Reference". 

You can buy it direct from the publisher for 30%-off and get instant access to the code depot of Oracle tuning scripts:

 

 


 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2017

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

Remote Emergency Support provided by Conversational