Re: Deallocate unused (above high water mark)

  • From: Mladen Gogala <mladen@xxxxxxxxxxxxxxx>
  • To: oracle-l@xxxxxxxxxxxxx
  • Date: Thu, 13 May 2004 09:35:06 -0400

Yes, you're right. Here is the procedure:

racle9i Enterprise Edition Release 9.2.0.5.0 - Production
With the Partitioning option
JServer Release 9.2.0.5.0 - Production
 
SQL> connect scott/tiger
Connected.
SQL> create table emp_test as select * from emp;
 
Table created.
 
SQL> analyze table emp_test compute statistics;
 
Table analyzed.
 

  1* select empty_blocks from user_Tables where table_name='EMP_TEST'
SQL> /
 
EMPTY_BLOCKS
------------
           4
 
SQL> delete from emp_test;
 
14 rows deleted.
 
SQL> commit;
 
Commit complete.
 
SQL> analyze table emp_test compute statistics;
 
Table analyzed.
 

SQL> select empty_blocks from user_Tables where table_name='EMP_TEST'
  2  /
 
EMPTY_BLOCKS
------------
           4
 

 
SQL> truncate table emp_test  reuse storage;
 
Table truncated.
 
SQL>  analyze table emp_test compute statistics;
 
Table analyzed.
 
SQL> select empty_blocks from user_Tables where table_name='EMP_TEST';
 
EMPTY_BLOCKS
------------
           8
 
SQL>

Please note that I am operating in an LMT, which means that my extents can only 
be
of several pre-defined sizes.

On 05/13/2004 09:20:21 AM, Richard Foote wrote:
> Hi Mladen,
> 
> Blocks that have been emptied are *not* considered empty blocks. Empty
> blocks are only those of the Drew Barrymore variety.
> 
> Simple test. Analyze table after you've deleted all the rows and check out
> the (lack of) difference in the empty_block count.
> 
> Cheers
> 
> Richard
> ----- Original Message -----
> From: "Mladen Gogala" <mladen@xxxxxxxxxxxxxxx>
> To: <oracle-l@xxxxxxxxxxxxx>
> Sent: Thursday, May 13, 2004 3:45 AM
> Subject: Re: Deallocate unused (above high water mark)
> 
> 
> Blocks that have been emptied are also considered empty blocks. Alter table
> deallocate
> unused deallocates blocks that, just like Drew Barrymore, have never been
> kissed or touched
> in any other way. It's the same distinction as made by RMAN: it diligently
> writes the blocks
> that have been emptied, but not the blocks that have never been (ab)used.
> 
> On 05/12/2004 12:36:08 PM, Sergei wrote:
> > Good morning Oracle gurus,
> >
> > Could somebody please explain why after 'alter table deallocate unused'
> > my user_tables view still shows empty blocks?
> > At the same time, dbms_space.unused_space procedure shows 0 empty blocks.
> --
> Mladen Gogala
> Oracle DBA
> 
> 
> 
> Note:
> This message is for the named person's use only.  It may contain
> confidential, proprietary or legally privileged information.  No
> confidentiality or privilege is waived or lost by any mistransmission.  If
> you receive this message in error, please immediately delete it and all
> copies of it from your system, destroy any hard copies of it and notify the
> sender.  You must not, directly or indirectly, use, disclose, distribute,
> print, or copy any part of this message if you are not the intended
> recipient. Wang Trading LLC and any of its subsidiaries each reserve the
> right to monitor all e-mail communications through its networks.
> Any views expressed in this message are those of the individual sender,
> except where the message states otherwise and the sender is authorized to
> state them to be the views of any such entity.
> 
> ----------------------------------------------------------------
> Please see the official ORACLE-L FAQ: http://www.orafaq.com
> ----------------------------------------------------------------
> To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx
> put 'unsubscribe' in the subject line.
> --
> Archives are at //www.freelists.org/archives/oracle-l/
> FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
> -----------------------------------------------------------------
> 
> 
> 
> ----------------------------------------------------------------
> Please see the official ORACLE-L FAQ: http://www.orafaq.com
> ----------------------------------------------------------------
> To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx
> put 'unsubscribe' in the subject line.
> --
> Archives are at //www.freelists.org/archives/oracle-l/
> FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
> -----------------------------------------------------------------
> 

-- 
Mladen Gogala
Oracle DBA



Note:
This message is for the named person's use only.  It may contain confidential, 
proprietary or legally privileged information.  No confidentiality or privilege 
is waived or lost by any mistransmission.  If you receive this message in 
error, please immediately delete it and all copies of it from your system, 
destroy any hard copies of it and notify the sender.  You must not, directly or 
indirectly, use, disclose, distribute, print, or copy any part of this message 
if you are not the intended recipient. Wang Trading LLC and any of its 
subsidiaries each reserve the right to monitor all e-mail communications 
through its networks.
Any views expressed in this message are those of the individual sender, except 
where the message states otherwise and the sender is authorized to state them 
to be the views of any such entity.

----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx
put 'unsubscribe' in the subject line.
--
Archives are at //www.freelists.org/archives/oracle-l/
FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------

Other related posts: