您好,欢迎访问一九零五行业门户网

【Oracle】undo损坏,无备份非常规恢复

客户的一个测试环境,主机异常断电,启动后发现undo文件损坏,无法启动,在open阶段报错如下: errors in file /u01/app/oracle/diag/rdbms/cdrdb/cdrdb/trace/cdrdb_ora_4109.trc: ora-01122: database file 3 failed verification check ora-01110: data f
客户的一个测试环境,主机异常断电,启动后发现undo文件损坏,无法启动,在open阶段报错如下:
errors in file /u01/app/oracle/diag/rdbms/cdrdb/cdrdb/trace/cdrdb_ora_4109.trc:
ora-01122: database file 3 failed verification check
ora-01110: data file 3: '/u01/app/oracle/oradata/cdrdb/undotbs01.dbf'
ora-01210: data file header is media corrupt
ora-1122 signalled during: alter database open...
由于是测试环境,没有备份,但是又需要里边的一些数据,所以我尝试使用非常规恢复方法进行了尝试。
先冷备份现有环境!!!!!!!!!!!!!!!!
创建pfile文件:
create pfile from spfile;
在pfile中修改这两个参数
#*.undo_tablespace='undotbs1'
*.undo_management= manual
之后用这个pfile启动:
sys@cdrdb>startup force pfile='/u01/app/oracle/product/11.2.0/dbhome_1/dbs/initcdrdb.ora';
oracle instance started.
total system global area  523108352 bytes
fixed size                  1337632 bytes
variable size             364906208 bytes
database buffers          150994944 bytes
redo buffers                5869568 bytes
database mounted.
ora-01122: database file 3 failed verification check
ora-01110: data file 3: '/u01/app/oracle/oradata/cdrdb/undotbs01.dbf'
ora-01210: data file header is media corrupt
仍然报错
之后尝试drop掉这个undo
sys@cdrdb>alter database datafile 3 offline drop;
database altered.
之后重新开库
sys@cdrdb>alter database open;
database altered.
之后创建新的undo表空间undotbs2
sys@cdrdb>create undo tablespace undotbs2 datafile '/u01/app/oracle/oradata/cdrdb/undotbs02_01.dbf' size 100m;
create undo tablespace undotbs2 datafile '/u01/app/oracle/oradata/cdrdb/undotbs02_01.dbf' size 100m
*
error at line 1:
ora-00604: error occurred at recursive sql level 1
ora-01552: cannot use system rollback segment for non-system tablespace
'data_ol'
ora-06512: at line 999
ora-01552: cannot use system rollback segment for non-system tablespace
'data_ol'
产生报错如上
比较疑惑创建undo为什么会影响到data_ol表空间,所以做了个10046
sys@cdrdb>oradebug event 10046 trace name context off
statement processed.
sys@cdrdb>oradebug tracefile_name
/u01/app/oracle/diag/rdbms/cdrdb/cdrdb/trace/cdrdb_ora_4279.trc
[oracle@centos-1 ~]$ tkprof /u01/app/oracle/diag/rdbms/cdrdb/cdrdb/trace/cdrdb_ora_4279.trc
output = 1.trm
查看1.trm,发现了原因:
  ogg.ddlreplication.dbqueried is null then
                select database_role,
  open_mode
                into dbrole, dbopenmode
                from v$database;
ogg.ddlreplication.dbqueried := true;
              end if;
                if not (
^@                      (dbrole = 'primary' or dbrole = 'logical standby')
                        and dbopenmode =
  'read write'
                        )
                        then
                        -- do not write any trace even though it
  should work as this is standby
                        ogg
  .ddlreplication.setctxinfo(-1,-1,-1,-1,-1);
                        return; -- do not use
  trigger if not read/write and primary/logical_standby
                end if;
        exception
......略
原来是因为这个库配置过ogg的ddl同步,有ddl产生时会产生insert操作,使用data_ol表空间。
原因找到~  跑脚本关闭该库ogg的ddl配置即可
sys@cdrdb>@ddl_disable.sql
trigger altered.
之后再重新创建undotbs2表空间
sys@cdrdb>create undo tablespace undotbs2 datafile '/u01/app/oracle/oradata/cdrdb/undotbs02_01.dbf' size 1000m;
tablespace created.
这次很顺利的添加成功。
undotbs2添加完毕,接下来关闭数据库,修改pfile参数
*.undo_tablespace='undotbs2'
*.undo_management=auto
重启数据库用pfile启动
sys@cdrdb>startup pfile='/u01/app/oracle/product/11.2.0/dbhome_1/dbs/initcdrdb.ora';
oracle instance started.
total system global area  523108352 bytes
fixed size                  1337632 bytes
variable size             364906208 bytes
database buffers          150994944 bytes
redo buffers                5869568 bytes
database mounted.
database opened.
数据库成功启动,然而在很多业务表查询时依然会报错:
error at line 1:
ora-00376: file 3 cannot be read at this time
ora-01110: data file 3: '/u01/app/oracle/oradata/cdrdb/undotbs01.dbf'
依然需要原来的undotbs01.dbf回滚数据库崩溃时未提交的事务
之后我先尝试了设置event 10513,来屏蔽smon的回滚
sys@cdrdb>alter system set events '10513 trace name context forever, level 2';
system altered.
发现还是会报之前的错误,看来需要自己手工去屏蔽回滚段了。
sys@cdrdb>select segment_name,status from dba_rollback_segs;
segment_name                   status
------------------------------ ----------------
system                         online
_syssmu10_4131489474$          needs recovery
_syssmu9_1735643689$           needs recovery
_syssmu8_3901294357$           needs recovery
_syssmu7_3517345427$           needs recovery
_syssmu6_2897970769$           needs recovery
_syssmu5_538557934$            needs recovery
_syssmu4_1003442803$           needs recovery
_syssmu3_1204390606$           needs recovery
_syssmu2_967517682$            needs recovery
_syssmu1_592353410$            needs recovery
segment_name                   status
------------------------------ ----------------
_syssmu30_244658789$           online
_syssmu29_1020880693$          online
_syssmu28_2912622077$          online
_syssmu27_747253598$           online
_syssmu26_560868814$           online
_syssmu25_1357066082$          online
_syssmu24_103440716$           online
_syssmu23_1006903361$          online
_syssmu22_2808190508$          online
_syssmu21_39626587$            online
21 rows selected.
之后把查询到的needs recovery的表加到以下两个参数中,屏蔽这些回滚段
_offline_rollback_segments/_corrupted_rollback_segments参数
*._offline_rollback_segments=(_syssmu10_4131489474$,_syssmu9_1735643689$,_syssmu8_3901294357$,_syssmu7_3517345427$,_syssmu6_2897970769$,_syssmu5_538557934$,_syssmu4_1003442803$,_syssmu3_1204390606$,_syssmu2_967517682$,_syssmu1_592353410$)
*._corrupted_rollback_segments=(_syssmu10_4131489474$,_syssmu9_1735643689$,_syssmu8_3901294357$,_syssmu7_3517345427$,_syssmu6_2897970769$,_syssmu5_538557934$,_syssmu4_1003442803$,_syssmu3_1204390606$,_syssmu2_967517682$,_syssmu1_592353410$)
使用这个pfile启动数据库
startup force pfile='/u01/app/oracle/product/11.2.0/dbhome_1/dbs/initcdrdb.ora';
之后对那些测试表都查询了一下,确认可以查询,之后导出帮他们导出数据,一切ok~
其它类似信息

推荐信息