What is Redo Information:
Each Oracle Database instance has redo logs, which consists of two or more preallocated files that store all changes made to the database as they occur. Every instance of an Oracle Database has an associated redo log to protect the database in case of an instance failure.

What is Nologging:
NOLOGGING can be used to prevent bulk operations from logging too much information to Oracle’s Redo log files.
NOLOGGING can be used to minimize the amount of redo generated by Oracle (It will not prevent the redo completely).
What operations can use NOLOGGING?
- Create Table As Select (CTAS)
- ALTER TABLE operationen
- ALTER TABLE statements (add/move/merge/split partitions)
- INSERT /*+APPEND*/
- CREATE INDEX
- ALTER INDEX statements (add/move/merge/split partitions)
What is the benefits of settings NOLOGGING:
- To speed up the transactions (e.g. Bulk loading of huge number of records)
- Reduce the I/O contention on the redo log files.
- It will save a disk space when the database is in the ARCHIVELOG mode.
So, NOLOGGING is good from performance side, but it is bad from recoverability prospective, because Oracle will not have the necessary information to recover.
So, NOLOGGING allows you to suppress (or minimize) the redo generated for some statements like (CREATE TABLE AS SELECT, INSERT INTO TABLE… SELECT and CREATE INDEX).
After doing some NOLOGGING operations:
If you take backups of the related datafiles after these operations è You are in the safe side, and you saved time during these operations and also save the space of the corresponding archive logs.
If the available backups were taken before these operations, and some files – with nologging operations – got damaged, then you are in trouble (unless you are able to upload the same data manually) !.
Let us have a quick demo:
sqlplus / as sysdba
SQL> select force_logging from v$database;
NO
SQL> grant dba to ahmed identified by ahmed;
Grant succeeded.
SQL > connect ahmed/ahmed
AHMED @ XPS > create tablespace tbs_01 datafile ‘D:\APP\AFATTAH\ORADATA\XPS\tbs_01.dbf’ size 100m;
Tablespace created.
AHMED @ XPS > create table t1 tablespace tbs_01 as select rownum as id, ‘Hello world’ as col from dual connect by level <= 1e5;
Table created.
RMAN> backup tablespace tbs_01;
Starting backup at 24-AUG-17
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=286 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=00024 name=D:\APP\AFATTAH\ORADATA\XPS\TBS_01.DBF
channel ORA_DISK_1: starting piece 1 at 24-AUG-17
channel ORA_DISK_1: finished piece 1 at 24-AUG-17
piece handle=D:\APP\12CDB\FAST_RECOVERY_AREA\XPS\BACKUPSET\2017_08_24\O1_MF_NNNDF_TAG20170824T211143_DSY97JMX_.BKP tag=TAG20170824T211143 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 24-AUG-17
Starting Control File and SPFILE Autobackup at 24-AUG-17
piece handle=D:\APP\12CDB\FAST_RECOVERY_AREA\XPS\AUTOBACKUP\2017_08_24\O1_MF_S_952895505_DSY97KJH_.BKP comment=NONE
Finished Control File and SPFILE Autobackup at 24-AUG-17
Check for nologging or unrecoverable operations:
RMAN> report unrecoverable;
Report of files that need backup due to unrecoverable operations
File Type of Backup Required Name
—- ———————– ———————————–
AHMED @ XPS > select file#,to_char(UNRECOVERABLE_TIME,’yyyy-mm-dd:hh24:mi:ss’) from v$datafile where file#=24;
FILE# TO_CHAR(UNRECOVERABLE_TIME,’YYYY-MM-DD:HH24:MI:SS’)
24
No nologging/unrecoverable operations yet
Now let us start doing some nologging operations:
AHMED @ XPS > alter table t1 nologging;
Table T1 altered.
AHMED @ XPS > insert /*+ append */ into t1 select * from t1;
100,000 rows inserted.
AHMED @ XPS > commit;
Commit complete.
AHMED @ XPS >select count(*) from t1 where rownum<=1e5;
COUNT(*)
100000
Now , let us check for for nologging or unrecoverable operations:
AHMED @ XPS > select file#,to_char(UNRECOVERABLE_TIME,’yyyy-mm-dd:hh24:mi:ss’) from v$datafile where file#=24;
FILE# TO_CHAR(UNRECOVERABLE_TIME,’YYYY-MM-DD:HH24:MI:SS’)
24 2017-08-24:21:19:07
RMAN> report unrecoverable;
Report of files that need backup due to unrecoverable operations
File Type of Backup Required Name
—- ———————– ———————————–
24 full or incremental D:\APP\AFATTAH\ORADATA\XPS\TBS_01.DBF
So, no problem so far from application side when doing nologging operation, but both RMAN & v$datafile will report unrecoverable operations. Also, there is nothing reported in the alert file so far.
RMAN> backup tablespace tbs_01;
Starting backup at 24-AUG-17
using channel ORA_DISK_1
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00024 name=D:\APP\AFATTAH\ORADATA\XPS\TBS_01.DBF
channel ORA_DISK_1: starting piece 1 at 24-AUG-17
channel ORA_DISK_1: finished piece 1 at 24-AUG-17
piece handle=D:\APP\12CDB\FAST_RECOVERY_AREA\XPS\BACKUPSET\2017_08_24\O1_MF_NNNDF_TAG20170824T212522_DSYB13MR_.BKP tag=TAG20170824T212522 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 24-AUG-17
Starting Control File and SPFILE Autobackup at 24-AUG-17
piece handle=D:\APP\12CDB\FAST_RECOVERY_AREA\XPS\AUTOBACKUP\2017_08_24\O1_MF_S_952896324_DSYB14HW_.BKP comment=NONE
Finished Control File and SPFILE Autobackup at 24-AUG-17
Now , let us check for for nologging or unrecoverable operations after having a backup:
RMAN> report unrecoverable;
Report of files that need backup due to unrecoverable operations
File Type of Backup Required Name
—- ———————– ———————————–
AHMED @ XPS >select file#,to_char(UNRECOVERABLE_TIME,’yyyy-mm-dd:hh24:mi:ss’) from v$datafile where file#=24;
FILE# TO_CHAR(UNRECOVERABLE_TIME,’YYYY-MM-DD:HH24:MI:SS’)
24 2017-08-24:21:19:07
Having the required backups/archivelogs to recover a file, will remove it from the RMAN report (RMAN> report unrecoverable;), but it will not remove it from the v$datafile
Now let us assume that the tablespace tbs_01 get damaged and we need to restore/recover it but before that let us do some nologging operations above the last backup:
AHMED @ XPS >insert /*+ append */ into t1 select * from t1;
200,000 rows inserted.
AHMED @ XPS >commit;
Commit complete.
RMAN> report unrecoverable;
Report of files that need backup due to unrecoverable operations
File Type of Backup Required Name
—- ———————– ———————————–
24 full or incremental D:\APP\AFATTAH\ORADATA\XPS\TBS_01.DBF
AHMED @ XPS >select file#,to_char(UNRECOVERABLE_TIME,’yyyy-mm-dd:hh24:mi:ss’) from v$datafile where file#=24;
FILE# TO_CHAR(UNRECOVERABLE_TIME,’YYYY-MM-DD:HH24:MI:SS’)
24 2017-08-24:21:28:00
Let us simulate the file damage, restore and recovery:
RMAN> alter database datafile 24 offline;
Statement processed
RMAN> restore datafile 24;
Starting restore at 24-AUG-17
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 00024 to D:\APP\AFATTAH\ORADATA\XPS\TBS_01.DBF
channel ORA_DISK_1: reading from backup piece D:\APP\12CDB\FAST_RECOVERY_AREA\XPS\BACKUPSET\2017_08_24\O1_MF_NNNDF_TAG20170824T212522_DSYB13MR_.BKP
channel ORA_DISK_1: piece handle=D:\APP\12CDB\FAST_RECOVERY_AREA\XPS\BACKUPSET\2017_08_24\O1_MF_NNNDF_TAG20170824T212522_DSYB13MR_.BKP tag=TAG20170824T212522
channel ORA_DISK_1: restored backup piece 1
channel ORA_DISK_1: restore complete, elapsed time: 00:00:01
Finished restore at 24-AUG-17
RMAN> recover datafile 24;
Starting recover at 24-AUG-17
using channel ORA_DISK_1
starting media recovery
media recovery complete, elapsed time: 00:00:00
Finished recover at 24-AUG-17
RMAN> alter database datafile 24 online;
Statement processed
Restore/Recover will be completed successfully for datafiles with nologging blocks, but RMAN and v$datafile still report unrecoverable.
RMAN> report unrecoverable;
Report of files that need backup due to unrecoverable operations
File Type of Backup Required Name
—- ———————– ———————————–
24 full or incremental D:\APP\AFATTAH\ORADATA\XPS\TBS_01.DBF
AHMED @ XPS >select file#,to_char(UNRECOVERABLE_TIME,’yyyy-mm-dd:hh24:mi:ss’) from v$datafile where file#=24;
FILE# TO_CHAR(UNRECOVERABLE_TIME,’YYYY-MM-DD:HH24:MI:SS’)
24 2017-08-24:21:28:00
Now what if you want to access the table:
AHMED @ XPS >select count (*) from t1;
Error starting at line : 1 in command –
select count (*) from t1
Error report –
ORA-01578: ORACLE data block corrupted (file # 24, block # 752)
ORA-01110: data file 24: ‘D:\APP\AFATTAH\ORADATA\XPS\TBS_01.DBF’
ORA-26040: Data block was loaded using the NOLOGGING option
So problem happened once you started to access a table with “restored/recovered” nologging blocks.
If no recovery happend, you will not feel any difference.
If recovery happened – as in case of Data Guard – you will not feel any issue until you start accessing the tables.
The solution with the Data Guard – which run in continuous recovery mode – is to enable force logging at the database level. Please remember to do that before taking the initial backup which will be used to build the standby database, otherwise you will face the above block corruption issue after failing over to the standby database.
On the Data Guard environments, Redo Apply processes will mark relevant blocks as corrupted block. Once you query on data that references these blocks, you will get ORA-01578. By issuing DBVERIFY agaist the datafiles on physical standby database, you can get a list of corrupted blocks (dbv file=D:\APP\AFATTAH\ORADATA\XPS\TBS_01.DBF). On the primary these blocks are not marked as corrupted (unless you recover them) but they will be marked as unrecoverable.
References:

Donate to support our blogging work
$1.00
Thanks
Ahmed