Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 

 

 

11g Flashback Transaction Interface

Oracle 11g New Features Tips by Donald BurlesonJune 29, 2015

Oracle 11g New Features Tips

The interface for flashback transaction is a new procedure in the dbms_flashback package.  Flashback transaction can be directly called from PL/SQL, or indirectly through the OEM interface.  The latter calls the overloaded procedure, transaction_backout, from the built in package. Using flashback transaction without the supplemental logging enabled will throw error ORA-55510. Note that if  OEM is being used to perform a transaction backout, minimal supplemental logging and identification key logging must be enabled, whereas ORA-55510 only requests minimal supplemental logging.

Let's take a look at using transaction backouts.  First of all, the  transaction(s) which need to back out must be found.  As already described, the 10g functionality FLASHBACK VERSIONS QUERY can be used to find  the transaction id.  The view flashback_transaction_query, also introduced in 10G, can be used next to find what the transaction has done.

LUTZ  @ orcl SQL> select versions_xid , col1 from t
    versions between scn minvalue and maxvalue;

VERSIONS_XID           COL1
---------------- ----------
07002000F2010000       2004
07002000F2010000       1004
01001F0002020000       2002
01001F0002020000       1002
0A00080020020000       2000
05000A00FA010000       1000

SQL> desc flashback_transaction_query

 Name                                      Null?    Type
 ----------------------------------------- -------- ---------------------------
 XID                                                RAW(8)
 START_SCN                                          NUMBER
 START_TIMESTAMP                                    DATE
 COMMIT_SCN                                         NUMBER
 COMMIT_TIMESTAMP                                   DATE
 LOGON_USER                                         VARCHAR2(30)
 UNDO_CHANGE#                                       NUMBER
 OPERATION                                          VARCHAR2(32)
 TABLE_NAME                                         VARCHAR2(256)
 TABLE_OWNER                                        VARCHAR2(32)
 ROW_ID                                             VARCHAR2(19)
 UNDO_SQL                                           VARCHAR2(4000)

Remember that the SELECT ANY TRANSACTION system privilege is needed in order to use this view.

The transaction_backout procedure is overloaded with four different versions in the package DBMS_FLASHBACK.

SYS AS SYSDBA @ orcl SQL> desc dbms_flashback
PROCEDURE DISABLE
PROCEDURE ENABLE_AT_SYSTEM_CHANGE_NUMBER

 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 QUERY_SCN                      NUMBER                  IN

PROCEDURE ENABLE_AT_TIME

 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 QUERY_TIME                     TIMESTAMP               IN

FUNCTION GET_SYSTEM_CHANGE_NUMBER RETURNS NUMBER
PROCEDURE TRANSACTION_BACKOUT

 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 NUMTXNS                        NUMBER                  IN
 XIDS                           XID_ARRAY               IN
 OPTIONS                        BINARY_INTEGER          IN     DEFAULT
 SCNHINT                        NUMBER                  IN     DEFAULT

PROCEDURE TRANSACTION_BACKOUT

 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 NUMTXNS                        NUMBER                  IN
 XIDS                           XID_ARRAY               IN
 OPTIONS                        BINARY_INTEGER          IN     DEFAULT
 TIMEHINT                       TIMESTAMP               IN

PROCEDURE TRANSACTION_BACKOUT

 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 NUMTXNS                        NUMBER                  IN
 NAMES                          TXNAME_ARRAY            IN
 OPTIONS                        BINARY_INTEGER          IN     DEFAULT
 SCNHINT                        NUMBER                  IN     DEFAULT

PROCEDURE TRANSACTION_BACKOUT

 Argument Name                  Type                    In/Out Default?
 ------------------------------ ----------------------- ------ --------
 NUMTXNS                        NUMBER                  IN
 NAMES                          TXNAME_ARRAY            IN
 OPTIONS                        BINARY_INTEGER          IN     DEFAULT
 TIMEHINT                       TIMESTAMP               IN

Once the DBA has decided which transaction(s) to back out, an array containing their transaction ids can be built. Progressively, the 11g database comes with a ready-made array datatypem sys.xid_array.  In the PL/SQL block below,  a sql*plus exchange valiable has been used to hand over the transaction id as a string at the prompt asking for the specification of a value for the variable during runtime of the block. 

DECLARE
         trans_arr SYS.XID_ARRAY :=  sys.xid_array();
          BEGIN
           trans_arr.extend;
           DBMS_OUTPUT.PUT_LINE(trans_arr.LAST);
            trans_arr(1) := '&tx_id';
           DBMS_FLASHBACK.TRANSACTION_BACKOUT (
                numtxns => 1,
                xids    => trans_arr,
                options => dbms_flashback.cascade);
END;
/

Using a loop, multiple rows of the array should be filled to back out multiple transactions. Then, the parameter numtxns can be adjusted to the number of transactions assigned to rows in the array.  If something is not prepared properly, the procedure throws an error:

TRANSACTION BACKOUT requires the database to be in ARCHIVELOG  mode

ERROR at line 1:

ORA-55510: Mining could not start
ORA-06512: at "SYS.DBMS_FLASHBACK", line 37
ORA-06512: at "SYS.DBMS_FLASHBACK", line 70
ORA-06512: at line 7

Oerr offers this information about the error:

> $ oerr ora 55510

55510, 0000, "Mining could not start"

// *Cause: Mining could not start for the following reasons.

//         1. A logminer session was processing
//         2. The database was not mounted or not opened for read and write
//         3. Minimum supplemental logging was not enabled
//         4. Archiving was not enabled

// *Action: Fix the mentioned problems and try again. Note that if
//          you enable supplemental logging now, you will not be able to
//          remove a transaction that has committed without supplemental
//          logging.

 
This is an excerpt from the new book Oracle 11g New Features: Expert Guide to the Important New Features by John Garmany, Steve Karam, Lutz Hartmann, V. J. Jain, Brian Carr.

You can buy it direct from the publisher for 30% off.

 

 
��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.