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: re Rebuilding Indexes in Oracle Apps -- Quoting an Apps

Re: re Rebuilding Indexes in Oracle Apps -- Quoting an Apps

From: Hemant K Chitale <hkchital_at_singnet.com.sg>
Date: Thu, 16 Oct 2003 07:49:44 -0800
Message-ID: <F001.005D361C.20031016074944@fatcity.com>



Richard,

Quoting Metalink Note "182699.1"  on "        bde_rebuild.sql - Validates and
        Rebuilds Fragmentated Indexes (8.0-9.0)"

Index fragmentation occurs when a key value changes, and the index row is
    deleted from one place (Leaf Block) and inserted into another.
    Deleted Leaf Rows are not reused.  Therefore, indexes whose columns are
    subject to value change must be rebuilt periodically, since they become
    naturally fragmentated.
 
    An index is considered to be 'fragmentated' when more than 20% of its
    Leaf Rows space is empty because of the implicit deletes caused by indexed
    columns value changes.
 
    Fragmentated indexes degrade the performance of index range scan
    operations.
At 06:29 AM 16-10-03 -0800, you wrote:
> On Wed, 2003-10-15 at 18:04, M Rafiq wrote:
> > Jared,
> >
> > Those tables are transit type of tables and depending on your volume of
> > data, there are lot of deletes and inserts all the time resuling index
> > fragmentation(holes due to deletes) and space usage.
> >
> > The rebuilding not only release the space but also reduces the index
> > fragmentation. If you don't have table truncation option for such tables
> > then it is much better to rebuid indexes on such tables at regular interval
> > to release space and for better performance.
> >

 
Hi Rafiq,
 
I haven't been receiving all the mail from this list so I don't know the full thread and it doesn't appear a mail I sent a few days ago regarding all this ever made it so I could be wasting my time again. But everytime I see comments as in the above, a voice in my head says "do something, do something". So I'll try again.
 
Having lots of deletes and inserts of course doesn't necessarily mean fragmentation. These so-called holes are fully re-usable and in the vast majority of cases results in no substantial issues. Having lots of deletes, inserts and updates rarely requires the index to be rebuilt.
 
Simple little demo for any newbies or those force-fed Oracle myths since child birth ...
 
First of all, create a simple table and index. I've intentionally left a value out "in the middle" of a range for extra effect.
SQL> create table bowie_test (ziggy number);

 
Table created.
 
SQL> insert into bowie_test values (1);
 
1 row created.
 
SQL> insert into bowie_test values (2);
 
1 row created.
 
SQL> insert into bowie_test values (3);
 
1 row created.
 
SQL> insert into bowie_test values (4);
 
1 row created.
 
SQL> insert into bowie_test values (6);
 
1 row created.
 
SQL> insert into bowie_test values (7);
 
1 row created.
 
SQL> insert into bowie_test values (8);
 
1 row created.
 
SQL> insert into bowie_test values (9);
 
1 row created.
 
SQL> insert into bowie_test values (10);
 
1 row created.
 
SQL> insert into bowie_test values (100);
 
1 row created.
 
SQL> commit;
 
Commit complete.
 
SQL> create index bowie_test_idx on bowie_test(ziggy);
 
Index created.
 
Now analyze the index ...
 
SQL> analyze index bowie_test_idx validate structure;
 
Index analyzed.
 
and we see that everything is sweet with no "wasted" deleted space ...
 
SQL> select lf_rows, del_lf_rows, del_lf_rows_len from index_stats;
 
   LF_ROWS DEL_LF_ROWS DEL_LF_ROWS_LEN
---------- ----------- ---------------
        10           0               0

 
We now delete a number of rows ..
 
SQL> delete bowie_test where ziggy in (2,3,4,6,7,8,9,10);
 
8 rows deleted.
 
SQL> commit;
 
Commit complete.
 
And we see that of the 10 leaf rows, 8 are deleted. As Gollum would say "nasty wasted spaces it is, gollum .."
 
SQL> select lf_rows, del_lf_rows, del_lf_rows_len from index_stats;
 
   LF_ROWS DEL_LF_ROWS DEL_LF_ROWS_LEN
---------- ----------- ---------------
        10           8             112

 
However, we now insert a new value (notice it's different from any previous value but obviously belongs in the same leaf node as the others) ...
 

SQL> insert into bowie_test values (5);

 
1 row created.
 
SQL> commit;
 
Commit complete.
 
SQL> analyze index bowie_test_idx validate structure;
 
Index analyzed.
 
SQL> select lf_rows, del_lf_rows, del_lf_rows_len from index_stats;
 
   LF_ROWS DEL_LF_ROWS DEL_LF_ROWS_LEN
---------- ----------- ---------------
         3           0               0
and we see that *all* the "wasted" deleted space within the leaf node has been freed and is available for reuse ...

 
With few exceptions (the key is picking those rare cases), index rebuilds are redundant, wasteful and can actually be "detrimental" to performance.
 
Cheers
 
Richard
 

Hemant K Chitale
Oracle 9i Database Administrator Certified Professional
My personal web site is :  http://hkchital.tripod.com

-- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Hemant K Chitale INET: hkchital@singnet.com.sg 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@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 Thu Oct 16 2003 - 10:49:44 CDT

Original text of this message

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