Skip to main content

Multitenant and standby: recover from subsetting

In the previous post we learnt how to exclude a PDB (or a datafile) from the standby database recovery. Of course, that might not be the real end goal. We may just want to skip it for now, but have the standby continue to be up-to-date for every other PDB, and eventually include the new PDB as well.

Again, standard Oracle pre-12c DBA knowledge is helpful here. These files are just missing datafiles and thus a backup can be used to restore them. The new 12c features add some quirks to this process, but the base is just sound backup and recovery.

Backup

So let's start with a proper backup:

rman target=/

Recovery Manager: Release 12.1.0.2.0 - Production on Mon Nov 16 12:42:38 2015

Copyright (c) 1982, 2014, Oracle and/or its affiliates.  All rights reserved.

backup database;
connected to target database: CDB2 (DBID=600824249)

Starting backup at 16-NOV-15
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=193 device type=DISK
channel ORA_DISK_1: starting full datafile backup set
...
... a lot of lines omitted,
... RMAN creates one backupset for each PDB.
...
Finished backup at 16-NOV-15

Starting Control File and SPFILE Autobackup at 16-NOV-15
piece handle=/home/oracle/fra/CDB2/autobackup/2015_11_16/o1_mf_s_895927547_c4mmzw1t_.bkp comment=NONE
Finished Control File and SPFILE Autobackup at 16-NOV-15

In order to make use of the backup on the standby side, the standby must know about this backup. We could either use RMAN catalog, or simply register the backup pieces on the standby, having copied the files there first, of course:
catalog start with '/home/oracle/fra/CDB2/';

...

searching for all files that match the pattern /home/oracle/fra/CDB2/

List of Files Unknown to the Database
=====================================
File Name: /home/oracle/fra/CDB2/205A13D4947F11DCE0530100007F5CA4/backupset/2015_11_16/o1_mf_nnndf_TAG20151116T124303_c4mmvjx4_.bkp
File Name: /home/oracle/fra/CDB2/244AEB6C0961185CE0530100007F6410/backupset/2015_11_16/o1_mf_nnndf_TAG20151116T124303_c4mmwhjd_.bkp
...
Do you really want to catalog the above files (enter YES or NO)? YES
cataloging files...
cataloging done

List of Cataloged Files
=======================
File Name: /home/oracle/fra/CDB2/205A13D4947F11DCE0530100007F5CA4/backupset/2015_11_16/o1_mf_nnndf_TAG20151116T124303_c4mmvjx4_.bkp
File Name: /home/oracle/fra/CDB2/244AEB6C0961185CE0530100007F6410/backupset/2015_11_16/o1_mf_nnndf_TAG20151116T124303_c4mmwhjd_.bkp
...

Offlined datafiles, standby file management auto

So let's restore one of the PDBs:
restore pluggable database 'PDBCOPY3';

Starting restore at 16-NOV-15
using channel ORA_DISK_1

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 00020 to /oradata2/CDB2SBY/pdbcopy3/system01.dbf
channel ORA_DISK_1: restoring datafile 00021 to /oradata2/CDB2SBY/pdbcopy3/sysaux01.dbf
channel ORA_DISK_1: reading from backup piece /home/oracle/fra/CDB2/246FA48B945F1085E0530100007FDD58/backupset/2015_11_16/o1_mf_nnndf_TAG20151116T124303_c4mmyf0t_.bkp
channel ORA_DISK_1: ORA-19870: error while restoring backup piece /home/oracle/fra/CDB2/246FA48B945F1085E0530100007FDD58/backupset/2015_11_16/o1_mf_nnndf_TAG20151116T124303_c4mmyf0t_.bkp
ORA-19504: failed to create file "/oradata2/CDB2SBY/pdbcopy3/sysaux01.dbf"
ORA-27040: file create error, unable to create file
Linux-x86_64 Error: 2: No such file or directory
Additional information: 1

failover to previous backup

RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-03002: failure of restore command at 11/16/2015 12:47:19
RMAN-06026: some targets not found - aborting restore
RMAN-06023: no backup or copy of datafile 21 found to restore
RMAN-06023: no backup or copy of datafile 20 found to restore

But wait... no backup of datafile 20 found? How come? We just backed it up and registered here... NO! That's a trap :-) The error itself is hidden few lines above: failed to create file "/oradata2/CDB2SBY/pdbcopy3/sysaux01.dbf So we need to actually create the path manually first:
!mkdir /oradata2/CDB2SBY/pdbcopy3

restore pluggable database pdbcopy3;

Starting restore at 16-NOV-15
using channel ORA_DISK_1

skipping datafile 20; already restored to file /oradata2/CDB2SBY/pdbcopy3/system01.dbf
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 00021 to /oradata2/CDB2SBY/pdbcopy3/sysaux01.dbf
channel ORA_DISK_1: reading from backup piece /home/oracle/fra/CDB2/246FA48B945F1085E0530100007FDD58/backupset/2015_11_16/o1_mf_nnndf_TAG20151116T124303_c4mmyf0t_.bkp
channel ORA_DISK_1: piece handle=/home/oracle/fra/CDB2/246FA48B945F1085E0530100007FDD58/backupset/2015_11_16/o1_mf_nnndf_TAG20151116T124303_c4mmyf0t_.bkp tag=TAG20151116T124303
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:00:07
Finished restore at 16-NOV-15


recover pluggable database pdbcopy3;

Starting recover at 16-NOV-15
using channel ORA_DISK_1

RMAN-00571: ===========================================================
RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS ===============
RMAN-00571: ===========================================================
RMAN-03002: failure of recover command at 11/16/2015 12:51:00
RMAN-06067: RECOVER DATABASE required with a backup or created control file

So we have restored the files ok, but RMAN cannot recover them by itself, so some additional steps are required. But the good news is that the standby recovery process will do this for us.
There is just one more step necessary before this; although the files are there on the standby server, the database marks them as offline. One can query v$datafile, or just do the usual check of the alert.log, and see the following:
Warning: Datafile 20 (/oradata/CDB2/pdbcopy3/system01.dbf) is offline during full database recovery and will not be recovered
Warning: Datafile 21 (/oradata/CDB2/pdbcopy3/sysaux01.dbf) is offline during full database recovery and will not be recovered

So let's finish off with this PDB, by onlining the datafiles and setting to recover mode:
alter session set container=pdbcopy3;

Session altered.

alter database datafile 20 online;

Database altered.

alter database datafile 21 online;

Database altered.

alter session set container=cdb$root;

Session altered.

alter database recover managed standby database;

And the standby database will then happily hum along.


Skipped standby

Does the picture change with the new STANDBYS clause introduced in 12.1.0.2? Indeed it does, but not dramatically.
First of all, the files don't have the proper names in v$datafile, as with standby_file_management=manual. This means we must set the new file names in the RMAN script and then switch to them:
run {
set newname for datafile 22 to '/oradata2/CDB2SBY/pdbcopy4/system.dbf';
set newname for datafile 23 to '/oradata2/CDB2SBY/pdbcopy4/sysaux.dbf';
restore pluggable database pdbcopy4;
}

executing command: SET NEWNAME

executing command: SET NEWNAME

Starting restore at 16-NOV-15
using channel ORA_DISK_1

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 00022 to /oradata2/CDB2SBY/pdbcopy4/system.dbf
channel ORA_DISK_1: restoring datafile 00023 to /oradata2/CDB2SBY/pdbcopy4/sysaux.dbf
channel ORA_DISK_1: reading from backup piece /home/oracle/fra/CDB2/246FA48B94601085E0530100007FDD58/backupset/2015_11_16/o1_mf_nnndf_TAG20151116T124303_c4mmywdq_.bkp
channel ORA_DISK_1: piece handle=/home/oracle/fra/CDB2/246FA48B94601085E0530100007FDD58/backupset/2015_11_16/o1_mf_nnndf_TAG20151116T124303_c4mmywdq_.bkp tag=TAG20151116T124303
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:00:07
Finished restore at 16-NOV-15

switch datafile 22 to datafilecopy;
datafile 22 switched to datafile copy "/oradata2/CDB2SBY/pdbcopy4/system.dbf"

switch datafile 23 to datafilecopy;
datafile 23 switched to datafile copy "/oradata2/CDB2SBY/pdbcopy4/sysaux.dbf"

The second difference is around how to bring the datafiles online. Instead of running alter online, we must enable recovery of the PDB itself:
alter session set container=pdbcopy4;

Session altered.

alter database datafile 22 online
*
ERROR at line 1:
ORA-65152: cannot bring datafile online

!oerr ora 65152
65152, 00000, "cannot bring datafile online"
// *Cause:   An attempt was made to bring online one or more datafiles
//           belonging to a pluggable database that is disabled for recovery.
// *Action:  Issue the ALTER PLUGGABLE DATABASE ENABLE RECOVERY statement first
//           and retry the operation.
//

alter pluggable database enable recovery;

Pluggable database altered.
alter session set container=cdb$root;

Session altered.

alter database recover managed standby database;

And once again, following these steps, the PDB is now properly recovered by the standby, ready for a switchover or failover.

Comments

Popular posts from this blog

ORA-27048: skgfifi: file header information is invalid

I was asked to analyze a situation, when an attempt to recover a 11g (standby) database resulted in bunch of "ORA-27048: skgfifi: file header information is invalid" errors. I tried to reproduce the error on my test system, using different versions (EE, SE, 11.1.0.6, 11.1.0.7), but to no avail. Fortunately, I finally got to the failing system: SQL> recover standby database; ORA-00279: change 9614132 generated at 11/27/2009 17:59:06 needed for thread 1 ORA-00289: suggestion : /u01/flash_recovery_area/T1/archivelog/2009_11_27/o1_mf_1_208_%u_.arc ORA-27048: skgfifi: file header information is invalid ORA-27048: skgfifi: file header information is invalid ORA-27048: skgfifi: file header information is invalid ORA-27048: skgfifi: file header information is invalid ORA-27048: skgfifi: file header information is invalid ORA-27048: skgfifi: file header information is invalid ORA-00280: change 9614132 for thread 1 is in sequence #208 Interestingly, nothing interesting is written to

Multitenant and standby: subsetting

In the previous post we looked at managing new PDBs added to a standby database, by copying the files to the DR server, as required. However, there is another possible approach, and that is to omit the PDB from the standby configuration altogether. There are two ways of achieving this: 1. Do it the old-school way. A long time before 12c arrived on the scene one could offline a datafile on the standby database to remove it. The same trick is used in TSPITR (tablespace point-in-time recovery), so that you don't need to restore and recover the entire database if you are only after some tablespaces. 2. 12.1.0.2 adds the option to automatically exclude the PDB from standby(s). And 12.2 adds the option to be more specific in case of multiple standbys. For the sake of curiosity I started by setting standby file management to manual again. What I found is that there was very little difference, and the steps to take are exactly the same - it’s just the error message that is slightly