Tuesday, November 18, 2014

Shrink a datafile, when ALTER TABLESPACE COALESCE is not working.

In a 11.2.0.3 database, we tried to reclaim space from USERS tablespace.
We faced a problem.
We use the following query to the the end of a particular USERS' datafile [file_id=72, filename=/oradb/SBLCCPRD/oradata4/users03.dbf]

SELECT
        A.FILE_ID,
        A.BLOCK_ID,
        A.BLOCK_ID + A.BLOCKS - 1   END_BLOCK,
        A.BLOCKS,
        --ROUND(A.BLOCKS*B.BLOCK_SIZE/1024/1024,2) MBYTES,
        A.BLOCKS*B.BLOCK_SIZE "SIZE",
        A.OWNER,
        A.SEGMENT_NAME,
        A.PARTITION_NAME,
        A.SEGMENT_TYPE
    FROM
        DBA_EXTENTS A, DBA_TABLESPACES B
    WHERE
        A.FILE_ID=:A AND A.TABLESPACE_NAME=B.TABLESPACE_NAME
UNION ALL
SELECT
        A.FILE_ID,
        A.BLOCK_ID,
        A.BLOCK_ID + A.BLOCKS - 1   END_BLOCK,
        A.BLOCKS,
        --ROUND(A.BLOCKS*B.BLOCK_SIZE/1024/1024,2) MBYTES,
        A.BLOCKS*B.BLOCK_SIZE "SIZE",
        'free'          OWNER,
        'free'          SEGMENT_NAME,
        NULL            PARTITION_NAME,
        NULL            SEGMENT_TYPE
    FROM
        DBA_FREE_SPACE A, DBA_TABLESPACES B
    WHERE
        A.FILE_ID=:A AND A.TABLESPACE_NAME=B.TABLESPACE_NAME
    ORDER BY 2 DESC;


We can see there were 5 contiguous free extents of 64 Kbytes each, total 320 Kbytes.

   
FILE_IDBLOCK_IDEND_BLOCKBLOCKSSIZEOWNERSEGMENT_NAMEPARTITION_NAMESEGMENT_TYPE
7216149521614959865536freefree
7216149441614951865536freefree
7216149361614943865536freefree
7216149281614935865536freefree
7216149201614927865536freefree
7216149121614919865536AMARGARICX_OTE_LOV_BACKUP_06052014TABLE
7216149041614911865536AMARGARICX_OTE_LOV_BACKUP_06052014TABLE
7216148961614903865536EFOTEINOPCX_OTE_LOV_0106TABLE
...........................


We tried to coalesce the tablespace, but it did not. The free extents did not get merged to one of 320 Kbytes.

SQL> alter tablespace users coalesce;
Tablespace altered. 



This is the datafile's size in bytes:
SELECT FILE_NAME, BYTES
FROM DBA_DATA_FILES
WHERE FILE_ID=72;

FILE_NAMEBYTES
/oradb/SBLCCPRD/oradata4/users03.dbf13229744128


When we tried to shrink the datafile, even by just 8 Kbytes, we got ORA-03297:

SQL> ALTER DATABASE DATAFILE 72 RESIZE 13229735936;
ALTER DATABASE DATAFILE 72 RESIZE 13229735936
*
ERROR at line 1:
ORA-03297: file contains used data beyond requested RESIZE value


The solution was to purge the tablespace's recycle bin, even if there were no recycled objects near the end of the datafile. Furthermore, before I begin all this procedure, I had purged the database's recycle bin, using "PURGE DBA_RECYCLEBIN".

SQL> PURGE TABLESPACE USERS;
Tablespace purged.

SQL> ALTER DATABASE DATAFILE 72 RESIZE 13229735936;
Database altered.

   
FILE_IDBLOCK_IDEND_BLOCKBLOCKSSIZEOWNERSEGMENT_NAMEPARTITION_NAMESEGMENT_TYPE
721614920161495132262144freefree
7216149121614919865536AMARGARICX_OTE_LOV_BACKUP_06052014TABLE
7216149041614911865536AMARGARICX_OTE_LOV_BACKUP_06052014TABLE
7216148961614903865536EFOTEINOPCX_OTE_LOV_0106TABLE
...........................