All of that is fair enough but the number of rows and the values you've
chosen fit the point you wished to prove. The value "5" conveniently fits
the range for an existing leaf block with empty space. 
 
The facts as I understand them are this :
Index space freed by deleted entries can be reused ( by subsequent
transactions ) so long as the indexed value 'belongs' in the leaf block
which has free space.
Index leaf blocks are only placed back on the free list when they are empty
of entries.
 
This means that given a constantly incrementing index value no free space
will be reused unless whole index blocks are emptied by deletes. This is
fine for working tables which are constantly filled and (totally) emptied
but it can lead to large indexes for tables which preserve small amounts os
data across the range of keys. Such monotonically increasing key values are
pretty common in my experience.
 
I agree though that index rebuilds are often necessary. For a while now
we've had useful commands like coalesce that could combine logically
adjacent, sparsely populated leaf blocks at far less cost than a rebuild. 
 
Regards,
Mike Hately
 

-----Original Message-----
Sent: 16 October 2003 14:29
To: Multiple recipients of list ORACLE-L


> 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
 



********************************************************************************************
E mail Disclaimer

You agree that you have read and understood this disclaimer and you agree to be bound 
by its terms.

The information contained in this e-mail and any files transmitted with it (if any) 
are confidential and intended for the addressee only.  If you have received this  
e-mail in error please notify the originator.    

This e-mail and any attachments have been scanned for certain viruses prior to sending 
but CE Electric UK Funding Company nor any of its associated companies from whom this 
e-mail originates shall be liable for any losses as a result of any viruses being 
passed on.

No warranty of any kind is given in respect of any information contained in this   
e-mail and you should be aware that that it might be incomplete, out of date or 
incorrect. It is therefore essential that you verify all such information with us 
before placing any reliance upon it.

CE Electric UK Funding Company
Lloyds Court
78 Grey Street
Newcastle upon Tyne
NE1 6AF
Registered in England and Wales: Number 3476201

********************************************************************************************

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Hately, Mike (LogicaCMG)
  INET: [EMAIL PROTECTED]

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: [EMAIL PROTECTED] (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).

Reply via email to