Maclochlainn's Weblog

Michael McLaughlin's Old Technical Blog

Cleaning up wasted LOB space

leave a comment »


After replacing the contents of a BLOB or CLOB column, you will see the size grow because old indexes and segments aren’t deleted or removed from the index. The only way to get rid of the old information is to perform some simple table maintenance. The following provides an example of dumping redundant or obsolete space and indexes.

You should first check space, by using the query provided earlier in my blog to compare LOB indexes and segments. In this test case, this is the starting point:

Table Column                              Segment      Segment
Name  Name      Segment Name              Type           Bytes



ITEM  ITEM_BLOB SYS_IL0000074435C00007$$  LOBINDEX       65536
ITEM  ITEM_BLOB SYS_LOB0000074435C00007$$ LOBSEGMENT   2097152
ITEM  ITEM_DESC SYS_IL0000074435C00006$$  LOBINDEX      393216
ITEM  ITEM_DESC SYS_LOB0000074435C00006$$ LOBSEGMENT 226492416

You create a temporary CLOB column in the target table. Then, you update the temporary column with the value from your real column.

ALTER TABLE item ADD (item_temp CLOB);
UPDATE item SET item_temp = item_desc;

When you requery the table’s indexes and segments, you’d find something like the following. You should note the size of the index and segments are three times larger in the real column than the temporary columns.

Table Column                              Segment      Segment
Name  Name      Segment Name              Type           Bytes



ITEM  ITEM_BLOB SYS_IL0000074435C00007$$  LOBINDEX       65536
ITEM  ITEM_BLOB SYS_LOB0000074435C00007$$ LOBSEGMENT   2097152
ITEM  ITEM_DESC SYS_IL0000074435C00006$$  LOBINDEX      393216
ITEM  ITEM_DESC SYS_LOB0000074435C00006$$ LOBSEGMENT 226492416
ITEM  ITEM_TEMP SYS_IL0000074435C00016$$  LOBINDEX      131072
ITEM  ITEM_TEMP SYS_LOB0000074435C00016$$ LOBSEGMENT  65011712

You drop the real column and add it back. Then, you update the real column with the values from the temporary column.

ALTER TABLE item DROP COLUMN item_desc;
ALTER TABLE item ADD (item_desc CLOB);
UPDATE item SET item_desc = item_temp;
ALTER TABLE item DROP COLUMN item_temp;

You can now requery the table and find that you’ve eliminated extraneous space.

Table Column                              Segment     Segment
Name  Name      Segment Name              Type          Bytes



ITEM  ITEM_BLOB SYS_IL0000074435C00006$$  LOBINDEX      65536
ITEM  ITEM_BLOB SYS_LOB0000074435C00006$$ LOBSEGMENT  2097152
ITEM  ITEM_DESC SYS_IL0000074435C00016$$  LOBINDEX     131072
ITEM  ITEM_DESC SYS_LOB0000074435C00016$$ LOBSEGMENT 65011712

Advertisements

Written by maclochlainn

April 18, 2008 at 6:18 pm

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

%d bloggers like this: