Oracle knows two types of table reorganizations.
- Rebuilding the table by means of recreating it
- Rebuilding the table by shrinking its free space ( Oracle 10g and up )
Below the two methods are explained.
Rebuilding the table by means of recreating it
There are two ways of rebuilding a table by recreating it. The first option is to export all the data into a file using the export utility.
After that truncate ( of recreate ) the table and reload the data back into it. The disadvantage here however is a long downtime.
Another method is moving the table either to another tablespace or within the same tablespace.
The advantage here is that the downtime will me much less, but it also has some disadvantages:
- The tablespace needs to be able to store this second copy of the table
- The tables indexes, any depending objects like packages, procedures can become INVALID and might need to be rebuild
- There will be a table-level exclusive lock on the table involved. Any application using that table will be affected by this lock.
By moving the table to another tablespace temporarily, the DBA is also able to reorganize the tablespace.
Rebuilding the table by shrinking its free space
Starting with Oracle 10g all the above is replaced by a very nice feature called 'SHRINK SPACE';
As of this release, tables can be reorganized online, without affecting the users functionality.
That is:
* The table itself must be in an ASMM tablespace
* The table must have row movement enabled
* At the end of the action a shortt table level lock takes place to adjust the HWM (Highwater Mark) of the table.
And it's easy !!
Just enable 'row movement' and start shrinking tables:
SQL> ALTER TABLE MYTABLE ENABLE ROW MOVEMENT;
This enables row movement of the table. THis is necessary so that oracle is able to actually move the rows to other free extents in order to shrink the space needed.
SQL> ALTER TABLE MYTABLE SHRINK SPACE COMPACT;
This shrinks the used space of the table, but does not update the HWM. This is usefull if you don't want to have a table-level lock during business hours.
SQL> ALTER TABLE MYTABLE SHRINK SPACE;
This command shrinks the contents of the table and subsequently updates the HWM. This statement can also be used after a shrink with 'compact' option has been done, just to update the HWM.
SQL> ALTER TABLE MYTABLE SHRINK SPACE CASCADE;
This command shrinks the contents of the table and all dependent objects like indexes.
High Water Mark:
Now we have mentioned the High Water Mark (HWM) a couple of times. A short explanation:
The HWM is the pointer to that location of a table where on any point in history the table has grown to. If a lot of rows are deleted from a table, a lot of free space exists before the HWM. Doing a full table scan Oracle will not only read the actual rows, but also the empty space up to the HWM.
This is wasted time and is worsening the performance of getting data from that table.
So if from a large table a lot of rows are deleted, e.g. a count(*) will still take as long as before the delete.
Triggers and indexes:
In contradiction to moving a table, or exporting/importing its data, triggers and indexes are NOT affected by a shrink space command. They will remain valid and functional during and after the operation.
Wasted space:
How to determine if a table is a candidate for a reorganization ?
Use the below script to determine if a table has a lot of wasted space.
If it substantial in relation to the total size of the table, then a reorganization ( shrink ) is recommended.
set lines 200;
column owner format a15;
column segment_name format a30;
select
a.owner,
a.segment_name,
a.segment_type,
round(a.bytes/1024/1024,0) MBS,
round((a.bytes-(b.num_rows*b.avg_row_len) )/1024/1024,0) WASTED
from dba_segments a, dba_tables b
where a.owner=b.owner
and a.owner not like 'SYS%'
and a.segment_name = b.table_name
and a.segment_type='TABLE'
group by a.owner, a.segment_name, a.segment_type, round(a.bytes/1024/1024,0) ,round((a.bytes-(b.num_rows*b.avg_row_len) )/1024/1024,0)
having round(bytes/1024/1024,0) >100
order by round(bytes/1024/1024,0) desc ;
The above script is only working if the tables involved have statistics gathered on them
PCTFREE
An extra remark about PCTFREE.
Tables with a high value of PCTFREE show also a higher value of wasted space.
The space reserved for PCTFREE in a block can not be shrinked. So even after a shrink of a table a lot of wasted space can remain.
The effect of PCTFREE also seen before the shrink is executed when looking at the wasted space using the above script.
In an example we have three identical tables with the following structure:
SQL> CREATE TABLE T1 ( ID NUMBER(10), VAL VARCHAR2(1000 CHAR) ) PCTFREE 40;
SQL> CREATE TABLE T2 ( ID NUMBER(10), VAL VARCHAR2(1000 CHAR) ) PCTFREE 10;
SQL> CREATE TABLE T3 ( ID NUMBER(10), VAL VARCHAR2(1000 CHAR) ) PCTFREE 50;
All tables are loaded with the same data, approx. 5.5 million rows.
When running the above script it shows:
SEGMENT_NAME | SEGMENT_TYPE | MBS | WASTED |
----------------------- | ------------------ | ---------- | ---------- |
T1 | TABLE | 5064 | 2348 |
T2 | TABLE | 3333 | 617 |
T3 | TABLE | 6144 | 3428 |
Just because of the variation in the value of PCTFREE, the total size and wasted space are different per table.
The effect of PCTFREE after the shrink is that not all "wasted space" is released.
The term "wasted space" therefore is not really valid with a high PCTFREE. It is wasted space + the reserved space directly available for updates. Of course above, just after table creation there is no wasted space. It is only reserved (pctfree) space. Therefore - for this example - we are going to delete approx 30% of the rows of all tables.
SEGMENT_NAME | SEGMENT_TYPE | MBS | WASTED |
----------------------- | ------------------ | ---------- | ---------- |
T1 | TABLE | 5064 | 2789 |
T2 | TABLE | 3333 | 1058 |
T3 | TABLE | 6144 | 3869 |
After this we are going to 'shrink' the available wasted space, using:
SQL> ALTER TABLE T1 SHRINK SPACE CASCADE;
SQL> ALTER TABLE T2 SHRINK SPACE CASCADE;
SQL> ALTER TABLE T3 SHRINK SPACE CASCADE;
The result is:
SEGMENT_NAME | SEGMENT_TYPE | MBS | WASTED |
----------------------- | ------------------ | ---------- | ---------- |
T1 | TABLE | 4245 | 1970 |
T2 | TABLE | 2779 | 505 |
T3 | TABLE | 5292 | 3018 |
This test clearly shows that even if Oracle or its tools like ADDM inform you about wasted space in a table, it might be that this is because you have a high value for PCTFREE. Shrinking these table might afterwards look like if nothing happened.
Check in that case if PCTFREE is high and if the value of 'wasted space' divided by the 'total size' is equal to that value:
Example:
Table T1: PCTFREE = 40% ==> 1970 / 4245= 46%
Table T3: PCTFREE = 50% ==> 3018/5292 = 57%
So, actually the 'wasted space' of these tables is respectively 6% and 7 %
Nice document
ReplyDeleteGreat Article Artificial Intelligence Projects
DeleteProject Center in Chennai
JavaScript Training in Chennai
JavaScript Training in Chennai Project Centers in Chennai
This is very very helpful. Thank you for putting it so simply.
ReplyDeleteExcellent article. U made us understand about re-org in a cool way. Thank you.
ReplyDeleteHi Franken,
ReplyDeleteNice article I had apply it on my DB but I had one doubt what if we enable row movement on table after shrinking that table we need to disable row movement on that table.
Thanks for the comment.
DeleteIt is not necessary to disable row movement if you will do a shrink again in the near future. Keeping row movement enabled does not affect normal database operations.
However, if this was a one time operation, and your application depends on rowid's ( not recommend ), then it might be safe to disable it again, so no unplanned shrink is executed during business hours
Hi Franken,
ReplyDeleteI Appritiate your quick response as I tested your given steps in this blog in our test env soon going to apply on production too and thanks for your reply...
Regards,
Mohammed khaja raziuddin
Hi Franken,
ReplyDeleteI'm going to apply your document steps in our production environment and we have data guard enable is there any precution I have to take before applying it.
Regards,
Mohammed
Hi,
ReplyDeleteMy knowledge about Dataguard is not up to date, so I can't tell for sure what would happen. My first guess is that all will be going fine.
Remember that this action will generate an extra amount of redo-shipping, so make sure there is sufficient redo/archive space available.
Thanks
Be careful on a dataguard logical standby. There is a bug in Oracle all the way up to v 11.2.0.3. Bug 13070166 - SHRINK SPACE receives ORA-16211 on real time apply logical standby[Article ID 13070166.8. I know - I just hit it! Not fixed until v12 !
ReplyDeleteReally helpful Franken..
ReplyDeleteThanks for Information Oracle Online Training
ReplyDeleteVery precise and clear document on Re-org. Thanks you for preparing and sharing this one.
ReplyDeleteThis is really very nice document.
ReplyDelete