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 


 

 

 


 

 

 
 

Oracle dbms_space.create_index_cost tips

Oracle Database Tips by Donald BurlesonMay 26,  2015

Question:  How can I do capacity planning for Oracle indexes.  I need to estimate the size of an index and see if an index rebuild will release a significant amount of disk space.

Answer:  Capacity planning is easy in Oracle if you know the methods for estimating growth of tables and indexes.  Also see these important notes on index rebuilding.  Here are notes on using the dbms_space.create_index_cost procedure to show expected space usage for an Oracle inex.

dbms_space.create_index_cost tips

The dbms_space.create_index_cost, procedure accepts the DDL for a "create index" statement and outputs the storage needed to create the index.  The Oracle documentation notes these input parameters for dbms_space.create_index_cost:

ddl

The create index DDL statement

used_bytes

The number of bytes representing the actual index data

alloc_bytes

Size of the index when created in the tablespace

plan_table

Which plan table to use, default NULL

 

Important Note:  Using dbms_space.create_index_cost requires that the table already exist and that the table have current metadata statistics (as computed with dbms_stats).

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:

 Here is a procedure to invoke dbms_space.create_index_cost:

 

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 running dbms_space.create_index_cost looks like this:

 

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 of using dbms_space.create_index_cost 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.




 

 

��  
 
 
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 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.