控制文件(control file)是一个相当小的文件(最多能增长到64M左右),其中包含Oracle需要的其他文件的一个目录。参数文件告知实例控制文件的位置,控制文件则告知示例数据库和在线重做日志文件的位置。控制文件还告知了Oracle其他一些事情,如已发生检查点的有关信息、数据库名(必须和db_name参数匹配)、创建数据库的时间戳、归档重做日志的历史(有时这会让控制文件变大)、RMAN信息等。
控制文件应该通过硬件(RAID)多路保存,如果不支持镜像,则要通过Oracle多路保存。应该有不止一个副本,而且它们应该保存在不同的磁盘上,以防止万一出现磁盘故障而丢失控制文件。丢失控制文件并不是致命的,但是会使恢复变得困难很多。
如果丢失了所有的控制文件并且没有任何的备份,我们可以通过重建控制文件来打开数据库。其中,重建控制文件至少需要以下信息:
1.数据库名
2.字符集
3.数据文件名称
4.初始化参数,包括MAXLOGFILES、MAXLOGMEMBERS、MAXDATAFILES、MAXINSTANCES、MAXLOGHISTORY等;
1.环境准备
数据库版本
我们在Oracle11g中进行测试。
-
SQL>
-
SQL> select * from v$version;
-
-
BANNER
-
--------------------------------------------------------------------------------
-
Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - Production
-
PL/SQL Release 11.2.0.3.0 - Production
-
CORE 11.2.0.3.0 Production
-
TNS for Linux: Version 11.2.0.3.0 - Production
-
NLSRTL Version 11.2.0.3.0 - Production
-
-
SQL>
删除控制文件
1.通过查询control_files初始化参数,获取控制文件路径;
-
SQL>
-
SQL> show parameter control_files
-
-
NAME TYPE VALUE
-
------------------------------------ ----------- ------------------------------
-
control_files string /u01/app/oracle/oradata/HOEGH/
-
control01.ctl, /u01/app/oracle
-
/oradata/HOEGH/control02.ctl
-
SQL>
2.然后,使用rm命令删除控制文件;
-
[oracle@HOEGH ~]$ rm /u01/app/oracle/oradata/HOEGH/control01.ctl
-
[oracle@HOEGH ~]$ rm /u01/app/oracle/oradata/HOEGH/control02.ctl
-
[oracle@HOEGH ~]$
3.此时,强制关闭数据库,然后重启数据库,报ORA-00205错误。需要注意的是,此时执行shutdown immediate命令,数据库无法正常关闭,只能关闭到mounted状态;需要使用shutdown abort命令强制关闭数据库。
-
SQL>
-
SQL> shutdown immediate
-
Database closed.
-
ORA-00210: cannot open the specified control file
-
ORA-00202: control file: \'/u01/app/oracle/oradata/HOEGH/control01.ctl\'
-
ORA-27041: unable to open file
-
Linux Error: 2: No such file or directory
-
Additional information: 3
-
-
-
SQL> select status from v$instance;
-
-
STATUS
-
------------
-
MOUNTED
-
-
SQL>
-
SQL> shutdown abort
-
ORACLE instance shut down.
-
SQL>
-
-
-
-
SQL>
-
SQL> startup
-
ORACLE instance started.
-
-
Total System Global Area 941600768 bytes
-
Fixed Size 1348860 bytes
-
Variable Size 515902212 bytes
-
Database Buffers 419430400 bytes
-
Redo Buffers 4919296 bytes
-
ORA-00205: error in identifying control file, check alert log for more info
-
-
-
SQL>
2.获取数据库名
首先生成文本格式的参数文件;
-
SQL>
-
SQL> create pfile from spfile;
-
-
File created.
-
-
SQL>
打开参数文件,查看db_name参数值,即为数据库名称。
-
[oracle@hoegh dbs]$ cat initHOEGH.ora
-
HOEGH.__db_cache_size=419430400
-
HOEGH.__java_pool_size=4194304
-
HOEGH.__large_pool_size=4194304
-
HOEGH.__oracle_base=\'/u01/app/oracle\'#ORACLE_BASE set from environment
-
HOEGH.__pga_aggregate_target=377487360
-
HOEGH.__sga_target=566231040
-
HOEGH.__shared_io_pool_size=0
-
HOEGH.__shared_pool_size=130023424
-
HOEGH.__streams_pool_size=0
-
*.audit_file_dest=\'/u01/app/oracle/admin/HOEGH/adump\'
-
*.audit_trail=\'db\'
-
*.compatible=\'11.2.0.0.0\'
-
*.control_files=\'/u01/app/oracle/oradata/HOEGH/control01.ctl\',\'/u01/app/oracle/oradata/HOEGH/control02.ctl\'
-
*.db_block_size=8192
-
*.db_domain=\'\'
-
*.db_name=\'HOEGH\'
-
*.diagnostic_dest=\'/u01/app/oracle\'
-
*.dispatchers=\'(PROTOCOL=TCP) (SERVICE=HOEGHXDB)\'
-
*.memory_max_target=943718400
-
*.memory_target=943718400
-
*.open_cursors=300
-
*.processes=150
-
*.remote_login_passwordfile=\'EXCLUSIVE\'
-
*.undo_tablespace=\'UNDOTBS1\'
-
[oracle@hoegh dbs]$
3.启动到nomount状态,获取字符集
由于需要执行查询语句select userenv('language') from dual;来获取字符集,因此需要将数据库启动到nomount状态。
-
SQL>
-
SQL> startup nomount
-
ORACLE instance started.
-
-
Total System Global Area 941600768 bytes
-
Fixed Size 1348860 bytes
-
Variable Size 515902212 bytes
-
Database Buffers 419430400 bytes
-
Redo Buffers 4919296 bytes
-
SQL>
-
SQL> select userenv(\'language\') from dual;
-
-
USERENV(\'LANGUAGE\')
-
----------------------------------------------------
-
AMERICAN_AMERICA.US7ASCII
-
-
SQL>
-
SQL>
4.获取数据文件名称
通过ls命令获取数据文件列表。
-
[oracle@hoegh HOEGH]$ ls -lh
-
total 1.8G
-
-rw-r----- 1 oracle oinstall 314M May 30 11:07 example01.dbf
-
-rw-r----- 1 oracle oinstall 51M May 30 11:07 redo01.log
-
-rw-r----- 1 oracle oinstall 51M May 30 11:07 redo02.log
-
-rw-r----- 1 oracle oinstall 51M May 30 11:07 redo03.log
-
-rw-r----- 1 oracle oinstall 541M May 30 11:07 sysaux01.dbf
-
-rw-r----- 1 oracle oinstall 721M May 30 11:07 system01.dbf
-
-rw-r----- 1 oracle oinstall 30M Oct 13 2014 temp01.dbf
-
-rw-r----- 1 oracle oinstall 96M May 30 11:07 undotbs01.dbf
-
-rw-r----- 1 oracle oinstall 5.1M May 30 11:07 users01.dbf
-
[oracle@hoegh HOEGH]$
5.生成创建控制文件脚本
这样,创建控制文件所需的基本信息都已经有了,我们来生成创建控制文件脚本。
-
STARTUP NOMOUNT
-
CREATE CONTROLFILE REUSE DATABASE \"HOEGH\" NORESETLOGS ARCHIVELOG
-
MAXLOGFILES 5
-
MAXLOGMEMBERS 3
-
MAXDATAFILES 100
-
MAXINSTANCES 1
-
MAXLOGHISTORY 226
-
LOGFILE
-
GROUP 1 \'/u01/app/oracle/oradata/HOEGH/redo01.log\' SIZE 50M,
-
GROUP 2 \'/u01/app/oracle/oradata/HOEGH/redo02.log\' SIZE 50M,
-
GROUP 3 \'/u01/app/oracle/oradata/HOEGH/redo03.log\' SIZE 50M
-
DATAFILE
-
\'/u01/app/oracle/oradata/HOEGH/system01.dbf\',
-
\'/u01/app/oracle/oradata/HOEGH/sysaux01.dbf\',
-
\'/u01/app/oracle/oradata/HOEGH/undotbs01.dbf\',
-
\'/u01/app/oracle/oradata/HOEGH/users01.dbf\',
-
\'/u01/app/oracle/oradata/HOEGH/example01.dbf\',
-
\'/u01/app/oracle/oradata/HOEGH/temp01.dbf\'
-
CHARACTER SET US7ASCII
-
;
6.重建控制文件
需要注意的是,在执行上述创建脚本时会报错,系统提示临时文件不属于数据文件,如下所示:
-
SQL> @/u01/app/oracle/oradata/HOEGH/CreateControlFile.sql
-
ORA-01081: cannot start already-running ORACLE - shut it down first
-
CREATE CONTROLFILE REUSE DATABASE \"HOEGH\" NORESETLOGS ARCHIVELOG
-
*
-
ERROR at line 1:
-
ORA-01503: CREATE CONTROLFILE failed
-
ORA-01160: file is not a data file
-
ORA-01110: data file : \'/u01/app/oracle/oradata/HOEGH/temp01.dbf\'
-
-
-
SQL>
修改脚本并重新执行,重建控制文件后,数据库会打开到mount状态。
-
SQL>
-
SQL> @/u01/app/oracle/oradata/HOEGH/CreateControlFile.sql
-
ORACLE instance started.
-
-
Total System Global Area 941600768 bytes
-
Fixed Size 1348860 bytes
-
Variable Size 515902212 bytes
-
Database Buffers 419430400 bytes
-
Redo Buffers 4919296 bytes
-
-
Control file created.
-
-
SQL>
-
SQL> select status from v$instance;
-
-
STATUS
-
------------
-
MOUNTED
-
-
SQL>
7.打开数据库
在打开数据库时,会报错,提示system01数据文件需要执行介质恢复,我们执行recover database即可。
-
SQL>
-
SQL> alater database open;
-
SP2-0734: unknown command beginning \"alater dat...\" - rest of line ignored.
-
SQL>
-
SQL> alter database open;
-
alter database open
-
*
-
ERROR at line 1:
-
ORA-01113: file 1 needs media recovery
-
ORA-01110: data file 1: \'/u01/app/oracle/oradata/HOEGH/system01.dbf\'
-
-
-
SQL>
-
SQL> recover database;
-
Media recovery complete.
-
SQL>
-
SQL> alter database open;
-
-
Database altered.
-
-
SQL>
-
SQL> select * from v$version;
-
-
BANNER
-
--------------------------------------------------------------------------------
-
Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - Production
-
PL/SQL Release 11.2.0.3.0 - Production
-
CORE 11.2.0.3.0 Production
-
TNS for Linux: Version 11.2.0.3.0 - Production
-
NLSRTL Version 11.2.0.3.0 - Production
-
-
SQL>
-
SQL> select tablespace_name from dba_tablespaces;
TABLESPACE_NAME
------------------------------
SYSTEM
SYSAUX
UNDOTBS1
TEMP
USERS
EXAMPLE
6 rows selected.
SQL>
-
8.总结
下面总结一下重建控制文件的步骤:
1.获取数据库名;
2.获取字符集名;
3.获取数据文件名;
4.重建控制文件;
5.执行介质恢复;
6.打开数据库。
阅读(2135) | 评论(0) | 转发(0) |