oracle表空间不足:ORA-01653: unable to extend table

问题背景:

      oracle表空间不足报错是比较常见的故障,尤其是没有对剩余表空间做定期巡检的系统;

       报错代码如下:

       oracle表空间不足错误代码:ORA-01653: unable to extend table ;

解决方式:

1、查看表空间使用率:

set linesize 220;
set pagesize 500;
col tbsn for a40;
select total.tablespace_name TBSN,
        round(total.MB,3) as total_space,
        case when free.MB is null then 0
                               else round(free.MB,3)
         end as free_space, 
       case when free.MB is null then 0
         else round(free.MB,3)/round(total.MB,3)*100  end as free_rate
from ( select tablespace_name, sum(bytes/1024/1024) MB from dba_data_files group by tablespace_name )  total,
        ( select tablespace_name, sum(bytes/1024/1024) MB from dba_free_space group by tablespace_name )  free
where total.tablespace_name=free.tablespace_name(+)
order by  free_rate desc;

上述代码可以查询中数据库有哪些表空间,总空间大小,剩余空间大小以及使用百分比,可以做到对表空间使用情况的一目了然

2、 查看磁盘那个空间表多,把表空间放在剩余空间比较多的地方(Linux操作系统)
df -h

3、查看表空间数据文件:
一定要确认好路径,和原有的文件路径保持一致

set wrap on;
set lines 170
col file_name for a80
select file_id,file_name,bytes/1024/1024 MB from dba_data_files where tablespace_name=upper(‘&tablespace_name‘);

4、如果是RAC环境还要查看asm磁盘剩余空间

1 select group_number,name,total_mb,free_mb from v$asm_diskgroup;



5、添加表空间  (手动条件数据文件)

1 alter tablespace tablespace_name add datafile ‘/xxxx/xxxx/xxxxx_number.dbf‘ size 30g autoextend off;


6、自己写了一个自动编辑增加数据文件的扩容sql ,可以批量生成扩容脚本(不保证百分百成功率,基本都没问题)

set linesize 150 pagesize 900
SELECT ‘alter tablespace ‘ || TABLESPACE_NAME || ‘ add datafile ‘‘‘ ||
       substr(file_name, 1, regexp_instr(file_name, ‘[[:digit:]]+\.‘) - 1) ||
       TO_CHAR(substr(file_name,
                      regexp_instr(file_name, ‘[[:digit:]]+\.‘),
                      instr(file_name, ‘.‘) -
                      regexp_instr(file_name, ‘[[:digit:]]+\.‘)) + B.RN) ||
       ‘.dbf‘‘ size ‘ || bytes / 1024 / 1024 || ‘m autoextend off;‘
  FROM DBA_DATA_FILES,
       (select rownum rn
          from dba_objects
         WHERE ROWNUM <= &number_of_datafile) B       ----增加几个数据文件,比如3个
 WHERE FILE_ID = (SELECT DISTINCT LAST_VALUE(FILE_ID) 
 OVER(ORDER BY to_number(substr(file_name, regexp_instr(file_name, ‘[[:digit:]]+\.‘), instr(file_name, ‘.‘) - regexp_instr(file_name, ‘[[:digit:]]+\.‘))) ASC ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING)
                    FROM DBA_DATA_FILES
                   WHERE tablespace_name = ‘&tablespace_name‘);    --表空间名称

相关推荐