Created
May 27, 2015 17:41
-
-
Save geo-stanciu/8ea0f6c0e0a1b9d05e10 to your computer and use it in GitHub Desktop.
Oracle monitor occupied space for each tablespace
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
/* | |
Copyright (c) 2015, Gheorghita Stanciu gheorghita(dot)stanciu(at)gmail(dot)com | |
All rights reserved. | |
Redistribution and use in source and binary forms, with or without | |
modification, are permitted provided that the following conditions are met: | |
1. Redistributions of source code must retain the above copyright notice, this | |
list of conditions and the following disclaimer. | |
2. Redistributions in binary form must reproduce the above copyright notice, | |
this list of conditions and the following disclaimer in the documentation | |
and/or other materials provided with the distribution. | |
THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND | |
ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED | |
WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE | |
DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR | |
ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES | |
(INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; | |
LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND | |
ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT | |
(INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS | |
SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. | |
The views and conclusions contained in the software and documentation are those | |
of the authors and should not be interpreted as representing official policies, | |
either expressed or implied, of the FreeBSD Project. | |
*/ | |
set linesize 10000; | |
set pagesize 50000; | |
set trimspool on; | |
spool free_space.txt; | |
select distinct substr("NAME", | |
1, | |
case | |
when instr("NAME", '\', -1) > instr("NAME", '/', -1) then | |
instr("NAME", '\', -1) | |
else | |
instr("NAME", '/', -1) | |
end) as "Path" | |
from v$datafile | |
order by 1; | |
column "Tablespace" format a32 | |
column "Used MB" format 99,999,999 | |
column "Free MB" format 99,999,999 | |
column "Total MB" format 99,999,999 | |
column "Max Size MB" format 99,999,999 | |
column "Pct. Free" format 99,999,999.00 | |
select fs.tablespace_name "Tablespace", | |
(df.totalspace - fs.freespace) "Used MB", | |
fs.freespace "Free MB", | |
df.totalspace "Total MB", | |
df.max_size "Max Size MB", | |
100 - round(100 * ((df.totalspace - fs.freespace) / df.max_size), 2) "Pct. Free" | |
from (select tablespace_name, | |
round(sum(bytes) / 1048576) TotalSpace, | |
round(sum(decode(autoextensible, 'YES', maxbytes, 'NO', bytes)) / | |
1048576) max_size | |
from dba_data_files | |
group by tablespace_name) df, | |
(select tablespace_name, round(sum(bytes) / 1048576) FreeSpace | |
from dba_free_space | |
group by tablespace_name) fs | |
where df.tablespace_name = fs.tablespace_name | |
order by fs.tablespace_name; | |
-- now I need to know what datafiles are created for each tablespace that have less than 50% free space | |
select distinct substr(v."NAME", | |
case | |
when instr(v."NAME", '\', -1) > instr(v."NAME", '/', -1) then | |
instr(v."NAME", '\', -1) | |
else | |
instr(v."NAME", '/', -1) | |
end + 1) as "File" | |
from v$datafile v, v$tablespace t | |
where v."TS#" = t."TS#" | |
and t.NAME in | |
(select fs.tablespace_name | |
from (select tablespace_name, | |
round(sum(bytes) / 1048576) TotalSpace, | |
round(sum(decode(autoextensible, | |
'YES', | |
maxbytes, | |
'NO', | |
bytes)) / 1048576) max_size | |
from dba_data_files | |
group by tablespace_name) df, | |
(select tablespace_name, round(sum(bytes) / 1048576) FreeSpace | |
from dba_free_space | |
group by tablespace_name) fs | |
where df.tablespace_name = fs.tablespace_name | |
and (100 - | |
round(100 * ((df.totalspace - fs.freespace) / df.max_size), | |
2) <= 50)) | |
order by 1; | |
spool off; | |
exit; | |
/ |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment