Tip

Determine used and free space in a tablespace

This small Oracle script can be executed as a script file from the SQL*Plus prompt and reports the total size, used space, free space and percentage of used and free space in all the tablespaces in a database. Very useful for DBAs! The user executing this script should have the select privilege on the dba_free_space and dba_data_files views. The script has been tested on Oracle 8i enterprise and standard editions.

 /* TOTAL, FREE AND USED SPACE IN TABLESPACES */ SET LINESIZE 100 COLUMN TABLESPACE FORMAT A15 select t.tablespace, t.totalspace as " Totalspace(MB)", round((t.totalspace-fs.freespace),2) as "Used Space(MB)", fs.freespace as "Freespace(MB)", round(((t.totalspace-fs.freespace)/t.totalspace)*100,2) as "% Used", round((fs.freespace/t.totalspace)*100,2) as "% Free" from (select round(sum(d.bytes)/(1024*1024)) as totalspace, d.tablespace_name tablespace from dba_data_files d group by d.tablespace_name) t, (select round(sum(f.bytes)/(1024*1024)) as freespace, f.tablespace_name tablespace from dba_free_space f group by f.tablespace_name) fs where t.tablespace=fs.tablespace order by t.tablespace;

 

Reader Feedback

Paul S. writes: I find it frustrating to find a freespace tip that does not take into account the fact that if tablespace has no freespace then it in not listed in the table. The simple solution is to place an outer join in the where clause, as use nvl like so:

 1> /* TOTAL, FREE

    Requires Free Membership to View

AND USED SPACE IN TABLESPACES */ 2> SET LINESIZE 100 3> COLUMN TABLESPACE FORMAT A15 4> select t.tablespace, t.totalspace as " Totalspace(MB)", 5> round((t.totalspace-nvl(fs.freespace,0)),2) as "Used Space(MB)", 6> nvl(fs.freespace,0) as "Freespace(MB)", 7> round(((t.totalspace-nvl(fs.freespace,0))/t.totalspace)*100,2) as "%Used", 8> round((nvl(fs.freespace,0)/t.totalspace)*100,2) as "% Free" 9> from 10> (select round(sum(d.bytes)/(1024*1024)) as totalspace,d.tablespace_name tablespace 11> from dba_data_files d 12> group by d.tablespace_name) t, 13> (select round(sum(f.bytes)/(1024*1024)) as freespace,f.tablespace_name tablespace 14> from dba_free_space f 15> group by f.tablespace_name) fs 16> where t.tablespace=fs.tablespace (+) 17> order by t.tablespace;

Note changes on lines 5, 6, 7, 8, & 16.

 

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 March 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.