HPlogo ALLBASE/SQL Reference Manual: HP 9000 Computer Systems > Chapter 12 SQL Statements S - Z

SET TRANSACTION

» 

Technical documentation

Complete book in PDF
» Feedback

 » Table of Contents

 » Index

The SET TRANSACTION statement sets one or more transaction attributes for a transaction. These attributes include: isolation level, priority, user label, constraint checking mode, timeout rollback, user timeout, termination level, and DML atomicity level.

Scope

ISQL or Application Programs

SQL Syntax

  SET TRANSACTION {ISOLATION LEVEL {RR 
                                    CS 
                                    RC 
                                    RU  
                                    REPEATABLE READ 
                                    SERIALIZABLE 
                                    CURSOR STABILITY 
                                    READ COMMITTED 
                                    READ UNCOMMITTED 
                                    :HostVariable1    } 
                   PRIORITY {Priority 
                             :HostVariable2} 
                   LABEL {'LabelString' 
                          :HostVariable3} 
                   ConstraintType [,...]CONSTRAINTS {DEFERRED 
                                                     IMMEDIATE} 
                   DML ATOMICITY AT {STATEMENT 
                                     ROW       }LEVEL 
                   ON {TIMEOUT 
                       DEADLOCK}ROLLBACK {QUERY 
                                          TRANSACTION} 
                   USER TIMEOUT [TO] {DEFAULT 
                                      MAXIMUM 
                                      TimeoutValue[{SECONDS 
                                                    MINUTES}] 
                                      :HostVariable4[{SECONDS 
                                                      MINUTES}]
                   TERMINATION AT {SESSION 
                                   TRANSACTION 
                                   QUERY 
                                   RESTRICTED   }LEVEL             }[,...]

Parameters

RR

Repeatable Read. Means that the transaction uses locking strategies to guarantee repeatable reads. RR is the default isolation level.

CS

Cursor Stability. Means that your transaction uses locking strategies to assure cursor-level stability only.

RC

Read Committed. Means that your transaction uses locking strategies to ensure that you retrieve only rows that have been committed by some transaction.

RU

Read Uncommitted. Means that the transaction reads data without obtaining additional locks.

REPEATABLE READ

Same as RR.

SERIALIZABLE

Same as RR.

CURSOR STABILITY

Same as CS.

READ COMMITTED

Same as RC.

READ UNCOMMITTED

Same as RU.

HostVariable1

is a string host variable containing one of the isolation level specifications above.

Priority

is an integer from 0 to 255 specifying the priority of the transaction. Priority 127 is the default. ALLBASE/SQL uses the priority to resolve a deadlock. The transaction with the largest priority number is aborted to remove the deadlock.

For example, if a priority-0 transaction and a priority-1 transaction are deadlocked, the priority-1 transaction is aborted. If two transactions involved in a deadlock have the same priority, the deadlock is resolved by aborting the newer transaction (the last transaction begun, either implicitly or with a BEGIN WORK statement).

HostVariable2

is an integer host variable containing the priority specification.

LabelString

is a user defined character string of up to 8 characters. The default is a blank string.

The label is visible in the SYSTEM.TRANSACTION pseudo-table and also in SQLMON. Transaction labels can be useful for troubleshooting and performance tuning. Each transaction in an application program can be marked uniquely, allowing the DBA to easily identify the transaction being executed by any user at any moment.

Labels for a new transaction can be specified with the BEGIN WORK, SET TRANSACTION, and SET SESSION statements. SET TRANSACTION can also be used to change the existing label of an active transaction. If a transaction consists of multiple queries and unique labels are set between each query, a DBA can identify the actual query being executed by an active transaction.

HostVariable3

is a string host variable containing the LabelString.

ConstraintType

identifies the types of constraints that are affected by the DEFERRED and IMMEDIATE options. Each ConstraintType can be one of the following:

       UNIQUE
       REFERENTIAL
       CHECK
DEFERRED

specifies that constraint errors are not checked until the constraint checking mode is reset to IMMEDIATE or the current transaction ends.

IMMEDIATE

specifies that constraint errors are checked when a statement executes. This is the default.

STATEMENT

specifies that error checking occurs at the statement level. This is the default.

ROW

specifies that error checking occurs at the row level.

QUERY

sets the action for timeouts or deadlocks to rollback the statement or query.

TRANSACTION

sets the action for timeouts or deadlocks to rollback the transaction.

DEFAULT

specifies to use the default timeout duration for the DBE specified in the START DBE statement.

MAXIMUM

specifies to use the maximum timeout duration for the DBE specified in the START DBE statement.

TimeoutValue

specifies the timeout duration to use in seconds or minutes.

:HostVariable4

is an integer host variable specifying the timeout duration to use in seconds or minutes.

SESSION

specifies self-termination at the session level, and allows external termination at the session level only.

TRANSACTION

specifies self-termination at the transaction level, and allows external termination at the session or transaction level.

QUERY

specifies self-termination at the query level, and allows external termination at the session, transaction, or query level.

RESTRICTED

specifies no self-termination, and allows external termination at the session level only. This is the default.

Description

  • Detailed information about isolation levels is presented in the "Concurrency Control through Locks and Isolation Levels" chapter.

  • You can issue the SET TRANSACTION statement at any point in an application or ISQL session. If the SET TRANSACTION statement is issued outside of an active transaction, its attribute(s) apply to the next transaction. If issued within a transaction, its attribute(s) apply to the current transaction.

  • Within a transaction, any attribute specified in a SET TRANSACTION statement remains in effect until the transaction terminates or until reset by another statement issued within the transaction. See Chapter 2 “Using ALLBASE/SQL” "Scoping of Transaction and Session Attributes" section for information about statements used to set transaction attributes.

  • When using RC or RU, you should verify the existence of a row before you issue an UPDATE statement. In application programs that employ cursors, you can use the REFETCH statement prior to updating. REFETCH is not available in ISQL. Therefore, you should use caution in employing RC and RU in ISQL if you are doing updates.

  • Within a transaction, different isolation levels can be set for different DML statements. For example, a cursor opened following a SET TRANSACTION statement is opened with the specified isolation level, but any cursor opened prior to this SET TRANSACTION statement maintains the isolation level with which it was opened.

  • As with the SET CONSTRAINTS statement, the SET TRANSACTION statement allows you to set the UNIQUE, REFERENTIAL or CHECK constraint error checking mode. If the constraint checking mode is deferred, checking of constraints is deferred until the end of a transaction or until the constraint mode is set back to immediate. If the constraint mode is immediate, integrity constraints are checked following processing of each SQL statement (if statement level atomicity is in effect) or each row (if row level atomicity is in effect). Refer to the SET DML ATOMICITY statement in this chapter for further information on statement and row level error checking. The following paragraph assumes that statement level atomicity is in effect.

    When constraint checking is deferred, a COMMIT WORK, or SET CONSTRAINTS IMMEDIATE statement executes if zero constraint violations exist at that time, otherwise a constraint error is reported. When constraint checking is immediate (the default), zero constraint violations must exist when an SQL statement executes, otherwise a constraint error is reported and the statement is rolled back. The SET CONSTRAINTS statement in this chapter gives further detail about constraint checking.

  • As with the SET DML ATOMICITY statement, the SET TRANSACTION statement allows you to set the general error checking level in data manipulation statements. General error checking refers to any errors, for example, arithmetic overflows or constraint violation errors.

    Setting ROW LEVEL atomicity guarantees that internal savepoints are not generated. For example, if an error occurs on the nth row of a bulk statement such as LOAD, BULK INSERT, or Type2 INSERT, the row is not processed, statement execution terminates, and any previously processed rows are not rolled back. In contrast, STATEMENT LEVEL atomicity guarantees that the entire statement is rolled back if it does not execute without error. STATEMENT LEVEL atomicity is the default. Refer to the SET DML ATOMICITY statement in this chapter for further information on statement and row level error checking.

  • All transaction attributes are sensitive to savepoints. That is, if you establish a savepoint, then change the transaction attribute(s) by issuing a SET TRANSACTION statement, and then roll back to the savepoint, the transaction attribute(s) set after the savepoint are undone.

  • When ON TIMEOUT ROLLBACK or ON DEADLOCK ROLLBACK is set to TRANSACTION, the whole transaction is aborted as a result of a timeout or deadlock.

  • When ON TIMEOUT ROLLBACK or ON DEADLOCK ROLLBACK is set to QUERY, only the SQL statement which has timed out will be rolled back. This means rolling back results of statements that modify the database and closing cursor for the cursor-related statements. (Cursor-related statements change the cursor position, and are not statements like UPDATE or DELETE WHERE CURRENT.)

  • In general, if a transaction with KEEP cursor(s) is committed, the new transaction started on behalf of the user inherits the most recent transaction attributes of the old transaction. However, the KEEP cursor(s) inherit the isolation level attribute of the old transaction at the time the cursor(s) were opened. For example:

       BEGIN WORK RC
       .
       .
       .
       OPEN C1 KEEP CURSOR ...
       .
       .
       .
       SET TRANSACTION ISOLATION LEVEL CS
       .
       .
       .
       OPEN C2 KEEP CURSOR ...
       .
       .
       .
       SET TRANSACTION ISOLATION LEVEL RU
       .
       .
       .
       COMMIT WORK
       .
       .
       .
       OPEN C3              
       .
       .
       .

    In the above example, the new transaction started on behalf of the user after the COMMIT WORK has isolation level RU; cursor C1 has isolation RC; cursor C2 has isolation level CS; and cursor C3 has isolation level RU.

  • The SET TRANSACTION statement is not allowed within a stored procedure.

Authorization

You do not need authorization to use the SET TRANSACTION statement.

Example

Declare multiple cursors

   DECLARE C1 CURSOR FOR SELECT BranchNo FROM Branches 
            WHERE TellerNo > :TellerNo
 
   DECLARE C2 CURSOR FOR SELECT BranchNo FROM Tellers
            WHERE BranchNo = :HostBranchNo FOR UPDATE OF Credit
 
   DECLARE C3 CURSOR FOR SELECT * FROM PurchDB.Parts

Set the isolation level to RC.

   SET TRANSACTION ISOLATION LEVEL RC, PRIORITY 100, LABEL 'xact1'
   .
   .
   .
   Implicit BEGIN WORK with transaction isolation level RC.
 
   OPEN C1
   FETCH C1 INTO :HostBranchNo1     
   .
   .
   .

Change isolation level to CS.

   SET TRANSACTION ISOLATION LEVEL CS
   OPEN C2
   FETCH C2 INTO :HostBranchNo2
   UPDATE Tellers SET Credit = Credit * 0.005
            WHERE CURRENT OF C2
   CLOSE C2                                    Close cursor C2.
   CLOSE C1                                    Close cursor C1. 

Change the transaction isolation level back to RC.

   SET TRANSACTION ISOLATION LEVEL RC
   OPEN C3
   FETCH C3 INTO :PartsBuffer
   .
   .
   .

End the transaction. Transaction attributes return to those set at the session level or to the session default.

   COMMIT WORK
Feedback to webmaster