Beiträge getaggt mit Backup & Recovery
FLASHBACK PLUGGABLE DATABASE now available in #Oracle 12cR2
With the current release 12.2, flashback can be done on the PDB layer. As a prerequisite, the database must be put into local undo mode. That means that each PDB has its own undo tablespace. Some other 12.2 features like hot PDB cloning also require this, so chances are that most 12cR2 multitenant databases will be using that mode.
SQL> select banner from v$version; BANNER -------------------------------------------------------------------- Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Pr oduction PL/SQL Release 12.2.0.1.0 - Production CORE 12.2.0.1.0 Production TNS for Linux: Version 12.2.0.1.0 - Production NLSRTL Version 12.2.0.1.0 - Production SQL> select name,open_mode,con_id from v$pdbs; NAME OPEN_MODE CON_ID --------------- ---------- ------ PDB$SEED READ ONLY 2 PDB1 READ WRITE 3 SQL> select name,con_id from v$tablespace; NAME CON_ID --------------- ------ SYSAUX 1 SYSTEM 1 UNDOTBS1 1 USERS 1 TEMP 1 SYSTEM 2 SYSAUX 2 SYSTEM 3 TEMP 2 SYSAUX 3 TEMP 3 11 rows selected.
Initially, this database operates in what we call now shared undo mode: There is only one undo tablespace in the root container that is shared by all PDBs. Let’s change that to local undo mode:
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup upgrade
ORACLE instance started.
Total System Global Area 1426063360 bytes
Fixed Size 8792776 bytes
Variable Size 486540600 bytes
Database Buffers 922746880 bytes
Redo Buffers 7983104 bytes
Database mounted.
Database opened.
SQL> alter database local undo on;
Database altered.
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup
ORACLE instance started.
Total System Global Area 1426063360 bytes
Fixed Size 8792776 bytes
Variable Size 486540600 bytes
Database Buffers 922746880 bytes
Redo Buffers 7983104 bytes
Database mounted.
Database opened.
SQL> select name,con_id from v$tablespace;
NAME CON_ID
--------------- ------
SYSAUX 1
SYSTEM 1
UNDOTBS1 1
USERS 1
TEMP 1
SYSTEM 2
SYSAUX 2
SYSTEM 3
TEMP 2
SYSAUX 3
TEMP 3
UNDO_1 2
12 rows selected.
CON_ID 2 is the seed PDB, which got a local undo tablespace already. The pdb1 gets it as soon as it is opened:
SQL> alter pluggable database all open; SQL> select name,con_id from v$tablespace; NAME CON_ID ---------- ------ SYSAUX 1 SYSTEM 1 UNDOTBS1 1 USERS 1 TEMP 1 SYSTEM 2 SYSAUX 2 SYSTEM 3 TEMP 2 SYSAUX 3 TEMP 3 UNDO_1 2 UNDO_1 3 SQL> select name from v$datafile where con_id=3; NAME -------------------------------------------------------------------- /u02/app/oracle/oradata/pdb1/system01.dbf /u02/app/oracle/oradata/pdb1/sysaux01.dbf /u02/app/oracle/oradata/pdb1/pdb1_i1_undo.dbf
Now to the flashback!
SQL> select flashback_on from v$database; FLASHBACK_ON ------------------ YES SQL> alter pluggable database pdb1 close immediate; Pluggable database altered. SQL> flashback pluggable database pdb1 to timestamp systimestamp - interval '2' minute; Flashback complete. SQL> alter pluggable database pdb1 open resetlogs; Pluggable database altered.
Of course, that works much faster than a PDB PITR 🙂
How to speed up Data Pump Import by suppressing redo generation in #Oracle 12c
With your database in archive log mode, a Data Pump Import may be severely slowed down by the writing of much redo into online logs and the the generation of many archive logs. A 12c New Feature enables you to avoid that slow down by suppressing redo generation for the import only. You can keep the database in archive log mode the whole time. Let’s see that in action!
First without the new feature:
[oracle@uhesse ~]$ sqlplus adam/adam SQL*Plus: Release 12.1.0.2.0 Production on Tue Oct 25 20:25:25 2016 Copyright (c) 1982, 2014, Oracle. All rights reserved. Last Successful login time: Tue Oct 25 2016 20:24:55 +02:00 Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options SQL> select log_mode from v$database; LOG_MODE ------------------------------------ ARCHIVELOG SQL> select * from v$recovery_area_usage; FILE_TYPE PERCENT_SPACE_USED PERCENT_SPACE_RECLAIMABLE NUMBER_OF_FILES CON_ID ------------------------------ ------------------ ------------------------- --------------- ---------- CONTROL FILE 0 0 0 0 REDO LOG 0 0 0 0 ARCHIVED LOG 15.37 15 10 0 BACKUP PIECE 25.17 0 2 0 IMAGE COPY 0 0 0 0 FLASHBACK LOG 0 0 0 0 FOREIGN ARCHIVED LOG 0 0 0 0 AUXILIARY DATAFILE COPY 0 0 0 0 8 rows selected. SQL> exit Disconnected from Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options [oracle@uhesse ~]$ impdp adam/adam tables=sales directory=DPDIR Import: Release 12.1.0.2.0 - Production on Tue Oct 25 20:26:45 2016 Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved. Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options Master table "ADAM"."SYS_IMPORT_TABLE_01" successfully loaded/unloaded Starting "ADAM"."SYS_IMPORT_TABLE_01": adam/******** tables=sales directory=DPDIR Processing object type TABLE_EXPORT/TABLE/TABLE Processing object type TABLE_EXPORT/TABLE/TABLE_DATA . . imported "ADAM"."SALES" 510.9 MB 10000000 rows Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER Job "ADAM"."SYS_IMPORT_TABLE_01" successfully completed at Tue Oct 25 20:29:46 2016 elapsed 0 00:03:00 [oracle@uhesse ~]$ sqlplus adam/adam SQL*Plus: Release 12.1.0.2.0 Production on Tue Oct 25 20:30:03 2016 Copyright (c) 1982, 2014, Oracle. All rights reserved. Last Successful login time: Tue Oct 25 2016 20:26:45 +02:00 Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options SQL> select * from v$recovery_area_usage; FILE_TYPE PERCENT_SPACE_USED PERCENT_SPACE_RECLAIMABLE NUMBER_OF_FILES CON_ID ------------------------------ ------------------ ------------------------- --------------- ---------- CONTROL FILE 0 0 0 0 REDO LOG 0 0 0 0 ARCHIVED LOG 30.63 15 17 0 BACKUP PIECE 25.17 0 2 0 IMAGE COPY 0 0 0 0 FLASHBACK LOG 0 0 0 0 FOREIGN ARCHIVED LOG 0 0 0 0 AUXILIARY DATAFILE COPY 0 0 0 0 8 rows selected.
The import took 3 minutes and generated 7 archive logs. Now with the new feature:
SQL> drop table sales purge; Table dropped. SQL> exit Disconnected from Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options [oracle@uhesse ~]$ impdp adam/adam tables=adam.sales directory=DPDIR transform=disable_archive_logging:Y Import: Release 12.1.0.2.0 - Production on Tue Oct 25 20:31:20 2016 Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved. Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options Master table "ADAM"."SYS_IMPORT_TABLE_01" successfully loaded/unloaded Starting "ADAM"."SYS_IMPORT_TABLE_01": adam/******** tables=adam.sales directory=DPDIR transform=disable_archive_logging:Y Processing object type TABLE_EXPORT/TABLE/TABLE Processing object type TABLE_EXPORT/TABLE/TABLE_DATA . . imported "ADAM"."SALES" 510.9 MB 10000000 rows Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER Job "ADAM"."SYS_IMPORT_TABLE_01" successfully completed at Tue Oct 25 20:32:15 2016 elapsed 0 00:00:54 [oracle@uhesse ~]$ sqlplus adam/adam SQL*Plus: Release 12.1.0.2.0 Production on Tue Oct 25 20:32:25 2016 Copyright (c) 1982, 2014, Oracle. All rights reserved. Last Successful login time: Tue Oct 25 2016 20:31:20 +02:00 Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options SQL> select * from v$recovery_area_usage; FILE_TYPE PERCENT_SPACE_USED PERCENT_SPACE_RECLAIMABLE NUMBER_OF_FILES CON_ID ------------------------------ ------------------ ------------------------- --------------- ---------- CONTROL FILE 0 0 0 0 REDO LOG 0 0 0 0 ARCHIVED LOG 30.63 15 17 0 BACKUP PIECE 25.17 0 2 0 IMAGE COPY 0 0 0 0 FLASHBACK LOG 0 0 0 0 FOREIGN ARCHIVED LOG 0 0 0 0 AUXILIARY DATAFILE COPY 0 0 0 0 8 rows selected. SQL> select logging from user_tables where table_name='SALES'; LOGGING --------- YES
About three times faster and no archive log generated! The table is still in logging mode after the import. Keep in mind to take a backup of the datafile that contains the table now, though! For the same reason you should take a backup after a NOLOGGING operation 🙂
How to do PDB PITR in #Oracle 12c
A logical error happened in one Pluggable Database. A PDB Point-In-Time-Recovery rewinds it while the others remain available and stay as they are.

Logical error in PDB2
The blue arrow represents the Multitenant Database cdb1 with all its containers. A while back in the past, a logical error affected only pdb2. cdb1 is in Archive Log Mode and backups from before the logical error of at least the root container and pdb2 are available. What happens now upon PDB PITR is quite similar to a Tablespace PITR: Backups of root and pdb2 are being restored. All other PDBs can be skipped. A PITR to rewind pdb2 only is done with the help of a temporary instance while cdb1 keeps running. Space is needed to restore the root container files to an auxiliary destination, while the pdb2 files will be restored over the existing files from pdb2:

PDB PITR
Let’s see that in action!
[oracle@uhesse ~]$ export NLS_LANG=american_america.utf8 [oracle@uhesse ~]$ export NLS_DATE_FORMAT='yyyy-mm-dd hh24:mi:ss' [oracle@uhesse ~]$ sqlplus sys/oracle_4U@pdb2 as sysdba SQL> select * from scott.dept; DEPTNO DNAME LOC ------ ---------- ---------- 10 ACCOUNTING NEW YORK 20 RESEARCH DALLAS 30 SALES CHICAGO 40 OPERATIONS BOSTON SQL> select sysdate from dual; SYSDATE ------------------- 2016-09-27 15:06:08 SQL> drop user scott cascade; User dropped.
The drop user stands for the logical error. Now to the PDB PITR:
SQL> alter pluggable database pdb2 close immediate; Pluggable database altered. SQL> exit Disconnected from Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options [oracle@edvmr1p0 ~]$ rman target / RMAN> run{set until time='2016-09-27 15:06:05';restore pluggable database pdb2; recover pluggable database pdb2 auxiliary destination '/home/oracle/'; alter pluggable database pdb2 open resetlogs;} executing command: SET until clause Starting restore at 2016-09-27 15:09:38 using target database control file instead of recovery catalog allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=279 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 00012 to /u01/app/oracle/oradata/pdb2/system01.dbf channel ORA_DISK_1: restoring datafile 00013 to /u01/app/oracle/oradata/pdb2/sysaux01.dbf channel ORA_DISK_1: restoring datafile 00014 to /u01/app/oracle/oradata/pdb2/users01.dbf channel ORA_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/CDB1/3D69FAB014BF7D48E0532A40CE0A8038/backupset/2016_09_27/o1_mf_nnndf_TAG20160927T101919_cynkyhtd_.bkp channel ORA_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/CDB1/3D69FAB014BF7D48E0532A40CE0A8038/backupset/2016_09_27/o1_mf_nnndf_TAG20160927T101919_cynkyhtd_.b kp tag=TAG20160927T101919 channel ORA_DISK_1: restored backup piece 1 channel ORA_DISK_1: restore complete, elapsed time: 00:00:15 Finished restore at 2016-09-27 15:09:55 Starting recover at 2016-09-27 15:09:55 current log archived using channel ORA_DISK_1 RMAN-05026: WARNING: presuming following set of tablespaces applies to specified Point-in-Time List of tablespaces expected to have UNDO segments Tablespace SYSTEM Tablespace UNDOTBS1 Creating automatic instance, with SID='gkon' initialization parameters used for automatic instance: db_name=CDB1 db_unique_name=gkon_pitr_pdb2_CDB1 compatible=12.1.0.2.0 db_block_size=8192 db_files=200 diagnostic_dest=/u01/app/oracle _system_trig_enabled=FALSE sga_target=752M processes=200 db_create_file_dest=/home/oracle/ log_archive_dest_1='location=/home/oracle/' enable_pluggable_database=true _clone_one_pdb_recovery=true #No auxiliary parameter file used starting up automatic instance CDB1 Oracle instance started Total System Global Area 788529152 bytes Fixed Size 2929352 bytes Variable Size 218107192 bytes Database Buffers 562036736 bytes Redo Buffers 5455872 bytes Automatic instance created contents of Memory Script: { # set requested point in time set until time "2016-09-27 15:06:05"; # restore the controlfile restore clone controlfile; # mount the controlfile sql clone 'alter database mount clone database'; } executing Memory Script executing command: SET until clause Starting restore at 2016-09-27 15:10:10 allocated channel: ORA_AUX_DISK_1 channel ORA_AUX_DISK_1: SID=165 device type=DISK channel ORA_AUX_DISK_1: starting datafile backup set restore channel ORA_AUX_DISK_1: restoring control file channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/CDB1/autobackup/2016_09_27/o1_mf_s_923661139_cynspmom_.bkp channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/CDB1/autobackup/2016_09_27/o1_mf_s_923661139_cynspmom_.bkp tag=TAG20160927T123219 channel ORA_AUX_DISK_1: restored backup piece 1 channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01 output file name=/home/oracle/CDB1/controlfile/o1_mf_cyo2ymfv_.ctl Finished restore at 2016-09-27 15:10:12 sql statement: alter database mount clone database contents of Memory Script: { # set requested point in time set until time "2016-09-27 15:06:05"; # switch to valid datafilecopies switch clone datafile 12 to datafilecopy "/u01/app/oracle/oradata/pdb2/system01.dbf"; switch clone datafile 13 to datafilecopy "/u01/app/oracle/oradata/pdb2/sysaux01.dbf"; switch clone datafile 14 to datafilecopy "/u01/app/oracle/oradata/pdb2/users01.dbf"; # set destinations for recovery set and auxiliary set datafiles set newname for clone datafile 1 to new; set newname for clone datafile 4 to new; set newname for clone datafile 3 to new; set newname for clone datafile 6 to new; # restore the tablespaces in the recovery set and the auxiliary set restore clone datafile 1, 4, 3, 6; switch clone datafile all; } executing Memory Script executing command: SET until clause datafile 12 switched to datafile copy input datafile copy RECID=7 STAMP=923670618 file name=/u01/app/oracle/oradata/pdb2/system01.dbf datafile 13 switched to datafile copy input datafile copy RECID=8 STAMP=923670618 file name=/u01/app/oracle/oradata/pdb2/sysaux01.dbf datafile 14 switched to datafile copy input datafile copy RECID=9 STAMP=923670618 file name=/u01/app/oracle/oradata/pdb2/users01.dbf executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME executing command: SET NEWNAME Starting restore at 2016-09-27 15:10:17 using channel ORA_AUX_DISK_1 channel ORA_AUX_DISK_1: starting datafile backup set restore channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set channel ORA_AUX_DISK_1: restoring datafile 00001 to /home/oracle/CDB1/datafile/o1_mf_system_%u_.dbf channel ORA_AUX_DISK_1: restoring datafile 00004 to /home/oracle/CDB1/datafile/o1_mf_undotbs1_%u_.dbf channel ORA_AUX_DISK_1: restoring datafile 00003 to /home/oracle/CDB1/datafile/o1_mf_sysaux_%u_.dbf channel ORA_AUX_DISK_1: restoring datafile 00006 to /home/oracle/CDB1/datafile/o1_mf_users_%u_.dbf channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/fast_recovery_area/CDB1/backupset/2016_09_27/o1_mf_nnndf_TAG20160927T101919_cynkxps1_.bkp channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/fast_recovery_area/CDB1/backupset/2016_09_27/o1_mf_nnndf_TAG20160927T101919_cynkxps1_.bkp tag=TAG20160927T101919 channel ORA_AUX_DISK_1: restored backup piece 1 channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:25 Finished restore at 2016-09-27 15:10:42 datafile 1 switched to datafile copy input datafile copy RECID=14 STAMP=923670642 file name=/home/oracle/CDB1/datafile/o1_mf_system_cyo2yshr_.dbf datafile 4 switched to datafile copy input datafile copy RECID=15 STAMP=923670642 file name=/home/oracle/CDB1/datafile/o1_mf_undotbs1_cyo2ysjc_.dbf datafile 3 switched to datafile copy input datafile copy RECID=16 STAMP=923670642 file name=/home/oracle/CDB1/datafile/o1_mf_sysaux_cyo2ysj1_.dbf datafile 6 switched to datafile copy input datafile copy RECID=17 STAMP=923670642 file name=/home/oracle/CDB1/datafile/o1_mf_users_cyo2ysjr_.dbf contents of Memory Script: { # set requested point in time set until time "2016-09-27 15:06:05"; # online the datafiles restored or switched sql clone "alter database datafile 1 online"; sql clone "alter database datafile 4 online"; sql clone "alter database datafile 3 online"; sql clone 'PDB2' "alter database datafile 12 online"; sql clone 'PDB2' "alter database datafile 13 online"; sql clone 'PDB2' "alter database datafile 14 online"; sql clone "alter database datafile 6 online"; # recover pdb recover clone database tablespace "SYSTEM", "UNDOTBS1", "SYSAUX", "USERS" pluggable database 'PDB2' delete archivelog; sql clone 'alter database open read only'; plsql <<>>; plsql <<>>; # shutdown clone before import shutdown clone abort plsql << 'PDB2'); end; >>>; } executing Memory Script executing command: SET until clause sql statement: alter database datafile 1 online sql statement: alter database datafile 4 online sql statement: alter database datafile 3 online sql statement: alter database datafile 12 online sql statement: alter database datafile 13 online sql statement: alter database datafile 14 online sql statement: alter database datafile 6 online Starting recover at 2016-09-27 15:10:43 using channel ORA_AUX_DISK_1 starting media recovery archived log for thread 1 with sequence 43 is already on disk as file /u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_43_cynm4w09_.arc archived log for thread 1 with sequence 44 is already on disk as file /u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_44_cynmy3k9_.arc archived log for thread 1 with sequence 45 is already on disk as file /u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_45_cynn3bds_.arc archived log for thread 1 with sequence 46 is already on disk as file /u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_46_cynn3d80_.arc archived log for thread 1 with sequence 47 is already on disk as file /u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_47_cynn6341_.arc archived log for thread 1 with sequence 48 is already on disk as file /u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_48_cynrz3bw_.arc archived log for thread 1 with sequence 49 is already on disk as file /u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_49_cyo2y39z_.arc archived log file name=/u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_43_cynm4w09_.arc thread=1 sequence=43 archived log file name=/u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_44_cynmy3k9_.arc thread=1 sequence=44 archived log file name=/u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_45_cynn3bds_.arc thread=1 sequence=45 archived log file name=/u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_46_cynn3d80_.arc thread=1 sequence=46 archived log file name=/u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_47_cynn6341_.arc thread=1 sequence=47 archived log file name=/u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_48_cynrz3bw_.arc thread=1 sequence=48 archived log file name=/u01/app/oracle/fast_recovery_area/CDB1/archivelog/2016_09_27/o1_mf_1_49_cyo2y39z_.arc thread=1 sequence=49 media recovery complete, elapsed time: 00:00:04 Finished recover at 2016-09-27 15:10:47 sql statement: alter database open read only Oracle instance shut down Removing automatic instance Automatic instance removed auxiliary instance file /home/oracle/CDB1/datafile/o1_mf_sysaux_cyo2ysj1_.dbf deleted auxiliary instance file /home/oracle/CDB1/controlfile/o1_mf_cyo2ymfv_.ctl deleted Finished recover at 2016-09-27 15:10:51 Statement processed
Now how is the state of affairs after the PDB PITR?
RMAN> exit [oracle@uhesse ~]$ sqlplus sys/oracle_4U@pdb2 as sysdba SQL*Plus: Release 12.1.0.2.0 Production on Tue Sep 27 15:19:45 2016 Copyright (c) 1982, 2014, Oracle. All rights reserved. Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options SQL> select count(*) from scott.dept; COUNT(*) ---------- 4 SQL> select DB_INCARNATION#,PDB_INCARNATION#,INCARNATION_TIME from v$pdb_incarnation; DB_INCARNATION# PDB_INCARNATION# INCARNATION_TIME --------------- ---------------- ------------------- 2 2 2016-09-27 15:06:29 2 0 2015-03-17 16:49:58 SQL> connect / as sysdba Connected. SQL> select sequence#,status from v$log; SEQUENCE# STATUS ---------- ------------------------------------------------ 49 INACTIVE 50 CURRENT 48 INACTIVE SQL> select INCARNATION#,RESETLOGS_TIME from v$database_incarnation; INCARNATION# RESETLOGS_TIME ------------ ------------------- 1 2014-07-07 05:38:47 2 2015-03-17 16:49:58
The logical error inside pdb2 is undone! In spite of the RESETLOGS clause, the CDB stays in the same incarnation as before and the Online Logs are not initialized. The new view V$PDB_INCARNATION confirms the creation of a new incarnation for pdb2, though.
I took this from a live demonstration at my present Oracle Database 12c New Features class. It has been done with 12.1, where Flashback on the PDB layer is not available. Hope you find it useful 🙂