пятница, 9 марта 2012 г.

Shrinking temporary tablespace in Oracle 10g and 11g

Useful links

Shrinking temporary tablespace in Oracle 10g

  1. CREATE TEMPORARY TABLESPACE TEMP02 TEMPFILE
  2. '/oracle/oradata/db/TEMP_02.dbf' SIZE 50M AUTOEXTEND ON;
  3.  
  4. ALTER DATABASE DEFAULT TEMPORARY TABLESPACE TEMP02;
Switch all existing users from old TEMP to new TEMP02 tablespace:
  1. set serveroutput on
  2. -- Switch all existing users to new temp tablespace.
  3. BEGIN
  4. FOR cur_user IN (SELECT username FROM dba_users WHERE temporary_tablespace = 'TEMP') LOOP
  5. dbms_output.put_line('ALTER USER ' || cur_user.username || ' TEMPORARY TABLESPACE TEMP02');
  6. EXECUTE IMMEDIATE 'ALTER USER ' || cur_user.username || ' TEMPORARY TABLESPACE TEMP02';
  7. END LOOP;
  8. END;
  9. /

Waiting for release old TEMP tablespace usage by applications/sessions:

  1. lsof | grep temp01.dbf | wc -l
  2. 124
  1. select count(*) from V$TEMPSEG_USAGE
  2. where tablespace = 'TEMP';
  3.  
  4. COUNT(*)
  5. ----------
  6. 91
  1. select tablespace, username, count(*)
  2. from V$TEMPSEG_USAGE
  3. where 1 = 1
  4. --and tablespace in ('TEMP', 'TEMP02')
  5. and tablespace = 'TEMP'
  6. group by tablespace, username;
when count become zero then drop unused old TEMP tablespace and files:
  1. DROP TABLESPACE TEMP INCLUDING CONTENTS AND DATAFILES;

Recreate old TEMP tablespace and if you want switch back from TEMP02

  1. CREATE TEMPORARY TABLESPACE TEMP TEMPFILE
  2. '/oracle/oradata/db/TEMP_01.dbf' SIZE 50M AUTOEXTEND ON;
  3.  
  4. ALTER DATABASE DEFAULT TEMPORARY TABLESPACE TEMP;
Switch all existing users back to TEMP tablespace:
  1. set serveroutput on
  2. -- Switch all existing users to new temp tablespace.
  3. BEGIN
  4. FOR cur_user IN (SELECT username FROM dba_users WHERE temporary_tablespace = 'TEMP02') LOOP
  5. dbms_output.put_line('ALTER USER ' || cur_user.username || ' TEMPORARY TABLESPACE TEMP');
  6. EXECUTE IMMEDIATE 'ALTER USER ' || cur_user.username || ' TEMPORARY TABLESPACE TEMP';
  7. END LOOP;
  8. END;
  9. /

Waiting for release TEMP02 tablespace usage by applications/sessions:

  1. lsof | grep temp02.dbf | wc -l
  2. 124
  1. select count(*) from V$TEMPSEG_USAGE
  2. where tablespace = 'TEMP02';
  3.  
  4. COUNT(*)
  5. ----------
  6. 91
  1. select tablespace, username, count(*)
  2. from V$TEMPSEG_USAGE
  3. where 1 = 1
  4. --and tablespace in ('TEMP', 'TEMP02')
  5. and tablespace = 'TEMP02'
  6. group by tablespace, username;
when count become zero then drop unused TEMP02 tablespace and files:
  1. DROP TABLESPACE TEMP02 INCLUDING CONTENTS AND DATAFILES;

Temporary Tablespace Enhancements in Oracle Database 11g

  1. alter tablespace temp shrink space [keep 100m];

The shrink can also be directed to a specific tempfile using the TEMPFILE clause.
  1. ALTER TABLESPACE temp SHRINK TEMPFILE '/oracle/oradata/db/temp01.dbf' KEEP 30M;

View V$TEMPSEG_USAGE

  1. lsof | grep temp01.dbf | wc -l
  2. 124
  1. select * from V$TEMPSEG_USAGE
  1. select count(*)
  2. from V$TEMPSEG_USAGE
  3. where tablespace = 'TEMP';
  1. select tablespace, username, count(*)
  2. from V$TEMPSEG_USAGE
  3. where 1 = 1
  4. --and tablespace in ('TEMP', 'TEMP02')
  5. --and tablespace = 'TEMP'
  6. group by tablespace, username;

Issue: Shrinking of Temp Tablespace does not take effect

Run this query to find if there are any sessions using your temp tablespace a long time:
  1. SELECT se.username username,
  2. se.SID sid, se.serial# serial#,
  3. se.status status,
  4. 'alter system kill session ''' || se.sid || ',' || se.serial# || ''' immediate;' kill_session_cmd,
  5. se.sql_hash_value, se.sql_id,
  6. se.prev_hash_value,se.machine machine,
  7. su.TABLESPACE tablespace,su.segtype,
  8. su.CONTENTS CONTENTS
  9. FROM v$session se,
  10. v$tempseg_usage su /* v$sort_usage */
  11. WHERE se.saddr=su.session_addr
  12. AND status = 'ACTIVE'
  13. ;
Check if you can drop those sessions and then try shrink. Or you can create a new tablespace move every user to that temp tablespace and than drop this old one.

2 комментария: