客服微信
本文为云贝教育 刘峰 原创,请尊重知识产权,转发请注明出处,不接受任何抄袭、演绎和未经注明出处的转载。
每个Oracle数据库都有一个控制文件,它是一个小的二进制文件,记录了数据库的物理结构。
The control file includes:
• The database name-->数据库名称 • Names and locations of associated data files and redo log files -->数据文件和日志文件的路径 • The timestamp of the database creation -->数据库创建的时间 • The current log sequence number -->当前日志的序列号 • Checkpoint information -->数据库检查点信息
Oracle数据库的控制文件是与数据库同时创建的。默认情况下,在创建数据库期间至少创建控制文件的一个副本。在某些操作系统上,默认是创建多个副本。在创建数据库期间,应该创建控制文件的两个或多个副本。如果丢失了控制文件或希望更改控制文件中的特定设置,也可以稍后创建控制文件。
1) 查看当前数据库的控制文件(pdb和cdb共享)
SYS@ORCLCDB> show parameter control_files NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ control_files string /opt/oracle/oradata/ORCLCDB/co ntrol01.ctl, /opt/oracle/orada ta/ORCLCDB/control02.ctl SYS@ORCLCDB> select name from v$controlfile; NAME -------------------------------------------------------------------------------- /opt/oracle/oradata/ORCLCDB/control01.ctl /opt/oracle/oradata/ORCLCDB/control02.ctl
2) 修改控制文件多路复用
1、修改参数 SYS@ORCLCDB>alter system set control_files='/opt/oracle/oradata/ORCLCDB/control01.ctl', '/opt/oracle/oradata/ORCLCDB/control02.ctl','/opt/oracle/oradata/ORCLCDB/control03.ctl' scope=spfile; 2、关闭数据库 SYS@ORCLCDB> shutdown immediate; Database closed. Database dismounted. ORACLE instance shut down. 3、操作系统上CP控制文件 [oracle@database ORCLCDB]$ cp control01.ctl control03.ctl 4、启动数据库 SYS@ORCLCDB> startup;
提问:如果误将改控制文件参数改成如下格式,如何通过修改参数文件将数据库OPEN
1、修改控制文件参数 alter system set control_files='/opt/oracle/oradata/ORCLCDB/control01.ctl', '/opt/oracle/oradata/ORCLCDB/control02.ctl','/opt/oracle/oradata/ORCLCDB/control03ctl' scope=spfile; 2、而实际3号控制文件是这样的 [oracle@database ORCLCDB]$ ll total 2715912 -rw-r----- 1 oracle oinstall 18726912 Jul 6 02:32 control01.ctl -rw-r----- 1 oracle oinstall 18726912 Jul 6 02:32 control02.ctl -rw-r----- 1 oracle oinstall 18726912 Jul 6 02:34 control03.ctl-->参数文件里是control03ctl
格意义上来说,不是针对控制文件的备份,而是根据现在系统情况生成了一份 trace文件,这个 trace 文件中记录了创建控制文件的基本信息。
1、CDB下执行,PDB无法执行 SQL> alter database backup controlfile to trace;
上面这句话生成的 trace 文件在 dump 里面,可以通过告警日志查看。
2023-07-06T07:23:56.772531-07:00 alter database backup controlfile to trace 2023-07-06T07:23:56.856692-07:00 Backup controlfile written to trace file /opt/oracle/diag/rdbms/orclcdb/ORCLCDB/trace/ORCLCDB_ora_16999.trc Completed: alter database backup controlfile to trace
具体内容见附件
CREATE CONTROLFILE REUSE DATABASE "ORCLCDB" NORESETLOGS NOARCHIVELOG MAXLOGFILES 16 MAXLOGMEMBERS 3 MAXDATAFILES 1024 MAXINSTANCES 8 MAXLOGHISTORY 292 LOGFILE GROUP 1 '/opt/oracle/oradata/ORCLCDB/redo01.log' SIZE 200M BLOCKSIZE 512, GROUP 2 '/opt/oracle/oradata/ORCLCDB/redo02.log' SIZE 200M BLOCKSIZE 512, GROUP 3 '/opt/oracle/oradata/ORCLCDB/redo03.log' SIZE 200M BLOCKSIZE 512 -- STANDBY LOGFILE DATAFILE '/opt/oracle/oradata/ORCLCDB/system01.dbf', '/opt/oracle/oradata/ORCLCDB/sysaux01.dbf', '/opt/oracle/oradata/ORCLCDB/undotbs01.dbf', '/opt/oracle/oradata/ORCLCDB/pdbseed/system01.dbf', '/opt/oracle/oradata/ORCLCDB/pdbseed/sysaux01.dbf', '/opt/oracle/oradata/ORCLCDB/users01.dbf', '/opt/oracle/oradata/ORCLCDB/pdbseed/undotbs01.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/system01.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/sysaux01.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/undotbs01.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/users01.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/tbs_t201.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/tbs_big01.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/ORCLCDB/FE8CF63D04B91F62E053814AA8C03B8A/datafile/o1_mf_tbs_d_l9qy2qvq_.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/ORCLCDB/FE8CF63D04B91F62E053814AA8C03B8A/datafile/o1_mf_tbs_data_l9qz094v_.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/ORCLCDB/FE8CF63D04B91F62E053814AA8C03B8A/datafile/o1_mf_tbs_idx_l9qz0jbq_.dbf', '/opt/oracle/product/19c/dbhome_1/dbs/shadow_lwp1_df', '/opt/oracle/oradata/ORCLCDB/test1.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/ORCLCDB/FE8CF63D04B91F62E053814AA8C03B8A/datafile/o1_mf_tbs_16k_l9thkbf9_.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/ORCLCDB/FE8CF63D04B91F62E053814AA8C03B8A/datafile/o1_mf_tbs1_l9y26m6z_.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/ORCLCDB/FE8CF63D04B91F62E053814AA8C03B8A/datafile/o1_mf_tbs2_l9y3f1bt_.dbf' CHARACTER SET AL32UTF8 ;
这种方式是针对控制文件的热备份。
--CDB下执行 SYS@ORCLCDB> alter database backup controlfile to '/home/oracle/ctl.bak'; Database altered.
模拟单个控制文件损坏,删除其中一个控制文件。数据库无法启动。
方案有两种:1、直接复制多路复用中的其他控制文件 2、通过pfile修改控制文件的参数,将损坏的控制文件删掉
1、单个控制文件丢失或损坏
1)、通过OS层复制参数文件
1、关闭数据库 SYS@ORCLCDB> shutdown immediate; Database closed. Database dismounted. ORACLE instance shut down. 2、删除其中一个控制文件 [oracle@database ORCLCDB]$ rm control03.ctl 3、启动数据库失败 SYS@ORCLCDB> startup ORACLE instance started. Total System Global Area 759166168 bytes Fixed Size 9139416 bytes Variable Size 583008256 bytes Database Buffers 58720256 bytes Redo Buffers 3440640 bytes In-Memory Area 104857600 bytes ORA-00205: error in identifying control file, check alert log for more info 4、具体报错如下,提示3号文件未找到 ALTER DATABASE MOUNT 2023-07-06T08:05:16.072594-07:00 ORA-00210: cannot open the specified control file ORA-00202: control file: '/opt/oracle/oradata/ORCLCDB/control03ctl' ORA-27037: unable to obtain file status Linux-x86_64 Error: 2: No such file or directory Additional information: 7 ORA-205 signalled during: ALTER DATABASE MOUNT... 2023-07-06T08:05:16.144178-07:00 Errors in file /opt/oracle/diag/rdbms/orclcdb/ORCLCDB/trace/ORCLCDB_mz00_17712.trc: ORA-00202: control file: '/opt/oracle/oradata/ORCLCDB/control03ctl' ORA-27037: unable to obtain file status Linux-x86_64 Error: 2: No such file or directory Additional information: 7 5、复制一个控制文件 [oracle@database ORCLCDB]$ cp control01.ctl control03.ctl 6、再次启动数据库成功
2)、通过pfile修改控制文件
1、关闭数据库 SYS@ORCLCDB> shutdown immediate; Database closed. Database dismounted. ORACLE instance shut down. 2、删除其中一个控制文件 [oracle@database ORCLCDB]$ rm control03.ctl 3、启动数据库失败 SYS@ORCLCDB> startup ORACLE instance started. Total System Global Area 759166168 bytes Fixed Size 9139416 bytes Variable Size 583008256 bytes Database Buffers 58720256 bytes Redo Buffers 3440640 bytes In-Memory Area 104857600 bytes ORA-00205: error in identifying control file, check alert log for more info 4、创建pfile,修改参数文件 SYS@ORCLCDB> create pfile from spfile; File created [oracle@database dbs]$cd /opt/oracle/product/19c/dbhome_1/dbs --修改参数文件vi initORCLCDB.ora 将损坏的参数文件删除 *.control_files='/opt/oracle/oradata/ORCLCDB/control01.ctl','/opt/oracle/oradata/ORCLCDB/control02.ctl' 5、以pfile启动数据库 startup pfile='/opt/oracle/product/19c/dbhome_1/dbs/initORCLCDB.ora'
1、日志文件名称,体积和块大小 2、所有的dbf文件 3、数据库的名称和字符集 CREATE CONTROLFILE REUSE DATABASE "ORCLCDB" NORESETLOGS NOARCHIVELOG MAXLOGFILES 16 MAXLOGMEMBERS 3 MAXDATAFILES 1024 MAXINSTANCES 8 MAXLOGHISTORY 292 LOGFILE GROUP 1 '/opt/oracle/oradata/ORCLCDB/redo01.log' SIZE 200M BLOCKSIZE 512, GROUP 2 '/opt/oracle/oradata/ORCLCDB/redo02.log' SIZE 200M BLOCKSIZE 512, GROUP 3 '/opt/oracle/oradata/ORCLCDB/redo03.log' SIZE 200M BLOCKSIZE 512 -- STANDBY LOGFILE DATAFILE '/opt/oracle/oradata/ORCLCDB/system01.dbf', '/opt/oracle/oradata/ORCLCDB/sysaux01.dbf', '/opt/oracle/oradata/ORCLCDB/undotbs01.dbf', '/opt/oracle/oradata/ORCLCDB/pdbseed/system01.dbf', '/opt/oracle/oradata/ORCLCDB/pdbseed/sysaux01.dbf', '/opt/oracle/oradata/ORCLCDB/users01.dbf', '/opt/oracle/oradata/ORCLCDB/pdbseed/undotbs01.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/system01.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/sysaux01.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/undotbs01.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/users01.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/tbs_t201.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/tbs_big01.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/ORCLCDB/FE8CF63D04B91F62E053814AA8C03B8A/datafile/o1_mf_tbs_d_l9qy2qvq_.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/ORCLCDB/FE8CF63D04B91F62E053814AA8C03B8A/datafile/o1_mf_tbs_data_l9qz094v_.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/ORCLCDB/FE8CF63D04B91F62E053814AA8C03B8A/datafile/o1_mf_tbs_idx_l9qz0jbq_.dbf', '/opt/oracle/product/19c/dbhome_1/dbs/shadow_lwp1_df', '/opt/oracle/oradata/ORCLCDB/test1.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/ORCLCDB/FE8CF63D04B91F62E053814AA8C03B8A/datafile/o1_mf_tbs_16k_l9thkbf9_.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/ORCLCDB/FE8CF63D04B91F62E053814AA8C03B8A/datafile/o1_mf_tbs1_l9y26m6z_.dbf', '/opt/oracle/oradata/ORCLCDB/ORCLPDB1/ORCLCDB/FE8CF63D04B91F62E053814AA8C03B8A/datafile/o1_mf_tbs2_l9y3f1bt_.dbf' CHARACTER SET AL32UTF8 ;