Muito obrigado pela ajuda Chiappa.
Só para complementar, essa query foi retirada do blog do Tanel Poder. Todos os 
scripts que ele disponibiliza foi ele mesmo quem criou. Em relação a UNDO e 
TEMP, tinha adicionado a consulta para excluir as duas tablespaces da query:

AND t.tablespace_name not in (select tablespace_name from dba_tablespaces where 
contents in ('TEMPORARY','UNDO'))

Já possuo as queries que fazem o monitoramento do UNDO e da TEMPObrigado.    Em 
quarta-feira, 4 de julho de 2018 13:55:57 BRT, jlchia...@yahoo.com.br 
[oracle_br] <oracle_br@yahoogrupos.com.br> escreveu:  
 
     
Blz ? Então, antes de tar a sua resposta, uma Obs : tenha ** certeza ** que a 
lógica implementada nesse tal script aí está correta principalmente no tocante 
à tablespace de UNDO e tablespace TEMP - como Acredito que vc deve saber, o 
espaço usado REAL na tablespace de UNDO vc deve consultar na V$TRANSACTION e o 
espaço REAL em uso na temp tablespace vc consulta na 
V$SORT_USAGE/V$SORT_SEGMENT.... Outra coisa é CUIDADO ao calcular %used e %free 
em datafiles auto-extensíveis : como vc sabe, o valor máximo de extensão é um 
limite FUTURO, a ser imposto AO SISTEMA OPERACIONAL não agora mas apenas QUANDO 
a tablespace crescer.. Assim, então em tese vc deveria SOMAR os autoextensíveis 
todos, verificar quanto vc tem livre em disco no sistema operacional e o espaço 
livre ** REAL ** seria a diferença desses dois...

 Muito bem, aviso dado vamos à resposta : primeiro vamos executar a tua query 
sem alterações :
 
SYSTEM:@O11GR2SE:SQL>get t.sql
  1 SELECT t.tablespace_name, t.mb  "TotalMB" 
  2     ,        t.mb - nvl(f.mb,0) "UsedMB" 
  3     ,               nvl(f.mb,0) "FreeMB" 
  4     ,lpad(ceil((1-nvl(f.mb,0)/decode(t.mb,0,1,t.mb))*100)||'%', 6) "% Used" 
  5     ,                                                        t.ext "Ext" 
  6     , 
'|'||rpad(lpad('#',ceil((1-nvl(f.mb,0)/decode(t.mb,0,1,t.mb))*20),'#'),20,' 
')||'|' "Used" 
  7  FROM 
  8     ( 
  9       select tablespace_name, trunc(sum(bytes)/1048576) MB 
 10         from dba_free_space 
 11        group by tablespace_name 
 12       union all 
 13       select tablespace_name, trunc(sum(bytes_free)/1048576) MB 
 14         from v$temp_space_header 
 15        group by tablespace_name 
 16      ) f, 
 17     (select tablespace_name, trunc(sum(bytes)/1048576) MB, 
max(autoextensible) ext 
 18        from dba_data_files 
 19       group by tablespace_name 
 20      union all 
 21      select tablespace_name, trunc(sum(bytes)/1048576) MB, 
max(autoextensible) ext 
 22        from dba_temp_files 
 23       group by tablespace_name 
 24      ) t 
 25 WHERE t.tablespace_name = f.tablespace_name (+) 
 26   AND t.tablespace_name not in (select tablespace_name from dba_tablespaces 
where contents in ('TEMPORARY','UNDO')) 
 27 ORDER BY t.tablespace_name; 

 SYSTEM:@O11GR2SE:SQL>@t

TABLESPACE_NAME                   TotalMB     UsedMB     FreeMB % Used Ext Used
------------------------------ ---------- ---------- ---------- ------ --- 
----------------------
EXAMPLE                               313         39        274    13% YES |### 
                |
STATSPACK                             372        355         17    96% YES 
|####################|
SYSAUX                                580        537         43    93% YES 
|################### |
SYSTEM                               1760       1721         39    98% YES 
|####################|
TS_TESTE                              363        346         17    96% YES 
|####################|
USERS                                1297       1235         62    96% YES 
|####################|

6 linhas selecionadas.

==> Okdoc... Bem, pelo que entendi a tua dúvida decorre primeiro do fato de a 
coluna "% Used" ser o resultado de uma expressão, o que o Oracle não deixa usar 
em GROUP BY, em WHERE.... A solução para isso é simplesmente ter um query 
EXTERNA, que use na cláusula de FROM a query original, assim 'materializando' 
as expressões.... O segundo ponto que imagino te  pegou foi o FATO de que essa 
coluna é uma CONTA/expressão numérica CONCATENADA com um caracter '%' : 
necessariamente se vc concatena uma string com uma conta o resultado é string, 
pra vc poder restringir com >= vc TEM que converter de volta pra número, assim :

SYSTEM:@O11GR2SE:SQL>get t.sql
  1  select *
  2  from
  3     (
  4     SELECT t.tablespace_name, t.mb  "TotalMB"
  5         ,        t.mb - nvl(f.mb,0) "UsedMB"
  6         ,               nvl(f..mb,0) "FreeMB"
  7         ,lpad(ceil((1-nvl(f.mb,0)/decode(t.mb,0,1,t.mb))*100)||'%', 6) "% 
Used"
  8         ,                                                        t.ext "Ext"
  9         , 
'|'||rpad(lpad('#',ceil((1-nvl(f.mb,0)/decode(t.mb,0,1,t.mb))*20),'#'),20,' 
')||'|' "Used"
 10      FROM
 11         (
 12           select tablespace_name, trunc(sum(bytes)/1048576) MB
 13             from dba_free_space
 14            group by tablespace_name
 15           union all
 16           select tablespace_name, trunc(sum(bytes_free)/1048576) MB
 17             from v$temp_space_header
 18            group by tablespace_name
 19          ) f,
 20         (select tablespace_name, trunc(sum(bytes)/1048576) MB, 
max(autoextensible) ext
 21            from dba_data_files
 22           group by tablespace_name
 23          union all
 24          select tablespace_name, trunc(sum(bytes)/1048576) MB, 
max(autoextensible) ext
 25            from dba_temp_files
 26           group by tablespace_name
 27          ) t
 28     WHERE t.tablespace_name = f.tablespace_name (+)
 29       AND t.tablespace_name not in (select tablespace_name from 
dba_tablespaces where contents in ('TEMPORARY','UNDO'))
 30     ORDER BY t.tablespace_name
 31     )
 32*  where TO_NUMBER(ltrim(rtrim(replace("% Used", '%')))) >= 90; -- <<== veja 
como ficou o filtro, que está na query EXTERNA !!
 
SYSTEM:@O11GR2SE:SQL>@t

TABLESPACE_NAME                   TotalMB     UsedMB     FreeMB % Used Ext Used
------------------------------ ---------- ---------- ---------- ------ --- 
----------------------
STATSPACK                             372        355         17    96% YES 
|####################|
SYSAUX                                580        537         43    93% YES 
|################### |
SYSTEM                               1760       1721         39    98% YES 
|####################|
TS_TESTE                              363        346         17    96% YES 
|####################|
USERS                                1297       1235         62    96% YES 
|####################|

SYSTEM:@O11GR2SE:SQL>

[]s

  Chiappa
  #yiv9218893337 #yiv9218893337 -- #yiv9218893337ygrp-mkp {border:1px solid 
#d8d8d8;font-family:Arial;margin:10px 0;padding:0 10px;}#yiv9218893337 
#yiv9218893337ygrp-mkp hr {border:1px solid #d8d8d8;}#yiv9218893337 
#yiv9218893337ygrp-mkp #yiv9218893337hd 
{color:#628c2a;font-size:85%;font-weight:700;line-height:122%;margin:10px 
0;}#yiv9218893337 #yiv9218893337ygrp-mkp #yiv9218893337ads 
{margin-bottom:10px;}#yiv9218893337 #yiv9218893337ygrp-mkp .yiv9218893337ad 
{padding:0 0;}#yiv9218893337 #yiv9218893337ygrp-mkp .yiv9218893337ad p 
{margin:0;}#yiv9218893337 #yiv9218893337ygrp-mkp .yiv9218893337ad a 
{color:#0000ff;text-decoration:none;}#yiv9218893337 #yiv9218893337ygrp-sponsor 
#yiv9218893337ygrp-lc {font-family:Arial;}#yiv9218893337 
#yiv9218893337ygrp-sponsor #yiv9218893337ygrp-lc #yiv9218893337hd {margin:10px 
0px;font-weight:700;font-size:78%;line-height:122%;}#yiv9218893337 
#yiv9218893337ygrp-sponsor #yiv9218893337ygrp-lc .yiv9218893337ad 
{margin-bottom:10px;padding:0 0;}#yiv9218893337 #yiv9218893337actions 
{font-family:Verdana;font-size:11px;padding:10px 0;}#yiv9218893337 
#yiv9218893337activity 
{background-color:#e0ecee;float:left;font-family:Verdana;font-size:10px;padding:10px;}#yiv9218893337
 #yiv9218893337activity span {font-weight:700;}#yiv9218893337 
#yiv9218893337activity span:first-child 
{text-transform:uppercase;}#yiv9218893337 #yiv9218893337activity span a 
{color:#5085b6;text-decoration:none;}#yiv9218893337 #yiv9218893337activity span 
span {color:#ff7900;}#yiv9218893337 #yiv9218893337activity span 
.yiv9218893337underline {text-decoration:underline;}#yiv9218893337 
.yiv9218893337attach 
{clear:both;display:table;font-family:Arial;font-size:12px;padding:10px 
0;width:400px;}#yiv9218893337 .yiv9218893337attach div a 
{text-decoration:none;}#yiv9218893337 .yiv9218893337attach img 
{border:none;padding-right:5px;}#yiv9218893337 .yiv9218893337attach label 
{display:block;margin-bottom:5px;}#yiv9218893337 .yiv9218893337attach label a 
{text-decoration:none;}#yiv9218893337 blockquote {margin:0 0 0 
4px;}#yiv9218893337 .yiv9218893337bold 
{font-family:Arial;font-size:13px;font-weight:700;}#yiv9218893337 
.yiv9218893337bold a {text-decoration:none;}#yiv9218893337 dd.yiv9218893337last 
p a {font-family:Verdana;font-weight:700;}#yiv9218893337 dd.yiv9218893337last p 
span {margin-right:10px;font-family:Verdana;font-weight:700;}#yiv9218893337 
dd.yiv9218893337last p span.yiv9218893337yshortcuts 
{margin-right:0;}#yiv9218893337 div.yiv9218893337attach-table div div a 
{text-decoration:none;}#yiv9218893337 div.yiv9218893337attach-table 
{width:400px;}#yiv9218893337 div.yiv9218893337file-title a, #yiv9218893337 
div.yiv9218893337file-title a:active, #yiv9218893337 
div.yiv9218893337file-title a:hover, #yiv9218893337 div.yiv9218893337file-title 
a:visited {text-decoration:none;}#yiv9218893337 div.yiv9218893337photo-title a, 
#yiv9218893337 div.yiv9218893337photo-title a:active, #yiv9218893337 
div.yiv9218893337photo-title a:hover, #yiv9218893337 
div.yiv9218893337photo-title a:visited {text-decoration:none;}#yiv9218893337 
div#yiv9218893337ygrp-mlmsg #yiv9218893337ygrp-msg p a 
span.yiv9218893337yshortcuts 
{font-family:Verdana;font-size:10px;font-weight:normal;}#yiv9218893337 
.yiv9218893337green {color:#628c2a;}#yiv9218893337 .yiv9218893337MsoNormal 
{margin:0 0 0 0;}#yiv9218893337 o {font-size:0;}#yiv9218893337 
#yiv9218893337photos div {float:left;width:72px;}#yiv9218893337 
#yiv9218893337photos div div {border:1px solid 
#666666;min-height:62px;overflow:hidden;width:62px;}#yiv9218893337 
#yiv9218893337photos div label 
{color:#666666;font-size:10px;overflow:hidden;text-align:center;white-space:nowrap;width:64px;}#yiv9218893337
 #yiv9218893337reco-category {font-size:77%;}#yiv9218893337 
#yiv9218893337reco-desc {font-size:77%;}#yiv9218893337 .yiv9218893337replbq 
{margin:4px;}#yiv9218893337 #yiv9218893337ygrp-actbar div a:first-child 
{margin-right:2px;padding-right:5px;}#yiv9218893337 #yiv9218893337ygrp-mlmsg 
{font-size:13px;font-family:Arial, helvetica, clean, sans-serif;}#yiv9218893337 
#yiv9218893337ygrp-mlmsg table {font-size:inherit;font:100%;}#yiv9218893337 
#yiv9218893337ygrp-mlmsg select, #yiv9218893337 input, #yiv9218893337 textarea 
{font:99% Arial, Helvetica, clean, sans-serif;}#yiv9218893337 
#yiv9218893337ygrp-mlmsg pre, #yiv9218893337 code {font:115% 
monospace;}#yiv9218893337 #yiv9218893337ygrp-mlmsg * 
{line-height:1.22em;}#yiv9218893337 #yiv9218893337ygrp-mlmsg #yiv9218893337logo 
{padding-bottom:10px;}#yiv9218893337 #yiv9218893337ygrp-msg p a 
{font-family:Verdana;}#yiv9218893337 #yiv9218893337ygrp-msg 
p#yiv9218893337attach-count span {color:#1E66AE;font-weight:700;}#yiv9218893337 
#yiv9218893337ygrp-reco #yiv9218893337reco-head 
{color:#ff7900;font-weight:700;}#yiv9218893337 #yiv9218893337ygrp-reco 
{margin-bottom:20px;padding:0px;}#yiv9218893337 #yiv9218893337ygrp-sponsor 
#yiv9218893337ov li a {font-size:130%;text-decoration:none;}#yiv9218893337 
#yiv9218893337ygrp-sponsor #yiv9218893337ov li 
{font-size:77%;list-style-type:square;padding:6px 0;}#yiv9218893337 
#yiv9218893337ygrp-sponsor #yiv9218893337ov ul {margin:0;padding:0 0 0 
8px;}#yiv9218893337 #yiv9218893337ygrp-text 
{font-family:Georgia;}#yiv9218893337 #yiv9218893337ygrp-text p {margin:0 0 1em 
0;}#yiv9218893337 #yiv9218893337ygrp-text tt {font-size:120%;}#yiv9218893337 
#yiv9218893337ygrp-vital ul li:last-child {border-right:none 
!important;}#yiv9218893337   

Responder a