Beiträge getaggt mit Backup & Recovery
How do NOLOGGING operations affect RECOVERY?

You are allowed to suppress redo generation for certain statements, especially for CREATE TABLE AS SELECT, INSERT INTO … SELECT and CREATE INDEX. If backups have been taken of the related datafiles after these operations, everything is ok. You simply saved time during the above mentioned operations. But what if these datafiles actually get damaged before a successful backup?
I setup a demo scenario for that:
SQL> grant dba to adam identified by adam; Grant succeeded. SQL> connect adam/adam Connected. SQL> create tablespace tbs datafile '/u01/app/oracle/oradata/orcl/tbs01.dbf' size 100m; Tablespace created. SQL> create table t tablespace tbs as select rownum as id, 'Just some text' as col from dual connect by level <= 1e5; Table created. RMAN> backup tablespace tbs; Starting backup at 15-SEP-09 [...] Finished backup at 15-SEP-09
No NOLOGGING yet, as v$datafile shows. But then I create an index with NOLOGGING:
SQL> select file#,to_char(UNRECOVERABLE_TIME,'yyyy-mm-dd:hh24:mi:ss') from v$datafile where file#=18; FILE# TO_CHAR(UNRECOVERAB ---------- ------------------- 18 SQL> create index i on t(id) tablespace tbs nologging; Index created. SQL> select file#,to_char(UNRECOVERABLE_TIME,'yyyy-mm-dd:hh24:mi:ss') from v$datafile where file#=18; FILE# TO_CHAR(UNRECOVERAB ---------- ------------------- 18 2009-09-15:16:21:18 RMAN> report unrecoverable; using target database control file instead of recovery catalog Report of files that need backup due to unrecoverable operations File Type of Backup Required Name ---- ----------------------- ----------------------------------- 18 full or incremental /u01/app/oracle/oradata/orcl/tbs01.dbf
I pretend the datafile 18 is damaged now, set if offline, restore it from backup and recover it. Of course, the index does not get recovered since we have no redo protocol from the modified index blocks in the archived logs or online logs!
RMAN> sql "alter database datafile 18 offline"; using target database control file instead of recovery catalog sql statement: alter database datafile 18 offline RMAN> restore datafile 18; Starting restore at 15-SEP-09 [...] channel ORA_DISK_1: restore complete, elapsed time: 00:00:03 Finished restore at 15-SEP-09 RMAN> recover datafile 18; Starting recover at 15-SEP-09 using channel ORA_DISK_1 starting media recovery media recovery complete, elapsed time: 00:00:00 Finished recover at 15-SEP-09 RMAN> sql "alter database datafile 18 online"; sql statement: alter database datafile 18 online
If now the index gets used, an error message is raised. But attention: The status of the index does not get UNUSABLE!
SQL> select * from t where id=42; select * from t where id=42 * ERROR at line 1: ORA-01578: ORACLE data block corrupted (file # 18, block # 397) ORA-01110: data file 18: '/u01/app/oracle/oradata/orcl/tbs01.dbf' ORA-26040: Data block was loaded using the NOLOGGING option SQL> select index_name,status,logging from user_indexes where tablespace_name='TBS'; INDEX_NAME STATUS LOG ------------------------------ -------- --- I VALID NO
We can find out what index is causing the problem with the LOGGING column of USER_INDEXES as above. Again attention: We can not simply REBUILD the index now!
SQL> alter index i rebuild nologging; alter index i rebuild nologging * ERROR at line 1: ORA-01578: ORACLE data block corrupted (file # 18, block # 397) ORA-01110: data file 18: '/u01/app/oracle/oradata/orcl/tbs01.dbf' ORA-26040: Data block was loaded using the NOLOGGING option
Only after setting the index to UNUSABLE, we can REBUILD it:
SQL> alter index i unusable; Index altered. SQL> alter index i rebuild nologging; Index altered. SQL> select file#,to_char(UNRECOVERABLE_TIME,'yyyy-mm-dd:hh24:mi:ss') from v$datafile where file#=18; FILE# TO_CHAR(UNRECOVERAB ---------- ------------------- 18 2009-09-15:16:30:36
If we take a RMAN backup now, still v$datafile is not affected, but RMAN does no longer report the file as UNRECOVERABLE:
RMAN> backup tablespace tbs; Starting backup at 15-SEP-09 [...] channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01 Finished backup at 15-SEP-09 RMAN> report unrecoverable; Report of files that need backup due to unrecoverable operations File Type of Backup Required Name ---- ----------------------- -----------------------------------
"No file shown"
How does the table t behave if I now do an INSERT with NOLOGGING into it?
SQL> alter table t nologging; Table altered. SQL> insert /*+ append */ into t select * from t; 100000 rows created. SQL> commit; Commit complete. SQL> select file#,to_char(UNRECOVERABLE_TIME,'yyyy-mm-dd:hh24:mi:ss') from v$datafile where file#=18; FILE# TO_CHAR(UNRECOVERAB ---------- ------------------- 18 2009-09-15:16:34:07 RMAN> sql "alter database datafile 18 offline"; using target database control file instead of recovery catalog sql statement: alter database datafile 18 offline RMAN> restore datafile 18; Starting restore at 15-SEP-09 [...] Finished restore at 15-SEP-09 RMAN> recover datafile 18; Starting recover at 15-SEP-09 using channel ORA_DISK_1 starting media recovery media recovery complete, elapsed time: 00:00:02 Finished recover at 15-SEP-09 RMAN> sql "alter database datafile 18 online"; sql statement: alter database datafile 18 online
I again pretended the file was damaged, restored it from backup and recovered it. As soon as rows are now demanded that got into the table with the direct load via the NOLOGGING operation, error messages are returned:
SQL> select count(*) from t where rownum<=1e5; COUNT(*) ---------- 100000 SQL> select count(*) from t where rownum<=1e5+1; select count(*) from t where rownum<=1e5+1 * ERROR at line 1: ORA-01578: ORACLE data block corrupted (file # 18, block # 368) ORA-01110: data file 18: '/u01/app/oracle/oradata/orcl/tbs01.dbf' ORA-26040: Data block was loaded using the NOLOGGING option
There is no way to get these rows back (at least not with recovery) since we suppressed the redo protocol during their generation. That is the price we pay for the speedup of the insert here…
Incremental Backups with Block Change Tracking & Recover Copy
I am in Berlin this week for an Administration Workshop II course. Unfortunately, it’s raining right now, so it would be no fun to stroll around the capital. Instead, there is time now for me to post something 🙂 Two major areas of that course are Performance Tuning and Backup & Recovery. One interesting feature that we discuss from the latter area is the ability to drastically speed up incremental backups (compared to versions before 10g) and to use these incremental backup for an actualization of level 0 image copies. Let’s look at an example:
SQL> alter database enable block change tracking using file '/home/oracle/bc.ora';
This command brings up the background process Change Tracking Writer (CTWR), that maintains a change tracking file. This file will contain the database block adresses of Oracle Blocks, modified after the next level 0 Full Backup. Because of this file, RMAN no longer has to scan all production datafiles and compare their blocks with the blocks of the level 0 backup in order to determine which blocks have changed. That was a very time consuming process before 10g. Now we will invoke RMAN with the following command:
RMAN> run {
recover copy of database with tag 'backrec';
backup incremental level 1 cumulative copies=1 for recover of copy with tag 'backrec' database;
}
Starting recover at 04-MAY-09
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: sid=127 devtype=DISK
no copy of datafile 1 found to recover
no copy of datafile 2 found to recover
no copy of datafile 3 found to recover
no copy of datafile 4 found to recover
no copy of datafile 5 found to recover
no copy of datafile 6 found to recover
Finished recover at 04-MAY-09
Starting backup at 04-MAY-09
using channel ORA_DISK_1
no parent backup or copy of datafile 1 found
no parent backup or copy of datafile 3 found
no parent backup or copy of datafile 5 found
no parent backup or copy of datafile 2 found
no parent backup or copy of datafile 6 found
no parent backup or copy of datafile 4 found
channel ORA_DISK_1: starting datafile copy
input datafile fno=00001 name=/u01/app/oracle/oradata/orcl/system01.dbf
output filename=/u01/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_system_4zy6pnsg_.dbf tag=BACKREC recid=14 stamp=685996946
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:35
channel ORA_DISK_1: starting datafile copy
input datafile fno=00003 name=/u01/app/oracle/oradata/orcl/sysaux01.dbf
output filename=/u01/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_sysaux_4zy6qqvp_.dbf tag=BACKREC recid=15 stamp=685996969
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:25
channel ORA_DISK_1: starting datafile copy
input datafile fno=00005 name=/u01/app/oracle/oradata/orcl/example01.dbf
output filename=/u01/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_example_4zy6rk0w_.dbf tag=BACKREC recid=16 stamp=685996982
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:07
channel ORA_DISK_1: starting datafile copy
input datafile fno=00002 name=/u01/app/oracle/oradata/orcl/undotbs01.dbf
output filename=/u01/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_undotbs1_4zy6rr46_.dbf tag=BACKREC recid=17 stamp=685996987
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:03
channel ORA_DISK_1: starting datafile copy
input datafile fno=00006 name=/u01/app/oracle/oradata/orcl/users02.dbf
output filename=/u01/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_users_4zy6rv92_.dbf tag=BACKREC recid=18 stamp=685996987
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:01
channel ORA_DISK_1: starting datafile copy
input datafile fno=00004 name=/u01/app/oracle/oradata/orcl/users01.dbf
output filename=/u01/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_users_4zy6rwc5_.dbf tag=BACKREC recid=19 stamp=685996988
channel ORA_DISK_1: datafile copy complete, elapsed time: 00:00:01
Finished backup at 04-MAY-09
Starting Control File and SPFILE Autobackup at 04-MAY-09
piece handle=/u01/app/oracle/flash_recovery_area/ORCL/autobackup/2009_05_04/o1_mf_s_685996989_4zy6rxvx_.bkp comment=NONE
Finished Control File and SPFILE Autobackup at 04-MAY-09
If you look at the output above, you will bascially see that we did a level 0 Full Backup with Image Copies of all the datafiles. Now let’s modify some blocks in the database:
SQL> update sh.sales set amount_sold=amount_sold*1 where rownum<10000;
9999 rows updated.
SQL> commit;
Commit complete.
Now we run the same RMAN command again:
RMAN> run { recover copy of database with tag 'backrec';
backup incremental level 1 cumulative copies=1 for recover of copy with tag 'backrec' database; }
Starting recover at 04-MAY-09
using channel ORA_DISK_1 no copy of datafile 1 found to recover no copy of datafile 2 found to recover no copy of datafile 3 found to recover no copy of datafile 4 found to recover no copy of datafile 5 found to recover no copy of datafile 6 found to recover Finished recover at 04-MAY-09 Starting backup at 04-MAY-09 using channel ORA_DISK_1 channel ORA_DISK_1: starting incremental level 1 datafile backupset channel ORA_DISK_1: specifying datafile(s) in backupset input datafile fno=00001 name=/u01/app/oracle/oradata/orcl/system01.dbf input datafile fno=00003 name=/u01/app/oracle/oradata/orcl/sysaux01.dbf input datafile fno=00005 name=/u01/app/oracle/oradata/orcl/example01.dbf input datafile fno=00002 name=/u01/app/oracle/oradata/orcl/undotbs01.dbf input datafile fno=00006 name=/u01/app/oracle/oradata/orcl/users02.dbf input datafile fno=00004 name=/u01/app/oracle/oradata/orcl/users01.dbf channel ORA_DISK_1: starting piece 1 at 04-MAY-09 channel ORA_DISK_1: finished piece 1 at 04-MAY-09 piece handle=/u01/app/oracle/flash_recovery_area/ORCL/backupset/2009_05_04/o1_mf_nnnd1_TAG20090504T185902_4zy7ppmg_.bkp tag=TAG20090504T185902 comment=NONE channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01 Finished backup at 04-MAY-09 Starting Control File and SPFILE Autobackup at 04-MAY-09 piece handle=/u01/app/oracle/flash_recovery_area/ORCL/autobackup/2009_05_04/o1_mf_s_685997943_4zy7pqr4_.bkp comment=NONE Finished Control File and SPFILE Autobackup at 04-MAY-09
Please notice the very short time it took RMAN to backup the (few) modified blocks during the incremental backup. Although this database is tiny of course, that would have taken a much longer time without block change tracking. The effect is way more dramatic in databases of more realistic sizes. Again we modify some blocks as before. After the third call of the command, we will see now always the following behavior:
RMAN> run {recover copy of database with tag 'backrec';
backup incremental level 1 cumulative copies=1 for recover of copy with tag 'backrec' database;}
Starting recover at 04-MAY-09
using channel ORA_DISK_1
channel ORA_DISK_1: starting incremental datafile backupset restore
channel ORA_DISK_1: specifying datafile copies to recover
recovering datafile copy fno=00001 name=/u01/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_system_4zy6pnsg_.dbf
recovering datafile copy fno=00002 name=/u01/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_undotbs1_4zy6rr46_.dbf
recovering datafile copy fno=00003 name=/u01/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_sysaux_4zy6qqvp_.dbf
recovering datafile copy fno=00004 name=/u01/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_users_4zy6rwc5_.dbf
recovering datafile copy fno=00005 name=/u01/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_example_4zy6rk0w_.dbf
recovering datafile copy fno=00006 name=/u01/app/oracle/flash_recovery_area/ORCL/datafile/o1_mf_users_4zy6rv92_.dbf
channel ORA_DISK_1: reading from backup piece /u01/app/oracle/flash_recovery_area/ORCL/backupset/2009_05_04/o1_mf_nnnd1_TAG20090504T185902_4zy7ppmg_.bkp
channel ORA_DISK_1: restored backup piece 1
piece handle=/u01/app/oracle/flash_recovery_area/ORCL/backupset/2009_05_04/o1_mf_nnnd1_TAG20090504T185902_4zy7ppmg_.bkp tag=TAG20090504T185902
channel ORA_DISK_1: restore complete, elapsed time: 00:00:02
Finished recover at 04-MAY-09
Starting backup at 04-MAY-09
using channel ORA_DISK_1
channel ORA_DISK_1: starting incremental level 1 datafile backupset
channel ORA_DISK_1: specifying datafile(s) in backupset
input datafile fno=00001 name=/u01/app/oracle/oradata/orcl/system01.dbf
input datafile fno=00003 name=/u01/app/oracle/oradata/orcl/sysaux01.dbf
input datafile fno=00005 name=/u01/app/oracle/oradata/orcl/example01.dbf
input datafile fno=00002 name=/u01/app/oracle/oradata/orcl/undotbs01.dbf
input datafile fno=00006 name=/u01/app/oracle/oradata/orcl/users02.dbf
input datafile fno=00004 name=/u01/app/oracle/oradata/orcl/users01.dbf
channel ORA_DISK_1: starting piece 1 at 04-MAY-09
channel ORA_DISK_1: finished piece 1 at 04-MAY-09
piece handle=/u01/app/oracle/flash_recovery_area/ORCL/backupset/2009_05_04/o1_mf_nnnd1_TAG20090504T190410_4zy80cd8_.bkp tag=TAG20090504T190410 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:03
Finished backup at 04-MAY-09
Starting Control File and SPFILE Autobackup at 04-MAY-09
piece handle=/u01/app/oracle/flash_recovery_area/ORCL/autobackup/2009_05_04/o1_mf_s_685998253_4zy80g2q_.bkp comment=NONE
First RMAN actualizes the image copies of the datafiles in the recover copy section of the command. Then again a very fast incremental backup is done. In this fashion, we always get a quite fast backup and have our backup very close (in terms of time) to the production datafiles, so that a restore & recovery can be done fairly fast also. This picture illustrates the Recovery Area as well as the Recommended Backup Strategy that you have seen at work in this posting:
Conclusion: Incremental Backups can be taken very fast with the 10g New Feature Block Change Tracking. Together with Image Copies and the 11g New Feature Recover Copy this is the Recommended Backup Strategy for Oracle Databases. What is your reason why it is not implemented at your site?
New OU EMEA Newsletter Article: Tablespace Point In Time Recovery
An article that I have posted on my Downloads page got published in the April Oracle University EMEA Newsletter. It is about Tablespace Point In Time Recovery – a technique, useful especially if you host mutliple applications in one Oracle Database, each of them associated with one tablespace and you want to correct a logical mistake for that application. Instead of turning the whole database with all applications into the past – to before the occurence of the logical mistake – you take just one and leave the status of the other applications – respectively their data – untouched.
