Tip

Autoextend free space check

This SQL script was developed and tested on Oracle 9i but should also work on Oracle 8 versions. It checks each data file for the free space left and how much the file can grow using dba_data_files and dba_free_space. The result is joined with a similar result from dba_temp_files without the dba_free_space values because there aren't any for tempfiles.

SET LINESIZE 250
SET PAGESIZE 150

COLUMN TSNAME FORMAT A11
COLUMN FNAME FORMAT A45
COLUMN TSFREEMEGS FORMAT 9999.00
COLUMN FSIZEMEGS FORMAT 9999.00
COLUMN FMAXMEGS FORMAT 9999.00
COLUMN FDIFFMEGS FORMAT 9999.00
COLUMN TOTFREEMEGS FORMAT 9999.00

BREAK ON TSNAME SKIP 1

COMPUTE SUM LABEL TOTAL OF TSFREEMEGS ON TSNAME
COMPUTE SUM LABEL TOTAL OF FDIFFMEGS ON TSNAME
COMPUTE SUM LABEL TOTAL OF TOTFREEMEGS ON TSNAME

SELECT 
DATA.TABLESPACE_NAME "TSNAME", 
NVL(SUM(FREE.BYTES)/1024/1024 ,0) "TSFREEMEGS", 
DATA.FILE_NAME "FNAME",
DATA.BYTES/1024/1024 "FSIZEMEGS", 
DATA.MAXBYTES/1024/1024 "FMAXMEGS",
(DATA.MAXBYTES/1024/1024 - DATA.BYTES/1024/1024) "FDIFFMEGS",
NVL((SUM(FREE.BYTES)/1024/1024 + (DATA.MAXBYTES/1024/1024 - DATA.BYTES/1024/1024)),0) "TOTFREEMEGS"
FROM DBA_DATA_FILES DATA 
LEFT OUTER JOIN DBA_FREE_SPACE FREE 
ON DATA.FILE_ID = FREE.FILE_ID
GROUP BY DATA.TABLESPACE_NAME, DATA.FILE_NAME, DATA.BYTES, DATA.MAXBYTES 
UNION
SELECT 
TABLESPACE_NAME "TSNAME", 
0 "TSFREEMEGS",
FILE_NAME "FNAME",
BYTES/1024/1024 "FSIZEMEGS",
MAXBYTES/1024/1024 "FMAXMEGS",
(MAXBYTES/1024/1024 - BYTES/1024/1024) "FDIFFMEGS",
(MAXBYTES/1024/1024

    Requires Free Membership to View

- BYTES/1024/1024) "TOTFREEMEGS" FROM DBA_TEMP_FILES ;

Reader Feedback

Michael D. writes: This SQL script was developed and tested on Oracle 9i but should also work on Oracle 8 versions. SQL92 compliant syntax is not available until Oracle 9i. The following lines should be replaced for other versions.

>>FROM DBA_DATA_FILES DATA LEFT OUTER JOIN DBA_FREE_SPACE FREE
>>ON DATA.FILE_ID = FREE.FILE_ID 

FROM DBA_DATA_FILES DATA, DBA_FREE_SPACE FREE 
WHERE DATA.FILE_ID = FREE.FILE_ID(+) 

For More Information

  • Feedback: E-mail the editor with your thoughts about this tip.
  • More tips: Hundreds of free Oracle tips and scripts.
  • Tip contest: Have an Oracle tip to offer your fellow DBAs and developers? The best tips submitted will receive a cool prize -- submit your tip today!
  • Ask the Experts: Our SQL, database design, Oracle, SQL Server, DB2, metadata, and data warehousing gurus are waiting to answer your toughest questions.
  • Forums: Ask your technical Oracle questions--or help out your peers by answering them--in our active forums.
  • Best Web Links: Oracle tips, tutorials, and scripts from around the Web.

This was first published in June 2003

There are Comments. Add yours.

 
TIP: Want to include a code block in your comment? Use <pre> or <code> tags around the desired text. Ex: <code>insert code</code>

REGISTER or login:

Forgot Password?
By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy
Sort by: OldestNewest

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to:

Disclaimer: Our Tips Exchange is a forum for you to share technical advice and expertise with your peers and to learn from other enterprise IT professionals. TechTarget provides the infrastructure to facilitate this sharing of information. However, we cannot guarantee the accuracy or validity of the material submitted. You agree that your use of the Ask The Expert services and your reliance on any questions, answers, information or other materials received through this Web site is at your own risk.