Wednesday, January 28, 2009

Oracle Flashback Transaction Query

Summary

Flashback Transaction Query has a lot of the same functionality as Log Miner without the additional overhead associated with Log Miner mining redo logs for undo information. Flashback Transaction Query utilizes an access path to undo data which makes it faster than LogMiner at extracting the undo information. Unlike flashback query, flashback transaction query requires the select any transaction system privilege. How far back to a previous point in time Flashback Transaction Query is capable of executing directly depends on the transaction rate of you database in relationship to the size of the undo tablespace. While the undo_retention database initialization parameter is used to target the undo retention time that makes flashback query possible there must be enough undo tablespace to handle the transactional activity of the database to meet the undo_retention target. The undo_retention is a target and if the transactional activity of the database is high enough and the database needs undo space to continue executing transaction it will overwrite undo information needed to meet the retention. Keep this in mind when setting up and planning your undo retention capabilities.
See Monitoring and Tuning Flashback Capabilities

Executing Flashback Transaction Query
Procedure assumes that the transaction flashback capabilities were setup and tuned as outline in Setup Transactional Flashback Capability (Automatic Undo)

Simple example will utilize the scott.emp table with the following records:

SQL> select * from scott.emp ;

EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
7369 SMITH CLERK 7902 17-DEC-80 800 20
7499 ALLEN SALESMAN 7698 20-FEB-81 1600 300 30
7521 WARD SALESMAN 7698 22-FEB-81 1250 500 30
7566 JONES MANAGER 7839 02-APR-81 2975 20
7654 MARTIN SALESMAN 7698 28-SEP-81 1250 1400 30
7698 BLAKE MANAGER 7839 01-MAY-81 2850 30
7782 CLARK MANAGER 7839 09-JUN-81 2450 10
7788 SCOTT ANALYST 7566 19-APR-87 3000 20
7839 KING PRESIDENT 17-NOV-81 5000 10
7844 TURNER SALESMAN 7698 08-SEP-81 1500 0 30
7876 ADAMS CLERK 7788 23-MAY-87 1100 20
7900 JAMES CLERK 7698 03-DEC-81 950 30
7902 FORD ANALYST 7566 03-DEC-81 3000 20
7934 MILLER CLERK 7782 23-JAN-82 1300 10

14 rows selected.


1. Record current scn prior to making any changes

SQL> select current_scn scn from sys.v_$database ;

SCN
----------
1068761


2. Change some records with various inserts, updates and deletes.

SQL> delete from scott.emp where empno = 7369 ;

1 row deleted.

SQL> delete from scott.emp where empno = 7782 ;

1 row deleted.

SQL> update scott.emp set sal=10000 where empno = 7876 ;

1 row updated.

SQL> update scott.emp set sal=0 where empno = 7839 ;

1 row updated.

SQL> commit ;

Commit complete.


3. Verify data changes

SQL> select * from scott.emp ;

EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
7499 ALLEN SALESMAN 7698 20-FEB-81 1600 300 30
7521 WARD SALESMAN 7698 22-FEB-81 1250 500 30
7566 JONES MANAGER 7839 02-APR-81 2975 20
7654 MARTIN SALESMAN 7698 28-SEP-81 1250 1400 30
7698 BLAKE MANAGER 7839 01-MAY-81 2850 30
7788 SCOTT ANALYST 7566 19-APR-87 3000 20
7839 KING PRESIDENT 17-NOV-81 0 10
7844 TURNER SALESMAN 7698 08-SEP-81 1500 0 30
7876 ADAMS CLERK 7788 23-MAY-87 10000 20
7900 JAMES CLERK 7698 03-DEC-81 950 30
7902 FORD ANALYST 7566 03-DEC-81 3000 20
7934 MILLER CLERK 7782 23-JAN-82 1300 10

12 rows selected.


4. Review Undo for Changes Made

SQL> select /*undo_change#,*/ undo_sql
2 from flashback_transaction_query
3 where table_name = 'EMP' and
4 table_owner = 'SCOTT' and
5 logon_user = 'SYS' and
6 commit_scn > 1068761
7 order by undo_change# ;

UNDO_SQL
----------------------------------------------------------------------------------------------------
update "SCOTT"."EMP" set "SAL" = '5000' where ROWID = 'AAAMlsAAEAAAAAgAAI';
update "SCOTT"."EMP" set "SAL" = '1100' where ROWID = 'AAAMlsAAEAAAAAgAAK';
insert into "SCOTT"."EMP"("EMPNO","ENAME","JOB","MGR","HIREDATE","SAL","COMM","DEPTNO") values ('7782','CLARK','MANAGER','7839',TO_DATE('09-JUN-81', 'DD-MON-RR'),'2450',NULL,'10');
insert into "SCOTT"."EMP"("EMPNO","ENAME","JOB","MGR","HIREDATE","SAL","COMM","DEPTNO") values ('7369','SMITH','CLERK','7902',TO_DATE('17-DEC-80', 'DD-MON-RR'),'800',NULL,'20');

5. Undo Changes
See Example Script Below Appendix A: Fix Script Example using Flashback Transaction Query

SQL> @flashback_transaction_query.sql
Enter value for scnnumber: 1068761
old 8: commit_scn > &scnnumber
new 8: commit_scn > 1068761
undo_change#: 1
update "SCOTT"."EMP" set "SAL" = '5000' where ROWID = 'AAAMlsAAEAAAAAgAAI';
undo_change#: 2
update "SCOTT"."EMP" set "SAL" = '1100' where ROWID = 'AAAMlsAAEAAAAAgAAK';
undo_change#: 3
insert into
"SCOTT"."EMP"("EMPNO","ENAME","JOB","MGR","HIREDATE","SAL","COMM","DEPTNO")
values ('7782','CLARK','MANAGER','7839',TO_DATE('09-JUN-81',
'DD-MON-RR'),'2450',NULL,'10');
undo_change#: 4
insert into
"SCOTT"."EMP"("EMPNO","ENAME","JOB","MGR","HIREDATE","SAL","COMM","DEPTNO")
values ('7369','SMITH','CLERK','7902',TO_DATE('17-DEC-80',
'DD-MON-RR'),'800',NULL,'20');

PL/SQL procedure successfully completed.

SQL> commit ;

Commit complete.

Or execute the SQL statements from the prior query

update "SCOTT"."EMP" set "SAL" = '5000' where ROWID = 'AAAMlsAAEAAAAAgAAI';

update "SCOTT"."EMP" set "SAL" = '1100' where ROWID = 'AAAMlsAAEAAAAAgAAK';

insert into "SCOTT"."EMP"("EMPNO","ENAME","JOB","MGR","HIREDATE","SAL","COMM","DEPTNO") values ('7782','CLARK','MANAGER','7839',TO_DATE('09-JUN-81', 'DD-MON-RR'),'2450',NULL,'10');

insert into "SCOTT"."EMP"("EMPNO","ENAME","JOB","MGR","HIREDATE","SAL","COMM","DEPTNO") values ('7369','SMITH','CLERK','7902',TO_DATE('17-DEC-80', 'DD-MON-RR'),'800',NULL,'20');


6. Verify Changes are Un-done

SQL> select * from scott.emp ;

EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
7782 CLARK MANAGER 7839 09-JUN-81 2450 10
7369 SMITH CLERK 7902 17-DEC-80 800 20
7499 ALLEN SALESMAN 7698 20-FEB-81 1600 300 30
7521 WARD SALESMAN 7698 22-FEB-81 1250 500 30
7566 JONES MANAGER 7839 02-APR-81 2975 20
7654 MARTIN SALESMAN 7698 28-SEP-81 1250 1400 30
7698 BLAKE MANAGER 7839 01-MAY-81 2850 30
7788 SCOTT ANALYST 7566 19-APR-87 3000 20
7839 KING PRESIDENT 17-NOV-81 5000 10
7844 TURNER SALESMAN 7698 08-SEP-81 1500 0 30
7876 ADAMS CLERK 7788 23-MAY-87 1100 20

EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
7900 JAMES CLERK 7698 03-DEC-81 950 30
7902 FORD ANALYST 7566 03-DEC-81 3000 20
7934 MILLER CLERK 7782 23-JAN-82 1300 10

14 rows selected.


Appendix A: Fix Script Example using Flashback Transaction Query

SET SERVEROUTPUT ON SIZE 1000000
begin
for r in (

select /*undo_change#,*/ undo_sql
from flashback_trasnaction_query
where table_name = 'EMP' and
table_owner = 'SCOTT' and
logon_user = 'SYS' and
commit_scn > &scnnumber
order by undo_change#
) loop

dbms_output.put_line('r.undo_change#: ' r.undo_change#);
dbms_output.put_line(' ' r.undo_sql);

execute immediate
substr(r.undo_sql, 1, length(r.undo_sql)-1);

end loop;
end ;
/