介紹
控制文件(control file)是一個(gè)相當(dāng)小的文件(最多能增長(zhǎng)到64M左右),其中包含Oracle需要的其他文件的一個(gè)目錄。參數(shù)文件告知實(shí)例控制文件的位置,控制文件則告知示例數(shù)據(jù)庫(kù)和在線重做日志文件的位置??刂莆募€告知了Oracle其他一些事情,如已發(fā)生檢查點(diǎn)的有關(guān)信息、數(shù)據(jù)庫(kù)名(必須和db_name參數(shù)匹配)、創(chuàng)建數(shù)據(jù)庫(kù)的時(shí)間戳、歸檔重做日志的歷史(有時(shí)這會(huì)讓控制文件變大)、RMAN信息等。
控制文件應(yīng)該通過硬件(RAID)多路保存,如果不支持鏡像,則要通過Oracle多路保存。應(yīng)該有不止一個(gè)副本,而且它們應(yīng)該保存在不同的磁盤上,以防止萬一出現(xiàn)磁盤故障而丟失控制文件。丟失控制文件并不是致命的,但是會(huì)使恢復(fù)變得困難很多。
如果丟失了所有的控制文件并且沒有任何的備份,我們可以通過重建控制文件來打開數(shù)據(jù)庫(kù)。其中,重建控制文件至少需要以下信息:
1.數(shù)據(jù)庫(kù)名
2.字符集
3.數(shù)據(jù)文件名稱
4.初始化參數(shù),包括MAXLOGFILES、MAXLOGMEMBERS、MAXDATAFILES、MAXINSTANCES、MAXLOGHISTORY等;
一、環(huán)境準(zhǔn)備
數(shù)據(jù)庫(kù)版本
我們?cè)贠racle11g中進(jìn)行測(cè)試。
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初始化參數(shù),獲取控制文件路徑;
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.此時(shí),強(qiáng)制關(guān)閉數(shù)據(jù)庫(kù),然后重啟數(shù)據(jù)庫(kù),報(bào)ORA-00205錯(cuò)誤。需要注意的是,此時(shí)執(zhí)行shutdown immediate命令,數(shù)據(jù)庫(kù)無法正常關(guān)閉,只能關(guān)閉到mounted狀態(tài);需要使用shutdown abort命令強(qiáng)制關(guān)閉數(shù)據(jù)庫(kù)。
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>
二、獲取數(shù)據(jù)庫(kù)名
首先生成文本格式的參數(shù)文件;
SQL>
SQL> create pfile from spfile;
File created.
SQL>
打開參數(shù)文件,查看db_name參數(shù)值,即為數(shù)據(jù)庫(kù)名稱。
[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]$
三、啟動(dòng)到nomount狀態(tài),獲取字符集
由于需要執(zhí)行查詢語句select userenv('language') from dual;來獲取字符集,因此需要將數(shù)據(jù)庫(kù)啟動(dòng)到nomount狀態(tài)。
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>
四、獲取數(shù)據(jù)文件名稱
通過ls命令獲取數(shù)據(jù)文件列表。
[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]$
五、生成創(chuàng)建控制文件腳本
這樣,創(chuàng)建控制文件所需的基本信息都已經(jīng)有了,我們來生成創(chuàng)建控制文件腳本。
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
;
六、重建控制文件
需要注意的是,在執(zhí)行上述創(chuàng)建腳本時(shí)會(huì)報(bào)錯(cuò),系統(tǒng)提示臨時(shí)文件不屬于數(shù)據(jù)文件,如下所示:
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>
修改腳本并重新執(zhí)行,重建控制文件后,數(shù)據(jù)庫(kù)會(huì)打開到mount狀態(tài)。
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>
七、打開數(shù)據(jù)庫(kù)
在打開數(shù)據(jù)庫(kù)時(shí),會(huì)報(bào)錯(cuò),提示system01數(shù)據(jù)文件需要執(zhí)行介質(zhì)恢復(fù),我們執(zhí)行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>
下面總結(jié)一下重建控制文件的步驟:
1.獲取數(shù)據(jù)庫(kù)名;
2.獲取字符集名;
3.獲取數(shù)據(jù)文件名;
4.重建控制文件;
5.執(zhí)行介質(zhì)恢復(fù);
6.打開數(shù)據(jù)庫(kù)。
總結(jié)
以上就是這篇文章的全部?jī)?nèi)容了,希望本文的內(nèi)容對(duì)大家的學(xué)習(xí)或者工作能帶來一定的幫助,如果有疑問大家可以留言交流,謝謝大家對(duì)腳本之家的支持。
您可能感興趣的文章:- Oracle數(shù)據(jù)庫(kù)中的控制文件管理以及常用參數(shù)設(shè)置
- Oracle RMAN自動(dòng)備份控制文件方法介紹
- Oracle重建控制文件的實(shí)例教程