8i | 9i | 10g | 11g | 12c | 13c | 18c | 19c | 21c | 23c | Misc | PL/SQL | SQL | RAC | WebLogic | Linux

Home » Articles » Misc » Here

ALTER TABLE ... SHRINK SPACE Command : Online Segment Shrink for Tables, LOBs and IOTs

The ALTER TABLE ... SHRINK SPACE command was introduced in Oracle 10g to perform online segment shrinks for tables, LOBs and IOT overflow segments.

Related articles.

Shrink Space Examples

Here are some simple examples of the ALTER TABLE ... SHRINK SPACE command.

-- Enable row movement.
ALTER TABLE scott.emp ENABLE ROW MOVEMENT;

-- Recover space and amend the high water mark (HWM).
ALTER TABLE scott.emp SHRINK SPACE;

-- Recover space, but don't amend the high water mark (HWM).
ALTER TABLE scott.emp SHRINK SPACE COMPACT;

-- Recover space for the object and all dependant objects.
ALTER TABLE scott.emp SHRINK SPACE CASCADE;

The COMPACT option allows the shrink operation to be broken into two stages. First the rows are moved using the COMPACT option but the high water mark (HWM) is not adjusted so no parsed SQL statements are invalidated. The HWM can be adjusted at a later date by reissuing the statement without the COMPACT option. At this point any dependent SQL statements will need to be re-parsed.

Other shrink commands of interest are displayed below.

-- Shrink a LOB segment (basicfile only until 21c).
ALTER TABLE table_name MODIFY LOB(lob_column) (SHRINK SPACE);
ALTER TABLE table_name MODIFY LOB(lob_column) (SHRINK SPACE CASCADE);

-- Shrink an IOT overflow segment.
ALTER TABLE iot_name OVERFLOW SHRINK SPACE;

There is more detail about this functionality below.

Identify Large Segments

The DBA|ALL|USER_SEGMENTS views can be used to identify large segments. The following example uses a top-n query to display the 20 largest segments.

SET LINESIZE 200
COLUMN owner FORMAT A30
COLUMN segment_name FORMAT A30
COLUMN tablespace_name FORMAT A30
COLUMN size_mb FORMAT 99999999.00

SELECT *
FROM   (SELECT owner,
               segment_name,
               segment_type,
               tablespace_name,
               ROUND(bytes/1024/1024,2) size_mb
        FROM   dba_segments
        ORDER BY 5 DESC)
WHERE  ROWNUM <= 20;

You may see many of the larger segments being LOB segments. You can get more information about LOB segments specifically using the following top-n query.

SET LINESIZE 200
COLUMN owner FORMAT A30
COLUMN table_name FORMAT A30
COLUMN column_name FORMAT A30
COLUMN segment_name FORMAT A30
COLUMN tablespace_name FORMAT A30
COLUMN size_mb FORMAT 99999999.00

SELECT *
FROM   (SELECT l.owner,
               l.table_name,
               l.column_name,
               l.segment_name,
               l.tablespace_name,
               ROUND(s.bytes/1024/1024,2) size_mb
        FROM   dba_lobs l
               JOIN dba_segments s ON s.owner = l.owner AND s.segment_name = l.segment_name
        ORDER BY 6 DESC)
WHERE  ROWNUM <= 20;

The following scripts are examples of these types of queries.

Row Movement

The ALTER TABLE ... SHRINK SPACE command moves rows between existing blocks to compact the data, so before you attempt to shrink a table segment you need to enable row movement. You can check if row movement is already enabled by querying the ROW_MOVEMENT column of the [DBA|ALL|USER]_TABLES views.

SELECT row_movement
FROM   user_tables
WHERE  table_name = 'EMP';

ROW_MOVE
--------
DISABLED

SQL>

Row movement is enabled with the following command.

ALTER TABLE emp ENABLE ROW MOVEMENT;

Repeating the previous query shows row movement is now enabled.

SELECT row_movement
FROM   user_tables
WHERE  table_name = 'EMP';

ROW_MOVE
--------
ENABLED

SQL>

SecureFile LOBs

When using basicfile LOBs the shrink commands work as expected. To demonstrate this we need to create the following table containing a basicfile LOB column.

DROP TABLE lob_tab PURGE;

CREATE TABLE lob_tab (
  id NUMBER,
  data CLOB
)
LOB(data) STORE AS BASICFILE (DISABLE STORAGE IN ROW);

INSERT INTO lob_tab VALUES (1, 'ONE');
COMMIT;

We can see both shrink commands complete without errors.

SQL> ALTER TABLE lob_tab MODIFY LOB(data) (SHRINK SPACE);

Table altered.

SQL> ALTER TABLE lob_tab MODIFY LOB(data) (SHRINK SPACE CASCADE);

Table altered.

SQL>

Now recreate the table using a securefile LOB column.

DROP TABLE lob_tab PURGE;

CREATE TABLE lob_tab (
  id NUMBER,
  data CLOB
)
LOB(data) STORE AS SECUREFILE (DISABLE STORAGE IN ROW);

INSERT INTO lob_tab VALUES (1, 'ONE');
COMMIT;

Now the first command fails, but adding the CASCADE option appears to make it work.

SQL> ALTER TABLE lob_tab MODIFY LOB(data) (SHRINK SPACE);
ALTER TABLE lob_tab MODIFY LOB(data) (SHRINK SPACE)
*
ERROR at line 1:
ORA-10635: Invalid segment or tablespace type


SQL> ALTER TABLE lob_tab MODIFY LOB(data) (SHRINK SPACE CASCADE);

Table altered.

SQL>

Unfortunately, the second command doesn't work and the securefile LOB segment is not shrunk.

Instead, to shrink a securefile LOB segment you need to move it. In the following example the move is to the same tablespace.

ALTER TABLE lob_tab MOVE LOB(data) STORE AS (TABLESPACE users);

Comments and Restrictions

Here are some things to consider before performing shrink operations.

For more information see:

Hope this helps. Regards Tim...

Back to the Top.