ITPub博客

首页 > Linux操作系统 > Linux操作系统 > 数据库表空间查询和扩展

数据库表空间查询和扩展

原创 Linux操作系统 作者:xueting86 时间:2012-07-13 10:16:32 0 删除 编辑
--表空间扩展:
ALTER TABLESPACE DEV_SOAINFRA ADD DATAFILE '/soadb/app/soadb/oradata/soadb/DEV_soainfra02.dbf' SIZE 4096M;
alter database datafile '/soadb/app/soadb/oradata/soadb/system01.dbf' resize 1024M;
--查询表空间使用情况
SELECT upper(f.tablespace_name) "表空间名",
       d.tot_grootte_mb "表空间大小(M)",
       d.tot_grootte_mb - f.total_bytes "已使用空间(M)",
       to_char(round((d.tot_grootte_mb - f.total_bytes) / d.tot_grootte_mb * 100,
                     2),
               '990.99') || '%' "使用比",
       f.total_bytes "空闲空间(M)",
       f.max_bytes "最大块(M)"
  FROM (SELECT tablespace_name,
               round(SUM(bytes) / (1024 * 1024), 2) total_bytes,
               round(MAX(bytes) / (1024 * 1024), 2) max_bytes
          FROM sys.dba_free_space
         GROUP BY tablespace_name) f,
       (SELECT dd.tablespace_name,
               round(SUM(dd.bytes) / (1024 * 1024), 2) tot_grootte_mb
          FROM sys.dba_data_files dd
         GROUP BY dd.tablespace_name) d
 WHERE d.tablespace_name = f.tablespace_name
 ORDER BY 1
--查询表空间的free space
SELECT tablespace_name,
       COUNT(*) AS extends,
       round(SUM(bytes) / 1024 / 1024, 2) AS mb,
       SUM(blocks) AS blocks
  FROM dba_free_space
 GROUP BY tablespace_name;
--查询表空间的总容量
SELECT tablespace_name, SUM(bytes) / 1024 / 1024 AS mb
  FROM dba_data_files
 GROUP BY tablespace_name;
--查询表空间使用率
SELECT total.tablespace_name,
       round(total.mb, 2) AS total_mb,
       round(total.mb - free.mb, 2) AS used_mb,
       round((1 - free.mb / total.mb) * 100, 2) || '%' AS used_pct
  FROM (SELECT tablespace_name, SUM(bytes) / 1024 / 1024 AS mb
          FROM dba_free_space
         GROUP BY tablespace_name) free,
       (SELECT tablespace_name, SUM(bytes) / 1024 / 1024 AS mb
          FROM dba_data_files
         GROUP BY tablespace_name) total
 WHERE free.tablespace_name = total.tablespace_name;

来自 “ ITPUB博客 ” ,链接:http://blog.itpub.net/9343996/viewspace-735365/,如需转载,请注明出处,否则将追究法律责任。

请登录后发表评论 登录
全部评论

注册时间:2012-05-22

  • 博文量
    6
  • 访问量
    59114