今天由于客户现场异常断电,Oracle数据库又无法启动了,远程上去看看吧。
1.数据库只能mount,已经无法启动
SQL> select status from v$instance; STATUS ------------ MOUNTED SQL> ALTER DATABASE OPEN; ALTER DATABASE OPEN * ERROR at line 1: ORA-01589: must use RESETLOGS or NORESETLOGS option for database open
2.尝试recover和resetlogs open都不行
SQL> recover database; ORA-00283: recovery session canceled due to errors ORA-01610: recovery using the BACKUP CONTROLFILE option must be done SQL> ALTER DATABASE OPEN resetlogs; ALTER DATABASE OPEN resetlogs * ERROR at line 1: ORA-01113: file 1 needs media recovery ORA-01110: data file 1: 'D:APPORACLEORADATAPRJDBSYSTEM01.DBF'
3.Alert log 显示错误
~~~~~~~~~~~~~~~~ Sun Jan 14 19:52:29 2018 ALTER DATABASE OPEN Beginning crash recovery of 1 threads parallel recovery started with 3 processes ...... Started redo scan Completed redo scan read 2300 KB redo, 0 data blocks need recovery Errors in file d:apporaclediagrdbmsprjdbprjdbtraceprjdb_ora_1644.trc (incident=315209): ORA-00600: internal error code, arguments: [kcratr_nab_less_than_odr], [1], [29904], [4864], [4870], [], [], [], [], [], [], [] Incident details in: d:apporaclediagrdbmsprjdbprjdbincidentincdir_315209prjdb_ora_1644_i315209.trc Aborting crash recovery due to error 600 Errors in file d:apporaclediagrdbmsprjdbprjdbtraceprjdb_ora_1644.trc: ORA-00600: internal error code, arguments: [kcratr_nab_less_than_odr], [1], [29904], [4864], [4870], [], [], [], [], [], [], [] Errors in file d:apporaclediagrdbmsprjdbprjdbtraceprjdb_ora_1644.trc: ORA-00600: internal error code, arguments: [kcratr_nab_less_than_odr], [1], [29904], [4864], [4870], [], [], [], [], [], [], [] ORA-600 signalled during: ALTER DATABASE OPEN... ~~~~~~~~~~~~~~~~~~~
4.结合ALERT里的错误ORA-00600: internal error code, arguments: [kcratr_nab_less_than_odr], [1], [29904], [4864], [4870],是由于服务器异常断电,导致LGWR写redo log时失败, 下次重新启动数据库时,需要做实例级恢复,而又无法从联机日志文件里获取到这些redo信息,因为上次断电时,写日志失败了。
5.那么ORA-00600的错误里,那几个参数 [1], [29904], [4864], [4870]的含义是,实例需要恢复sequence为29904的redo文件,需要恢复到编号为4870的日志块,而实际上只能恢复到第4864个日志块儿,所以数据库就不能正常启动。
6.那我们怎么办呢?先检查一下控制文件和datafile记录的checkpoint_change#信息吧。
数据文件检查点(记录在控制文件中)
SQL> select file#,checkpoint_change#,last_change# from v$datafile where rownum<5; FILE# CHECKPOINT_CHANGE# LAST_CHANGE# ---------- ------------------ ------------ 1 664629049 2 664629049 3 664629049 4 664629049
系统检查点(记录在控制文件中)
SQL> select checkpoint_change# from v$database; CHECKPOINT_CHANGE# ---------- ------------------ ------------ 664607310
数据文件头检查点(记录在数据文件中)
SQL> select file#,checkpoint_change# from v$datafile_header where rownum<5; FILE# CHECKPOINT_CHANGE# ---------- ------------------ 1 664629049 2 664629049 3 664629049 4 664629049
-7. 以上三个checkpoint_change#要一致(只读、脱机表空间除外),数据库才能正常打开。否则会需要进行一步的处理。正常关库时,会生成新的检查点,写入上述三个checkpoint_change#,同时数据文件中的last_change#也会记录下该检查点,也就是说三个checkpoint_change#与last_change#记录着同一个值。
-8. 通过上面的错误,以及checkpoint_change#的不一致,已经可以确认,就是控制文件,由于断电。导致的controlfile损坏(checkpoint_change#不一致)。
-9. 由于没有备份,我们只能通过重建controlfile的方式,来解决这个问题。
指定trace文件的生成路径 SQL> alter database backup controlfile to trace as '/tmp/controlfile.trc';
生成文件提取建库脚本如下,启动数据库到nomount状态,执行下面脚本。 注意:类似的恢复操作,先将现有的数据库进行备份。即使这个数据库已经无法启动。我们也要防止恢复操作导致的更严重的问题。
CREATE CONTROLFILE REUSE DATABASE "PRJDB" NORESETLOGS FORCE LOGGING ARCHIVELOG MAXLOGFILES 16 MAXLOGMEMBERS 3 MAXDATAFILES 200 MAXINSTANCES 8 MAXLOGHISTORY 584 LOGFILE GROUP 1 'D:APPORACLEORADATAPRJDBREDO01.LOG' SIZE 50M BLOCKSIZE 512, GROUP 2 'D:APPORACLEORADATAPRJDBREDO02.LOG' SIZE 50M BLOCKSIZE 512, GROUP 3 'D:APPORACLEORADATAPRJDBREDO03.LOG' SIZE 50M BLOCKSIZE 512 DATAFILE 'D:APPORACLEORADATAPRJDBSYSTEM01.DBF', 'D:APPORACLEORADATAPRJDBSYSAUX01.DBF', 'D:APPORACLEORADATAPRJDBUNDOTBS01.DBF', 'D:APPORACLEORADATAPRJDBUSERS01.DBF' CHARACTER SET US7ASCII;
-10. 检查数据库状态
SQL> select status from v$instance; STATUS ------ ----- - MOUNTED
-11. 尝试重启一下,看到是需要恢复的(其实我是知道这样起不来的,但是就像任性的看看报错)。
SQL> alter database open; alter database open * ERROR at line 1: ORA-01113: file 1 needs media recovery ORA-01110: data file 1: 'D:APPORACLEORADATAPRJDBSYSTEM01.DBF'
-12. 恢复数据库,其实啥也没做,recover就是走个过场,但是必须得走这个流程。
SQL> recover database; Media recovery complete.
11.启动数据库,成功
SQL> alter database open; Database altered. SQL> select status from v$instance; STATUS --- -------- OPEN
12.再看看checkpoint_change#值,统一了吧。 SQL> select file#,checkpoint_change#,last_change# from v$datafile where rownum<5; FILE# CHECKPOINT_CHANGE# LAST_CHANGE# ---------- ------------------ ------------ 1 664649053 2 664649053 3 664649053 4 664649053
SQL> select checkpoint_change# from v$database; CHECKPOINT_CHANGE# ------------------ 664649053
SQL> select file#,checkpoint_change# from v$datafile_header where rownum<5; FILE# CHECKPOINT_CHANGE# ---------- ------------------ 1 664649053 2 664649053 3 664649053 4 664649053
最后,再唠叨一下,备份真的很重要!很简单!没有备份的数据库,不单单是裸奔那么简单!不出问题,丢人!出问题,伤身啊!!
如何重建控制文件,请参考:https://www.linuxidc.com/Linux/2018-03/151561.htm