In today’s article, I will be explaining what is Oracle Control File, its place in the operating system, how to back it up and what is kept.
Control File,
The name of our database,
Names and locations of Data Files,
Names and locations of online redo log files,
Sequence number of the online redo log file in use,
Checkpoint information,
If the database is in archive mode and backup is taken, the names and locations of the RMAN backup files,
It is a small binary file that stores the sequence numbers of the archive log files required for successful recovery of the backup.
Its extension is *.ctl. We can see where these files are in the operating system with the following command.
1 2 3 4 5 | [root@DBONUR ~]# locate *control*.ctl /oracle/ora11g/backup_ONURDB/control01.ctl /oracle/ora11g/backup_ONURDB/control02.ctl /oracle/ora11g/data_ONURDB/ONURDB/control01.ctl /oracle/ora11g/data_ONURDB/ONURDB/control02.ctl |
Control file content can only be viewed properly when backed up as a trace file. Trace file can also be backed up as follows.
1. SID information of the user logged into the database is learned.
1 2 3 4 5 | SQL> SELECT SID FROM V$SESSION WHERE USERNAME='SYS'; SID ---------- 131 |
2. We can back up the content of Control File as a trace file with the following command.,
1 2 3 | SQL> ALTER DATABASE BACKUP CONTROLFILE TO TRACE; Database altered. |
3. To find which trace file the backup is in, we run the following command.
1 2 3 4 5 | SQL> SELECT TRACEFILE FROM V$PROCESS JOIN V$SESSION ON (ADDR=PADDR) WHERE SID=131; TRACEFILE -------------------------------------------------------------------------------- /oracle/diag/rdbms/onurdb/ONURDB/trace/ONURDB_ora_9021.trc |
4. The contents of the trace file are opened with the vi text editor.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 | Trace file /oracle/diag/rdbms/onurdb/ONURDB/trace/ONURDB_ora_20802.trc Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, OLAP, Data Mining and Real Application Testing options ORACLE_HOME = /oracle/ora11g System name: Linux Node name: DBONUR Release: 2.6.18-348.el5 Version: #1 SMP Wed Nov 28 21:22:00 EST 2012 Machine: x86_64 VM name: VMWare Version: 6 Instance name: ONURDB Redo thread mounted by this instance: 1 Oracle process number: 22 Unix process pid: 20802, image: oracle@DBONUR *** 2015-06-26 17:12:10.345 *** SESSION ID:(129.157) 2015-06-26 17:12:10.345 *** CLIENT ID:() 2015-06-26 17:12:10.345 *** SERVICE NAME:(SYS$USERS) 2015-06-26 17:12:10.345 *** MODULE NAME:(TOAD 9.5.0.31) 2015-06-26 17:12:10.345 *** ACTION NAME:() 2015-06-26 17:12:10.345 -- The following are current System-scope REDO Log Archival related -- parameters and can be included in the database initialization file. -- -- LOG_ARCHIVE_DEST='' -- LOG_ARCHIVE_DUPLEX_DEST='' -- -- LOG_ARCHIVE_FORMAT=ONURDB_%t_%s_%r.arc -- -- DB_UNIQUE_NAME="ONURDB" -- -- LOG_ARCHIVE_CONFIG='SEND, RECEIVE, NODG_CONFIG' -- LOG_ARCHIVE_MAX_PROCESSES=4 -- STANDBY_FILE_MANAGEMENT=MANUAL -- STANDBY_ARCHIVE_DEST=?/dbs/arch -- FAL_CLIENT='' -- FAL_SERVER='' -- -- LOG_ARCHIVE_DEST_1='LOCATION=/oracle/ora11g/backup_ONURDB' -- LOG_ARCHIVE_DEST_1='OPTIONAL REOPEN=300 NODELAY' -- LOG_ARCHIVE_DEST_1='ARCH NOAFFIRM NOEXPEDITE NOVERIFY SYNC' -- LOG_ARCHIVE_DEST_1='REGISTER NOALTERNATE NODEPENDENCY' -- LOG_ARCHIVE_DEST_1='NOMAX_FAILURE NOQUOTA_SIZE NOQUOTA_USED NODB_UNIQUE_NAME' -- LOG_ARCHIVE_DEST_1='VALID_FOR=(PRIMARY_ROLE,ONLINE_LOGFILES)' -- LOG_ARCHIVE_DEST_STATE_1=ENABLE -- -- Below are two sets of SQL statements, each of which creates a new -- control file and uses it to open the database. The first set opens -- the database with the NORESETLOGS option and should be used only if -- the current versions of all online logs are available. The second -- set opens the database with the RESETLOGS option and should be used -- if online logs are unavailable. -- The appropriate set of statements can be copied from the trace into -- a script file, edited as necessary, and executed when there is a -- need to re-create the control file. -- -- Set #1. NORESETLOGS case -- -- The following commands will create a new control file and use it -- to open the database. -- Data used by Recovery Manager will be lost. -- Additional logs may be required for media recovery of offline -- Use this only if the current versions of all online logs are -- available. -- After mounting the created controlfile, the following SQL -- statement will place the database in the appropriate -- protection mode: -- ALTER DATABASE SET STANDBY DATABASE TO MAXIMIZE PERFORMANCE STARTUP NOMOUNT CREATE CONTROLFILE REUSE DATABASE "ONURDB" NORESETLOGS NOARCHIVELOG MAXLOGFILES 16 MAXLOGMEMBERS 3 MAXDATAFILES 100 MAXINSTANCES 8 MAXLOGHISTORY 292 LOGFILE GROUP 1 '/oracle/ora11g/data_ONURDB/ONURDB/redo01.log' SIZE 50M BLOCKSIZE 512, GROUP 2 '/oracle/ora11g/data_ONURDB/ONURDB/redo02.log' SIZE 50M BLOCKSIZE 512, GROUP 3 '/oracle/ora11g/data_ONURDB/ONURDB/redo03.log' SIZE 50M BLOCKSIZE 512 -- STANDBY LOGFILE DATAFILE '/oracle/ora11g/data_ONURDB/ONURDB/system01.dbf', '/oracle/ora11g/data_ONURDB/ONURDB/sysaux01.dbf', '/oracle/ora11g/data_ONURDB/ONURDB/undotbs01.dbf', '/oracle/ora11g/data_ONURDB/ONURDB/users01.dbf', '/oracle/ora11g/data_ONURDB/ONURDB/webtvnew01.dbf', '/oracle/ora11g/data_ONURDB/ONURDB/webtvnew02.dbf', '/oracle/ora11g/data_ONURDB/hr_bigts.dbf', '/oracle/ora11g/data_ONURDB/ONURDB/undotbs02.dbf' CHARACTER SET WE8ISO8859P9 ; -- Commands to re-create incarnation table -- Below log names MUST be changed to existing filenames on -- disk. Any one log file from each branch can be used to -- re-create incarnation records. -- ALTER DATABASE REGISTER LOGFILE '/oracle/ora11g/backup_ONURDB/ONURDB_1_1_824297850.arc'; -- ALTER DATABASE REGISTER LOGFILE '/oracle/ora11g/backup_ONURDB/ONURDB_1_1_880719621.arc'; -- ALTER DATABASE REGISTER LOGFILE '/oracle/ora11g/backup_ONURDB/ONURDB_1_1_882032561.arc'; -- Recovery is required if any of the datafiles are restored backups, -- or if the last shutdown was not normal or immediate. RECOVER DATABASE -- Database can now be opened normally. ALTER DATABASE OPEN; -- Commands to add tempfiles to temporary tablespaces. -- Online tempfiles have complete space information. -- Other tempfiles may require adjustment. ALTER TABLESPACE TEMP ADD TEMPFILE '/oracle/ora11g/data_ONURDB/ONURDB/temp01.dbf' SIZE 20971520 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M; -- End of tempfile additions. -- -- Set #2. RESETLOGS case -- -- The following commands will create a new control file and use it -- to open the database. -- Data used by Recovery Manager will be lost. -- The contents of online logs will be lost and all backups will -- be invalidated. Use this only if online logs are damaged. -- After mounting the created controlfile, the following SQL -- statement will place the database in the appropriate -- protection mode: -- ALTER DATABASE SET STANDBY DATABASE TO MAXIMIZE PERFORMANCE STARTUP NOMOUNT CREATE CONTROLFILE REUSE DATABASE "ONURDB" RESETLOGS NOARCHIVELOG MAXLOGFILES 16 MAXLOGMEMBERS 3 MAXDATAFILES 100 MAXINSTANCES 8 MAXLOGHISTORY 292 LOGFILE GROUP 1 '/oracle/ora11g/data_ONURDB/ONURDB/redo01.log' SIZE 50M BLOCKSIZE 512, GROUP 2 '/oracle/ora11g/data_ONURDB/ONURDB/redo02.log' SIZE 50M BLOCKSIZE 512, GROUP 3 '/oracle/ora11g/data_ONURDB/ONURDB/redo03.log' SIZE 50M BLOCKSIZE 512 -- STANDBY LOGFILE DATAFILE '/oracle/ora11g/data_ONURDB/ONURDB/system01.dbf', '/oracle/ora11g/data_ONURDB/ONURDB/sysaux01.dbf', '/oracle/ora11g/data_ONURDB/ONURDB/undotbs01.dbf', '/oracle/ora11g/data_ONURDB/ONURDB/users01.dbf', '/oracle/ora11g/data_ONURDB/ONURDB/webtvnew01.dbf', '/oracle/ora11g/data_ONURDB/ONURDB/webtvnew02.dbf', '/oracle/ora11g/data_ONURDB/hr_bigts.dbf', '/oracle/ora11g/data_ONURDB/ONURDB/undotbs02.dbf' CHARACTER SET WE8ISO8859P9 ; -- Commands to re-create incarnation table -- Below log names MUST be changed to existing filenames on -- disk. Any one log file from each branch can be used to -- re-create incarnation records. -- ALTER DATABASE REGISTER LOGFILE '/oracle/ora11g/backup_ONURDB/ONURDB_1_1_824297850.arc'; -- ALTER DATABASE REGISTER LOGFILE '/oracle/ora11g/backup_ONURDB/ONURDB_1_1_880719621.arc'; -- ALTER DATABASE REGISTER LOGFILE '/oracle/ora11g/backup_ONURDB/ONURDB_1_1_882032561.arc'; -- Recovery is required if any of the datafiles are restored backups, -- or if the last shutdown was not normal or immediate. RECOVER DATABASE USING BACKUP CONTROLFILE -- Database can now be opened zeroing the online logs. ALTER DATABASE OPEN RESETLOGS; -- Commands to add tempfiles to temporary tablespaces. -- Online tempfiles have complete space information. -- Other tempfiles may require adjustment. ALTER TABLESPACE TEMP ADD TEMPFILE '/oracle/ora11g/data_ONURDB/ONURDB/temp01.dbf' SIZE 20971520 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M; -- End of tempfile additions. -- |
You can find out what is kept in the Control File by querying the v$controlfile_record_section view. In the v$controlfile view, the names and locations of our control files can be seen.
While opening the database, we can learn where and what the control files are, according to the control_files parameter registered in the spfile or pfile parameter file in the NOMOUNT step.
If it cannot find even one of the control files in the specified names or places, it cannot proceed to the MOUNT step and an error is received.
This can be seen with the test below.
1. The names and locations of Control Files are learned from the Pfile parameter file.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 | -bash-3.2$ cd /oracle/ora11g/dbs/ -bash-3.2$ ll total 24 -rw-rw---- 1 oracle oinstall 1544 Jun 26 16:00 hc_ONURDB.dat -rw-r--r-- 1 oracle oinstall 803 May 26 17:09 initONURDB.ora -rw-r--r-- 1 oracle oinstall 2851 May 15 2009 init.ora -rw-r----- 1 oracle oinstall 24 May 26 12:20 lkONURDB -rw-r----- 1 oracle oinstall 1536 May 28 12:37 orapwONURDB -rw-r----- 1 oracle oinstall 2560 Jun 28 10:03 spfileONURDB.ora -bash-3.2$ vi initONURDB.ora ONURDB.__db_cache_size=654311424 ONURDB.__java_pool_size=16777216 ONURDB.__large_pool_size=33554432 ONURDB.__oracle_base='/oracle'#ORACLE_BASE set from environment ONURDB.__pga_aggregate_target=637534208 ONURDB.__sga_target=1023410176 ONURDB.__shared_io_pool_size=0 ONURDB.__shared_pool_size=301989888 ONURDB.__streams_pool_size=0 *.audit_file_dest='/oracle/admin/ONURDB/adump' *.audit_trail='db' *.compatible='11.2.0.4.0' *.control_files='/oracle/ora11g/data_ONURDB/ONURDB/control01.ctl','/oracle/ora11g/data_ONURDB/ONURDB/control02.ctl' *.db_block_size=8192 *.db_domain='' *.db_name='ONURDB' *.diagnostic_dest='/oracle' *.dispatchers='(PROTOCOL=TCP) (SERVICE=ONURDBXDB)' *.log_archive_dest_1='location=/oracle/ora11g/backup_ONURDB' *.log_archive_format='ONURDB_%t_%s_%r.arc' *.memory_target=1655701504 *.open_cursors=300 *.processes=150 *.remote_login_passwordfile='EXCLUSIVE' *.undo_tablespace='UNDOTBS1' |
Or run the command below while on the SQL prompt.
1 2 3 4 5 6 7 8 | SQL> show parameter control_files NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ control_files string /oracle/ora11g/data_ONURDB/ONU RDB/control01.ctl, /oracle/ora 11g/data_ONURDB/ONURDB/control 02.ctl |
2. Change the name of one of the Control Files.
1 | -bash-3.2$ mv control02.ctl control02.ctl.old |
3. The database is closed.
1 2 3 4 | SQL> shutdown immediate; Database closed. Database dismounted. ORACLE instance shut down. |
4. The database opens.
1 2 3 4 5 6 7 8 9 | SQL> startup ORACLE instance started. Total System Global Area 1653518336 bytes Fixed Size 2253784 bytes Variable Size 989858856 bytes Database Buffers 654311424 bytes Redo Buffers 7094272 bytes ORA-00205: error in identifying control file, check alert log for more info |