Home » RDBMS Server » Server Administration » reclaim tablespace after deleting data
reclaim tablespace after deleting data [message #60707] Fri, 27 February 2004 08:06 Go to next message
WALID
Messages: 31
Registered: August 2002
Member
We have a production 8i tablespace that is getting 97% full.  I am going to delete some old data using staight delete statement.  After doing the delete, I noticed that the tablespace is still 97%.  Now I did some basic research on Oracle metalink and found out that either I have to trucate to reclaim diskspace or export/re-import the bg table.  Well, I don't like either of these options, although partionining and truncating would solve the problem.  My question to somebody to help me with the needed steps to create a table partion on date range.  Would I need a seperate tablespace to create the partions becuase of the 97% full production tablespace? the table I am intersting in purging has the following storage definitions.  Any suggestions on changing these storage parameters would aslo be helpful. This table is used mainly for inserts and updates.

TABLESPACE "WSF1_DATA"

STORAGE ( INITIAL 16K NEXT 0K MINEXTENTS 1 MAXEXTENTS

2147483645 PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1)

PCTFREE 10 INITRANS 2 MAXTRANS 255)

TABLESPACE "WSF1_DATA" PCTFREE 10 PCTUSED 40 INITRANS 1

MAXTRANS 255

STORAGE ( INITIAL 827320K NEXT 0K MINEXTENTS 1 MAXEXTENTS

2147483645 PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1)

LOGGING
Re: reclaim tablespace after deleting data [message #60708 is a reply to message #60707] Fri, 27 February 2004 09:28 Go to previous messageGo to next message
andrew again
Messages: 2577
Registered: March 2000
Senior Member
A report like the following is useful for seeing how much of your allocated space is actually used. Note that the indented indexes are reported before the table they belong to - so the format looks a bit funny, but the info is useful. The query is quite slow because it queries extents for each row too.

REM	To see the actual space allocated and used for tables and 
REM corresponding indexes
REM
set serveroutput on format wrapped feedback off echo off verify off lines 80 trims on 
spool space.lst
declare
 v_tablepspace varchar2(32) := 'MY_TS';
-- v_owner varchar2(32) := 'SCOTT';
 
  cursor ctab is 
        select a.owner, a.table_name, b.extents
 		from dba_tables a, dba_segments b
		where a.TABLE_NAME = b.segment_name
		and a.OWNER = b.owner
		and a.tablespace_name = v_tablepspace 
		order by a.owner, a.table_name
 	;

-- cursor ctab is select owner, table_name
--		from dba_tables where owner = v_owner order by owner, table_name
--	;

 cursor cind (wowner in varchar2, wtab in varchar2) is 
        select a.owner, a.index_name, b.extents
		from dba_indexes a, dba_segments b
		where a.INDEX_NAME = b.segment_name
		and a.owner = b.owner
		and a.table_name = wtab 
		and a.table_owner = wowner;

 wtotal_blocks               number;
 wtotal_bytes                number;
 wunused_blocks              number;
 wunused_bytes               number;
 wlast_used_extent_file_id   number;
 wlast_used_extent_block_id  number;
 wlast_used_block            number;

 wtaballoc       number;
 wtabused        number;
 wtabfree        number;
 windalloc       number;
 windused        number;
 windfree        number;

 wtottaballoc       number := 0;
 wtottabused        number := 0;
 wtottabfree        number := 0;
 wtotindalloc       number := 0;
 wtotindused        number := 0;
 wtotindfree        number := 0;

begin

 dbms_output.enable (9999999);
 
 dbms_output.new_line ();
-- for rec in (select to_char(sysdate, 'dd Mon yyyy hh24:mi:ss' )||
-- 	 	 	 		' - User ('||v_owner||') on Database ('||global_name||')' Where_am_i 
--					from global_name)
 for rec in (select to_char(sysdate, 'dd Mon yyyy hh24:mi:ss' )||
 	 	 	 		' - Tabelspace ('||v_tablepspace||') on Database ('||global_name||')' Where_am_i 
					from global_name)
 loop
   dbms_output.put_line (rec.Where_am_i );
 end loop;
  dbms_output.new_line ();

  dbms_output.put_line ('Expanded space report for Table Space :'|| v_tablepspace );
  dbms_output.put_line ('---------------------------------------'|| rpad('-', length(v_tablepspace), '-'));
  dbms_output.put_line ('Table Owner.Name(extents)             Tab.   UsedM  FreeM  Ind.   UsedM  FreeM' );
  dbms_output.put_line ('------------------------------------  -----  -----  -----  -----  -----  -----');

 for rtab in ctab loop

   dbms_space.unused_space (rtab.owner, rtab.table_name, 'TABLE', 
                            wtotal_blocks,  wtotal_bytes,  wunused_blocks,
                            wunused_bytes, wlast_used_extent_file_id,
                            wlast_used_extent_block_id, wlast_used_block);

   wtaballoc := wtotal_bytes/1048576;
   wtabused  := (wtotal_bytes - wunused_bytes)/ 1048576;
   wtabfree  := wunused_bytes/1048576;
   windalloc := 0;
   windused  := 0;
   windfree  := 0;

   wtottaballoc := wtottaballoc + wtaballoc;
   wtottabused  := wtottabused  + wtabused;
   wtottabfree  := wtottabfree  + wtabfree;

   for rind in cind (rtab.owner, rtab.table_name) loop

     dbms_space.unused_space (rind.owner, rind.index_name, 'INDEX', 
                              wtotal_blocks,  wtotal_bytes,  wunused_blocks,
                              wunused_bytes, wlast_used_extent_file_id,
                              wlast_used_extent_block_id, wlast_used_block);
     -- print Index detail!
     dbms_output.put_line (rpad((  --rtab.owner || '.' || 
				  '  '||rind.index_name||'('||rind.extents||')'),34) || 
			   lpad(' ', 23) ||
			   lpad(to_char(wtotal_bytes/1048576, '9999.9'), 7) ||
			   lpad(to_char((wtotal_bytes - wunused_bytes)/ 1048576, '9999.9'), 7) ||
			   lpad(to_char(wunused_bytes/1048576, '9999.9'), 7) );
			 
     windalloc := windalloc + wtotal_bytes/1048576;
     windused  := windused + (wtotal_bytes - wunused_bytes)/ 1048576;
     windfree  := windfree + wunused_bytes/1048576;
  
   end loop;

   wtotindalloc := wtotindalloc + windalloc;
   wtotindused  := wtotindused  + windused;
   wtotindfree  := wtotindfree  + windfree;

   dbms_output.put_line (rpad(( -- rtab.owner || '.' || 
				rtab.table_name ||'('||rtab.extents||')' ),36) || 
			 lpad(to_char(wtaballoc, '9999.9'), 7) ||
			 lpad(to_char(wtabused, '9999.9'), 7) ||
			 lpad(to_char(wtabfree, '9999.9'), 7) ||
			 lpad(to_char(windalloc, '9999.9'), 7) ||
			 lpad(to_char(windused, '9999.9'), 7) ||
			 lpad(to_char(windfree, '9999.9'), 7) );

 end loop;

 dbms_output.put_line ('------------------------------------  -----  -----  -----  -----  -----  -----');

 dbms_output.put_line (rpad('TOTAL',36) || 
        		 lpad(to_char(wtottaballoc, '99999.9'), 7) ||
			 lpad(to_char(wtottabused, '99999.9'), 7) ||
			 lpad(to_char(wtottabfree, '99999.9'), 7) ||
			 lpad(to_char(wtotindalloc, '99999.9'), 7) ||
			 lpad(to_char(wtotindused, '99999.9'), 7) ||
			 lpad(to_char(wtotindfree, '99999.9'), 7) );

 dbms_output.put_line ('------------------------------------------------------------------------------');

     dbms_output.put_line ('Full segment type breakdown is:');
     dbms_output.put_line ('-------------------------------');
 for j in (select rpad(segment_type, 20) seg_type, sum(bytes) / 1048576 All_Seg_Types 
           from dba_segments 
	   where tablespace_name = v_tablepspace
	   group by rpad(segment_type, 20)) loop
     dbms_output.put_line (
     	j.seg_type||' '||
     	to_char(j.All_Seg_Types, '99999.99'));
 end loop;
     dbms_output.put_line ('                       --------');
 for k in (select sum(bytes) / 1048576 All_Seg_Types 
           from dba_segments 
	   where tablespace_name = v_tablepspace) loop
     dbms_output.put_line ('Total                '||to_char(k.All_Seg_Types, '99999.99'));
 end loop;
end;
/
set feedback on verify on 
spool off

</pre>
Re: reclaim tablespace after deleting data [message #60709 is a reply to message #60707] Fri, 27 February 2004 09:38 Go to previous message
andrew again
Messages: 2577
Registered: March 2000
Senior Member
To see if your PCTFREE 10 is sufficient to handle your updates (depends on how much your updates make the row length actually grow when you update it), analyze the teable and check to see if you have "bad" row chaining. It's not always possible to avoid row chaining (e.g. if you have very long rows) and or small blocks. Commonly it's close to 0% chaining though.

analyse table EMP compute/analyze statistics;
select table_name, num_rows, chain_cnt from user_tables where table = 'EMP';

Increase PCTFREE to say 20 until it improves if necessary. 0 is fine if no updates or updates never increase the length of rows e.g. data warehouse.
Previous Topic: how to change sys.props$'s value$ back since couldn't open
Next Topic: CPU 100% USAGES
Goto Forum:
  


Current Time: Fri Sep 20 12:48:20 CDT 2024