Sunday, May 22, 2016

Ensuring Data Protection Using Oracle Flashback Features - Part 5

Introduction

In the previous article we have reviewed Oracle 11g and 12c Flashback new features and enhancements.
In this part (last one in this articles series) we will review the Oracle Flashback licensing. In addition, we will also summarize everything and we will see which Oracle Flashback feature should be used in various human errors use cases.

Oracle Flashback - Licensing 

Most of the powerful Flashback features require having a license for the Enterprise Edition. This includes the following features:
  • Flashback Table
  • Flashback Drop
  • Flashback Transaction Query
  • Flashback Transaction
  • Flashback Database
Flashback Query and Flashback Version Query are available for all Oracle Editions. As for Flashback Data Archive, starting from 11.2.0.4, it is supported for all of the Oracle Editions, but for versions earlier than 11.2.0.4, it requires having a license for the Enterprise Edition + Oracle Advanced Compression option (extra cost option).

Figure 1: Oracle Flashback Features Licensing

Summary
Oracle Flashback technology provides a set of tools which can be used by the DBA in order to recover from various human errors that caused undesired data loss or data modifications. The following table summarizes this article by explaining which Oracle Flashback feature is most suitable per each scenario:

Figure 2: Various Use Cases for using Oracle Flashback Features

The great thing about Oracle Flashback technology is that it allows recovering from various human errors with the minimum effort and time, which results in a reduced RTO (Recovery Time Objective). Having said that, Oracle Flashback technology should never be used as a replacement of the traditional backups, but rather as a complementary solution that provides a very effective way to recover from various human errors and does not require restoring and recovering data using backup (either RMAN or user-managed backups). For example, Oracle Flashback technology will not protect against the following scenarios:
  • Loss of data file or control file
  • Block corruptions (either physical or logical)
  • Site disaster 


The article reviewed the Oracle Flashback technology from Oracle version 9i – where the first flashback feature named “Flashback Query” was introduced, up to the most recent Oracle Database version (12.1.0.2). Oracle Flashback technology can definitely empower the DBAs by making their lives easier when it comes to protecting the data from various human errors.

Sunday, May 15, 2016

Ensuring Data Protection Using Oracle Flashback Features - Part 4

Introduction

In my previous article we have reviewed Oracle 10g Flashback features. We started with the Flashback Query enhancements (Flashback Version Query, Flashback Transaction Query, Flashback Table) and continued with additional flashback enhancements (Flashback Drop and Flashback Database).
In this part, we will review Oracle 11g and 12c Flashback Features.

Oracle 11gR1 - Flashback Transaction

In the previous part, when we reviewed “Flashback Version Query” section we have demonstrated how to view historical changes of records in a table and also how find the associated Transaction ID (XID) per each version of record in the table.  In the “Flashback Transaction Query” we have demonstrated how we can also view the undo statement for the selected transaction. Starting from Oracle 11g, using the Flashback Transaction feature, we can even take these 2 features one step further by rolling-back the changes made by a transaction and its dependent transactions (optionally).  In the following example, a sample table is created. Afterwards, the first transaction will insert a single record, and then a second transaction updates the record. In the last step of this demo we will perform a rollback for the first transaction:
SQL> CREATE TABLE DEPARTMENTS
    (
    DEPT_ID   NUMBER,
    Name      VARCHAR2 (20),
    CONSTRAINT id_pk PRIMARY KEY (DEPT_ID)
     );
Table created.

SQL> insert into DEPARTMENTS values (1, 'SALES');
1 row created.

SQL> commit;
Commit complete.

SQL> update DEPARTMENTS set name = 'HR' where dept_id = 1;
1 row updated.

SQL> commit;
Commit complete.

SQL> select * from DEPARTMENTS;

   DEPT_ID NAME
---------- --------------------
         1 HR

SQL> SELECT versions_starttime, versions_endtime,
           versions_xid, versions_operation, dept_id, name
      FROM   DEPARTMENTS
    VERSIONS BETWEEN SCN MINVALUE AND MAXVALUE;

VERSIONS_STARTTIME        VERSIONS_ENDTIME          VERSIONS_XID     V    DEPT_ID NAME
------------------------- ------------------------- ---------------- - ---------- ------
28-JAN-16 06.18.10 PM     28-JAN-16 06.19.01 PM     000A001A0000BF39 I          1 SALES
28-JAN-16 06.19.01 PM                               000800110000648B U          1 HR


SQL> EXECUTE DBMS_FLASHBACK.transaction_backout(numtxns=>1, xids=>xid_array('000A001A0000BF39'));

ERROR at line 1:
ORA-55504: Transaction conflicts in NOCASCADE mode
ORA-06512: at "SYS.DBMS_FLASHBACK", line 37
ORA-06512: at "SYS.DBMS_FLASHBACK", line 70
ORA-06512: at line 2
The reason that the “ORA-55504: Transaction conflicts in NOCASCADE mode” error has been raised is because the DBMS_FLASHBACK.TRANSACTION_BACKOUT procedure has a parameter named “options” which defaults to NOCASCADE, meaning that if a dependent transaction has been found, Oracle will raise an error. In our demonstration, the second transaction that updates the row depends on the first transaction that inserts the row; therefore, Oracle raises an error. We can tell Oracle to rollback the dependent transactions using the CASCADE value for the “options” parameter, as follows:
SQL> BEGIN 
  DBMS_FLASHBACK.transaction_backout (numtxns=> 1,
                                      xids    => xid_array('000A001A0000BF39'),
                                      options => DBMS_FLASHBACK.cascade);
END;
PL/SQL procedure successfully completed.

SQL> select * from DEPARTMENTS;
no rows selected
Note that supplemental logging for primary key columns must be enabled in order to use Flashback Transaction:
SQL> ALTER DATABASE ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS;
Database altered. 


Oracle 11gR1 - Flashback Data Archive

As mentioned, most of the Flashback Features (including: Flashback Version Query, Flashback Transaction Query, and Flashback Table and Flashback Transaction) rely on the undo information that reside in the Undo Tablespace. If the information is not available in the Undo Tablespace, the flashback operation will fail. Whether the information is available or not depends on several factors including:

  • Size of the undo tablespace 
  • UNDO_RETENTION parameter 
  • Auto extend property
  • Undo Guarantee property 
In order to allow an extended and even unlimited historical undo information for flashback purposes, Oracle introduced in version 11gR1 a new feature named Flashback Data Archive (also known as Total Recall). Flashback Data Archive is a repository for storing undo records and it is transparent to the application, i.e. once configured, the usage of the Oracle Flashback features remain the same in terms of syntax. In order to configure this feature, an object named Flashback Archive must be created. Flashback Archive has the following properties:

  • Tablespace – Where the information will be stored 
  • Quota - Maximum amount of storage that can be allocated on the tablespace 
  • Retention – The amount of time that information will be kept in the tablespace 
Oracle introduced a new process named “fbda” that takes care of all the Flashback Data Archive related tasks such as writing the information into the Flashback Archive and purging it once the information is older than the retention period. In the following example a new default Flashback Archive object named “my_fda” with 25GB quota on a tablespace named “my_fda_ts” and a retention period of 5 years is created:
SQL> CREATE TABLESPACE my_fda_ts DATAFILE SIZE 100M AUTOEXTEND ON NEXT 10M;
TABLESPACE created.

SQL> CREATE FLASHBACK ARCHIVE DEFAULT my_fda TABLESPACE my_fda_ts QUOTA 25G RETENTION 5 YEAR;
FLASHBACK archive created.
When enabling Flashback Archive for a table, unless explicitly specifying the Flashback Archive name, the default Flashback Archive will be used (in our case, “my_fda”. There can be only 1 default Flashback Archive. Let us create an additional non-default Flashback Archive with a 5GB quota and a retention period of 1 year:
SQL> CREATE FLASHBACK ARCHIVE one_year_fda TABLESPACE my_fda_ts QUOTA 5G RETENTION 1 YEAR;
Flashback archive created.
The retention information for the Flashback Archives is available in the DBA_FLASHBACK_ARCHIVE dictionary view:
SQL> SELECT flashback_archive_name, retention_in_days, status FROM DBA_FLASHBACK_ARCHIVE;

FLASHBACK_ARCHIVE_NAME   RETENTION_IN_DAYS STATUS
------------------------ ----------------- -------
MY_FDA                                1825 DEFAULT
ONE_YEAR_FDA                           365
The information about the quota per each Flashback Archive and the associated tablespace is available in the DBA_FLASHBACK_ARCHIVE_TS dictionary view:
SQL> SELECT flashback_archive_name, tablespace_name, quota_in_mb/1024 QUOTA_GB FROM DBA_FLASHBACK_ARCHIVE_TS;

FLASHBACK_ARCHIVE_NAME    TABLESPACE_NAME                  QUOTA_GB
------------------------- ------------------------------ ----------
MY_FDA                    MY_FDA_TS                              25
ONE_YEAR_FDA              MY_FDA_TS                               5
Once the Flashback Archive has been configured, the user can easily enable and disable this feature for the desired tables, as follows:
SQL> alter table departments flashback archive;
Table altered.

SQL> alter table departments no flashback archive;
Table altered.
To enable FDA for a table using a non-default Flashback Archive, the Flashback Archive must be explicitly set, as follows:
SQL> alter table departments flashback archive ONE_YEAR_FDA;
Table altered.
The DBA_FLASHBACK_ARCHIVE_TABLES dictionary view displays all of the tables that have a Flashback Archive configured:
SQL> SELECT table_name,owner_name,flashback_archive_name FROM DBA_FLASHBACK_ARCHIVE_TABLES;

TABLE_NAME  OWNER_NAME  FLASHBACK_ARCHIVE_NAME    
----------- ----------- ------------------------- 
DEPARTMENTS  SALES         ONE_YEAR_FDA            


Oracle 11gR2 Flashback enhancements

In Oracle 11gR2 the following enhancements were introduced:
  • Flashback Database – Prior to 11gR2, the DBA had to restart the database to a MOUNTED state and only then enable the Flashback Database feature. Now, the DBA can enable the Flashback Database when the instance is open with no downtime. 
  • Flashback Data Archive – Prior to Oracle 11gR2, several DDL commands on a table with Flashback Archive enabled raised an error: “ERROR at line 1 ORA-55610: Invalid DDL statement on history-tracked table”. This includes the following DDL operations:
    • TRUNCATE TABLE
    • ALTER TABLE [ADD| DROP| RENAME| MODIFY] Column
    • DROP|TRUNCATE Partition
    • ALTER TABLE RENAME 
    • ALTER TABLE [ADD| DROP| RENAME| MODIFY] Constraint
Staring with Oracle 11gR2, these operations are now supported on tables with Flashback Archive enabled.


Oracle 12c Flashback enhancements

12.1.0.1 New Features:
In Oracle version 12.1.0.1, new enhancements were introduced to the Flashback Data Archive feature including:
  • The user context information for the transactions is now tracked as well. This allows us to understand not only what the changes were but also who is responsible for those changes.
  • Support for tables that use the Hybrid Columnar Compression (HCC) feature.
  • Support for exporting and importing the Flashback Data Archive tables.
12.1.0.2 New Features:
In version 12.1.0.1, the Flashback Data Archive feature was supported only for Non-CDB environments. Starting from version 12.1.0.2 the Flashback Data Archive feature is supported for a Container Database (also known as the Multitenant Architecture) in addition to Non-CDB option.

Summary

In this article we have reviewed Oracle 11g and 12c Flashback new features and enhancements.
In the next part (last one in this articles series) we will review the Oracle Flashback licensing. In addition, we will also summarize everything and we will see which Oracle Flashback feature should be used in various human errors use cases.

Sunday, May 8, 2016

Ensuring Data Protection Using Oracle Flashback Features - Part 3

Introduction

In my previous article we have reviewed the first Oracle Flashback feature which was introduced in Oracle 9i, named "Flashback Query" and we saw how this feature works "behind the scenes" using undo tablespace' contents.
In this article, we will review Oracle 10g Flashback features.

Oracle 10g Flashback Features

Oracle Database version 10g introduced some great flashback-related enhancements and new features. We can categorize these features into two main categories, Flashback query enhancements and additional flashback features.


Oracle Flashback Query Enhancements
This category contains all of the Oracle 10g flashback query enhancements including the following: Flashback Version Query, Flashback Transaction Query, and Flashback Table. The reason these features are categorized as enhancements to the 9i Flashback query feature is because they all rely on the undo records in the Undo Tablespace, where the “Additional Flashback Features” are flashback capabilities that do not rely on the undo tablespace, but rather on other Oracle Database components and features.

Flashback Version Query
The Flashback Version Query allows viewing the historical versions of a specific row or set of rows. Let us continue with the previous example of table EMP. In the previous example, there was an update of employee with ID #1 to be named ROBERT instead of DAVID, and then using by the flashback query, it was updated to be DAVID (as it was originally).
By using Flashback Version Query, we can see the history of the row modifications:
SQL> select versions_starttime, versions_endtime,
           versions_xid, versions_operation, name
    from EMP
VERSIONS BETWEEN TIMESTAMP TO_TIMESTAMP('2016-01-10 18:02:28', 'YYYY-MM-DD HH24:MI:SS')  AND TO_TIMESTAMP('2016-01-10 18:03:00', 'YYYY-MM-DD HH24:MI:SS')
    where id = 1
    order by VERSIONS_STARTTIME;

VERSIONS_STARTTIME     VERSIONS_ENDTIME        VERSIONS_XID      V          NAME
---------------------- ----------------------  ----------------  -          --------------------
10-JAN-16 06.02.47 PM   10-JAN-16 06.04.08 PM  060016000A2A0100  U          ROBERT
10-JAN-16 06.04.08 PM                         01000200EBFA0000   U          DAVID
The VERSIONS_XID column represents the ID of the transaction that is associated with the row. The transaction ID is useful for retrieving the undo SQL statement for the transaction using the Flashback Transaction Query (more details to follow in the next section). The VERSIONS_OPERATION column value is ‘U’ which indicates that an update has occurred. Other possible values are ‘I’ (which indicates an INSERT) and ‘D’ (which indicates a DELETE). The “VERSIONS BETWEEN” clause allows the DBA to specify SCN MINVALUE AND MAXVALUE, which takes all of the undo information that is available in the undo tablespace as follows:
SQL> select versions_starttime, versions_endtime,
           versions_xid, versions_operation, name
    from EMP
VERSIONS BETWEEN SCN MINVALUE AND MAXVALUE WHERE  id = 1
    order by VERSIONS_STARTTIME;

VERSIONS_STARTTIME     VERSIONS_ENDTIME        VERSIONS_XID           V       NAME
---------------------- ----------------------  ----------------       -       --------------------
10-JAN-16 06.02.47 PM   10-JAN-16 06.04.08 PM  060016000A2A0100       U       ROBERT
10-JAN-16 06.04.08 PM                          01000200EBFA0000       U       DAVID

Let us see an example of the output of the query after an insertion and deletion of a row.
SQL> insert into EMP values (2, 'STEVE');
1 row created.

SQL> commit;
Commit complete.

SQL> delete EMP where id=2;
1 row deleted.

SQL> commit;
Commit complete.

SQL> select versions_starttime, versions_endtime,
          versions_xid, versions_operation, name
    from EMP
           VERSIONS BETWEEN SCN MINVALUE AND MAXVALUE    
    order by VERSIONS_STARTTIME;

VERSIONS_STARTTIME     VERSIONS_ENDTIME        VERSIONS_XID           V          NAME
---------------------- ----------------------  ----------------       -          --------------------
10-JAN-16 06.02.47 PM   10-JAN-16 06.04.08 PM  060016000A2A0100       U          ROBERT
10-JAN-16 06.04.08 PM                          01000200EBFA0000       U          DAVID
10-JAN-16 06.27.55 PM   10-JAN-16 06.28.01 PM  08000E007A330100       I          STEVE
10-JAN-16 06.28.01 PM                          0A0000009C120100       D          STEVE

Flashback Transaction Query
The flashback transaction query feature allows the DBA to view the transaction information including the start and the end of the transaction as well as the undo SQL statements for rolling back the transaction. In order to use this feature Oracle introduced a new dictionary view in version 10g named FLASHBACK_TRANSACTION_QUERY which requires having the SELECT ANY TRANSACTION system privilege.  In the example above, we found out that transaction ID 0A0000009C120100 has deleted the row of employee named “STEVE” by using the flashback version query. The flashback transaction query can assist in rolling back the transaction by using the UNDO_SQL column, as follows:
SQL> select xid, start_scn, commit_scn,
            operation OP,  undo_sql FROM flashback_transaction_query
            WHERE xid = HEXTORAW('0A0000009C120100');

XID               START_SCN   COMMIT_SCN  UNDO_SQL
----------------- ----------  ----------  -----------------------------------------------------------
090017001B380100  483051290   483051291   insert into "PINI"."EMP"("ID","NAME") values ('2','STEVE');
Note that in order to have the UNDO_SQL column populated with data, a minimal database supplemental logging must be enabled, which will add additional information to the redo logs. Verify whether minimal database supplemental logging is enabled or not by querying SUPPLEMENTAL_LOG_DATA_MIN from V$DATABASE. If minimal database supplemental logging is disabled (the output of the query is “NO”), you can enable it by executing the following command:
SQL> ALTER DATABASE ADD SUPPLEMENTAL LOG DATA; 
Flashback Table
The flashback table feature allows restoring the entire table’s data into an historical point in time in a very simple and straight-forward way- by specifying either SCN or TIMESTAMP. This feature is the best way for the DBA to recover the entire table’s data from human errors or undesired application changes (e.g. inserts, updates, deletes). In order to use this feature, make sure to be aligned with following prerequisites:

  • Have either FLASHBACK object privilege on the table or FLASHBACK ANY TABLE system privilege. In addition, have the following privileges on the table: ALTER, SELECT, INSERT, UPDATE, and DELETE. 
  • Enable row movement for the table using ALTER TABLE … ENABLE ROW MOVEMENT. The reason for this requirement is because rows will be moved (inserted, updated, and deleted) during the FLASHBACK TABLE, which is the reason that the user must be granted with the INSERT, UPDATE, DELETE privileges on the table.
The following is a demonstration of this feature:
SQL> CREATE TABLE EMP (ID NUMBER, NAME VARCHAR2(20));
Table created.

SQL> insert into EMP values (1, 'DAVID');
1 row created.

SQL> insert into EMP values (2, 'ROBERT');
1 row created.

SQL> insert into EMP values (3, 'DANIEL');
1 row created

SQL> commit;
Commit complete.

SQL> select current_scn from v$database; 

CURRENT_SCN
-----------
  483077247

SQL> delete EMP;
3 rows deleted.

SQL> commit;
Commit complete.

SQL> select * from EMP;
no rows selected

SQL> flashback table EMP to scn 483077247;
flashback table emp to scn 483077247
                *
ERROR at line 1:
ORA-08189: cannot flashback the table because row movement is not enabled
The ORA-08189 is expected because as previously mentioned, one of the prerequisites for using this feature is to enable row movement, and then it would be possible to execute the flashback table command, as follows:
SQL> alter table EMP enable row movement;
Table altered.

SQL> flashback table EMP to scn 483077247;
Flashback complete.

SQL> select * from EMP;
        ID NAME
---------- --------------------
         1 DAVID
         2 ROBERT
  3 DANIEL
Note that this feature is using the information in the undo tablespace in order to recover the table so it can only be used to recover the data and not the structure of the table. If there was a change in the structure of the table, for example, by adding a column, Oracle would not be able to recover the table prior to the execution of DDL command. Also, if a table has been dropped, Oracle would not be able to recover it using this feature.

Additional Flashback Features
So far we have reviewed the Flashback features that rely on the contents of the undo tablespace. In this section we will explore the other 10g Flashback features: Flashback Drop and Flashback Database. These features do not rely on the contents of the undo tablespace.

Flashback Drop
Starting with Oracle version 10g, Oracle introduced a new parameter named “RECYCLEBIN” (defaults to “ON”):
SQL> show parameter RECYCLEBIN

NAME                                 TYPE        VALUE
------------------------------------ ----------- --------
recyclebin                           string      on
Assuming that RECYCLEBIN parameter is set to ON, then once the object is dropped, it will remain in the tablespace and Oracle will keep the information about the dropped table and its associated objects in a dictionary view named USER_RECYCLEBIN (it has a synonym named RECYCLEBIN), which shows per each schema its objects in the recycle bin, as follows:
SQL> SELECT object_name, original_name, droptime FROM RECYCLEBIN;

OBJECT_NAME                    ORIGINAL_NANE TYPE DROPTIME
------------------------------ ------------- ----- --------------
BIN$ZW5M6bSsRKe6PiqynWR9Xw==$0 EMP           TABLE 2016-01-21:17:24:26
BIN$tWgtlRlzTZ2lCoZd0Ex7Rg==$0 ID_PK         INDEX 2016-01-21:17:24:25
Note: that it is possible to query the recycle bin of the entire instance using DBA_RECYCLEBIN, and CDB_RECYCLEBIN in version 12c to query the recycle bin of all the schemas across all the containers. As seen in the demonstration above, the names of the table and its associated objects in the RECYCLEBIN have a system-generated name (starts with BIN$). It is possible to query directly the recycle bin system-generated names:
SQL> SELECT object_name, original_name, droptime FROM RECYCLEBIN;
SQL> select * from "BIN$ZW5M6bSsRKe6PiqynWR9Xw==$0";

        ID NAME
---------- --------------------
         1 DAVID
         2 ROBERT
However, it is not possible to execute DML or DDL commands against the tables in the recycle bin. Once the table is being restored from the recycle bin, it will be restored with its original name, but the associated objects will be restored with system-generated names so it is possible to rename these objects later as an optional step. The following is an example that demonstrates how simple it is to restore a dropped table using this feature:
SQL> SELECT object_name, original_name, droptime FROM RECYCLEBIN;
SQL> FLASHBACK TABLE EMP TO BEFORE DROP;
Flashback complete.

SQL> select * from EMP;

        ID NAME
---------- --------------------
         1 DAVID
         2 ROBERT
It is also possible that the object will be restored with a different name (for example, when another object with the same name already exists), using a very simple syntax, as follows:
SQL> SELECT object_name, original_name, droptime FROM RECYCLEBIN;
SQL> FLASHBACK TABLE EMP TO BEFORE DROP RENAME TO EMP_OLD;
Flashback complete.
Note that it is not guaranteed to have the dropped objects in the recycle bin. In the following scenarios the objects will not be available in the recycle bin:

  • Execution of a DROP TABLE command with the PURGE clause
  • Manual execution of PURGE RECYCLEBIN or PURGE DBA_RECYCLEBIN commands 
  • Drop of the entire tablespace will not leave its objects in the recycle bin 
  • When dropping a user, all its objects are not placed in the recycle bin
  • Space-pressure in the tablespace on which the objects reside 
 Another thing to keep in mind is that Oracle restores the objects from the recycle bin in a LIFO (Last In First Out) order, so if there are several objects with the same name in the recycle bin and the DBA restores that object using the Flashback Drop feature, then the last one that was dropped will be restored.

Flashback Database
The Flashback Database feature is the most simple and straightforward way to rewind the entire database to a historical point in time. The reason it is so fast and simple is because it does not require restoring database backups using either RMAN or user-managed backup. However, its biggest disadvantage is that it can only recover “logical failures”, i.e. unnecessary data modifications due to human error. It cannot be used to recover from block corruptions or a loss of a file (e.g. Data Files, Control File).
In order to undo changes in the database, this feature uses flashback logs. Flashback logs are being generated once the Flashback Database is enabled. The flashback logs contain before-images of data blocks prior to their change. The Flashback Database operates at a physical level and revert the current data files to their contents at a past time using the flashback logs. The prerequisites for enabling this feature are:

  • The database must be running in ARCHIVELOG mode
  • Enable the FRA (Flash Recovery Area).

The FRA is a storage location that contains recovery-related files such as archived logs, RMAN backups, and of course, flashback logs. Once configured, the FRA will simplify the DBA’s daily tasks by retaining the recovery-related files as long as they are needed, and delete them once they are no longer needed (based on the retention policies that are defined by the DBA).
Once the FRA prerequisites have been configured properly, it is possible to enable the Flashback Database feature by executing the following command: 
SQL> ALTER DATABASE FLASHBACK ON;
Prior to 11gR2, in order to execute this command, the database had to be restarted to a mounted state and only then it was possible to execute the above command. Starting with 11gR2, it is possible to enable the Flashback Database with no downtime by executing this command when the instance is in OPEN status. It is possible to set the DB_FLASHBACK_RETENTION_TARGET parameter which specifies the upper limit (in minutes) on how far back in time the database may be flashed back. Its default value is 1440 minutes (=one day) of retention for the flashback logs. The reason that it is only an upper limit and not a guaranteed retention period is because if the FRA is full (reached the maximum FRA size limit defined by the DB_RECOVERY_FILE_DEST_SIZE parameter) or if there is not enough disk space, then Oracle will reuse the oldest flashback logs which might be within the retention period. It is possible to monitor the oldest possible flashback time via the V$FLASHBACK_DATABASE_LOG dictionary view. In the following demonstration, the FRA is set with a 100GB size limit and flashback retention target of 1 week (=10080 minutes):
SQL> ALTER SYSTEM SET DB_RECOVERY_FILE_DEST_SIZE=100g;
System altered.

SQL> ALTER SYSTEM SET db_recovery_file_dest='/oravl01/oracle/FRA';
System altered.

SQL> ALTER SYSTEM SET DB_FLASHBACK_RETENTION_TARGET=10080;
System altered.

SQL> ALTER DATABASE FLASHBACK ON;
Database altered.
In order to rewind the database, restart the database in a MOUNT mode, and then execute the FLASHBACK DATABASE command. It is possible to rewind the database to an exact SCN or Time. It is also possible to rewind the database prior to the SCN or Time. Another simple way is to create a restore point in which a name represents a specific point in time, and then the flashback will restore the database to the time that the restore point had been created. In the following example, a sample table is created, populated with a few records and truncated right after a restore point name “before_truncate” has been created. In this demo, a Flashback Database is used to rewind the enitre database prior to the truncate command that was executed using the “before_truncate” restore point.
SQL> create table test_flashback (id number, name varchar2(20));
Table created.

SQL> insert into test_flashback values (1, 'DAVID');
1 row created.

SQL> insert into test_flashback values (2, 'JOHN');
1 row created.

SQL> commit;
Commit complete.

SQL> create restore point before_truncate;
Restore point created.

SQL> truncate table test_flashback;
Table truncated.

SQL> select name,scn,time from V$RESTORE_POINT;
NAME                   SCN TIME
--------------- ---------- -------------------------------
BEFORE_TRUNCATE   119193304 24-JAN-16 09.14.06.000000000 PM

SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.

SQL> startup mount;
ORACLE instance started.

Total System Global Area  809500672 bytes
Fixed Size                  2929600 bytes
Variable Size             318770240 bytes
Database Buffers          482344960 bytes
Redo Buffers                5455872 bytes
Database mounted.

SQL> FLASHBACK DATABASE TO RESTORE POINT before_truncate;
Flashback complete.

SQL> alter database open resetlogs;
Database altered.

SQL> select * from test_flashback;
        ID NAME
---------- ---------------
         1 DAVID
         2 JOHN

Summary

In this article, have reviewed Oracle 10g Flashback features. We started with the Flashback Query enhancements (Flashback Version Query, Flashback Transaction Query, Flashback Table) and continued with additional flashback enhancements (Flashback Drop and Flashback Database).

In the next part, we will review Oracle 11g Flashback features.
Stay tuned :)

Wednesday, May 4, 2016

Ensuring Data Protection Using Oracle Flashback Features - Part 2

Introduction

In the previous article we have reviewed the basics of Oracle Data Protection, and explored Oracle Data Protection solutions. We also covered the data protection objectives which are measured by the RPO (Recovery Point Objective) and RTO (Recovery Time Objective).
In this article we will review the first Oracle Flashback feature which was introduced in Oracle 9i, named "Flashback Query" and we will see how this feature works "behind the scenes". Oracle Flashback Query allows querying a table's data as of a specific point in the past by providing either a TIMESTAMP or an SCN.

Demonstration

In the below first step, we will create a sample table named “EMP” with a single row: 
SQL> CREATE TABLE EMP (ID NUMBER, NAME VARCHAR2(20));
Table created.

SQL> insert into EMP values (1, 'DAVID');
1 row created.

SQL> select * from EMP;
        ID NAME
---------- --------------------
         1 DAVID

SQL> commit;
Commit complete.
Now, we will determine the current SCN and time:
SQL> select current_scn from v$database;
CURRENT_SCN
-----------
  476372816

SQL> select to_char(systimestamp, 'YYYY-MM-DD HH24:MI:SS') CURRENT_TIME from dual;
CURRENT_TIME
-------------------
2016-01-04 14:37:12
In the final step, we will update the row, and by using Flashback Query we will be able to view the contents of the table prior to the data modifications:
SQL> update emp set name = 'ROBERT';
1 row updated.

SQL> select * from EMP;
        ID NAME
---------- --------------------
         1 ROBERT

SQL> commit;
Commit complete.

SQL> select * from EMP as of scn 476372816;
        ID NAME
---------- --------------------
         1 DAVID

SQL> select * from EMP as of TIMESTAMP  
TO_TIMESTAMP('2016-01-04 14:37:12', 'YYYY-MM-DD HH24:MI:SS');
        ID NAME
---------- --------------------
         1 DAVID
This feature can be also very useful for investigating the contents of the table in a specific point in time in the past. It can also be used to restore the value of a row, a set of rows, or even the entire table. In the following example, an update sets the name of EMPLOYEE with ID #1 to be as of a specific time point in the past:
SQL> update EMP set name =
         (select name 
          from EMP 
   as of timestamp TO_TIMESTAMP('2016-01-04 14:37:12', 'YYYY-MM-DD HH24:MI:SS') WHERE  ID=1) 
    WHERE ID=1;
1 row updated.

SQL> select * from EMP;
        ID NAME
---------- --------------------
         1 DAVID
It is possible to specify a relative time by subtracting the current timestamp using the INTERVAL clause, as follows:
select * from emp
     as of timestamp (SYSTIMESTAMP - INTERVAL '60' MINUTE); 
In the following example, an INSERT AS SELECT command is using flashback query in order to insert all the rows that existed in “emp” table 2 hours ago:
insert into emp
   (select *
      from emp as of timestamp (SYSTIMESTAMP - INTERVAL '2' HOUR));
Note: It is possible to convert between SCN to TIMESTAMP using the SCN_TO_TIMESTAMP function

How does the Flashback Query feature work?

The Flashback Query feature uses the contents of the undo tablespace. The undo tablespace is a key component in Oracle Databases. It consists of undo segments which hold the "before" images of the data that has been changed by users running transactions. The undo is essential for rollback operations, data concurrency and read consistency. 

In order to use Flashback Query, the instance must have an automatic undo management by setting the UNDO_MANAGEMENT initialization parameter to be TRUE (default since version 11gR1). It is also important to set a proper value for the UNDO_DETENTION parameter. The UNDO_RETENTION specifies the low threshold (in seconds) for the undo retention period (defaults to 900, i.e. 15 minutes). It is important to bear in mind the different behaviors of this parameter in a fixed-size undo tablespace vs. autoextend undo tablespace.

Fixed-Size Undo Tablespace
For fixed-size undo tablespaces, the UNDO_RETENTION parameter is being ignored and Oracle automatically tunes for the maximum possible undo retention period based on the undo tablespace size and undo usage history.

Autoextend Undo Tablespace
For auto extend undo tablespace, the UNDO_RETENTION parameter specifies the minimum retention period Oracle will attempt to honor. When space in the undo tablespace becomes low (due to running transactions which generate undo records) Oracle will increase the tablespace size (up to the MAXSIZE limit). Once it will reach the upper limit of the MAXSIZE, it will begin to overwrite unexpired undo information; therefore, the retention period defined in the UNDO_RETENTION period is not guaranteed. This is why the actual undo retention period might be lower or even higher than the one defined in the UNDO_RETENTION parameter. The actual undo retention period can be obtained by querying the TUNED_UNDORETENTION column in V$UNDOSTAT dynamic performance view. 

Note: It is possible to specify the RETENTION GUARANTEE clause in the CREATE UNDO TABLESPACE or ALTER TABLESPACE commands, and then Oracle will never overwrite unexpired undo data even if it means that transactions will fail due to lack of space in the undo tablespace.

Monday, May 2, 2016

Ensuring Data Protection Using Oracle Flashback Features - Introduction (Part 1)

Introduction

This article is the first part of my article series regarding data protection using Oracle Flashback Features. Ensuring Data Protection for Oracle Databases is one of the most important tasks every Oracle DBA is faced with. Without protecting the data, the DBA will never be able to ensure high level of SLA (Service Level Agreement) to the business. 

Data Protection is a wide term that refers to the protection from many different potential issues in Oracle Databases such as:
  • Data Corruptions – Block corruption could be either physical or logical: 
    • Physical Corruption (also called media corruption) - When the block has an invalid checksum, therefore it cannot even be recognized as an Oracle block. 
    • Logical Corruption - When the block checksum is valid but its content is logically inconsistent; for example, when there is a missing index entry or a row piece. 
  • Disaster Recovery – Ranges from large-scale natural disasters such as floods, earthquakes, and fires, to small/medium disasters like power outages and viruses. 
  • Human Errors - A user operation that causes data to become unavailable (e.g. dropping/truncating a table, deleting rows) or logically wrong; for example, by modifying the contents of existing rows to wrong values. 


Data Protection Objectives

Every DBA should have a clear and tested recovery strategy in order to enforce the organization's Data Protection policy, which is usually defined by 2 important objectives, RPO and RTO: 
  • RPO (Recovery Point Objective) - The maximum amount of data that a business can allow itself to lose; for example, if the RPO of a company is 5 hours, then the DBA must restore and recover the database to a point in time in the last 5 hours. In some companies, the RPO is 0, i.e. the business can’t afford any data loss. 
  • RTO (Recovery Time Objective) - The maximum amount of downtime that a business can incur until the system is up and available again for the users. For example, if a database was crashed due to a physical corruption of a data file that belongs to SYSTEM tablespace, then assuming the RTO is 1 hour, the DBA must restore and recover the data file to ensure the database will be up and running within 1 hour since the crash occurred. 
Figure 1: the RPO and RTO data protection objectives


    Oracle provides a set of tools and features that can be used by the DBA for protecting Oracle Databases from various scenarios:
    • Data Corruptions - The most common way for detecting and recovering data corruptions is by using RMAN and user-managed backup/recovery methods.
    • Disaster Recovery - There are various ways for ensuring server protection, e.g. RAC, RAC One Node and Failover Clusters. For ensuring storage-level protection Oracle provides ASM 2-way or 3-way mirroring, and for ensuring site protection Oracle provides replication solutions such as Oracle Data Guard and Oracle Golden Gate.
    • Human Errors - There are various ways to handle human errors including using backups (either RMAN or user-managed backups); however, by using flashback features the DBA can recover from human errors in a much faster and simpler way.
    Figure 2: Oracle High Availability and Disaster Recovery Solutions



    This article will be focused on the last item - how to recover from various human errors scenarios, with the minimum RTO using Oracle Flashback features.


    Summary

    In the first part of the series I reviewed the basics of Oracle Data Protection. In the next part I will review the first Oracle Flashback feature which was introduced in Oracle 9i, named "Flashback Query" and we will see how this feature works "behind the scenes".