Wednesday, May 28, 2014

Difference between Table MOVE and Table SHRINK

Move:  Moves the WaterMark for a segment, no change in no. of blocks
Shrink: Shrinks the segment, i.e. frees the unused blocks and extents.

Code:
SQL>
SQL> create table t ( x number )
2 tablespace users
3 storage ( initial 10M next 10M )
4 /

Table created.

SQL> analyze table t compute statistics;

Table analyzed.

SQL> select blocks, extents from user_segments where segment_name = 'T';

BLOCKS EXTENTS
---------- ----------
1280 10

SQL> select blocks, empty_blocks from user_tables where table_name = 'T';

BLOCKS EMPTY_BLOCKS
---------- ------------
0 1280
So, I started creating a table named T and requested initially 10mb allocated, which turned out to be 1280 blocks and 10 extents. From there you can see:
- table T has 1280 blocks allocated (blocks in user_segment)
- none of which are *formatted* to receive data (blocks in user_tables)

Then, I insert some data
Code:
SQL> insert into t
2 select rownum
3 from dual
4 connect by level <= 100000;

100000 rows created.

SQL> analyze table t compute statistics;

Table analyzed.

SQL> select blocks, extents from user_segments where segment_name = 'T';

BLOCKS EXTENTS
---------- ----------
1280 10

SQL> select blocks, empty_blocks from user_tables where table_name = 'T';

BLOCKS EMPTY_BLOCKS
---------- ------------
186 1094
I inserted 100,000 rows, from there you can see:
- allocated blocks/extents for the table did not change
- however, blocks formated to receive data were raised by 186 and the remaining blocks are empty

186 blocks are the HWM now, because those are the blocks that sometime were formatted to receive data. Blocks above 186 are allocated blocks which have never been formatted to receive data.

I will delete some data now to show you it will not raise empty_blocks nor it will lower the blocks that are formatted to receive data (that is, the HWM).
Code:
SQL> delete from t where rownum <= 90000;

90000 rows deleted.

SQL> analyze table t compute statistics;

Table analyzed.

SQL> select blocks, empty_blocks from user_tables where table_name = 'T';

BLOCKS EMPTY_BLOCKS
---------- ------------
186 1094
See, the delete did nothing to change the HWM, but..
Code:
SQL> select count(distinct dbms_rowid.rowid_block_number(rowid)) used_blocks from t;

USED_BLOCKS
-----------
16
tells me only 16 of those 186 contains data. The rest blocks belong to the segment's freelist to be used for inserts/updates.

Now, I will *move* the table to show you how it will re-adjust the HWM.
Code:
SQL> alter table t move tablespace users;

Table altered.

SQL> analyze table t compute statistics;

Table analyzed.

SQL> select blocks, empty_blocks from user_tables where table_name = 'T';

BLOCKS EMPTY_BLOCKS
---------- ------------
20 1260
See, it shrinked down the HWM to just 20 from 86 and raised the empty_blocks, but..
Code:
SQL> select blocks, extents from user_segments where segment_name = 'T';

BLOCKS EXTENTS
---------- ----------
1280 10
tells you it did nothing to *shrink* the allocated space asigned to the segment, meaning that at this stage the segment will still be using, at the operating system level, the same kind of storage. Now, to *reclaim* that space we will use shrink.
Code:
SQL> alter table t enable row movement;

Table altered.

SQL> alter table t shrink space;

Table altered.

SQL> analyze table t compute statistics;

Table analyzed.

SQL> select blocks, extents from user_segments where segment_name = 'T';

BLOCKS EXTENTS
---------- ----------
128 1

SQL> select blocks, empty_blocks from user_tables where table_name = 'T';

BLOCKS EMPTY_BLOCKS
---------- ------------
20 108

SQL>
There, you see the table actually shrinked down from 1280 blocks allocated and 10 extents, to its minimum, 128 blocks and just 1 extent

No comments:

Post a Comment