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 different. So let’s look at this example:
So for MANUAL:
And for AUTO:
Now we can drop the missing datafile.
However, note that:
1. You need to be in the right container, otherwise you will get a misleading error message.
2. The files appear on the standby one-by-one and each of them stops the apply. So you have to drop, restart recovery, drop, restart recovery, rinse, repeat (and switch containers in the process as needed).
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 different. So let’s look at this example:
create pluggable database pdbcopy2 as clone using '/home/oracle/unplug_pdb.xml' file_name_convert=('/oradata/CDB2/pdbfrompdb','/oradata/CDB2/pdbcopy2');
So for MANUAL:
ALTER DATABASE RECOVER MANAGED STANDBY DATABASE * ERROR at line 1: ORA-00283: recovery session canceled due to errors ORA-07202: sltln: invalid parameter to sltln.
And for AUTO:
ALTER DATABASE RECOVER MANAGED STANDBY DATABASE * ERROR at line 1: ORA-00283: recovery session canceled due to errors ORA-01274: cannot add data file that was originally created as '/oradata/CDB2/pdbcopy3/system01.dbf'
Now we can drop the missing datafile.
However, note that:
1. You need to be in the right container, otherwise you will get a misleading error message.
2. The files appear on the standby one-by-one and each of them stops the apply. So you have to drop, restart recovery, drop, restart recovery, rinse, repeat (and switch containers in the process as needed).
alter database datafile 20 offline drop * ERROR at line 1: ORA-01516: nonexistent log file, data file, or temporary file "20" alter session set container=pdbcopy3; Session altered. select file#, name from v$datafile; FILE# NAME ----- ---------------------------------------- 20 /oradata2/CDB2SBY/pdbcopy3/system01.dbf alter database datafile 20 offline drop; Database altered. ALTER DATABASE RECOVER MANAGED STANDBY DATABASE; * ERROR at line 1: ORA-65040: operation not allowed from within a pluggable database alter session set container=cdb$root; Session altered. ALTER DATABASE RECOVER MANAGED STANDBY DATABASE; ALTER DATABASE RECOVER MANAGED STANDBY DATABASE * ERROR at line 1: ORA-00283: recovery session canceled due to errors ORA-01274: cannot add data file that was originally created as '/oradata/CDB2/pdbcopy3/sysaux01.dbf' alter session set container=pdbcopy3; Session altered. alter database datafile 21 offline drop; Database altered. alter session set container=cdb$root; Session altered. ALTER DATABASE RECOVER MANAGED STANDBY DATABASE;
And let's try with the 12.1.0.2 new feature, specifying standby behavior directly:
After all this activity, what do we see in v$datafile? The UNNAMED files are from manual standby file management and from the STANDBYS=NONE clause.
We can also see minor difference in v$pdbs:
Note that the PDBs are still defined in the standby controlfile and you can switch to it, although you cannot open it, of course:
As with offline datafiles in any other database, you can recover them. But that's a topic for another post.
create pluggable database pdbcopy4 as clone using '/home/oracle/unplug_pdb.xml' file_name_convert=('/oradata/CDB2/pdbfrompdb','/oradata/CDB2/pdbcopy4') standbys=none; Media Recovery Log /home/oracle/fra/CDB2SBY/archivelog/2015_11_13/o1_mf_1_778_c4d4m8q0_.arc Recovery created pluggable database PDBCOPY4 File #22 added to control file as 'UNNAMED00022'. Originally created as: '/oradata/CDB2/pdbcopy4/system01.dbf' because the pluggable database was created with nostandby or the tablespace belonging to the pluggable database is offline. File #23 added to control file as 'UNNAMED00023'. Originally created as: '/oradata/CDB2/pdbcopy4/sysaux01.dbf' because the pluggable database was created with nostandby or the tablespace belonging to the pluggable database is offline.
After all this activity, what do we see in v$datafile? The UNNAMED files are from manual standby file management and from the STANDBYS=NONE clause.
select file#, status, name from v$datafile; FILE# STATUS NAME ----- ------- ------------------------------------------------- 1 SYSTEM /oradata2/CDB2SBY/system01.dbf 2 SYSTEM /oradata2/CDB2SBY/pdbseed/system01.dbf 3 ONLINE /oradata2/CDB2SBY/sysaux01.dbf 4 ONLINE /oradata2/CDB2SBY/pdbseed/sysaux01.dbf 5 ONLINE /oradata2/CDB2SBY/undotbs01.dbf 6 ONLINE /oradata2/CDB2SBY/users01.dbf 7 SYSTEM /oradata2/CDB2SBY/pdb1/system01.dbf 8 ONLINE /oradata2/CDB2SBY/pdb1/sysaux01.dbf 9 ONLINE /oradata2/CDB2SBY/pdb1/users.dbf 10 SYSTEM /oradata2/CDB2SBY/pdbfromseeduser/system01.dbf 11 ONLINE /oradata2/CDB2SBY/pdbfromseeduser/sysaux01.dbf 12 SYSTEM /oradata2/CDB2SBY/pdbfrompdb/system01.dbf 13 ONLINE /oradata2/CDB2SBY/pdbfrompdb/sysaux01.dbf 14 SYSTEM /oradata2/CDB2SBY/pdbfrompdbcopy/system01.dbf 15 ONLINE /oradata2/CDB2SBY/pdbfrompdbcopy/sysaux01.dbf 16 SYSOFF /u01/app/oracle/product/12.1.0.2/dbs/UNNAMED00016 17 RECOVER /u01/app/oracle/product/12.1.0.2/dbs/UNNAMED00017 18 SYSOFF /u01/app/oracle/product/12.1.0.2/dbs/UNNAMED00018 19 RECOVER /u01/app/oracle/product/12.1.0.2/dbs/UNNAMED00019 20 SYSOFF /oradata2/CDB2SBY/pdbcopy3/system01.dbf 21 RECOVER /oradata2/CDB2SBY/pdbcopy3/sysaux01.dbf 22 SYSOFF /u01/app/oracle/product/12.1.0.2/dbs/UNNAMED00022 23 RECOVER /u01/app/oracle/product/12.1.0.2/dbs/UNNAMED00023
We can also see minor difference in v$pdbs:
SQL> select con_id, name, open_mode, recovery_status from v$pdbs; CON_ID NAME OPEN_MODE RECOVERY ------ --------------- ---------- -------- 2 PDB$SEED MOUNTED ENABLED 3 PDB1 MOUNTED ENABLED 4 PDBFROMSEED MOUNTED ENABLED 5 PDBFROMPDB MOUNTED ENABLED 6 PDFROMPDBCOPY MOUNTED ENABLED 7 PDFROMPDBCOPY2 MOUNTED ENABLED 8 PDBCOPY2 MOUNTED ENABLED 9 PDBCOPY3 MOUNTED ENABLED 10 PDBCOPY4 MOUNTED DISABLEDThe last one has recovery disabled, as we used the STANDBYS=NONE clause. The others are being recovered, they just have all their tablespaces offline.
Note that the PDBs are still defined in the standby controlfile and you can switch to it, although you cannot open it, of course:
alter pluggable database pdbcopy3 open * ERROR at line 1: ORA-01147: SYSTEM tablespace file 20 is offline
As with offline datafiles in any other database, you can recover them. But that's a topic for another post.
Comments