Flashback Table in Oracle Explained With Examples
Let's check out flashback tables and how they restore existing tables to earlier versions using timestamp and SCN number.
Join the DZone community and get the full member experience.
Join For FreeFlashback table restores the existing tables to earlier versions using timestamp and SCN number. It is available in and after Oracle 10g version.
It also helps to retrieve removed tables from the database, dropped using DROP and TRUNCATE commands.
Tables altered using DDL statements can also not be restored to a prior state with flashback operation.
One thing you must remember about flashback operation is that undo of data is controlled by UNDO_RETENTION parameter. In simpler words, if undo data is available, then only tables can be restored back.
Once you trigger FLASHBACK TABLE statement on any table, it cannot be rolled back. Best practice is to record the current SCN number before issuing a FLASHBACK TABLE statement.
You must enable row movement during the creation of the table to carry out flashback operation on it. Row movement can also be enabled using ALTER command later on.
ALTER TABLE employees ENABLE ROW MOVEMENT;
Syntax
FLASHBACK TABLE table_name
[TO BEFORE DROP] |
[TO TIMESTAMP time_stamp] |
[TO SCN scn_number] |
[ENABLE TRIGGERS | DISABLE TRIGGERS];
Parameters Explanation
table_name — Name of the table to restore
time_stamp — User defined timestamp
scn_number — Oracle SCN (Service Change Number) number
Restoring Table to Earlier State
The below example shows FLASHBACK TABLE command used to restore the table to an earlier state.
Create table emp_temp from table employees whose department number is 10.
CREATE TABLE emp_temp
SELECT * FROM employees WHERE dept_no = 10;
Fetching the data from emp_temp retrieves the list of employees belonging to department number 10.
SELECT dept_no, salary FROM emp_temp;
DEPT_NO | SALARY |
10 | 1500 |
10 | 3600 |
10 | 4000 |
Now, delete the employees with salary less than 2000 from the emp_temp table using below query.
DELETE FROM emp_temp WHERE salary < 2000;
This will leave only 2 records in the emp_temp table.
DEPT_NO | SALARY |
10 | 3600 |
10 | 4000 |
With below query, we can restore table emp_temp to 2 minutes prior to current time using flashback operation
FLASHBACK TABLE emp_temp
TO TIMESTAMP (SYSTIMESTAMP – INTERVAL '2' MINUTE);
Querying table emp_temp again will retrieve the original results
DEPT_NO | SALARY |
10 | 1500 |
10 | 3600 |
10 | 4000 |
Another way of restoring table emp_temp to particular timestamp is as follows
FLASHBACK TABLE emp_temp
TO TIMESTAMP TO_TIMESTAMP('2018-09-19 13:34:12', 'YYYY-MM-DD HH24:MI:SS');
Retrieve Table Using SCN
You can also retrieve the older version of the table using SCN number.
Let us continue with the above example TO TIMESTAMP
In order to query 2 minutes, the prior version of table emp_temp using SCN number, below query can be used
FLASHBACK TABLE emp_temp TO SCN (3187302511937);
This SCN number is of 2 minutes prior state of table emp_temp.
So the output after flashback operation while querying emp_temp table will be
DEPT_NO | SALARY |
10 | 1500 |
10 | 3600 |
10 | 4000 |
Retrieving a Dropped Table
Suppose you had dropped table employees accidentally in a hurry to go home by firing a below query
DROP TABLE employees;
To retrieve the table employees back, use TO BEFORE DROP clause of FLASHBACK TABLE.
FLASHBACK TABLE employees TO BEFORE DROP;
The retrieved employees table can also be renamed to emp with the below query
FLASHBACK TABLE employees TO BEFORE DROP RENAME TO emp;
ENABLE or DISABLE TRIGGERS
By default Oracle database disable triggers during the flashback. These triggers are enabled when flashback operation is completed.
You need to specify ENABLE TRIGGERS to keep the triggers enabled during flashback operation.
FLASHBACK TABLE emp_temp TO SCN (3187302511937) ENABLE TRIGGERS;
However, the triggers that are already disabled before flashback operation cannot be enabled using this option.
DISABLE TRIGGERS acts the same as a default behaviour in flashback operation.
RECYCLEBIN and USER_RECYCLEBIN
USER_RECYCLEBIN is the view from which you can retrieve the tables that are dropped or truncated.
SELECT * FROM user_recyclebin;
RECYCLEBIN is the synonym of USER_RECYCLEBIN view.
TO SCN Clause
The table can be returned to a point in time of mentioned SCN number using TO SCN clause.
SCN number can be retrieved from the v$database table using below query
SELECT current_scn FROM v$database;
You can also convert a timestamp to SCN number and vice versa using SCN_TO_TIMESTAMP and TIMESTAMP_TO_SCN functions
SELECT TIMESTAMP_TO_SCN(SYSTIMESTAMP – INTERVAL '2' MINUTE) FROM dual;
SCN_TO_TIMESTAMP(3187302511937) will retrieve the timestamp of this SCN number.
TO TIMESTAMP Clause
In order to restore the table back to particular timestamp, use TO TIMESTAMP clause.
TO BEFORE DROP Clause
The clause TO BEFORE DROP retrieves back the dropped table.
However, the tables dropped using PURGE option cannot be retrieved back.
TO BEFORE DROP clause is also unable to recover tables dropped TRUNCATE TABLE command.
RENAME TO Clause
RENAME TO clause retrieves the table from recycle bin with a new name during flashback operation.
Retrieve Table After TRUNCATE TABLE
Tables dropped by TRUNCATE TABLE can be restored using TO TIMESTAMP and TO SCN clause. Recovery of lost data is not possible in this case.
Published at DZone with permission of Paras Shah. See the original article here.
Opinions expressed by DZone contributors are their own.
Comments