Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: re Rebuilding Indexes in Oracle Apps -- was RE: RE: Separate
List,
The %INTERFACE% tables (usually) consist of rows that are temporary in nature. The indexes supporting them are 'fragmented' (the term can be argued I suppose). I did test this out on the GL_INTERFACE_N2 index - ANALYZE/VALIDATE and record INDEX_STATS, Rebuild index, ANALYZE/VALIDATE and record INDEX_STATS again. The figures are below, but just to highlight a few:
HEIGHT (Index depth) dropped from 3 to 2; BLKS_GETS_PER_ACCESS (expected
number of CR reads to get to a row) dropped from 12 to 3; the PCT_USED
(percentage of space allocated that is used) increased from 38% to 99%...
HEIGHT 3 2 BLOCKS 4480 4432 LF_ROWS 362409 22552 LF_BLKS 4230 75 LF_ROWS_LEN 12531538 578797 LF_BLK_LEN 7948 7780 BR_ROWS 4229 74 BR_BLKS 58 1 BR_ROWS_LEN 134043 1919 BR_BLK_LEN 8028 8028 DEL_LF_ROWS 339857 0 DEL_LF_ROWS_LEN 11952741 0 DISTINCT_KEYS 20869 9548 MOST_REPEATED_KEY 38594 8430 BTREE_SPACE 34085664 591528 USED_SPACE 12665581 580716 PCT_USED 38 99 ROWS_PER_KEY 17.3659016 2.36196062 BLKS_GETS_PER_ACCESS 12.1829508 3.68098031 PRE_ROWS 0 0 PRE_ROWS_LEN 0 0
For a detailed explanation, look at the definition of INDEX_STATS. YMMV, but you will probably get the most from Non-unique indexes... (as in this case).
John Kanagaraj
DB Soft Inc
Phone: 408-970-7002 (W)
Grace - Getting something we do NOT deserve Mercy - NOT getting something we DO deserve Click on 'http://www.needhim.org' for Grace and Mercy that is freely available!
Please explain why these indexes must be built.
What benefits do you see from it?
Are they quantifiable?
Jared
"M Rafiq" <rafiq9857_at_hotmail.com>
Sent by: ml-errors_at_fatcity.com
10/14/2003 03:49 PM
Please respond to ORACLE-L
To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> cc: Subject: RE: re Rebuilding Indexes in Oracle Apps -- was RE:RE: Separate
John
What about gl_interface table indexes? I think indexes on all *interface(
tables must be rebuild on a regular interval...I was building indexes on
gl_interfaces and fnd_request* tables on monthly basis.
Regards
Rafiq
Reply-To: ORACLE-L_at_fatcity.com
To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com>
Date: Tue, 14 Oct 2003 13:34:24 -0800
Hemant,
This applies on 11i only. I would rebuild all indexes supporting the WF_ITEM_ACTIVITY_STATUSES and WF_ATTRIBUTE_VALUES tables. I have been working on some AOL table(space) problems in the background and noticed that in 11i by default, we are not be purging _all_ the WF data that we should be purging. I believe the current Purge routine purges activity rows whose persistence has expired and are marked 'TEMPORARY' and ignores those that are COMPLETE (see below). My contention is that it should be deleting old rows that are COMPLETEd... (Fyi, this is 12+ million rows...) Notes 141853.1, 144806.1, 132254.1, 148705.1, 148678.1 may help.
You could check this using the following SQLs
select activity_status, count(*)
from applsys.wf_item_activity_statuses
group by activity_status;
select item_type,activity_status,count(*)
from
applsys.wf_item_activity_statuses where activity_status='COMPLETE'
group by item_type,activity_status;
Once the 'correct' purge is complete, the 'holey' indexes will need to be rebuilt and the WF_ tables copied/truncated/recopied to shrink the HWM to reasonable levels.
Let me know what your install shows up.
John Kanagaraj
DB Soft Inc
Phone: 408-970-7002 (W)
Grace - Getting something we do NOT deserve Mercy - NOT getting something we DO deserve Click on 'http://www.needhim.org' for Grace and Mercy that is freely available!
-----Original Message-----
Sent: Tuesday, October 14, 2003 8:39 AM
To: Multiple recipients of list ORACLE-L
John,
I rebuild the FND_CONCURRENT_REQUESTS indexes every four months [and the
table itself, occassionally].
This Saturday I will also be rebuilding some ALR indexes.
Which WorkFlow Indexes do you rebuild ?
Hemant
At 11:44 AM 13-10-03 -0800, you wrote:
-- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: John Kanagaraj INET: john.kanagaraj_at_hds.com 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_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-LReceived on Wed Oct 15 2003 - 17:34:47 CDT
(or the name of mailing list you want to be removed from). You may
also send the HELP command for other information (like subscribing). _________________________________________________________________ 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 -- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: M Rafiq INET: rafiq9857_at_hotmail.com 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_at_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). -- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: John Kanagaraj INET: john.kanagaraj_at_hds.com 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_at_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).