Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: Checking the rebuildability of an index
The attached script is quite useful it indicates which tables or indexes
have a lot of wasted space in them. Local knowledge can then tell whether
that space is retrievable or not. It was written by James Gardner (based
around something on Steve Adam's site re sparse indexes).
John
--run as follows sqlplus -s system/password @script |sort -nr2
set serveroutput on
set feedback off
declare
total_bytes NUMBER ; total_blocks NUMBER ; unused_blocks NUMBER ; unused_bytes NUMBER ; lastextf NUMBER ; last_extb NUMBER ; lastusedblock NUMBER ; schema_name VARCHAR2(30); segment_type VARCHAR2(30);
begin
schema_name := '&schema_name';
segment_type := '&segment_type';
IF segment_type = 'INDEX' THEN
dbms_output.put_line(segment_type ||' usage report for ' ||
schema_name || ' schema');
dbms_output.put_line('*********************************'); dbms_output.put_line(''); dbms_output.put_line('Object Name Size MB UnusedMb');
dbms_output.enable(10000000);
dbms_space.unused_space(schema_name, v_rec.index_name, segment_type,
total_blocks, total_bytes, unused_blocks, unused_bytes, lastextf, last_extb, lastusedblock); dbms_output.put_line(rpad(v_rec.index_name,35) ||' '|| lpad(trunc(total_bytes/1024/1024,1),6) ||' '|| lpad(trunc(unused_bytes/1024/1024,1),9));end loop;
dbms_output.put_line('*********************************'); dbms_output.put_line(''); dbms_output.put_line('Object Name Size MB UnusedMb');
dbms_output.enable(10000000);
dbms_space.unused_space(schema_name, v_rec.table_name, segment_type,
total_blocks, total_bytes, unused_blocks, unused_bytes, lastextf, last_extb, lastusedblock); dbms_output.put_line(rpad(v_rec.table_name,35) ||' '|| lpad(trunc(total_bytes/1024/1024,1),6) ||' '|| lpad(trunc(unused_bytes/1024/1024,1),9));end loop;
dbms_output.put_line('****************************************************** ******'); dbms_output.put_line('USAGE - This script only works with TABLE andINDEX segments');
dbms_output.put_line('************************************************************');
-----Original Message-----
Sent: 06 August 2002 10:10
To: Multiple recipients of list ORACLE-L
I'll throw a contentious comment...I would say that using the figures in index_stats to rebuild indexes is a waste of time. Consider
This could be due to everyday usage patterns. Do you really want to rebuild it - since by tomorrow (or the next day) it will be back to 30% deleted space.
Alternatively, the 30% might be due to a one-off archive of data. If that deleted space is *entire* blocks that have been freed up, then maybe you do not want to rebuild since those blocks will be re-used anyway. Then again, if you don't plan on doing any more dml, maybe you do want to rebuild it to speed up its use in queries. Then again, rebuilding it could pack more into a block and introduce contention. Then again, rebuilding it could spread things out and make spanning parts of the index actually slower
b) an index may have *no* deleted space
You might want to rebuild with a very low pctfree if there is no more dml to be issued against it. Then again, you might want to rebuild with a higher pctfree to avoid contention on some of the blocks
Except in DSS or partition-style environments where drop/rebuild is mandated for load/space/etc reasons, I would say there are very few times when the decision on whether to rebuild an index can be made solely on the stats or some other automated decision.
hth
connor
"Remember amateurs built the ark - Professionals built the Titanic"
-- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: =?iso-8859-1?q?Connor=20McDonald?= INET: hamcdc_at_yahoo.co.uk Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- 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.com -- Author: INET: John.Hallas_at_vodafone.co.uk Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- 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).Received on Tue Aug 06 2002 - 06:08:28 CDT