The WITH CONCURRENT TRANSACTION clause enables you to switch to a different connection while a transaction is active in the current connection. If the current connection was not established using the WITH CONCURRENT TRANSACTION clause, you cannot switch to a different connection if a transaction is active; the CONNECT or SET CONNECTION statement fails, returning an error, and the transaction in the current connection continues to be active.
In this case, the application must commit or roll back the active transaction in the current connection before it switches to a different connection.
The WITH CONCURRENT TRANSACTION clause supports the concept of multiple concurrent transactions, where each connection can have its own transaction and the COMMIT WORK and ROLLBACK WORK statements affect only the current connection. The WITH CONCURRENT TRANSACTION clause does not support global transactions in which a single transaction spans databases over multiple connections. The COMMIT WORK and ROLLBACK WORK statements do not act on databases across multiple connections.
The following example illustrates how to use the WITH CONCURRRENT TRANSACTION clause:
main() { EXEC SQL connect to 'a@srv1' as 'A'; EXEC SQL connect to 'b@srv2' as 'B' with concurrent transaction; EXEC SQL connect to 'c@srv3' as 'C' with concurrent transaction; /* Execute SQL statements in connection 'C' , starting a transaction */ EXEC SQL set connection 'B'; -- switch to connection 'B' /* Execute SQL statements starting a transaction in 'B'. Now there are two active transactions, one each in 'B' and 'C'. */ EXEC SQL set connection 'A'; -- switch to connection 'A' /* Execute SQL statements starting a transaction in 'A'. Now there are three active transactions, one each in 'A', 'B' and 'C'. */ EXEC SQL set connection 'C'; -- ERROR, transaction active in 'A' /* SET CONNECTION 'C' fails (current connection is still 'A') The transaction in 'A' must be committed or rolled back because connection 'A' was started without the CONCURRENT TRANSACTION clause. */
EXEC SQL commit work; -- commit tx in current connection ('A') /* Now, there are two active transactions, in 'B' and in 'C', which must be committed or rolled back separately */ EXEC SQL set connection 'B'; -- switch to connection 'B' EXEC SQL commit work; -- commit tx in current connection ('B') EXEC SQL set connection 'C'; -- go back to connection 'C' EXEC SQL commit work; -- commit tx in current connection ('C') EXEC SQL disconnect all; }
Database Environment: |--+-'dbname'--------------+------------------------------------| +-'@dbservername'-------+ +-'dbname@dbservername'-+ | (1) | '--------db_var---------'
Element | Description | Restrictions | Syntax |
---|---|---|---|
db_var | Host variable that contains a valid database environment (in one of the formats in the syntax diagram) | Must be a fixed-length character data type, whose contents are in a format from the syntax diagram | Language specific |
dbname | Database to which to connect | Must already exist | Identifier |
dbservername | Name of the database server to which a connection is made | Must already exist; blank space is not valid between @
symbol and dbservername.
See also Restrictions on dbservername. |
Identifier |
If the DELIMIDENT environment variable is set, any quotation ( ' ) marks in the database environment must be single. If DELIMIDENT is not set, then either single ( ' ) or double ( " ) quotation marks are valid here.
Enterprise Edition Home | Express Edition Home | [ Top of Page | Previous Page | Next Page | Contents | Index ]