Pages

Tuesday, December 20, 2022

Re-Creating control file from existing database following ORA-00202: control file: ORA-27070: OSD-04006: Data error (cyclic redundancy check).

How to create a control file from existing database

Real life example, Control files got corrupted due to HW issue
Errors in file d:\software\oracle\diag\rdbms\igt\igt\trace\igt_ora_2324.trc:

ORA-00202: control file: 'D:\ORACLE_DB\DB1\DB_IGT\ORA_CONTROL_01.CTL'
ORA-27070: async read/write failed
OSD-04006: ReadFile() failure, unable to read from file
O/S-Error: (OS 23) Data error (cyclic redundancy check).
ORA-204 signalled during: alter database mount exclusive...

Option 1 - Generate a script for recreating the control files using a command below.
can work only if database is mounted or open

Option 2 - Write same script manually...

ALTER DATABASE BACKUP CONTROLFILE TO TRACE;

The trace keyword tells oracle to generate a script containing a create controlfile command 
and store it in the trace directory identified in the 
user_dump_dest parameter of the init.ora file.


SQL> show parameter user_dump_dest

NAME            TYPE    VALUE
--------------- ------- ---------------------------------------------
user_dump_dest  string  d:\software\oracle\diag\rdbms\igt\igt\trace

SQL> ALTER DATABASE BACKUP CONTROLFILE TO TRACE;

Database altered.
================================================================
This is the output d:\software\oracle\diag\rdbms\igt\igt\trace\igt_ora_6632.trc
================================================================

Trace file 
d:\software\oracle\diag\rdbms\igt\igt\trace\igt_ora_6632.trc
Oracle Database 11g Enterprise Edition Release 11.1.0.7.0 - Production
With the Partitioning, Oracle Label Security, OLAP, Data Mining,
Oracle Database Vault and Real Application Testing options
Windows NT Version V5.2 Service Pack 2
CPU                 : 16 - type 586, 2 Physical Cores
Process Affinity    : 0x00000000
Memory (Avail/Total): Ph:1619M/4095M, Ph+PgF:5712M/8010M, VA:1093M/2047M
Instance name: igt
Redo thread mounted by this instance: 1
Oracle process number: 25
Windows thread id: 6632, image: ORACLE.EXE (SHAD)


*** 2022-12-19 17:38:18.381
*** SESSION ID:(242.10210) 2022-12-19 17:38:18.381
*** CLIENT ID:() 2022-12-19 17:38:18.381
*** SERVICE NAME:(igt) 2022-12-19 17:38:18.381
*** MODULE NAME:(SQL*Plus) 2022-12-19 17:38:18.381
*** ACTION NAME:() 2022-12-19 17:38:18.381
 
-- 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=arch%T_%s_%r.arc
--
-- DB_UNIQUE_NAME="igt"
--
-- LOG_ARCHIVE_CONFIG='SEND, RECEIVE, NODG_CONFIG'
-- LOG_ARCHIVE_MAX_PROCESSES=4
-- ARCHIVE_LAG_TARGET=1800
-- STANDBY_FILE_MANAGEMENT=MANUAL
-- STANDBY_ARCHIVE_DEST=%ORACLE_HOME%\RDBMS
-- FAL_CLIENT=''
-- FAL_SERVER=''
--
-- LOG_ARCHIVE_DEST_1='LOCATION=m:\oracle_db\db2\db_igt\arch'
-- 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 "IGT" NORESETLOGS  ARCHIVELOG
    MAXLOGFILES 16
    MAXLOGMEMBERS 3
    MAXDATAFILES 1024
    MAXINSTANCES 8
    MAXLOGHISTORY 584
LOGFILE
  GROUP 1 'D:\ORACLE_DB\DB1\DB_IGT\ORA_REDO_01_A.RDO'  SIZE 100M,
  GROUP 2 'D:\ORACLE_DB\DB1\DB_IGT\ORA_REDO_02_A.RDO'  SIZE 100M,
  GROUP 3 'D:\ORACLE_DB\DB1\DB_IGT\ORA_REDO_03_A.RDO'  SIZE 100M
-- STANDBY LOGFILE
DATAFILE
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_SYSTEM_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_SYSAUX_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_UNDOTBS_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_GIN_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_GININDEX_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_IGT_TABLE_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_IGT_INDEX_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_WORKAREA_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_DWH_TABLE_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_DWH_INDEX_01.DBF'
CHARACTER SET WE8ISO8859P1
;
-- Configure RMAN configuration record 1
VARIABLE RECNO NUMBER;
EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CONTROLFILE AUTOBACKUP','ON');
-- Configure RMAN configuration record 2
VARIABLE RECNO NUMBER;
EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('BACKUP OPTIMIZATION','ON');
-- 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 'M:\ORACLE_DB\DB2\DB_IGT\ARCH\ARCH001_1_779550848.ARC';
-- Recovery is required if any of the datafiles are restored backups,
-- or if the last shutdown was not normal or immediate.
RECOVER DATABASE
-- All logs need archiving and a log switch is needed.
ALTER SYSTEM ARCHIVE LOG ALL;
-- 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 TEMPORARY ADD TEMPFILE 'D:\ORACLE_DB\DB1\DB_IGT\ORA_TEMPORARY_01.DBF'
     SIZE 629145600  REUSE AUTOEXTEND ON NEXT 104857600  MAXSIZE 6000M;
-- 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 "IGT" RESETLOGS  ARCHIVELOG
    MAXLOGFILES 16
    MAXLOGMEMBERS 3
    MAXDATAFILES 1024
    MAXINSTANCES 8
    MAXLOGHISTORY 584
LOGFILE
  GROUP 1 'D:\ORACLE_DB\DB1\DB_IGT\ORA_REDO_01_A.RDO'  SIZE 100M,
  GROUP 2 'D:\ORACLE_DB\DB1\DB_IGT\ORA_REDO_02_A.RDO'  SIZE 100M,
  GROUP 3 'D:\ORACLE_DB\DB1\DB_IGT\ORA_REDO_03_A.RDO'  SIZE 100M
-- STANDBY LOGFILE
DATAFILE
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_SYSTEM_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_SYSAUX_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_UNDOTBS_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_GIN_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_GININDEX_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_IGT_TABLE_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_IGT_INDEX_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_WORKAREA_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_DWH_TABLE_01.DBF',
  'D:\ORACLE_DB\DB1\DB_IGT\ORA_DWH_INDEX_01.DBF'
CHARACTER SET WE8ISO8859P1
;
-- Configure RMAN configuration record 1
VARIABLE RECNO NUMBER;
EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('CONTROLFILE AUTOBACKUP','ON');
-- Configure RMAN configuration record 2
VARIABLE RECNO NUMBER;
EXECUTE :RECNO := SYS.DBMS_BACKUP_RESTORE.SETCONFIG('BACKUP OPTIMIZATION','ON');
-- 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 'M:\ORACLE_DB\DB2\DB_IGT\ARCH\ARCH001_1_779550848.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 TEMPORARY ADD TEMPFILE 'D:\ORACLE_DB\DB1\DB_IGT\ORA_TEMPORARY_01.DBF'
     SIZE 629145600  REUSE AUTOEXTEND ON NEXT 104857600  MAXSIZE 6000M;
-- End of tempfile additions.
--


By Example:


SQL> SHUTDOWN IMMEDIATE;
ORA-01507: database not mounted
ORACLE instance shut down.

SQL> STARTUP NOMOUNT;
ORACLE instance started.

Total System Global Area  523108352 bytes
Fixed Size                  1348420 bytes
Variable Size             461376700 bytes
Database Buffers           54525952 bytes
Redo Buffers                5857280 bytes


SQL> CREATE CONTROLFILE REUSE DATABASE "igt" NORESETLOGS ARCHIVELOG
     MAXLOGFILES 16
     MAXLOGMEMBERS 3
     MAXDATAFILES 1024
     MAXINSTANCES 8
     MAXLOGHISTORY 1
LOGFILE 
     GROUP 1 ('d:\oracle_db\db1\db_igt\ora_redo_01_a.rdo') SIZE 100M,
     GROUP 2 ('d:\oracle_db\db1\db_igt\ora_redo_02_a.rdo') SIZE 100M,
     GROUP 3 ('d:\oracle_db\db1\db_igt\ora_redo_03_a.rdo') SIZE 100M 
DATAFILE 'd:\oracle_db\db1\db_igt\ora_system_01.dbf',
     'D:\oracle_db\db1\db_igt\ORA_DWH_INDEX_01.DBF',
     'D:\oracle_db\db1\db_igt\ORA_DWH_TABLE_01.DBF',
     'D:\oracle_db\db1\db_igt\ORA_GIN_01.DBF',
     'D:\oracle_db\db1\db_igt\ORA_GININDEX_01.DBF',
     'D:\oracle_db\db1\db_igt\ORA_IGT_INDEX_01.DBF',
     'D:\oracle_db\db1\db_igt\ORA_IGT_TABLE_01.DBF',
     'D:\oracle_db\db1\db_igt\ORA_SYSAUX_01.DBF',
     'D:\oracle_db\db1\db_igt\ORA_SYSTEM_01.DBF',
     'D:\oracle_db\db1\db_igt\ORA_WORKAREA_01.DBF',
     'D:\oracle_db\db1\db_igt\'
CHARACTER SET WE8ISO8859P1;


At this point, control files should be recreated, and have a new timestamp.


SQL> RECOVER DATABASE;
Media recovery complete.

SQL> ALTER SYSTEM ARCHIVE LOG ALL;
System altered.


SQL> ALTER DATABASE OPEN;
Database altered.


SQL> ALTER TABLESPACE TEMPORARY ADD TEMPFILE 'D:\ORACLE_DB\DB1\DB_IGT\ORA_TEMPORARY_01.DBF'
 SIZE 629145600  REUSE AUTOEXTEND ON NEXT 104857600  MAXSIZE 6000M;
Tablespace altered.

 

SQL> SHUTDOWN IMMEDIATE;
Database closed.
Database dismounted.
ORACLE instance shut down.

SQL> STARTUP;
ORACLE instance started.

Total System Global Area  523108352 bytes
Fixed Size                  1348420 bytes
Variable Size             461376700 bytes
Database Buffers           54525952 bytes
Redo Buffers                5857280 bytes
Database mounted.
Database opened.


Now is a good idea to take a backup 


rman target / 

RMAN> run {
   configure controlfile autobackup on;
   configure backup optimization on;
   set controlfile autobackup format for device type disk to 'p:\backup\ora_online\20221219_1811\%F';
   allocate channel 'dev_0' type disk format = 'p:\backup\ora_online\20221219_1811\dbf_%d_%T_%U';
   backup full database;
   backup archivelog from time = 'sysdate-10/1440' format 'p:\backup\ora_online\20221219_1811\arch_%d_%T_%U';
   release channel 'dev_0';
}
exit;

retentionRedundancy=2
rman target / 
report obsolete redundancy = $retentionRedundancy;
exit;

rman target / 
allocate channel for delete type disk;
delete noprompt force archivelog all backed up $retentionRedundancy times to device type disk;
delete noprompt force copy of archivelog all completed before 'sysdate-10';
delete noprompt force obsolete redundancy = $retentionRedundancy;
release channel;
exit;

No comments:

Post a Comment