Pro*COBOL Precompiler Programmer's Guide
Release 8.1.5

A68023-01

Library

Product

Contents

Index

Prev Next

3
Database Concepts

This chapter explains the CONNECT statement and its options, Net8, and related statements used for network connections. Next, how to do transaction processing is presented. You learn the basic techniques that safeguard the consistency of your database, including how to control whether changes to Oracle data are made permanent or undone.

Connecting to Oracle

Your Pro*COBOL program must log on to Oracle before querying or manipulating data. To log on, you use the CONNECT statement, as in

     EXEC SQL 
         CONNECT :USERNAME IDENTIFIED BY :PASSWD
     END-EXEC. 

where USERNAME and PASSWD are PIC X(n) or PIC X(n) VARYING host variables. Alternatively, you can use the statement

     EXEC SQL 
         CONNECT :USR-PWD 
     END-EXEC. 

where the host variable USR-PWD contains your username and password separated by a slash (/).

The syntax for the CONNECT statement has an optional ALTER AUTHORIZATION clause. The syntax for CONNECT is shown here:

     EXEC SQL 
        CONNECT { :user IDENTIFIED BY :oldpswd | :usr_psw }
        [[AT { dbname | :host_variable }] USING :connect_string ]
        [ {ALTER AUTHORIZATION :newpswd  | IN {SYSDBA | SYSOPER} MODE} ]
     END-EXEC.

The ALTER AUTHORIZATION clause is explained in "Changing Passwords at Runtime". The SYSDBA and SYSOPER options are explained in "SYSDBA or SYSOPER Privileges" .

The CONNECT statement must be the first SQL statement executed by the program. That is, other executable SQL statements can positionally, but not logically, precede the CONNECT statement. If the precompiler option AUTO_CONNECT=YES, a CONNECT statement is not needed.)

To supply the Oracle username and password separately, you define two host variables as character strings or VARCHAR variables. If you supply a userid containing both username and password, only one host variable is needed.

Make sure to set the username and password variables before the CONNECT is executed or it will fail. Your program can prompt for the values or you can hard-code them, as follows:

 WORKING STORAGE SECTION. 
     ... 
 01  USERNAME  PIC X(10) VARYING. 
 01  PASSWD    PIC X(10) VARYING. 
         ... 
     ... 
 PROCEDURE DIVISION. 
 LOGON. 
     MOVE "SCOTT" TO USERNAME-ARR. 
     MOVE 5 TO USERNAME-LEN. 
     MOVE "TIGER" TO PASSWD-ARR. 
     MOVE 5 TO PASSWD-LEN. 
     EXEC SQL WHENEVER SQLERROR GOTO LOGON-ERROR END-EXEC. 
     EXEC SQL 
         CONNECT :USERNAME IDENTIFIED BY :PASSWD 
     END-EXEC. 

However, you cannot hard-code a username and password into the CONNECT statement or use quoted literals. For example, the following statements are invalid:

     EXEC SQL 
         CONNECT SCOTT IDENTIFIED BY TIGER 
     END-EXEC. 

     EXEC SQL 
         CONNECT "SCOTT" IDENTIFIED BY "TIGER" 
     END-EXEC.

Default Databases and Connections

Each node has a default database. If you specify a node but no database in your CONNECT statement, you connect to the default database on the named local or remote node. If you specify no database and no node, you connect to the default database on the current node. Although it is unnecessary, you can specify the default database and current node in your CONNECT statement.s

A default connection is made using a CONNECT statement without an AT clause. The connection can be to any default or non-default database at any local or remote node. SQL statements without an AT clause are executed against the default connection. Conversely, a non-default connection is made by a CONNECT statement that has an AT clause. A SQL statement with an AT clause is executed against the non-default connection.

All database names must be unique, but two or more database names can specify the same connection. That is, you can have multiple connections to any database on any node.

Using Username/Password

Usually, you establish a connection to Oracle as follows:

     EXEC SQL CONNECT :USERNAME IDENTIFIED BY :PASSWORD END-EXEC.

Or, you can use:

     EXEC SQL CONNECT :USR-PWD END-EXEC. 

where USR-PWD contains USERNAME/PASSWORD.

You can also log on automatically as shown in "Automatic Logons".

These are simplified subsets of the CONNECT statement. For all details, read the next sections in this chapter and also see "CONNECT (Executable Embedded SQL Extension)".

If you do not specify a database and node, you are connected to the default database at the current node. If you want to connect to a different database, you must explicitly identify that database.

With explicit logons, you connect to another database directly, giving the connection a name that will be referenced in SQL statements. You can connect to several databases at the same time and to the same database multiple times.

Single Explicit Logons

In the following example, you connect to a single non-default database at a remote node:

* --  Declare necessary host variables
 WORKING-STORAGE SECTION.
     ...
     EXEC SQL BEGIN DECLARE SECTION END-EXEC.
 01  USERNAME  PIC X(10) .
 01  PASSWORD  PIC X(10) .
 01  DB-STRING PIC X(20) .
        ...
     EXEC SQL END DECLARE SECTION END-EXEC.
     ...
 PROCEDURE DIVISION.
     MOVE "scott" TO USERNAME.
     MOVE "tiger" TO PASSSWORD.
     MOVE "nyremote" TO DB-STRING.
      ... 
* --  Assign a unique name to the database connection.
     EXEC SQL DECLARE DBNAME DATABASE END-EXEC.
* --  Connect to the non-default database
     EXEC SQL
     CONNECT :USERNAME IDENTIFIED BY :PASSWORD 
     AT DBNAME USING :DB-STRING
     END-EXEC.

The identifiers in this example serve the following purposes:

The USING clause specifies the network, machine, and database to be associated with DBNAME. Later, SQL statements using the AT clause (with DBNAME) are executed at the database specified by DB-STRING.

Alternatively, you can use a character host variable in the AT clause, as the following example shows:

* --  Declare necessary host variables
 WORKING-STORAGE SECTION.
     ...
     EXEC SQL BEGIN DECLARE SECTION END-EXEC.
 01  USERNAME  PIC X(10).
 01  PASSWORD  PIC X(10).
 01  DB-NAME   PIC X(10).
 01  DB-STRING PIC X(20).
        ...
     EXEC SQL END DECLARE SECTION END-EXEC.
     ...
 PROCEDURE DIVISION.
     MOVE "scott" TO USERNAME.
     MOVE "tiger" TO PASSSWORD.
     MOVE "oracle1" TO DB-NAME.
     MOVE "nyremote" TO DB-STRING.
     ... 
* --  Connect to the non-default database
     EXEC SQL
     CONNECT :USERNAME IDENTIFIED BY :PASSWORD 
     AT :DB-NAME USING :DB-STRING
     END-EXEC.

If DB-NAME is a host variable, the DECLARE DATABASE statement is not needed. Only if DBNAME is an undeclared identifier must you execute a DECLARE DBNAME DATABASE statement before executing a CONNECT ... AT DBNAME statement.

SQL Operations. If granted the privilege, you can execute any SQL data manipulation statement at the non-default connection. For example, you might execute the following sequence of statements:

     EXEC SQL AT DBNAME SELECT ... 
     EXEC SQL AT DBNAME INSERT ... 
     EXEC SQL AT DBNAME UPDATE ... 

In the next example, DB-NAME is a host variable:

     EXEC SQL AT :DB-NAME DELETE ... 

If DB-NAME is a host variable, all database tables referenced by the SQL statement must be defined in DECLARE TABLE statements.

Cursor Control. Cursor control statements such as OPEN, FETCH, and CLOSE are exceptions--they never use an AT clause. If you want to associate a cursor with an explicitly identified database, use the AT clause in the DECLARE CURSOR statement, as follows:

     EXEC SQL AT :DB-NAME DECLARE emp_cursor CURSOR FOR ... 
     EXEC SQL OPEN EMP-CURSOR ... 
     EXEC SQL FETCH EMP-CURSOR ... 
     EXEC SQL CLOSE EMP-CURSOR END-EXEC.

If DB-NAME is a host variable, its declaration must be within the scope of all SQL statements that refer to the declared cursor. For example, if you open the cursor in one subprogram, then fetch from it in another, you must declare DB-NAME globally or pass it to each subprogram.

When opening, closing, or fetching from the cursor, you do not use the AT clause. The SQL statements are executed at the database named in the AT clause of the DECLARE CURSOR statement or at the default database if no AT clause is used in the cursor declaration.

The AT :host-variable clause allows you to change the connection associated with a cursor. However, you cannot change the association while the cursor is open. Consider the following example:

     EXEC SQL AT :DB-NAME DECLARE EMP-CURSOR CURSOR FOR ... 
     MOVE "oracle1" TO DB-NAME.
     EXEC SQL OPEN EMP-CURSOR END-EXEC. 
     EXEC SQL FETCH EMP-CURSOR INTO ... 
     MOVE "oracle2" TO DB-NAME.
* -- illegal, cursor still open 
     EXEC SQL OPEN EMP-CURSOR END-EXEC.
     EXEC SQL FETCH EMP-CURSOR INTO ... 

This is illegal because EMP-CURSOR is still open when you try to execute the second OPEN statement. Separate cursors are not maintained for different connections; there is only one EMP-CURSOR, which must be closed before it can be reopened for another connection. To debug the last example, simply close the cursor before reopening it, as follows:

* -- close cursor first 
     EXEC SQL CLOSE EMP-CURSOR END-EXEC.
     MOVE "oracle2" TO DB-NAME.
     EXEC SQL OPEN EMP-CUROR END-EXEC. 
     EXEC SQL FETCH EMP-CURSOR INTO ... 

Dynamic SQL. Dynamic SQL statements are similar to cursor control statements in that some never use the AT clause. For dynamic SQL Method 1, you must use the AT clause if you want to execute the statement at a non-default connection. An example follows:

     EXEC SQL AT :DB-NAME EXECUTE IMMEDIATE :SQL-STMT END-EXEC.
 

For Methods 2, 3, and 4, you use the AT clause only in the DECLARE STATEMENT statement if you want to execute the statement at a non-default connection. All other dynamic SQL statements such as PREPARE, DESCRIBE, OPEN, FETCH, and CLOSE never use the AT clause. The next example shows Method 2:

     EXEC SQL AT :DB-NAME DECLARE SQL-STMT STATEMENT END-EXEC. 
     EXEC SQL PREPARE SQL-STMT FROM :SQL-STRING END-EXEC. 
     EXEC SQL EXECUTE SQL-STMT END-EXEC. 

The following example shows Method 3:

     EXEC SQL AT :DB-NAME DECLARE SQL-STMT STATEMENT END-EXEC. 
     EXEC SQL PREPARE SQL-STMT FROM :SQL-STRING END-EXEC. 
     EXEC SQL DECLARE EMP-CURSOR CURSOR FOR SQL-STMT END-EXEC. 
     EXEC SQL OPEN EMP-CURSOR ... 
     EXEC SQL FETCH EMP-CURSOR INTO ... 
     EXEC SQL CLOSE EMP-CURSOR END-EXEC. 

You need not use the AT clause when connecting to a remote database unless you open two or more connections simultaneously (in which case the AT clause is needed to identify the active connection). To make the default connection to a remote database, use the following syntax:

     EXEC SQL 
        CONNECT :USERNAME IDENTIFIED BY :PASSWORD USING :DB-STRING
     END-EXEC.

Multiple Explicit Logons

You can use the AT db_name clause for multiple explicit logons, just as you would for a single explicit logon. In the following example, you connect to two non-default databases concurrently:

     EXEC SQL BEGIN DECLARE SECTION END-EXEC.
 01  USERNAME   PIC X(10) .
 01  PASSWORD   PIC X(10) .
 01  DB-STRING1 PIC X(20) .
 01  DB-STRING2 PIC X(20) . 
     EXEC SQL END DECLARE SECTION END-EXEC. 
     ... 
     MOVE "scott" TO USERNAME.
     MOVE "tiger" TO PASSWORD.
     MOVE "New-York" TO DB-STRING1.
     MOVE "Boston" TO DB-STRING2.

* --  give each database connection a unique name 
     EXEC SQL DECLARE DBNAME1 DATABASE END-EXEC. 
     EXEC SQL DECLARE DBNAME2 DATABASE; 
* --  connect to the two non-default databases 
     EXEC SQL CONNECT :USERNAME IDENTIFIED BY :PASSWORD 
     AT DBNAME1 USING :DB-STRING1 END-EXEC. 
     EXEC SQL CONNECT :USERNAME IDENTIFIED BY :PASSWORD 
     AT DBNAME2 USING :DB-STRING2 END-EXEC.

The undeclared identifiers DBNAME1 and DBNAME2 are used to name the default databases at the two non-default nodes so that later SQL statements can refer to the databases by name.

Alternatively, you can use a host variable in the AT clause, as the following example shows:

 01  USERNAME   PIC X(10) .
 01  PASSWORD   PIC X(10) .
 01  DB-NAME    PIC X(10) .
 01  DB-STRING  PIC X(20) .
     ... 
     MOVE "scott" TO USERNAME.
     MOVE "tiger" TO PASSWORD.
     PERFORM GETDB 2 TIMES.       
     ...
* --  get next database name and Net8 string 
 GETDB.
     DISPLAY "Database Name? ".
     ACCEPT DB-NAME.
     DISPLAY "Net8 String? ".
     ACCEPT DB-STRING. 
* --  connect to the non-default database 
     EXEC SQL CONNECT :USERNAME IDENTIFIED BY :PASSWORD 
     AT :DB-NAME USING :DB-STRING
     END-EXEC.
     ...

You can also use this method to make multiple connections to the same database, as the following example shows:

     MOVE "scott" TO USERNAME.
     MOVE "tiger" TO PASSWORD.
     MOVE "nyremote" TO DB-STRING.
     PERFORM GETDB 2 TIMES
     ...       
 GETDB.
* -- get next database name 
     DISPLAY 'Database Name? '. 
     ACCEPT DB-NAME. 
* -- connect to the non-default database 
     EXEC SQL CONNECT :USERNAME IDENTIFIED BY :PASSWORD 
        AT :DB-NAME USING :DB-STRING
     END-EXEC.
     ... 

You must use different database names for the connections, even if they use the same Net8 string.

Automatic Logons

You can log on to Oracle automatically with the userid:

<prefix><username> 

where prefix is the value of the Oracle initialization parameter OS_AUTHENT_PREFIX (the default value is OPS$) and username is your operating system user or task name. For example, if the prefix is OPS$, your user name is TBARNES, and OPS$TBARNES is a valid Oracle userid, you log on to Oracle as user OPS$TBARNES.

To take advantage of the automatic logon feature, you simply pass a slash (/) character to Pro*COBOL, as follows:

     EXEC SQL BEGIN DECLARE SECTION END-EXEC. 
 01 ORACLEID   PIC X.
     ...
     EXEC SQL END DECLARE SECTION END-EXEC. 
     ... 
     MOVE '/' TO ORACLEID.
     EXEC SQL CONNECT :ORACLEID END-EXEC. 

This automatically connects you as user OPS$username. For example, if your operating system username is RHILL, and OPS$RHILL is a valid Oracle username, connecting with a slash (/) automatically logs you on to Oracle as user OPS$RHILL.

You can also pass a character string to Pro*COBOL. However, the string cannot contain trailing blanks. For example, the following CONNECT statement will fail:

     EXEC SQL BEGIN DECLARE SECTION END-EXEC. 
           01 ORACLEID   PIC X(5).
     ...
     EXEC SQL END DECLARE SECTION END-EXEC. 
     ... 
     MOVE '/    ' TO ORACLEID.
     EXEC SQL CONNECT :ORACLEID END-EXEC.

The AUTO_CONNECT Precompiler Option

Pro*COBOL lets your program log on to the default database without using the CONNECT statement. Simply specify the precompiler option AUTO_CONNECT on the command line.

Assume that the default value of OS_AUTHENT_PREFIX is OPS$, your username is TBARNES, and OPS$TBARNES is a valid Oracle userid. When AUTO_CONNECT=YES, as soon as Pro*COBOL encounters an executable SQL statement, your program logs on to Oracle automatically with the userid OPS$TBARNES.

When AUTO_CONNECT=NO (the default), you must use the CONNECT statement to log on to Oracle.

Changing Passwords at Runtime

Pro*COBOL provides client applications with a convenient way to change a user password at runtime through the optional ALTER AUTHORIZATION clause.

The syntax for the ALTER AUTHORIZATION clause is shown here:

     EXEC SQL CONNECT .. ALTER AUTHORIZATION :newpswd END-EXEC.

Using this clause indicates that you want to change the account password to the value indicated by newpswd. After the change is made, when an attempt is made to connect as user/newpswd. This can have the following results:

Connect Without Alter Authorization

This section describes the possible outcomes of different variations of the CONNECT statement.

Standard CONNECT

If an application issues the following statement

      EXEC SQL CONNECT ...   /* No ALTER AUTHORIZATION clause */

it performs a normal connection attempt. The possible results include the following:

SYSDBA or SYSOPER Privileges

Before Oracle release 8.1 you did not have to use this clause to have the SYSOPER or SYSDBA system privilege, but now you must.

Append the following optional string to the CONNECT statement after all other clauses if you want to log on with either SYSDBA or SYSOPER system privileges:

IN { SYSDBA | SYSOPER } MODE

For example:

EXEC SQL CONNECT ... IN SYSDBA MODE END-EXEC.

Here are the restrictions that apply to this option:

Advanced Connection Options

The communicating points in a network are called nodes. Net8 lets you transmit information (SQL statements, data, and status codes) over the network from one node to another.

A protocol is a set of rules for accessing a network. The rules establish such things as procedures for recovering after a failure and formats for transmitting data and checking errors.

The Net8 syntax for connecting to the default database in the local domain is simply to use the service name for the database.

If the service name is not in the default (local) domain, you must use a global specification (all domains specified). For example:

HR.US.ORACLE.COM

Connecting Using Net8

To connect using a Net8 driver, substitute a service name, as defined in your tnsnames.ora configuration file or in Oracle Names, in place of the SQL*Net V1 connect string.

If you are using Oracle Names, the name server obtains the service name from the network definition database.

Note: SQL*Net V1 does work with Oracle8i.

See Net8 Administrator's Guide for more information about Net8.


Concurrent Logons

Pro*COBOL supports distributed processing via Net8. Your application can concurrently access any combination of local and remote databases or make multiple connections to the same database. In Figure 3-1, an application program communicates with one local and three remote Oracle8i databases. ORA2, ORA3, and ORA4 are simply logical names used in CONNECT statements.

Figure 3-1 Connecting via Net8

By eliminating the boundaries in a network between different machines and operating systems, Net8 provides a distributed processing environment for Oracle tools. This section shows you how the Pro*COBOL supports distributed processing via Net8. You learn how your application can

Using Links

Implicit logons are supported through the Oracle8i distributed database option, which does not require explicit logons. For example, a distributed query allows a single SELECT statement to access data on one or more non-default databases.

The distributed query facility depends on database links, which assign a name to a CONNECT statement rather than to the connection itself. At run time, the embedded SELECT statement is executed by the specified database server, which connects implicitly to the non-default database(s) to get the required data.

Single Implicit Logons

In the next example, you connect to a single non-default database. First, your program executes the following statement to define a database link (database links are usually established interactively by the DBA or user):

     EXEC SQL CREATE DATABASE LINK db_link 
        CONNECT TO username IDENTIFIED BY password USING 'nyremote'
     END-EXEC. 

Then, the program can query the non-default EMP table using the database link, as follows:

     EXEC SQL SELECT ENAME, JOB INTO :EMP-NAME, :JOB-TITLE 
         FROM emp@db_link 
         WHERE DEPTNO = :DEPT-NUMBER
     END-EXEC. 

The database link is not related to the database name used in the AT clause of an embedded SQL statement. It simply tells Oracle where the non-default database is located, the path to it, and what Oracle username and password to use. The database link is stored in the data dictionary until it is explicitly dropped.

In our example, the default Oracle8i Server logs on to the non-default database via Net8 using the database link db_link. The query is submitted to the default server, but is "forwarded" to the non-default database for execution.

To make referencing the database link easier, you can create a synonym as follows (again, this is usually done interactively):

     EXEC SQL CREATE SYNONYM emp FOR emp@db_link END-EXEC. 

Then, your program can query the non-default EMP table, as follows:

     EXEC SQL SELECT ENAME, JOB INTO :EMP-NAME, :JOB-TITLE 
         FROM emp 
         WHERE DEPTNO = :DEPT-NUMBER
     END-EXEC. 

This provides location transparency for emp.

Multiple Implicit Logons

In the following example, you connect to two non-default databases concurrently. First, you execute the following sequence of statements to define two database links and create two synonyms:

     EXEC SQL CREATE DATABASE LINK db_link1 
         CONNECT TO username1 IDENTIFIED BY password1 
         USING 'nyremote'
     END-EXEC. 
     EXEC SQL CREATE DATABASE LINK db_link2 
         CONNECT TO username2 IDENTIFIED BY password2 
         USING 'chiremote'
     END-EXEC. 
     EXEC SQL CREATE SYNONYM emp FOR emp@db_link1 END-EXEC. 
     EXEC SQL CREATE SYNONYM dept FOR dept@db_link2 END-EXEC. 

Then, your program can query the non-default EMP and DEPT tables, as follows:

     EXEC SQL SELECT ENAME, JOB, SAL, LOC 
         FROM emp, dept 
         WHERE emp.DEPTNO = dept.DEPTNO AND DEPTNO = :dept_number
     END-EXEC. 

Oracle8i executes the query by performing a join between the non-default EMP table at db_link1 and the non-default DEPT table at db_link2.

Embedding OCI (Oracle Call Interface) Calls

Pro*COBOL allows you embed OCI calls in your program. Just take the following steps:

  1. Declare the OCI Logon Data Area (LDA) outside the Declare Section, if it exists. For details, see the Oracle Call Interface Programmer's Guide.

  2. Connect to Oracle using the embedded SQL statement CONNECT, not the OCI call OLOG.

  3. Call the Oracle8i run-time library routine SQLLDA to store the connect information in the LDA.

That way, Pro*COBOL and the OCI "know" that they are working together. However, there is no sharing of Oracle8i cursors.

You need not worry about declaring the OCI Host Data Area (HDA) because the Oracle8i run-time library manages connections and maintains the HDA for you.

Setting Up the LDA

You set up the LDA by issuing the OCI call

     CALL "SQLLDA" USING LDA.

where LDA identifies the LDA data structure. See the Oracle Call Interface Programmer's Guide. If the CONNECT statement fails, the LDA-RC field in the lda is set to 1012 to indicate the error.

Remote and Multiple Connections

A call to SQLLDA sets up an LDA for the connection used by the most recently executed SQL statement. To set up the different LDAs needed for additional connections, just call SQLLDA with a different lda after each CONNECT. In the following example, you connect to two non-default databases concurrently:

     EXEC SQL BEGIN DECLARE SECTION END-EXEC.
 01  USERNAME   PIC X(10) .
 01  PASSWORD   PIC X(10) .
 01  DB-STRING1 PIC X(20) .
 01  DB-STRING2 PIC X(20) . 
     EXEC SQL END DECLARE SECTION END-EXEC. 
     ... 
* -- Field sizes in LDA are system-dependent.
 01  LDA1.
     02 LDA1-V2RC  PIC S9(4) COMP.
     02 FILLER     PIC X(10).
     02 LDA1-RC    PIC S9(4) COMP.
     02 FILLER     PIC X(50).
 01  LDA2.
     02 LDA2-V2RC  PIC S9(4) COMP.
     02 FILLER     PIC X(10).
     02 LDA2-RC    PIC S9(4) COMP.
     02 FILLER     PIC X(50).
     ... 
     MOVE 'SCOTT' TO USERNAME.
     MOVE 'TIGER' TO PASSWORD.
     MOVE 'nyremote' TO DB-STRING1.
     MOVE 'chiremote' TO DB-STRING2.
     ...
* --  give each database connection a unique name 
     EXEC SQL DECLARE db_name1 DATABASE END-EXEC. 
     EXEC SQL DECLARE db_name2 DATABASE END-EXEC. 
     ...
* -- connect to first non-default database 
     EXEC SQL CONNECT :USERNAME IDENTIFIED BY :PASSWORD 
         AT db_name1 USING :DB-STRING1
     END-EXEC. 
* --  set up first LDA for OCI use 
     CALL 'SQLLDA' USING LDA1. 
* -- connect to second non-default database 
     EXEC SQL CONNECT :USERNAME IDENTIFIED BY :PASSWORD 
         AT db_name2 USING :DB-STRING2
     END-EXEC. 
* --  set up second LDA for OCI use 
     CALL 'SQLLDA' USING LDA2. 

Remember, do not declare db_name1 and db_name2 because they are not host variables. You use them only to name the default databases at the two non-default nodes so that later SQL statements can refer to the databases by name.

Some Terms You Should Know

Before delving into the subject of transactions, you should know the terms defined in this section.

The jobs or tasks that the database manages are called sessions. A user session is started when you run an application program or a tool such as Oracle Forms and connect to the database. Oracle8i allows user sessions to work "simultaneously" and share computer resources. To do this, Oracle8i must control concurrence, the accessing of the same data by many users. Without adequate concurrence controls, there might be a loss of data integrity. That is, changes to data or structures might be made in the wrong order.

Oracle8i uses locks to control concurrent access to data. A lock gives you temporary ownership of a database resource such as a table or row of data. Thus, data cannot be changed by other users until you finish with it. You need never explicitly lock a resource, because default locking mechanisms protect table data and structures. However, you can request data locks on tables or rows when it is to your advantage to override default locking. You can choose from several modes of locking such as row share and exclusive.

A deadlock can occur when two or more users try to access the same database object. For example, two users updating the same table might wait if each tries to update a row currently locked by the other. Because each user is waiting for resources held by another user, neither can continue until the server breaks the deadlock. The server signals an error to the participating transaction that had completed the least amount of work, and the "deadlock detected while waiting for resource" error code is returned to SQLCODE in the SQLCA.

When a table is being queried by one user and updated by another at the same time, the database generates a read-consistent view of the table's data for the query. That is, once a query begins and as it proceeds, the data read by the query does not change. As update activity continues, the database takes snapshots of the table's data and records changes in a rollback segment. The database uses information in the rollback segment to build read-consistent query results and to undo changes if necessary.

How Transactions Guard Your Database

The database is transaction oriented; it uses transactions to ensure data integrity. A transaction is a series of one or more logically related SQL statements you define to accomplish some task. The database treats the series of SQL statements as a unit so that all the changes brought about by the statements are either committed (made permanent) or rolled back (undone) at the same time. If your application program fails in the middle of a transaction, the database is automatically restored to its former (pre-transaction) state.

The coming sections show you how to define and control transactions. Specifically, you learn how to:

For details about the SQL statements discussed in this chapter, see the Oracle8i SQL Reference.

How to Begin and End Transactions

You begin a transaction with the first executable SQL statement (other than CONNECT) in your program. When one transaction ends, the next executable SQL statement automatically begins another transaction. Thus, every executable statement is part of a transaction. Because they cannot be rolled back and need not be committed, declarative SQL statements are not considered part of a transaction.

You end a transaction in one of the following ways:

A transaction also ends when there is a system failure or your user session stops unexpectedly because of software problems, hardware problems, or a forced interrupt. Oracle8i rolls back the transaction.

If your program fails in the middle of a transaction, Oracle8i detects the error and rolls back the transaction. If your operating system fails, Oracle8i restores the database to its former (pre-transaction) state.

Using the COMMIT Statement

You use the COMMIT statement to make changes to the database permanent. Until changes are committed, other users cannot access the changed data; they see it as it was before your transaction began. The COMMIT statement has no effect on the values of host variables or on the flow of control in your program. Specifically, the COMMIT statement

When MODE={ANSI13 | ORACLE}, explicit cursors not referenced in a CURRENT OF clause remain open across commits. This can boost performance. For an example, see "Fetching Across Commits".

Because they are part of normal processing, COMMIT statements should be placed inline, on the main path through your program. Before your program terminates, it must explicitly commit pending changes. Otherwise, Oracle8i rolls them back. In the following example, you commit your transaction and disconnect:

    EXEC SQL COMMIT WORK RELEASE END-EXEC.

The optional keyword WORK provides ANSI compatibility. The RELEASE option frees all resources (locks and cursors) held by your program and logs off the database.

You need not follow a data definition statement with a COMMIT statement because data definition statements issue an automatic commit before and after executing. So, whether they succeed or fail, the prior transaction is committed.

WITH HOLD Clause in DECLARE CURSOR Statements

Any cursor that has been declared with the clause WITH HOLD after the word CURSOR, remains open after a COMMIT or a ROLLBACK. The following example shows how to use this clause:

     EXEC SQL 
         DECLARE C1 CURSOR WITH HOLD
         FOR SELECT ENAME FROM EMP
         WHERE EMPNO BETWEEN 7600 AND 7700
     END-EXEC.

The cursor must not be declared for UPDATE. The WITH HOLD clause is used in DB2 to override the default, which is to close all cursors on commit. Pro*COBOL provides this clause in order to ease migrations of applications from DB2 to Oracle. When MODE=ANSI, Oracle uses the DB2 default, but all host variables must be declared in a Declare Section. To avoid having a Declare Section, use the precompiler option CLOSE_ON_COMMIT described next. See "DECLARE CURSOR (Embedded SQL Directive)".

CLOSE_ON_COMMIT Precompiler Option

The precompiler option CLOSE_ON_COMMIT is available for DB2 compatibility:

CLOSE_ON_COMMIT = {YES | NO} 

The default is NO. This option must be entered only on the command line or in a configuration file. If you specify MODE=ANSI on the command line, any cursors not declared with the WITH HOLD clause are closed on commit.

Note: Use this option carefully; applications may be slowed if cursors are opened and closed many times because of the need to re-parse for each OPEN statement. See "CLOSE_ON_COMMIT".

Using the ROLLBACK Statement

You use the ROLLBACK statement to undo pending changes made to the database. For example, if you make a mistake, such as deleting the wrong row from a table, you can use ROLLBACK to restore the original data. The ROLLBACK statement has no effect on the values of host variables or on the flow of control in your program. Specifically, the ROLLBACK statement

When MODE={ANSI13 | ORACLE}, explicit cursors not referenced in a CURRENT OF clause remain open across rollbacks.

Because they are part of exception processing, ROLLBACK statements should be placed in error handling routines, off the main path through your program. In the following example, you roll back your transaction and disconnect:

    EXEC SQL ROLLBACK WORK RELEASE END-EXEC.

The optional keyword WORK provides ANSI compatibility. The RELEASE option frees all resources held by your program and logs off the database.

If a WHENEVER SQLERROR GOTO statement branches to an error handling routine that includes a ROLLBACK statement, your program might enter an infinite loop if the rollback fails with an error. You can avoid this by coding WHENEVER SQLERROR CONTINUE before the ROLLBACK statement.

For example, consider the following:

     EXEC SQL
         WHENEVER SQLERROR GOTO SQL-ERROR
     END-EXEC.
     ...
     DISPLAY 'Employee number? '.
     ACCEPT EMP-NUMBER.
     DISPLAY 'Employee name? '.
     ACCEPT EMP-NAME.
     EXEC SQL INSERT INTO EMP (EMPNO, ENAME)
        VALUES (:EMP-NUMBER, :EMP-NAME)
     END-EXEC.
     ...
 SQL-ERROR.
     EXEC SQL WHENEVER SQLERROR CONTINUE END-EXEC.
     EXEC SQL ROLLBACK WORK RELEASE END-EXEC.
     DISPLAY 'Processing error'.
* -- exit program with an error.
     STOP RUN.

Oracle8i rolls back transactions if your program terminates abnormally.

Statement-Level Rollbacks

Before executing any SQL statement, Oracle8i marks an implicit savepoint (not available to you). Then, if the statement fails, Oracle8i rolls it back automatically and returns the applicable error code to SQLCODE in the SQLCA. For example, if an INSERT statement causes an error by trying to insert a duplicate value in a unique index, the statement is rolled back.

Only work started by the failed SQL statement is lost; work done before that statement in the current transaction is kept. Thus, if a data definition statement fails, the automatic commit that precedes it is not undone.

Note: Before executing a SQL statement, Oracle8i must parse it, that is, examine it to make sure it follows syntax rules and refers to valid database objects. Errors detected while executing a SQL statement cause a rollback, but errors detected while parsing the statement do not.

Oracle8i can also roll back single SQL statements to break deadlocks. Oracle8i signals an error to one of the participating transactions and rolls back the current statement in that transaction.

Using the SAVEPOINT Statement

You use the SAVEPOINT embedded SQL statement to mark and name the current point in the processing of a transaction. Each marked point is called a savepoint. For example, the following statement marks a savepoint named start_delete:

    EXEC SQL SAVEPOINT start_delete END-EXEC.

Savepoints let you divide long transactions, giving you more control over complex procedures. For example, if a transaction performs several functions, you can mark a savepoint before each function. Then, if a function fails, you can easily restore the data to its former state, recover, then re-execute the function.

To undo part of a transaction, you use savepoints with the ROLLBACK statement and its TO SAVEPOINT clause. The TO SAVEPOINT clause lets you roll back to an intermediate statement in the current transaction, so you do not have to undo all your changes. Specifically, the ROLLBACK TO SAVEPOINT statement

In the example below, you access the table MAIL_LIST to insert new listings, update old listings, and delete (a few) inactive listings. After the delete, you check SQLERRD(3) in the SQLCA for the number of rows deleted. If the number is unexpectedly large, you roll back to the savepoint start_delete, undoing just the delete.

* -- For each new customer
     DISPLAY 'New customer number? '.
     ACCEPT CUST-NUMBER.
     IF CUST-NUMBER = 0
          GO TO REV-STATUS
     END-IF.
     DISPLAY 'New customer name? '.
          ACCEPT  CUST-NAME.
     EXEC SQL INSERT INTO MAIL-LIST (CUSTNO, CNAME, STAT)
         VALUES (:CUST-NUMBER, :CUST-NAME, 'ACTIVE').
     END-EXEC.
     ...
* -- For each revised status
 REV-STATUS.
     DISPLAY 'Customer number to revise status? '.
     ACCEPT CUST-NUMBER.
     IF CUST-NUMBER = 0
         GO TO SAVE-POINT
     END-IF.
     DISPLAY 'New status? '.
     ACCEPT NEW-STATUS.
     EXEC SQL UPDATE MAIL-LIST
        SET STAT = :NEW-STATUS WHERE CUSTNO = :CUST-NUMBER
     END-EXEC.
     ...
* -- mark savepoint
 SAVE-POINT.
     EXEC SQL SAVEPOINT START-DELETE END-EXEC.
     EXEC SQL DELETE FROM MAIL-LIST WHERE STAT = 'INACTIVE'
     END-EXEC.
     IF SQLERRD(3) < 25 
* -- check number of rows deleted
         DISPLAY 'Number of rows deleted is ', SQLERRD(3)
     ELSE
         DISPLAY 'Undoing deletion of ', SQLERRD(3), ' rows'
         EXEC SQL
             WHENEVER SQLERROR GOTO SQL-ERROR
         END-EXEC
         EXEC SQL
             ROLLBACK TO SAVEPOINT START-DELETE
         END-EXEC
     END-IF.
     EXEC SQL WHENEVER SQLERROR CONTINUE END-EXEC.
     EXEC SQL COMMIT WORK RELEASE END-EXEC.
     STOP RUN.
* -- exit program.
     ...
 SQL-ERROR.
     EXEC SQL WHENEVER SQLERROR CONTINUE END-EXEC.
     EXEC SQL ROLLBACK WORK RELEASE END-EXEC.
     DISPLAY 'Processing error'.
* -- exit program with an error.
     STOP RUN.

Note that you cannot specify the RELEASE option in a ROLLBACK TO SAVEPOINT statement.

Rolling back to a savepoint erases any savepoints marked after that savepoint. The savepoint to which you roll back, however, is not erased. For example, if you mark five savepoints, then roll back to the third, only the fourth and fifth are erased. A COMMIT or ROLLBACK statement erases all savepoints.

Using the RELEASE Option

Oracle8i rolls back changes automatically if your program terminates abnormally. Abnormal termination occurs when your program does not explicitly commit or roll back work and disconnect using the RELEASE embedded SQL statement.

Normal termination occurs when your program runs its course, closes open cursors, explicitly commits or rolls back work, disconnects, and returns control to the user. Your program will exit gracefully if the last SQL statement it executes is either

     EXEC SQL COMMIT RELEASE END-EXEC. 

or

     EXEC SQL ROLLBACK RELEASE END-EXEC.
 

Otherwise, locks and cursors acquired by your user session are held after program termination until Oracle8i recognizes that the user session is no longer active. This might cause other users in a multi-user environment to wait longer than necessary for the locked resources.

Using the SET TRANSACTION Statement

You use the SET TRANSACTION statement to begin a read-only or read-write transaction, or to assign your current transaction to a specified rollback segment. A COMMIT, ROLLBACK, or data definition statement ends a read-only transaction.

Because they allow "repeatable reads," read-only transactions are useful for running multiple queries against one or more tables while other users update the same tables. During a read-only transaction, all queries refer to the same snapshot of the database, providing a multi-table, multi-query, read-consistent view. Other users can continue to query or update data as usual. An example of the SET TRANSACTION statement follows:

     EXEC SQL SET TRANSACTION READ ONLY END-EXEC.
 

The SET TRANSACTION statement must be the first SQL statement in a read-only transaction and can appear only once in a transaction. The READ ONLY parameter is required. Its use does not affect other transactions. Only the SELECT (without FOR UPDATE), LOCK TABLE, SET ROLE, ALTER SESSION, ALTER SYSTEM, COMMIT, and ROLLBACK statements are allowed in a read-only transaction.

In the example below, as a store manager, you check sales activity for the day, the past week, and the past month by using a read-only transaction to generate a summary report. The report is unaffected by other users updating the database during the transaction.

     EXEC SQL SET TRANSACTION READ ONLY END-EXEC. 
     EXEC SQL SELECT SUM(SALEAMT) INTO :DAILY FROM SALES 
         WHERE SALEDATE = SYSDATE END-EXEC.
     EXEC SQL SELECT SUM(SALEAMT) INTO :WEEKLY FROM SALES
         WHERE SALEDATE > SYSDATE - 7 END-EXEC.
     EXEC SQL SELECT SUM(SALEAMT) INTO :MONTHLY FROM SALES 
         WHERE SALEDATE > SYSDATE - 30 END-EXEC. 
     EXEC SQL COMMIT WORK END-EXEC. 
* --  simply ends the transaction since there are no changes 
* --  to make permanent 
* --  format and print report 

Overriding Default Locking

By default, Oracle8i implicitly (automatically) locks many data structures for you. However, you can request specific data locks on rows or tables when it is to your advantage to override default locking. Explicit locking lets you share or deny access to a table for the duration of a transaction or ensure multi-table and multi-query read consistency.

With the SELECT FOR UPDATE OF statement, you can explicitly lock specific rows of a table to make sure they do not change before an update or delete is executed. However, Oracle8i automatically obtains row-level locks at update or delete time. So, use the FOR UPDATE OF clause only if you want to lock the rows before the update or delete.

You can explicitly lock entire tables using the LOCK TABLE statement.

Using the FOR UPDATE OF Clause

When you DECLARE a cursor that is referenced in the CURRENT OF clause of an UPDATE or DELETE statement, you use the FOR UPDATE OF clause to acquire exclusive row locks. SELECT FOR UPDATE OF identifies the rows that will be updated or deleted, then locks each row in the active set. (All rows are locked at the open, not as they are fetched.) This is useful, for example, when you want to base an update on the existing values in a row. You must make sure the row is not changed by another user before your update.

The FOR UPDATE OF clause is optional. For instance, instead of

     EXEC SQL DECLARE EMP-CURSOR CURSOR FOR 
         SELECT ENAME, JOB, SAL FROM EMP WHERE DEPTNO = 20 
         FOR UPDATE OF SAL
     END-EXEC.
 

you can drop the FOR UPDATE OF clause and simply code

    EXEC SQL DECLARE EMP-CURSOR CURSOR FOR 
        SELECT ENAME, JOB, SAL FROM EMP WHERE DEPTNO = 20
    END-EXEC.

The CURRENT OF clause signals the precompiler to add a FOR UPDATE clause if necessary. You use the CURRENT OF clause to refer to the latest row fetched from a cursor. For an example, see "Using the CURRENT OF Clause".

Restrictions

If you use the FOR UPDATE OF clause, you cannot reference multiple tables. Also, an explicit FOR UPDATE OF or an implicit FOR UPDATE acquires exclusive row locks. Row locks are released when you commit or rollback (except when you rollback to a savepoint). If you try to fetch from a FOR UPDATE cursor after a commit, Oracle8i generates an error:

Using the LOCK TABLE Statement

You use the LOCK TABLE statement to lock one or more tables in a specified lock mode. For example, the statement below locks the EMP table in row share mode. Row share locks allow concurrent access to a table; they prevent other users from locking the entire table for exclusive use.

     EXEC SQL
         LOCK TABLE EMP IN ROW SHARE MODE NOWAIT
     END-EXEC.

The lock mode determines what other locks can be placed on the table. For example, many users can acquire row share locks on a table at the same time, but only one user at a time can acquire an exclusive lock. While one user has an exclusive lock on a table, no other users can insert, update, or delete rows in that table. For more information about lock modes, see the Oracle8i Application Developer's Guide - Fundamentals.

The optional keyword NOWAIT tells Oracle8i not to wait for a table if it has been locked by another user. Control is immediately returned to your program, so it can do other work before trying again to acquire the lock. (You can check SQLCODE in the SQLCA to see if the table lock failed.) If you omit NOWAIT, Oracle8i waits until the table is available; the wait has no set limit.

A table lock never keeps other users from querying a table, and a query never acquires a table lock. So, a query never blocks another query or an update, and an update never blocks a query. Only if two different transactions try to update the same row will one transaction wait for the other to complete. Table locks are released when your transaction issues a commit or rollback.

Fetching Across Commits

If you want to mix commits and fetches, do not use the CURRENT OF clause. Instead, select the rowid of each row, then use that value to identify the current row during the update or delete. Consider the following example:

     EXEC SQL DECLARE EMP-CURSOR CURSOR FOR
         SELECT ENAME, SAL, ROWID FROM EMP WHERE JOB = 'CLERK'
     END-EXEC.
     ...
     EXEC SQL OPEN EMP-CURSOR END-EXEC.
     EXEC SQL WHENEVER NOT FOUND GOTO ...
     PERFORM
     EXEC SQL
         FETCH EMP-CURSOR INTO :EMP_NAME, :SALARY, :ROW-ID
     END-EXEC
     ... 
         EXEC SQL UPDATE EMP SET SAL = :NEW-SALARY
             WHERE ROWID = :ROW-ID
         END-EXEC
         EXEC SQL COMMIT END-EXEC
     END-PERFORM.

Note, however, that the fetched rows are not locked. So, you can receive inconsistent results if another user modifies a row after you read it but before you update or delete it.

Handling Distributed Transactions

A distributed database is a single logical database comprising multiple physical databases at different nodes. A distributed statement is any SQL statement that accesses a remote node using a database link. A distributed transaction includes at least one distributed statement that updates data at multiple nodes of a distributed database. If the update affects only one node, the transaction is non-distributed.

When you issue a commit, changes to each database affected by the distributed transaction are made permanent. If instead you issue a rollback, all the changes are undone. However, if a network or machine fails during the commit or rollback, the state of the distributed transaction might be unknown or in doubt. In such cases, if you have FORCE TRANSACTION system privileges, you can manually commit or roll back the transaction at your local database by using the FORCE clause. The transaction must be identified by a quoted literal containing the transaction ID, which can be found in the data dictionary view DBA_2PC_PENDING. Some examples follow:

     EXEC SQL COMMIT FORCE '22.31.83' END-EXEC.
     ...
     EXEC SQL ROLLBACK FORCE '25.33.86'END-EXEC.

FORCE commits or rolls back only the specified transaction and does not affect your current transaction. Note that you cannot manually roll back in-doubt transactions to a savepoint.

The COMMENT clause in the COMMIT statement lets you specify a Comment to be associated with a distributed transaction. If ever the transaction is in doubt, The server stores the text specified by COMMENT in the data dictionary view DBA_2PC_PENDING along with the transaction ID. The text must be a quoted literal of no more than 50 characters in length. An example follows:

     EXEC SQL
         COMMIT COMMENT 'In-doubt trans; notify Order Entry'
     END-EXEC.

For more information about distributed transactions, see Oracle8i Concepts.

Guidelines for Transaction Processing

The following guidelines will help you avoid some common problems.

Designing Applications

When designing your application, group logically related actions together in one transaction. A well-designed transaction includes all the steps necessary to accomplish a given task -- no more and no less.

Data in the tables you reference must be left in a consistent state. So, the SQL statements in a transaction should change the data in a consistent way. For example, a transfer of funds between two bank accounts should include a debit to one account and a credit to another. Both updates should either succeed or fail together. An unrelated update, such as a new deposit to one account, should not be included in the transaction.

Obtaining Locks

If your application programs include SQL locking statements, make sure the users requesting locks have the privileges needed to obtain the locks. Your DBA can lock any table. Other users can lock tables they own or tables for which they have a privilege, such as ALTER, SELECT, INSERT, UPDATE, or DELETE.

Using PL/SQL

If a PL/SQL block is part of a transaction, commits and rollbacks inside the block affect the whole transaction. In the following example, the rollback undoes changes made by the update and the insert:

     EXEC SQL INSERT INTO EMP ...
     EXEC SQL EXECUTE
     BEGIN        UPDATE emp 
     ...
         ...
     EXCEPTION
         WHEN DUP_VAL_ON_INDEX THEN
             ROLLBACK;
     END;
     END-EXEC.
     ...

Developing X/Open Applications

X/Open applications run in a distributed transaction processing (DTP) environment. In an abstract model, an X/Open application calls on resource managers (RMs) to provide a variety of services. For example, a database resource manager provides access to data in a database. Resource managers interact with a transaction manager (TM), which controls all transactions for the application.

Figure 3-2 shows one way that components of the DTP model can interact to provide efficient access to data in an Oracle8i database. The DTP model specifies the XA interface between resource managers and the transaction manager. Oracle supplies an XA-compliant library, which you must link to your X/Open application. Also, you must specify the native interface between your application program and the resource managers.

Figure 3-2 Hypothetical DTP Model


The DTP model that specifies how a transaction manager and resource managers interact with an application program is described in the X/Open guide Distributed Transaction Processing Reference Model and related publications, which you can obtain by writing to

X/Open Company Ltd.

1010 El Camino Real, Suite 380

Menlo Park, CA 94025

For instructions on using the XA interface, see your Transaction Processing (TP) Monitor user's guide.

Oracle-Specific Issues

You can use Pro*COBOL to develop applications that comply with the X/Open standards. However, you must meet the following requirements.

Connecting to Oracle

The X/Open application does not establish and maintain connections to a database. Instead, the transaction manager and the XA interface, which is supplied by Oracle, handle database connections and disconnections transparently. So, normally an X/Open-compliant application does not execute CONNECT statements.

Transaction Control

The X/Open application must not execute statements such as COMMIT, ROLLBACK, SAVEPOINT, and SET TRANSACTION that affect the state of global transactions. For example, the application must not execute the COMMIT statement because the transaction manager handles commits. Also, the application must not execute SQL data definition statements such as CREATE, ALTER, and RENAME because they issue an implicit commit.

The application can execute an internal ROLLBACK statement if it detects an error that prevents further SQL operations. However, this might change in later versions of the XA interface.

OCI Calls

If you want your X/Open application to issue OCI calls, you must use the run-time library routine SQLLD2, which sets up an LDA for a specified connection established through the XA interface. For a description of the SQLLD2 call, see the Oracle Call Interface Programmer's Guide. Note that OCOM, OCON, OCOF, ORLON, OLON, OLOG, and OLOGOF cannot be issued by an X/Open application.

Linking

To get XA functionality, you must link the XA library to your X/Open application object modules. For instructions, see your system-specific Oracle8i manuals.





Prev

Next
Oracle
Copyright © 1999 Oracle Corporation.

All Rights Reserved.

Library

Product

Contents

Index