Oracle undo表空间文件丢失情况案例汇总

场景1:

undo表空间文件丢失,有undo数据文件备份,日志存在且可用。

如果备份文件为RMAN备份:

restore

recover

如果为手工备份:

cp

recover


场景2:

undo表空间文件丢失,无undo数据文件备份,日志存在且可用。

mount模式执行:

alter database cre ate datafile 3 as ‘/u03/app/oracle/oradata/prod/undotbs01.dbf’ size 50m;

recover进行读取日志恢复。

不允许在重建控制文件后 ,“alter database create datafile ”重建创建此控制文件之前的数据文件。

场景3:

undo表空间文件丢失,无undo数据文件备份,undo段头存在未提交的事务need recovery。


案例模拟:

查看当前回滚段状态

SYS@prod>select segment_name,status from dba_rollback_segs;

SEGMENT_NAME  STATUS

SYSTEM         ONLINE

_SYSSMU10_1197734989$ ONLINE

_SYSSMU9_1650507775$ ONLINE

_SYSSMU8_517538920$   ONLINE

_SYSSMU7_2070203016$ ONLINE

_SYSSMU6_1263032392$ ONLINE

_SYSSMU5_898567397$ ONLINE

_SYSSMU4_1254879796$ ONLINE

_SYSSMU3_1723003836$ ONLINE

_SYSSMU2_2996391332$ ONLINE

_SYSSMU1_3724004606$ ONLINE


执行一个事务:

HR@prod>update employees set salary = 100;

107 rows updated.


破坏undo:

[oracle@service1 prod]$ cp /etc/passwd undotbs01.dbf


SYS@prod>shutdown abort;

ORACLE instance shut down.

SYS@prod>startup;

ORACLE instance started.


Total System Global Area 835104768 bytes

Fixed Size 2257840 bytes

Variable Size 541068368 bytes

Database Buffers 285212672 bytes

Redo Buffers 6565888 bytes

Database mounted.

ORA-01157: cannot identify/lock data file 3 - see DBWR trace file

ORA-01110: data file 3: ‘/u01/app/oracle/oradata/prod/undotbs01.dbf’


SYS@prod>alter system set undo_management=manual scope=spfile;

SYS@prod>alter database datafile 3 offline;

Database altered.


SYS@prod>select name,status from v$datafile;

/u01/app/oracle/oradata/prod/undotbs01.dbf

RECOVER

undo段上存在事务,需要recover。

但是我们没有备份无法恢复。


SYS@prod>alter database open;( 不能进行DML操作)

Database altered.


创建一个undo表空间:

SYS@prod>create undo tablespace undotbs02 datafile ‘/u01/app/oracle/oradata/prod/untbs02.dbf’ 

size 10M autoextend on;


修改undo_tablespace/undo_management参数:

SYS@prod>alter system set undo_tablespace=undotbs2 scope=spfile;

SYS@prod>alter system set undo_management=auto scope=spfile;

SYS@prod>startup mount force;


SYS@prod>drop tablespace undotbs1 including contents and datafiles;

error:

ORA-01548: 已找到活动回退段’_SYSSMU1$’,终止删除表空间


查看回滚段状态:

SYS@prod>select segment_name,status from dba_rollback_segs;

SEGMENT_NAME                 STATUS

  SYSTEM         ONLINE

_SYSSMU10_1197734989$ NEEDS RECOVERY

_SYSSMU9_1650507775$ NEEDS RECOVERY

_SYSSMU8_517538920$   NEEDS RECOVERY

_SYSSMU7_2070203016$ NEEDS RECOVERY

_SYSSMU6_1263032392$ NEEDS RECOVERY

_SYSSMU5_898567397$   NEEDS RECOVERY

_SYSSMU4_1254879796$ NEEDS RECOVERY

_SYSSMU3_1723003836$ NEEDS RECOVERY

_SYSSMU2_2996391332$ NEEDS RECOVERY

_SYSSMU1_3724004606$ NEEDS RECOVERY


修改隐藏参数:

SYS@prod>alter system set “_offline_rollback_segments”=true scope=spfile;

SYS@prod>alter system set “_corrupted_rollback_segments”=’_SYSSMU1_3724004606$ ‘,

’_SYSSMU2_2996391332$ ‘,’_SYSSMU3_1723003836$ ‘,

’_SYSSMU4_1254879796$ ‘,’_SYSSMU5_898567397$ ‘,

’_SYSSMU6_1263032392$ ‘,’_SYSSMU7_2070203016$ ‘,

’_SYSSMU8_517538920$ ‘,’_SYSSMU9_1650507775$ ‘,

’_SYSSMU10_1197734989$’ scope=spfile


SYS@prod>drop tablespace undotbs1 including contents and datafiles;


Tablespace dropped.


再次查看回滚段状态:

SYS@prod>select segment_name,status from dba_rollback_segs;


SEGMENT_NAME STATUS


SYSTEM              ONLINE

_SYSSMU30_260568829    $ ONLINE

_SYSSMU29_1074352905   $ ONLINE

_SYSSMU28_3910680688   $ ONLINE

_SYSSMU27_3692739459   $ ONLINE

_SYSSMU26_345096822    $ ONLINE

_SYSSMU25_2172562784   $ ONLINE

_SYSSMU24_109115100    $ ONLINE

_SYSSMU23_3673005684   $ ONLINE

_SYSSMU22_2483286186   $ ONLINE

_SYSSMU21_2267006838   $ ONLINE


可以校验数据,数据会被默认提交。

结论 open状态下,undo数据文件损坏,存在未提交活动的事务,恢复后,数据默认会提交。


场景4:

undo表空间文件丢失,无undo数据文件备份,不存在未提交的事务,无需recover情况恢复。

简单描述处理方法:

undo数据文件offline后,直接变为offline状态,不是recover状态。

直接创建新的undo表空间,修改undo_tablespace参数替换即可。

请使用浏览器的分享功能分享到微信等