Posts Tagged Backup & Recovery

New 12c Default: Controlfile Autobackup On – But only for Multitenant

This a a little discovery from my present Oracle Database 12c New Features course in Copenhagen: The default setting for Controlfile Autobackup has changed to ON – but only for Multitenant, apparently:

$ rman target sys/oracle_4U@cdb1

Recovery Manager: Release 12.1.0.1.0 - Production on Wed Sep 24 13:28:39 2014

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

connected to target database: CDB1 (DBID=832467154)

RMAN> select cdb from v$database;

using target database control file instead of recovery catalog
CDB
---
YES

RMAN> show controlfile autobackup;

RMAN configuration parameters for database with db_unique_name CDB1 are:
CONFIGURE CONTROLFILE AUTOBACKUP ON; # default

Above you see the setting for a container database (CDB). Now an ordinary (Non-CDB) 12c Database:

$ rman target sys/oracle_4U@orcl

Recovery Manager: Release 12.1.0.1.0 - Production on Wed Sep 24 13:33:27 2014

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

connected to target database: ORCL (DBID=1386527354)

RMAN> select cdb from v$database;

using target database control file instead of recovery catalog
CDB
---
NO

RMAN> show controlfile autobackup;

RMAN configuration parameters for database with db_unique_name ORCL are:
CONFIGURE CONTROLFILE AUTOBACKUP OFF; # default

I really wonder why we have this difference! Is that still so with 12.1.0.2? Don’t believe it, test it! :-)

About these ads

, , ,

1 Comment

Restore datafile from service: A cool #Oracle 12c Feature

You can restore a datafile directly from a physical standby database to the primary. Over the network. With compressed backupsets. How cool is that?

Here’s a demo from my present class Oracle Database 12c: Data Guard Administration. prima is the primary database on host01, physt is a physical standby database on host03. There is an Oracle Net configuration on both hosts that enable host01 to tnsping physt and host03 to tnsping prima

 

[oracle@host01 ~]$ rman target sys/oracle@prima

Recovery Manager: Release 12.1.0.1.0 - Production on Wed Jul 2 16:43:39 2014

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

connected to target database: PRIMA (DBID=2084081935)

RMAN> run
{
set newname for datafile 4 to '/home/oracle/stage/users01.dbf';
restore (datafile 4 from service physt) using compressed backupset;
catalog datafilecopy '/home/oracle/stage/users01.dbf';
}

executing command: SET NEWNAME

Starting restore at 02-JUL-14
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=47 device type=DISK

channel ORA_DISK_1: starting datafile backup set restore
channel ORA_DISK_1: using compressed network backup set from service physt
channel ORA_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_DISK_1: restoring datafile 00004 to /home/oracle/stage/users01.dbf
channel ORA_DISK_1: restore complete, elapsed time: 00:00:07
Finished restore at 02-JUL-14

cataloged datafile copy
datafile copy file name=/home/oracle/stage/users01.dbf RECID=8 STAMP=851877850

This does not require backups taken on the physical standby database.

, ,

4 Comments

Backup & Restore one Datafile in Parallel

A lesser known 11g New Feature is the option to backup and restore single large datafiles with multiple channels in parallel, which can speed up these processes dramatically. This posting is supposed to give an example for it.

SQL> select * from v$version;
BANNER
 --------------------------------------------------------------------------------
 Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
 PL/SQL Release 11.2.0.3.0 - Production
 CORE    11.2.0.3.0    Production
 TNS for Linux: Version 11.2.0.3.0 - Production
 NLSRTL Version 11.2.0.3.0 - Production
SQL> select file#,bytes/1024/1024 as mb from v$datafile;
FILE#       MB
 ---------- ----------
 1                300
 2                200
 3                179
 4               2136

My demo system is on 11gR2, but the feature was there in 11gR1 already – it is easy to miss and just keep the old backup scripts in place like with 10g, though, where one channel could only read one datafile. bk is the same service that we have seen in a previous posting. I will now just backup & restore datafile 4 to show this can be done with two channels:

[oracle@uhesse1 ~]$ time rman target sys/oracle@uhesse1/bk cmdfile=backup_par.rmn
Recovery Manager: Release 11.2.0.3.0 - Production on Wed Dec 12 21:20:49 2012
Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.
connected to target database: PRIMA (DBID=2003897072)
RMAN> configure device type disk parallelism 2;
 2> backup datafile 4 section size 1100m;
 3>
 using target database control file instead of recovery catalog
 old RMAN configuration parameters:
 CONFIGURE DEVICE TYPE DISK PARALLELISM 1 BACKUP TYPE TO BACKUPSET;
 new RMAN configuration parameters:
 CONFIGURE DEVICE TYPE DISK PARALLELISM 2 BACKUP TYPE TO BACKUPSET;
 new RMAN configuration parameters are successfully stored
Starting backup at 2012-12-12:21:20:50
 allocated channel: ORA_DISK_1
 channel ORA_DISK_1: SID=24 device type=DISK
 allocated channel: ORA_DISK_2
 channel ORA_DISK_2: SID=9 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=00004 name=/home/oracle/prima/users01.dbf
 backing up blocks 1 through 140800
 channel ORA_DISK_1: starting piece 1 at 2012-12-12:21:20:51
 channel ORA_DISK_2: starting full datafile backup set
 channel ORA_DISK_2: specifying datafile(s) in backup set
 input datafile file number=00004 name=/home/oracle/prima/users01.dbf
 backing up blocks 140801 through 273408
 channel ORA_DISK_2: starting piece 2 at 2012-12-12:21:20:51
 channel ORA_DISK_2: finished piece 2 at 2012-12-12:21:21:46
 piece handle=/home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3kr_.bkp tag=TAG20121212T212051 comment=NONE
 channel ORA_DISK_2: backup set complete, elapsed time: 00:00:55
 channel ORA_DISK_1: finished piece 1 at 2012-12-12:21:22:06
 piece handle=/home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3bm_.bkp tag=TAG20121212T212051 comment=NONE
 channel ORA_DISK_1: backup set complete, elapsed time: 00:01:15
 Finished backup at 2012-12-12:21:22:06
Recovery Manager complete.
real    1m17.681s
 user    0m1.356s
 sys    0m0.129s

The script backup_par.rmn contains these lines:

[oracle@uhesse1 ~]$ cat backup_par.rmn
 configure device type disk parallelism 2;
 backup datafile 4 section size 1100m;

As you can see, the two channels were running in parallel, each taking about 1 minute to backup its section into a separate backupset. Also the restore can now be done in parallel for a single datafile:

[oracle@uhesse1 ~]$ time rman target sys/oracle@uhesse1/bk cmdfile=restore_par.rmn
Recovery Manager: Release 11.2.0.3.0 - Production on Wed Dec 12 21:23:28 2012
Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.
 connected to target database: PRIMA (DBID=2003897072)
RMAN> configure device type disk parallelism 2;
 2> sql "alter database datafile 4 offline";
 3> restore datafile 4;
 4> recover datafile 4;
 5> sql "alter database datafile 4 online";
 6>
 7>
 using target database control file instead of recovery catalog
 old RMAN configuration parameters:
 CONFIGURE DEVICE TYPE DISK PARALLELISM 2 BACKUP TYPE TO BACKUPSET;
 new RMAN configuration parameters:
 CONFIGURE DEVICE TYPE DISK PARALLELISM 2 BACKUP TYPE TO BACKUPSET;
 new RMAN configuration parameters are successfully stored
sql statement: alter database datafile 4 offline
Starting restore at 2012-12-12:21:23:30
 allocated channel: ORA_DISK_1
 channel ORA_DISK_1: SID=9 device type=DISK
 allocated channel: ORA_DISK_2
 channel ORA_DISK_2: SID=24 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 00004 to /home/oracle/prima/users01.dbf
 channel ORA_DISK_1: restoring section 1 of 2
 channel ORA_DISK_1: reading from backup piece /home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3bm_.bkp
 channel ORA_DISK_2: starting datafile backup set restore
 channel ORA_DISK_2: specifying datafile(s) to restore from backup set
 channel ORA_DISK_2: restoring datafile 00004 to /home/oracle/prima/users01.dbf
 channel ORA_DISK_2: restoring section 2 of 2
 channel ORA_DISK_2: reading from backup piece /home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3kr_.bkp
 channel ORA_DISK_2: piece handle=/home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3kr_.bkp tag=TAG20121212T212051
 channel ORA_DISK_2: restored backup piece 2
 channel ORA_DISK_2: restore complete, elapsed time: 00:02:05
 channel ORA_DISK_1: piece handle=/home/oracle/flashback/PRIMA/backupset/2012_12_12/o1_mf_nnndf_TAG20121212T212051_8dkss3bm_.bkp tag=TAG20121212T212051
 channel ORA_DISK_1: restored backup piece 1
 channel ORA_DISK_1: restore complete, elapsed time: 00:02:16
 Finished restore at 2012-12-12:21:25:46
Starting recover at 2012-12-12:21:25:46
 using channel ORA_DISK_1
 using channel ORA_DISK_2
starting media recovery
 media recovery complete, elapsed time: 00:00:01
Finished recover at 2012-12-12:21:25:48
sql statement: alter database datafile 4 online
Recovery Manager complete.
real    2m20.137s
 user    0m1.229s
 sys    0m0.187s

This is the script I have used for the restore:

[oracle@uhesse1 ~]$ cat restore_par.rmn
 configure device type disk parallelism 2;
 sql "alter database datafile 4 offline";
 restore datafile 4;
 recover datafile 4;
 sql "alter database datafile 4 online";

Conclusion: Multisection backup & restore can be very useful for the processing of large (bigfile) datafiles with multiple channels in parallel. If you have not done it yet, you should definitely give it a try! As always: Don’t believe it, test it :-)

Addendum: With 12c, this feature got enhanced to support also image copies.

, , ,

6 Comments

Follow

Get every new post delivered to your Inbox.

Join 2,802 other followers

%d bloggers like this: