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

2003-10-17 Thread Jared . Still

Doesn't reuse leaf rows?!

The myth is perpetuated.


Try running these scripts. In a nutshell, a table is created with about
20k rows, with an incrementing id. There is a non-unique index created
on the id column.

An analyze is done on the table then index_stats is populated with 
'analyze index validate structure', and the number of leaf rows, 
All rows with an id that is evenly divisible by 2 are copied to another table
and then deleted.

The rows are then reinserted into the first table.

Between each step, statistics are computed on the table and index, the
index structure validated, and the number of leaf rows, leaf blocks, deleted
leaf rows and deleted leaf blocks are displayed.

=== ai.sql ===

analyze table t1 compute statistics;
analyze index t1_id_idx validate structure;

=== is.sql ===

select lf_rows, lf_blks, lf_blk_len, del_lf_rows, pct_used
from index_stats
/

=== j1.sql ===

drop table t1 cascade constraints;
drop table t2 cascade constraints;

create table t1 (
id number(8)
, last_name varchar2(30)
, first_name varchar2(30)
)
nologging
/


insert /*+ append */
into t1( id, last_name, first_name)
select
rownum id
, substr(owner,1,30) last_name
, substr(object_name,1,30) first_name
from dba_objects
/

create index t1_id_idx on t1(id);

@@ai
@@is

create table t2
nologging
as
select *
from t1
where 1=0
/

insert /*+ append */
into t2
select *
from t1
where id/2 = floor(id/2)
/


delete from t1
where id/2 = floor(id/2)
/

commit;

@@ai
@@is

insert into t1 (id, last_name, first_name)
select id+1 id, last_name, first_name
from t2
/

@@ai
@@is

==








Hemant K Chitale [EMAIL PROTECTED]
Sent by: [EMAIL PROTECTED]
10/16/2003 08:49 AM
Please respond to ORACLE-L


To:Multiple recipients of list ORACLE-L [EMAIL PROTECTED]
cc:
Subject:Re: re Rebuilding Indexes in Oracle Apps -- Quoting an Apps



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

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

2003-10-16 Thread Hemant K Chitale


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: [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).  

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

2003-10-16 Thread M Rafiq
Hemant,

It is absolutely true with Oracle Financials Databases and I have seen 
performance degradation when indexes on such databses are not rebuilt at a 
regular interval meaning indexes on certain tables on mothly basis.

Regards
Rafiq




Reply-To: [EMAIL PROTECTED]
To: Multiple recipients of list ORACLE-L [EMAIL PROTECTED]
Date: Thu, 16 Oct 2003 07:49:44 -0800
_
Concerned that messages may bounce because your Hotmail account has exceeded 
its 2MB storage limit? Get Hotmail Extra Storage! 
http://join.msn.com/?PAGE=features/es
---BeginMessage---


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