Temporary space usage
                                                 Last update (2012-06-12 22:41:51)
                                                                                                                   Date added (2008-02-12 15:26:02)

Summary
When you create an index, or doing a hash join, or group by operations and some other stuff, you use temporary space. To find who is using any kind of "TEMP" space use the following queries:

Oracle9i and later
SELECT DECODE(TRUNC(SYSDATE - LOGON_TIME), 0, NULL, TRUNC(SYSDATE - LOGON_TIME) || ' Days' || ' + ') ||
TO_CHAR(TO_DATE(TRUNC(MOD(SYSDATE-LOGON_TIME,1) * 86400), 'SSSSS'), 'HH24:MI:SS') LOGON,
v$session.SID, v$process.SPID spid, CONTENTS, SEGTYPE, ROUND(blocks*:block_size/(1024*1024),2) MB_USED,
v$session.USERNAME, STATUS, OSUSER, MACHINE, v$session.PROGRAM, MODULE, action
FROM v$session, v$process, v$tempseg_usage
WHERE v$session.paddr = v$process.addr
--AND SID = 438
--AND v$session.module LIKE 'XXACC_TRANSFERTOGL%'
--AND v$session.status = 'ACTIVE'
--and segtype = 'HASH'
AND v$session.SADDR = v$tempseg_usage.session_addr
ORDER BY blocks DESC;

Free space for the TEMPORARY tablespaces
SELECT tablespace_name, SUM(cached_mb) SIZE_MB, SUM(used_mb) USED_MB, SUM(cached_mb) - SUM(used_mb) FREE_MB, 
100-ROUND(SUM(used_mb)/SUM(cached_mb),2)*100 || '%' free FROM (
SELECT v$temp_extent_pool.tablespace_name, dba_temp_files.file_name, 
round(bytes/(1024*1024),2) CACHED_MB, bytes_used/(1024*1024) USED_MB, 
100-ROUND(bytes_used/bytes_cached,2)*100 ||'%' free
FROM v$temp_extent_pool, dba_temp_files 
WHERE v$temp_extent_pool.file_id (+) = dba_temp_files.file_id) 
GROUP BY tablespace_name;

TABLESPACE_NAME                   SIZE_MB    USED_MB    FREE_MB FREE
------------------------------ ---------- ---------- ---------- -----
TEMP2                              206880         32     206848 100%
TEMP                               124997      64903      60094 48%

Oracle8i
SELECT DECODE(TRUNC(SYSDATE - LOGON_TIME), 0, NULL, TRUNC(SYSDATE - LOGON_TIME) || ' Days' || ' + ') ||
TO_CHAR(TO_DATE(TRUNC(MOD(SYSDATE-LOGON_TIME,1) * 86400), 'SSSSS'), 'HH24:MI:SS') LOGON,
v$session.SID, v$session.SERIAL#, status, v$process.SPID spid, CONTENTS, SEGTYPE,
ROUND(blocks*:block_size/(1024*1024),2) MB_USED,
v$session.USERNAME, OSUSER, MACHINE, v$session.PROGRAM, MODULE, action
FROM v$session, v$process, v$sort_usage
WHERE v$session.paddr = v$process.addr
AND v$session.SADDR = v$sort_usage.SESSION_ADDR
--and v$session.sid = 1181
ORDER BY SID ASC;
Sql statements that use temp space
SELECT /*+ RULE */ s.SID "SID",s.username "User",s.program "Program", u.TABLESPACE "Tablespace",
u.CONTENTS "Contents", u.EXTENTS "Extents", a.OBJECT, u.blocks*8/1024 "USED_SPACE_MB", q.sql_text "SQL TEXT",
k.bytes/1024/1024 "Temp File Size"
FROM v$session s, v$sort_usage u, dba_temp_files k, v$sql q, v$access a
WHERE s.saddr = u.session_addr
AND s.sql_address = q.address
AND s.SID = a.SID
--AND s.SID = 438
AND u.TABLESPACE=k.tablespace_name;
Reviews
Categories
Oracle DBA-> (147)
  Alertlog (3)
  Archivelog (5)
  Auditing (1)
  Backup - Recovery (19)
  Database files (6)
  Database options (2)
  DB links (2)
  Dependencies (1)
  Dictionary (2)
  Exp-Imp Datapump (6)
  Jobs (2)
  Mview (2)
  Networking (3)
  Objects (7)
  Parameters (2)
  Redologs (6)
  Roles - Grants (2)
  Rollback - Undo (8)
  Segments (3)
  Sequences (2)
  Sessions (14)
  SGA (14)
  Tables (10)
  Tablespaces (10)
  Temp (4)
  Toad (5)
  Transactions (1)
  Upgrade (2)
  Users (3)
Oracle APPS DBA-> (66)
Exadata (1)
Performance Tuning-> (59)
Oracle Real Cases (24)
Oracle Errors (23)
Oracle SQL tricks (32)
Oracle RAC (3)
Oracle Security (8)
Filters
Search