Oracle Control Files
Version 12.1.0.2

General Information
Current Control Files conn / as sysdba

col value format a105

SELECT value
FROM gv$parameter
WHERE name = 'control_files';

SELECT RPAD(SUBSTR(name, 1, 50), 51,' ') "CONTROL FILE NAME"
FROM gv$controlfile;
Data Dictionary Objects
V$CONTROLFILE V$CONTROLFILE_RECORD_SECTION X$KCCCF
 
Create Control File
Reuse previously existing control file(s) if they exist CREATE CONTROLFILE [REUSE]
DATABASE <database_name>
<RESETLOGS | NORESETLOGS>;
conn / as sysdba

STARTUP NOMOUNT;

CREATE CONTROFILE REUSE
SET DATABASE orabase
RESETLOGS;

ALTER DATABASE OPEN RESETLOGS;
Reuse previously existing control file(s) if they exist but do not perform a logfile reset CREATE CONTROLFILE [REUSE]
DATABASE <database_name>
<RESETLOGS | NORESETLOGS>;
conn / as sysdba

STARTUP NOMOUNT;

CREATE CONTROFILE REUSE
SET DATABASE orabase
NORESETLOGS;
 
Create Standby Control File
Create Control File For Logical Standby (issue on the primary database) ALTER DATABASE CREATE LOGICAL STANDBY CONTROLFILE
AS <file_name> REUSE;
ALTER DATABASE CREATE LOGICAL STANDBY CONTROLFILE
AS 'c:\oragrid\control03.ctl';
Create Control File For Physical Standby (issue on the primary database) ALTER DATABASE CREATE PHYSICAL STANDBY CONTROLFILE
AS <file_name> REUSE;
ALTER DATABASE CREATE PHYSICAL STANDBY CONTROLFILE
AS 'c:\oragrid\control03.ctl' REUSE;
To put the standby control file on the standby with ASM SQL> startup nomount;

RMAN> connect target /
RMAN> restore controlfile to ‘+DATA01/ORADB01/controlfile/<new_control_file';s_name>′ FROM /usr/tmp/oradb01.<file_name>.ctl;
-- repeat the RMAN command for all other control file copies substituting the real names for the tags above
 
Relocate Control Files
Change Control File Location conn / as sysdba

SQL> show parameter control

SQL> shutdown immediate

SQL> create pfile from spfile;

SQL> host

-- use cp to copy the control file from its current location to the new location
$ cp $ORACLE_BASE/oradata/orabase/control02.ctl /u02/oradata/orabase/control02.ctl

$ vi $ORACLE_HOME/dbs/initorabase.ora
-- change the control file location to the new location save the changes and exit vi

$ exit

SQL> create spfile from pfile;

startup

show parameter control

host

-- remove the copy of the control file in the original location
$ rm $ORACLE_BASE/oradata/orabase/control02.ctl
 
Backup Control Files
Backup Control File To Text File ALTER DATABASE BACKUP CONTROLFILE TO TRACE AS <file_name> REUSE <RESETLOGS | NORESETLOGS>;
ALTER DATABASE BACKUP CONTROLFILE TO TRACE;

ALTER DATABASE BACKUP CONTROLFILE TO TRACE AS 'c:\temp\control.bkp';

ALTER DATABASE BACKUP CONTROLFILE TO TRACE AS '/u01/control.bkp' REUSE;

ALTER DATABASE BACKUP CONTROLFILE TO TRACE AS 'c:\temp\control01.ctl' NORESETLOGS;
Backup to Binary File ALTER DATABASE BACKUP CONTROLFILE TO '/u01/oradata/control.bkp';

ALTER DATABASE BACKUP CONTROLFILE TO 'c:\temp\control.bkp' REUSE;
Sample Backup Control File Script Output -- 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=ARC%S_%R.%T
--
-- DB_UNIQUE_NAME="orabase"
--
-- LOG_ARCHIVE_CONFIG='SEND, RECEIVE, NODG_CONFIG'
-- LOG_ARCHIVE_MAX_PROCESSES=4
-- STANDBY_FILE_MANAGEMENT=MANUAL
-- STANDBY_ARCHIVE_DEST=%ORACLE_HOME%\RDBMS
-- FAL_CLIENT=''
-- FAL_SERVER=''
--
-- LOG_ARCHIVE_DEST_10='LOCATION=USE_DB_RECOVERY_FILE_DEST'
-- LOG_ARCHIVE_DEST_10='OPTIONAL REOPEN=300 NODELAY'
-- LOG_ARCHIVE_DEST_10='ARCH NOAFFIRM NOEXPEDITE NOVERIFY SYNC'
-- LOG_ARCHIVE_DEST_10='REGISTER NOALTERNATE NODEPENDENCY'
-- LOG_ARCHIVE_DEST_10='NOMAX_FAILURE NOQUOTA_SIZE NOQUOTA_USED NODB_UNIQUE_NAME'
-- LOG_ARCHIVE_DEST_10='VALID_FOR=(PRIMARY_ROLE,ONLINE_LOGFILES)'
-- LOG_ARCHIVE_DEST_STATE_10=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 "ORABASE" NORESETLOGS NOARCHIVELOG
MAXLOGFILES 16
MAXLOGMEMBERS 3
MAXDATAFILES 100
MAXINSTANCES 8
MAXLOGHISTORY 292
LOGFILE
GROUP 1 'C:\APP\ORACLE\ORADATA\ORABASE\REDO01.LOG' SIZE 50M,
GROUP 2 'C:\APP\ORACLE\ORADATA\ORABASE\REDO02.LOG' SIZE 50M,
GROUP 3 'C:\APP\ORACLE\ORADATA\ORABASE\REDO03.LOG' SIZE 50M;
-- STANDBY LOGFILE

DATAFILE
'C:\APP\ORACLE\ORADATA\ORABASE2\SYSAUX01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\SYSTEM01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\UNDOTBS01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\USERS01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\PDBSEED\SYSAUX01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\PDBSEED\SYSTEM01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\ORCL\EXAMPLE01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\ORCL\SAMPLE_SCHEMA_USERS01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\ORCL\SYSAUX01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\ORCL\SYSTEM01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\PDBDEV\CATTBSP.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\PDBDEV\ORADATA01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\PDBDEV\SYSAUX01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\PDBDEV\SYSTEM01.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\PDBDEV\TBFS.DBF';,
'C:\APP\ORACLE\ORADATA\ORABASE2\PDBDEV\UWDATA01.DBF';
CHARACTER SET WE8MSWIN1252;

-- 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 'C:\APP\ORACLE\FAST_RECOVERY_AREA\ORABASE\ARCHIVELOG\2009_02_02\O1_MF_1_1_%U_.ARC';
-- ALTER DATABASE REGISTER LOGFILE 'C:\APP\ORACLE\FAST_RECOVERY_AREA\ORABASE\ARCHIVELOG\2009_02_02\O1_MF_1_1_%U_.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 'C:\APP\ORACLE\ORADATA\ORABASE\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 "ORABASE" RESETLOGS NOARCHIVELOG
MAXLOGFILES 16
MAXLOGMEMBERS 3
MAXDATAFILES 100
MAXINSTANCES 8
MAXLOGHISTORY 292
LOGFILE
GROUP 1 'C:\APP\ORACLE\ORADATA\ORABASE\REDO01.LOG' SIZE 50M,
GROUP 2 'C:\APP\ORACLE\ORADATA\ORABASE\REDO02.LOG' SIZE 50M,
GROUP 3 'C:\APP\ORACLE\ORADATA\ORABASE\REDO03.LOG' SIZE 50M
-- STANDBY LOGFILE

DATAFILE
';C:\APP\ORACLE\ORADATA\ORABASE2\SYSAUX01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\SYSTEM01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\UNDOTBS01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\USERS01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\PDBSEED\SYSAUX01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\PDBSEED\SYSTEM01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\ORCL\EXAMPLE01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\ORCL\SAMPLE_SCHEMA_USERS01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\ORCL\SYSAUX01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\ORCL\SYSTEM01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\PDBDEV\CATTBSP.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\PDBDEV\ORADATA01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\PDBDEV\SYSAUX01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\PDBDEV\SYSTEM01.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\PDBDEV\TBFS.DBF';,
';C:\APP\ORACLE\ORADATA\ORABASE2\PDBDEV\UWDATA01.DBF';
CHARACTER SET WE8MSWIN1252;

-- 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 'C:\APP\ORACLE\FAST_RECOVERY_AREA\ORABASE\ARCHIVELOG\2014_02_02\O1_MF_1_1_%U_.ARC';
-- ALTER DATABASE REGISTER LOGFILE 'C:\APP\ORACLE\FAST_RECOVERY_AREA\ORABASE\ARCHIVELOG\2014_02_02\O1_MF_1_1_%U_.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 'C:\APP\ORACLE\ORADATA\ORABASE\TEMP01.DBF'
SIZE 20971520 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M;
-- End of tempfile additions.

Related Topics
Database
Data Guard
Initialization Parameters
RMAN
What's New In 12cR1
What's New In 12cR2

Morgan's Library Page Footer
This site is maintained by Dan Morgan. Last Updated: This site is protected by copyright and trademark laws under U.S. and International law. © 1998-2017 Daniel A. Morgan All Rights Reserved