Oracle Control Files
Version 19.2.0.1

General Information
Current Control Files conn / as sysdba

col value format a105
SQL> col "control file name" format a50

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

VALUE
---------------------------------------------------------------------------------------------------------
/u01/orahome19/oradata/orabase19/control01.ctl, /u01/orahome19/recovery_area/oradata/orabase19/conrol02.ctl

SELECT RPAD(SUBSTR(name, 1, 50), 51,' ') "CONTROL FILE NAME"
FROM gv$controlfile;

CONTROL FILE NAME
--------------------------------------------------
/u01/orahome19/oradata/orabase19/control01.ctl
/u01/orahome19/recovery_area/orabase19/control02.ctl
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 To Trace 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="orabase198"
--
-- LOG_ARCHIVE_CONFIG='SEND, RECEIVE, NODG_CONFIG'
-- LOG_ARCHIVE_MAX_PROCESSES=4
-- STANDBY_FILE_MANAGEMENT=MANUAL
-- FAL_CLIENT=''
-- FAL_SERVER=''
--
-- LOG_ARCHIVE_DEST_1='LOCATION=USE_DB_RECOVERY_FILE_DEST'
-- LOG_ARCHIVE_DEST_1='MANDATORY REOPEN=300 NODELAY'
-- LOG_ARCHIVE_DEST_1='ARCH NOAFFIRM NOVERIFY SYNC'
-- LOG_ARCHIVE_DEST_1='NOREGISTER'
-- LOG_ARCHIVE_DEST_1='NOALTERNATE'
-- LOG_ARCHIVE_DEST_1='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 "ORABASE1" NORESETLOGS FORCE LOGGING ARCHIVELOG
MAXLOGFILES 16
MAXLOGMEMBERS 3
MAXDATAFILES 1024
MAXINSTANCES 8
MAXLOGHISTORY 292
LOGFILE
GROUP 1 'C:\APPS19\ORADATA\ORABASE18\REDO01.LOG' SIZE 200M BLOCKSIZE 512,
GROUP 2 'C:\APPS19\ORADATA\ORABASE18\REDO02.LOG' SIZE 200M BLOCKSIZE 512,
GROUP 3 'C:\APPS19\ORADATA\ORABASE18\REDO03.LOG' SIZE 200M BLOCKSIZE 512
-- STANDBY LOGFILE
DATAFILE
'C:\APPS19\ORADATA\ORABASE19\SYSTEM01.DBF',
'C:\APPS19\ORADATA\ORABASE19\SYSAUX01.DBF',
'C:\APPS19\ORADATA\ORABASE19\UNDOTBS01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBSEED\SYSTEM01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBSEED\SYSAUX01.DBF',
'C:\APPS19\ORADATA\ORABASE19\USERS01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBSEED\UNDOTBS01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBDEV\SYSTEM01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBDEV\SYSAUX01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBDEV\UNDOTBS01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBDEV\USERS01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBDEV\UWDATA.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBDEV\EXAMPLE01.DBF',
'C:\APPS19\ORADATA\ORABASE19\EXAMPLE01.DBF'
CHARACTER SET AL32UTF8
;

-- Configure RMAN configuration record 1
VARIABLE RECNO NUMBER;
EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE','DISK TO ''%F''');
-- 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:\APPS19\RECOVERY_AREA\ORABASE19\ARCHIVELOG\2019_01_22\O1_MF_1_1_%U_.ARC';
-- ALTER DATABASE REGISTER LOGFILE 'C:\APPS19\RECOVERY_AREA\ORABASE19\ARCHIVELOG\2019_01_22\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

-- Set Database Guard and/or Supplemental Logging
ALTER DATABASE ADD SUPPLEMENTAL LOG DATA;
-- All logs need archiving and a log switch is needed.
ALTER SYSTEM ARCHIVE LOG ALL;

-- Database can now be opened normally.
ALTER DATABASE OPEN;

-- Open all the PDBs.
ALTER PLUGGABLE DATABASE ALL 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:\APPS19\ORADATA\ORABASE19\TEMP01.DBF'
SIZE 135266304 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M;
ALTER SESSION SET CONTAINER = PDB$SEED;
ALTER TABLESPACE TEMP ADD TEMPFILE 'C:\APPS19\ORADATA\ORABASE19\PDBSEED\TEMP012019-11-01_10-38-13-442-AM.DBF'
SIZE 65011712 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M;
ALTER SESSION SET CONTAINER = PDBDEV;
ALTER TABLESPACE TEMP ADD TEMPFILE 'C:\APPS19\ORADATA\ORABASE19\PDBDEV\TEMP01.DBF'
SIZE 135266304 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M;
ALTER SESSION SET CONTAINER = CDB$ROOT;
-- 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 "ORABASE1" RESETLOGS FORCE LOGGING ARCHIVELOG
MAXLOGFILES 16
MAXLOGMEMBERS 3
MAXDATAFILES 1024
MAXINSTANCES 8
MAXLOGHISTORY 292
LOGFILE
GROUP 1 'C:\APPS19\ORADATA\ORABASE19\REDO01.LOG' SIZE 200M BLOCKSIZE 512,
GROUP 2 'C:\APPS19\ORADATA\ORABASE19\REDO02.LOG' SIZE 200M BLOCKSIZE 512,
GROUP 3 'C:\APPS19\ORADATA\ORABASE19\REDO03.LOG' SIZE 200M BLOCKSIZE 512
-- STANDBY LOGFILE
DATAFILE
'C:\APPS19\ORADATA\ORABASE19\SYSTEM01.DBF',
'C:\APPS19\ORADATA\ORABASE19\SYSAUX01.DBF',
'C:\APPS19\ORADATA\ORABASE19\UNDOTBS01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBSEED\SYSTEM01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBSEED\SYSAUX01.DBF',
'C:\APPS19\ORADATA\ORABASE19\USERS01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBSEED\UNDOTBS01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBDEV\SYSTEM01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBDEV\SYSAUX01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBDEV\UNDOTBS01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBDEV\USERS01.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBDEV\UWDATA.DBF',
'C:\APPS19\ORADATA\ORABASE19\PDBDEV\EXAMPLE01.DBF',
'C:\APPS19\ORADATA\ORABASE19\EXAMPLE01.DBF'
CHARACTER SET AL32UTF8
;

-- Configure RMAN configuration record 1
VARIABLE RECNO NUMBER;
EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE','DISK TO ''%F''');
-- 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:\APPS19\RECOVERY_AREA\ORABASE19\ARCHIVELOG\2019_01_22\O1_MF_1_1_%U_.ARC';
-- ALTER DATABASE REGISTER LOGFILE 'C:\APPS19\RECOVERY_AREA\ORABASE19\ARCHIVELOG\2019_01_22\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

-- Set Database Guard and/or Supplemental Logging
ALTER DATABASE ADD SUPPLEMENTAL LOG DATA;
-- Database can now be opened zeroing the online logs.
ALTER DATABASE OPEN RESETLOGS;

-- Open all the PDBs.
ALTER PLUGGABLE DATABASE ALL 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:\APPS19\ORADATA\ORABASE19\TEMP01.DBF'
SIZE 135266304 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M;
ALTER SESSION SET CONTAINER = PDB$SEED;
ALTER TABLESPACE TEMP ADD TEMPFILE 'C:\APPS19\ORADATA\ORABASE19\PDBSEED\TEMP012019-11-01_10-38-13-442-AM.DBF'
SIZE 65011712 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M;
ALTER SESSION SET CONTAINER = PDBDEV;
ALTER TABLESPACE TEMP ADD TEMPFILE 'C:\APPS19\ORADATA\ORABASE19\PDBDEV\TEMP01.DBF'
SIZE 135266304 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M;
ALTER SESSION SET CONTAINER = CDB$ROOT;
-- End of tempfile additions.
--

Related Topics
Database
Data Guard
Initialization Parameters
RMAN
What's New In 18cR3
What's New In 19cR2

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-2019 Daniel A. Morgan All Rights Reserved
DBSecWorx