Enable Flashback Mode
Step 1:- Log on to the database and check archivelog mode for database. Its mandatory that database must have enabled archivelog mode
[oracle@pract1 fra]$ sqlplus "/ as sysdba"
SQL*Plus: Release 11.2.0.1.0 Production on Thu Jul 28 18:03:43 2016
Copyright (c) 1982, 2009, Oracle. All rights reserved.
Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
SQL> select instance_name, status from v$instance;
INSTANCE_NAME STATUS
---------------- ------------
KMDB OPEN
SQL> archive log list
Database log mode No Archive Mode
Automatic archival Disabled
Archive destination /u01/app/oracle/product/11.2.0/dbhome_1/dbs/arch
Oldest online log sequence 1
Current log sequence 2
Step 2:- Looks like archivelog destination parameter is set to default location. We will change the archivelog destination to new location
SQL> alter system set log_archive_dest_1='LOCATION=/u01/oradata/KMDB/arch' scope = both;
System altered.
Step 3:- Verify the archivelog destination which is pointing to new location
SQL> archive log list
Database log mode No Archive Mode
Automatic archival Disabled
Archive destination /u01/oradata/KMDB/arch
Oldest online log sequence 1
Current log sequence 2
Step 4:- Shutdown the database and start it in mount state
SQL> shu immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup mount
ORACLE instance started.
Total System Global Area 839282688 bytes
Fixed Size 2217992 bytes
Variable Size 494929912 bytes
Database Buffers 339738624 bytes
Redo Buffers 2396160 bytes
Database mounted.
Step 5:- We need to set archivelog mode and open the database
SQL> alter database archivelog;
Database altered.
SQL> alter database open;
Database altered.
SQL> archive log list
Database log mode Archive Mode
Automatic archival Enabled
Archive destination /u01/oradata/KMDB/arch
Oldest online log sequence 1
Next log sequence to archive 2
Current log sequence 2
Step 6:- Check the flashback mode and flash recovery area parameter for the database
SQL> select name, flashback_on from v$database;
NAME FLASHBACK_ON
--------- ------------------
KMDB NO
SQL> sho parameter recovery
NAME TYPE VALUE
------------------------------------ ----------- --------------
db_recovery_file_dest string
db_recovery_file_dest_size big integer 0
recovery_parallelism integer 0
Step 7:- Now we will set the flash recovery area parameter
SQL> alter system set db_recovery_file_dest_size=2g scope = both;
System altered.
SQL> alter system set db_recovery_file_dest='/u01/oradata/KMDB/fra' scope = both;
System altered.
Step 8:- Enable flashback mode and verify if its enabled
SQL> alter database flashback on;
Database altered.
SQL> select name, flashback_on from v$database;
NAME FLASHBACK_ON
--------- ------------------
KMDB YES
Disable Flashback Mode
Step 1:- Disable the flashback mode using below mentioned command and verify the status
SQL> alter database flashback off;
Database altered.
SQL> select name, flashback_on from v$database;
NAME FLASHBACK_ON
--------- ------------------
KMDB NO
Possible Errors during Activity
ORA-38706: Cannot turn on FLASHBACK DATABASE logging.
ORA-38707: Media recovery is not enabled.
ORA-02097: parameter cannot be modified because specified value is invalid
ORA-19802: cannot use DB_RECOVERY_FILE_DEST without DB_RECOVERY_FILE_DEST_SIZE
ORA-01126: database must be mounted in this instance and not open in any
instance
Case 1:- Archivelog not enabled
SQL> alter database flashback on;
alter database flashback on
*
ERROR at line 1:
ORA-38706: Cannot turn on FLASHBACK DATABASE logging.
ORA-38707: Media recovery is not enabled.
Cause:-
This error occurs when we try to enable the flashback mode without enabling archivelog mode
Solution:-
After the enabling the archivelog mode, issue should be resolved. Click Here on How to enable archivelog mode
Case 2:- DB_RECOVERY_FILE_DEST parameter no set in database parameter file
SQL> alter system set db_recovery_file_dest='/u01/oradata/KMDB/fra' scope = both;
alter system set db_recovery_file_dest='/u01/oradata/KMDB/fra' scope = both
*
ERROR at line 1:
ORA-02097: parameter cannot be modified because specified value is invalid
ORA-19802: cannot use DB_RECOVERY_FILE_DEST without DB_RECOVERY_FILE_DEST_SIZE
Cause:-
This error occurs when we try to set DB_RECOVERY_FILE_DEST without setting the database recovery destination size parameter DB_RECOVERY_FILE_DEST_SIZE
Solution:-
Set the database recovery destination size parameter DB_RECOVERY_FILE_DEST_SIZE
SQL> alter system set db_recovery_file_dest_size=2g scope = both;
Case 3:- Database is open while enabling archivelog mode
This error occurs when we try to set DB_RECOVERY_FILE_DEST without setting the database recovery destination size parameter DB_RECOVERY_FILE_DEST_SIZE
Solution:-
Set the database recovery destination size parameter DB_RECOVERY_FILE_DEST_SIZE
SQL> alter system set db_recovery_file_dest_size=2g scope = both;
Case 3:- Database is open while enabling archivelog mode
SQL> alter database archivelog;
*
ERROR at line 1:
ERROR at line 1:
ORA-01126: database must be mounted in this instance and not open in any
instance
Cause:-
This error happens when you try to enable archivelog mode when the database is in open state
Solution:-
Shutdown the database and start the database in mount state. Then try to enable archivelog mode, it should work
No comments:
Post a Comment