Need tablespace usage details? want to check how much space used from current size and max size of the tablespace? Below are some queries to check the free space with extendable size,used space & their percentage of usage.
The below query is to check the particular tablespace usage details
set lines 300
col TABLESPACE_NAME for a30
col file_name for a45
select
a.TABLESPACE_NAME,
round(avail,1) curr_size_MB,
round(used,1) used_MB,
round(total,1) Maxsize_MB,
round(free+extentable_MB,1) "Free+extendable_MB",
round(100*(1-(free+extentable_MB)/total),1)"Usage %"
from (
select
TABLESPACE_NAME,
sum(BYTES)/(1024*1024) avail,
sum(MAXBYTES)/(1024*1024) total,
(sum(MAXBYTES)/(1024*1024) - sum(BYTES)/(1024*1024)) extentable_MB
from dba_data_files
group by TABLESPACE_NAME) a,
(
select
TABLESPACE_NAME,
sum(BYTES)/(1024*1024) free
from dba_free_space group by TABLESPACE_NAME) b,
(
select
TABLESPACE_NAME,
BYTES/(1024*1024) Used
from sm$ts_used) c
where a.TABLESPACE_NAME=b.TABLESPACE_NAME and
a.TABLESPACE_NAME=c.TABLESPACE_NAME and
a.TABLESPACE_NAME='DATA'
order by 4 DESC;
The below query is to check the all tablespaces usage details in the db
set lines 300
The below query is to check the particular tablespace usage details
set lines 300
col TABLESPACE_NAME for a30
col file_name for a45
select
a.TABLESPACE_NAME,
round(avail,1) curr_size_MB,
round(used,1) used_MB,
round(total,1) Maxsize_MB,
round(free+extentable_MB,1) "Free+extendable_MB",
round(100*(1-(free+extentable_MB)/total),1)"Usage %"
from (
select
TABLESPACE_NAME,
sum(BYTES)/(1024*1024) avail,
sum(MAXBYTES)/(1024*1024) total,
(sum(MAXBYTES)/(1024*1024) - sum(BYTES)/(1024*1024)) extentable_MB
from dba_data_files
group by TABLESPACE_NAME) a,
(
select
TABLESPACE_NAME,
sum(BYTES)/(1024*1024) free
from dba_free_space group by TABLESPACE_NAME) b,
(
select
TABLESPACE_NAME,
BYTES/(1024*1024) Used
from sm$ts_used) c
where a.TABLESPACE_NAME=b.TABLESPACE_NAME and
a.TABLESPACE_NAME=c.TABLESPACE_NAME and
a.TABLESPACE_NAME='DATA'
order by 4 DESC;
Output:
The below query is to check the all tablespaces usage details in the db
set lines 300
col TABLESPACE_NAME for a30
col file_name for a45
select
a.TABLESPACE_NAME,
round(avail,1) curr_size_MB,
round(used,1) used_MB,
round(total,1) Maxsize_MB,
round(free+extentable_MB,1) "Free+extendable_MB",
round(100*(1-(free+extentable_MB)/total),1)"Usage %"
from (
select
TABLESPACE_NAME,
sum(BYTES)/(1024*1024) avail,
sum(MAXBYTES)/(1024*1024) total,
(sum(MAXBYTES)/(1024*1024) - sum(BYTES)/(1024*1024)) extentable_MB
from dba_data_files
group by TABLESPACE_NAME) a,
(
select
TABLESPACE_NAME,
sum(BYTES)/(1024*1024) free
from dba_free_space group by TABLESPACE_NAME) b,
(
select
TABLESPACE_NAME,
BYTES/(1024*1024) Used
from sm$ts_used) c
where a.TABLESPACE_NAME=b.TABLESPACE_NAME and
a.TABLESPACE_NAME=c.TABLESPACE_NAME
order by 4 DESC;
Output:
Both queries given above will provide correct output only for the tablespaces which is auto extendable.
If you want to check the free space,used space and current size of the tablespace which is not auto extendable, please use the below query
All tablespaces usage details:
set pages 1000
set pages 1000
break on report
compute sum of Total_MB on report
compute sum of Used_MB on report
compute sum of Free_MB on report
select a.TABLESPACE_NAME, round(Curr_Size,1) Total_MB,round(Used,1) Used_MB,round(Free,1) Free_MB, round(100*(1-free/Curr_Size),1) Usage
from (select TABLESPACE_NAME,BYTES/(1024*1024) Curr_Size from sm$ts_avail) a
,(select TABLESPACE_NAME,BYTES/(1024*1024) Used from sm$ts_used) b,
(select TABLESPACE_NAME,BYTES/(1024*1024) Free from sm$ts_free) c
where a.TABLESPACE_NAME=b.TABLESPACE_NAME(+) and
a.TABLESPACE_NAME=c.TABLESPACE_NAME order by 5 DESC;
Output:
Single tablespace usage details:
set pages 1000
clear computes
select a.TABLESPACE_NAME, round(Curr_Size,1) Total_MB,round(Used,1) Used_MB,round(Free,1) Free_MB, round(100*(1-free/Curr_Size),1) Usage
from (select TABLESPACE_NAME,BYTES/(1024*1024) Curr_Size from sm$ts_avail) a
,(select TABLESPACE_NAME,BYTES/(1024*1024) Used from sm$ts_used) b,
(select TABLESPACE_NAME,BYTES/(1024*1024) Free from sm$ts_free) c
where a.TABLESPACE_NAME=b.TABLESPACE_NAME(+) and
a.TABLESPACE_NAME=c.TABLESPACE_NAME and a.TABLESPACE_NAME='RETEK_' order by 1 ASC;
Output:
We'll see datafiles' usage in the next post. Until then bye to all Oracle dba.
Comments
Post a Comment