Today, One of the database was having lag an MRP process was terminating with Internal errors ORA 600 arguments: [3020]
Here, Checked the standby database, the gap was increasing rapidly.
SQL:hostname_standby01:(MYPROD):PHYSICAL STANDBY> SELECT ARCH.THREAD# "Thread", ARCH.SEQUENCE# "Last Sequence Received", APP L.SEQUENCE# "Last Sequence Applied", (ARCH.SEQUENCE# - APPL.SEQUENCE#) "Difference" 2 FROM (SELECT THREAD# ,SEQUENCE# FROM V$ARCHIVED_LOG WHERE (THREAD#,FIRST_TIME ) IN (SELECT THREAD#,MAX(FIRST_TIME) FROM V$ARCHIVED_LOG GROUP BY THREAD#)) ARCH, (SELECT THREAD# ,SEQUENCE# FROM V$LOG_HISTORY WHERE (THREAD#,FIRST_TIME ) 3 IN (SELECT THREAD#,MAX(FIRST_TIME) FROM V$LOG_HISTORY GROUP BY THREAD#)) APPL WHERE ARCH.THREAD# = APPL.THREAD# ; Thread Last Sequence Received Last Sequence Applied Difference ---------- ---------------------- --------------------- ---------- 1 18223 17969 254 SQL:hostname_standby01:(MYPROD):PHYSICAL STANDBY>
I
was curious to check the alert log to check and know what went wrong and why
MRP process keeps on terminating. So, I went through the alert log and I found
below details.
hostname_standby01(oracle):MYPROD:trace$ tail -400f alert_MYPROD.log Errors in file /app/ora/local/admin/MYPROD/diag/rdbms/myprod_hostname_129/MYPROD/trace/MYPROD_pr0s_3151989.trc: ORA-00600: internal error code, arguments: [3020], [2], [16431], [8405039], [], [], [], [], [], [], [], [] ORA-10567: Redo is inconsistent with data block (file# 2, block# 16431, file offset is 134602752 bytes) ORA-10564: tablespace SYSAUX ORA-01110: data file 2: '+DATA01/myprod_hostname_129/datafile/sysaux.256.914736089' ORA-10561: block type 'TRANSACTION MANAGED DATA BLOCK', data object# 6478 Errors in file /app/ora/local/admin/MYPROD/diag/rdbms/myprod_hostname_129/MYPROD/trace/MYPROD_mrp0_3151683.trc (incident=17881):
Login to Primary database and perform the backup of datafile, Here we will backup the datafile and restore the datafile to standby database.
RMAN> backup format '/db/dump01/backup_stdby/sysaux.256.914736089' datafile 2 ; Starting backup at 19-AUG-17 using target database control file instead of recovery catalog allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=156 device type=DISK channel ORA_DISK_1: starting full datafile backup set channel ORA_DISK_1: specifying datafile(s) in backup set input datafile file number=00002 name=+DATA01/myprod_hostname_129/datafile/sysaux.257.914670317 channel ORA_DISK_1: starting piece 1 at 19-AUG-17 channel ORA_DISK_1: finished piece 1 at 19-AUG-17 piece handle=/db/files/backup_stdby/sysaux.256.914736089 tag=TAG20170219T103456 comment=NONE channel ORA_DISK_1: backup set complete, elapsed time: 00:00:07 Finished backup at 19-AUG-17 Starting Control File and SPFILE Autobackup at 19-AUG-17 piece handle=/app/ora/local/admin/MYPROD/files/PRIMARY_MYPROD_c-218898855-20170219-01.ctl comment=NONE Finished Control File and SPFILE Autobackup at 19-AUG-17 RMAN> exit
Now
transfer the backup piece to standby server and perform the recovery :
Once
the files are copied to standby server, Login to Standby database and start the
restore of datafile to remediate the issue.
Catalog
the backup piece using rman on standby database.
hostname_ standby01 (oracle):MYPROD:backup_stdby$ rman target / RMAN> catalog start with '/db/files/backup_stdby' ; using target database control file instead of recovery catalog searching for all files that match the pattern /db/files/backup_stdby List of Files Unknown to the Database ===================================== File Name: /db/files/backup_stdby/sysaux.256.914736089 Do you really want to catalog the above files (enter YES or NO)? YES cataloging files... cataloging done List of Cataloged Files ======================= File Name: /db/files/backup_stdby/sysaux.256.914736089 RMAN> exit SQL: hostname_ standby01:(MYPROD):PHYSICAL STANDBY> shut immediate ; ORA-01109: database not open Database dismounted. ORACLE instance shut down. SQL: hostname_ standby01:(MYPROD):PHYSICAL STANDBY> startup mount; ORACLE instance started. Total System Global Area 1068937216 bytes Fixed Size 2235208 bytes Variable Size 494929080 bytes Database Buffers 566231040 bytes Redo Buffers 5541888 bytes Database mounted. SQL: hostname_ standby01:(MYPRD):PHYSICAL STANDBY> !rman target / Recovery Manager: Release 11.2.0.3.0 - Production on Sun AUG 19 10:46:20 2017 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. connected to target database: MYPROD(DBID=218895632, not open) RMAN> restore datafile 2 ; Starting restore at 19-AUG-17 using target database control file instead of recovery catalog allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=78 device type=DISK channel ORA_DISK_1: starting datafile backup set restore channel ORA_DISK_1: specifying datafile(s) to restore from backup set channel ORA_DISK_1: restoring datafile 00002 to +DATA01/myprod_files/datafile/sysaux.256.914736089 channel ORA_DISK_1: reading from backup piece /db/dump01/backup_stdby/sysaux.256.914736089 channel ORA_DISK_1: piece handle=/db/files/backup_stdby/sysaux.256.914736089 tag=TAG20170219T103456 channel ORA_DISK_1: restored backup piece 1 channel ORA_DISK_1: restore complete, elapsed time: 00:00:01 Finished restore at 19-AUG-17 RMAN> exit Recovery Manager complete.
Once the restore via RMAN is completed. Bounce the MRP and check the behaviour.
SQL: hostname_ standby01:(MYPROD):PHYSICAL STANDBY> alter database recover managed standby database cancel ; Database altered. SQL: hostname_ standby01:(MYPROD):PHYSICAL STANDBY> ALTER DATABASE RECOVER MANAGED STANDBY DATABASE DISCONNECT; Database altered. Check if MRP is running now. All looks good.. ! J SQL: hostname_ standby01:(MYPROD):PHYSICAL STANDBY> !ps -ef|grep mrp oracle 3500966 1 0 10:47 ? 00:00:00 ora_mrp0_MYPROD oracle 3501928 3456846 0 10:48 pts/10 00:00:00 /bin/ksh -c ps -ef|grep mrp oracle 3501930 3501928 0 10:48 pts/10 00:00:00 grep mrp
Check if lag is reducing and is in Sync with Primary database:
SQL: hostname_ standby01:( MYPROD):PRIMARY> archive log list ; Database log mode Archive Mode Automatic archival Enabled Archive destination /app/ora/local/admin/myprod/arch1 Oldest online log sequence 18233 Next log sequence to archive 18235 Current log sequence 18235 SQL: hostname_ standby01:( MYPROD):PHYSICAL STANDBY> SELECT ARCH.THREAD# "Thread", ARCH.SEQUENCE# "Last Sequence Received", APPL.SEQUENCE# "Last Sequence Applied", (ARCH.SEQUENCE# - APPL.SEQUENCE#) "Difference" FROM (SELECT THREAD# ,SEQUENCE# FROM V$ARCHIVED_LOG WHERE (THREAD#,FIRST_TIME ) IN (SELECT THREAD#,MAX(FIRST_TIME) FROM V$ARCHIVED_LOG GROUP BY THREAD#)) ARCH, (SELECT THREAD# ,SEQUENCE# FROM V$LOG_HISTORY WHERE (THREAD#,FIRST_TIME ) IN (SELECT THREAD#,MAX(FIRST_TIME) FROM V$LOG_HISTORY GROUP BY THREAD#)) APPL WHERE ARCH.THREAD# = APPL.THREAD# ; SQL:xstm6551bor:( MYPROD):PHYSICAL STANDBY> / Thread Last Sequence Received Last Sequence Applied Difference ---------- ---------------------- --------------------- ---------- 1 18234 18215 19 SQL:hostname_standby01:( MYPROD):PHYSICAL STANDBY> / Thread Last Sequence Received Last Sequence Applied Difference ---------- ---------------------- --------------------- ---------- 1 18234 18228 6 SQL:hostname_standby01:( MYPROD):PHYSICAL STANDBY> / Thread Last Sequence Received Last Sequence Applied Difference ---------- ---------------------- --------------------- ---------- 1 18234 18234 0 SQL: hostname_standby01:( MYPROD):PHYSICAL STANDBY> SQL: hostname_ standby01:(MYPROD):PHYSICAL STANDBY>
The Standby is in Sync with Primary database now.
Really very nice and informative post.Thanks a lot to you... Looking more post form you...
ReplyDelete