home | O'Reilly's CD bookshelfs | FreeBSD | Linux | Cisco | Cisco Exam  


1.9 Cursors in PL/SQL

Every SQL statement executed by the RDBMS has a private SQL area that contains information about the SQL statement and the set of data returned. In PL/SQL, a cursor is a name assigned to a specific private SQL area for a specific SQL statement. There can be either static cursors, whose SQL statement is determined at compile time, or dynamic cursors, whose SQL statement is determined at runtime. Static cursors are covered in greater detail in this section. Dynamic cursors in PL/SQL are implemented via the built-in package DBMS_SQL. See the book Oracle Built-in Packages and the corresponding Oracle PL/SQL Built-ins Pocket Reference , both from O'Reilly & Associates, for full coverage on DBMS_SQL and the other built-in packages.

1.9.1 Explicit Cursors

Explicit cursors are SELECT statements that are DECLAREd explicitly in the declaration section of the current block or in a package specification. Use OPEN, FETCH, and CLOSE in the execution or exception sections of your programs.

1.9.1.1 Declaring explicit cursors

To use an explicit cursor, you must first declare it in the declaration section of a block or package. There are three types of explicit cursor declarations:

  • A cursor without parameters, such as:

      CURSOR company_cur 
         IS
         SELECT company_id FROM company;
  • A cursor that accepts arguments through a parameter list:

      CURSOR company_cur (id_in IN NUMBER) IS
      SELECT name FROM company
      WHERE  company_id = id_in;
  • A cursor header that contains a RETURN clause in place of the SELECT statement:

      CURSOR company_cur (id_in IN NUMBER) 
      RETURN company%ROWTYPE IS
      SELECT * FROM company;

This technique can be used in packages to hide the implementation of the cursor in the package body. See the Section 1.14 " section for more information.

1.9.1.2 Opening explicit cursors

To open a cursor, use the following syntax:

OPEN cursor_name [(argument [,argument ...])];

where cursor_name is the name of the cursor as declared in the declaration section. The arguments are required if the definition of the cursor contains a parameter list.

You must open an explicit cursor before you can fetch rows from that cursor. When the cursor is opened, the processing includes the PARSE, BIND, OPEN, and EXECUTE statements. This OPEN processing includes: determining an execution plan, associating host variables and cursor parameters with the placeholders in the SQL statement, determining the result set, and, finally, setting the current row pointer to the first row in the result set.

When using a cursor FOR loop, the OPEN is implicit in the FOR statement. If you try to open a cursor that is already open, PL/SQL will raise an "ORA-06511: PL/SQL: cursor already open" exception.

1.9.1.3 Fetching from explicit cursors

The FETCH statement places the contents of the current row into local variables. To retrieve all rows in a result set, each row needs to be fetched. The syntax for a FETCH statement is:

FETCH cursor_name INTO record_or_variable_list;

where cursor_name is the name of the cursor as declared and opened.

1.9.1.4 Closing explicit cursors

The syntax of the CLOSE statement is:

CLOSE cursor_name;

where cursor_name is the name of the cursor declared and opened.

After all rows have been fetched, a cursor needs to be closed. Closing a cursor releases the private SQL area used by the cursor, freeing the memory used by that cursor.

If you declare a cursor in a local anonymous, procedure, or function block, that cursor will automatically close when the block terminates. Package-based cursors must be closed explicitly, or they stay open for the duration of your session. Closing a cursor that is not open raises an INVALID CURSOR exception.

1.9.1.5 Explicit cursor attributes

There are four attributes associated with cursors: ISOPEN, FOUND, NOTFOUND, and ROWCOUNT. These attributes can be accessed with the % delimiter to obtain information about the state of the cursor. The syntax for a cursor attribute is:

cursor_name%attribute

where cursor_name is the name of the explicit cursor.

The behaviors of the explicit cursor attributes are described in the following table.

Attribute

Description

%ISOPEN

TRUE if cursor is open.

FALSE if cursor is not open.

%FOUND

INVALID_CURSOR is raised if cursor has not been OPENed.

NULL before the first fetch.

TRUE if record was fetched successfully.

FALSE if no row was returned.

INVALID_CURSOR if cursor has been CLOSEd.

%NOTFOUND

INVALID_CURSOR is raised if cursor has not been OPENed.

NULL before the first fetch.

FALSE if record was fetched successfully.

TRUE if no row was returned.

INVALID_CURSOR if cursor has been CLOSEd.

%ROWCOUNT

INVALID_CURSOR is raised if cursor has not been OPENed.

The number of rows fetched from the cursor.

INVALID_CURSOR if cursor has been CLOSEd.

Frequently a cursor attribute is checked as part of a WHILE loop that fetches rows from a cursor:

DECLARE
   caller_rec caller_pkg.caller_cur%ROWTYPE;
BEGIN
   OPEN caller_pkg.caller_cur;
   LOOP
      FETCH caller_pkg.caller_cur into caller_rec;
      EXIT WHEN caller_pkg.caller_cur%NOTFOUND
               OR 
               caller_pkg.caller_cur%ROWCOUNT > 10;

      UPDATE call
         SET caller_id = caller_rec.caller_id
         WHERE call_timestamp < SYSDATE;
   END LOOP;
   CLOSE caller_pkg.caller_cur;
END;

1.9.2 Implicit Cursors

Whenever a SQL statement is directly in the execution or exception section of a PL/SQL block, you are working with implicit cursors. These statements include INSERT, UPDATE, DELETE, and SELECT INTO statements. Unlike explicit cursors, implicit cursors do not need to be declared, OPENed, FETCHed, or CLOSEd.

SELECT statements handle the %FOUND and %NOTFOUND attributes differently from explicit cursors. When an implicit SELECT statement does not return any rows, PL/SQL immediately raises the NO_DATA_FOUND exception and control passes to the exception section. When an implicit SELECT returns more than one row, PL/SQL immediately raises the TOO_MANY_ROWS exception and control passes to the exception section.

Implicit cursor attributes are referenced via the SQL cursor. For example:

BEGIN
   UPDATE activity SET last_accessed := SYSDATE
   WHERE UID = user_id;

   IF SQL%NOTFOUND THEN
      INSERT INTO activity_log (uid,last_accessed)
      VALUES (user_id,SYSDATE);
   END IF
END;

SQL Attributes

Description

%ISOPEN

Always FALSE since the cursor is opened implicitly and closed immediately after the statement is executed.

%FOUND

NULL before the statement.

TRUE if one or more rows were inserted, updated, or deleted or if only one row was selected.

FALSE if no row was selected, updated, inserted, or deleted.

%NOTFOUND

NULL before the statement.

TRUE if no row was selected, updated, inserted, or deleted.

FALSE if one or more rows were inserted, updated, or deleted.

%ROWCOUNT

The number of rows affected by the cursor.

%BULK_ROWCOUNT (Oracle8 i)

A pseudo index-by table containing the numbers of rows affected by the statements executed in bulk bind operations. See the "Bulk Binds (Oracle8 i )" section for more information on %BULK_ROWCOUNT.

Use the RETURNING clause in INSERT, UPDATE, and DELETE statements to obtain data modified by the associated DML statement. This clause allows you to avoid an additional SELECT statement to query the results of the DML statement. For example:

BEGIN
   UPDATE activity SET last_accessed := SYSDATE
   WHERE UID = user_id
   RETURNING last_accessed, cost_center 
   INTO timestamp, chargeback_acct;

1.9.2.1 The SELECT FOR UPDATE clause

By default, the Oracle RDBMS locks rows as they are changed. To lock all rows in a result set, use the FOR UPDATE clause in your SELECT statement when you OPEN the cursor, instead of when you change the data. Using the FOR UPDATE clause does not require you to actually make changes to the data; it only locks the rows when opening the cursor. These locks are released on the next COMMIT or ROLLBACK. As always, these row locks do not affect other SELECT statements unless they, too, are FOR UPDATE. The FOR UPDATE clause is appended to the end of the SELECT statement and has the following syntax:

SELECT ...
  FROM ...
   FOR UPDATE [OF column_reference] [NOWAIT];

where column_reference is a comma-delimited list of columns that appear in the SELECT clause. The NOWAIT keyword tells the RDBMS to not wait for other blocking locks to be released. The default is to wait forever.

In the following example, only columns from the inventory (pet) table are referenced FOR UPDATE, so no rows in the dog_breeds (dog) table are locked when hounds_in_stock_cur is opened:

DECLARE
   CURSOR hounds_in_stock_cur IS
      SELECT pet.stock_no, pet.breeder, dog.size
        FROM dog_breeds dog ,inventory pet
       WHERE dog.breed = pet.breed
         AND dog.class = 'HOUND'
         FOR UPDATE OF pet.stock_no, pet.breeder;
BEGIN

1.9.2.2 The WHERE CURRENT OF clause

UPDATE and DELETE statements can use a WHERE CURRENT OF clause if they reference a cursor declared FOR UPDATE. This syntax indicates that the UPDATE or DELETE should modify the current row identified by the FOR UPDATE cursor. The syntax is:

[UPDATE | DELETE ] ...
   WHERE CURRENT OF cursor_name;

By using WHERE CURRENT OF, you do not have to repeat the WHERE clause in the SELECT statement. For example:

DECLARE
   CURSOR wip_cur IS
      SELECT acct_no, enter_date FROM wip
       WHERE enter_date < SYSDATE -7
         FOR UPDATE;
BEGIN
   FOR wip_rec IN wip_cur
   LOOP
      INSERT INTO acct_log (acct_no, order_date)
         VALUES (wip_rec.acct_no, wip_rec.enter_
            date);
      DELETE FROM wip 
         WHERE CURRENT OF wip_cur;
   END LOOP;
END; 

1.9.3 Cursor Variables

A cursor variable is a data structure that points to a cursor object, which in turn points to the cursor's result set. You can use cursor variables to more easily retrieve rows in a result set from client and server programs. You can also use cursor variables to hide minor variations in queries.

The syntax for a REF_CURSOR type is:

TYPE ref_cursor_name IS REF CURSOR 
   [RETURN record_type];

If you do not include a RETURN clause, then you are declaring a weak REF CURSOR. Cursor variables declared from weak REF CURSORs can be associated with any query at runtime. A REF CURSOR declaration with a RETURN clause defines a "strong" REF CURSOR. A cursor variable based on a strong REF CURSOR can be associated with queries whose result sets match the number and datatype of the record structure after the RETURN at runtime.

To use cursor variables, you must first create a REF_CURSOR type, then declare a cursor variable based on that type.

The following example shows the use of both weak and strong REF CURSORs:

DECLARE
   -- Create a cursor type based on the companies   
      table.
   TYPE company_curtype IS REF CURSOR 
      RETURN companies%ROWTYPE;

   -- Create the variable based on the REF CURSOR.
   company_cur company_curtype;

   -- And now the weak, general approach.
   TYPE any_curtype IS REF CURSOR;
   generic_curvar any_curtype;

The syntax to OPEN a cursor variable is:

OPEN cursor_name FOR select_statement;

FETCH and CLOSE a cursor variable using the same syntax as for explicit cursors. There are a number of restrictions on cursor variables:

  • Cursor variables cannot be declared in a package since they do not have a persistent state.

  • You cannot use the FOR UPDATE clause with cursor variables.

  • You cannot assign NULLs to a cursor variable nor use comparison operators to test for equality, inequality, or nullity.

  • Neither database columns nor collections can store cursor variables.

  • You cannot use RPCs to pass cursor variables from one server to another.

  • Cursor variables cannot be used with the dynamic SQL built-in package DBMS_SQL.


Previous: 1.8 Database Interaction and Cursors Oracle PL/SQL Language Pocket Reference Next: 1.10 Exception Handling
1.8 Database Interaction and Cursors   1.10 Exception Handling

The Oracle Library Navigation

Copyright (c) 2000 O'Reilly & Associates. All rights reserved.

Library Home Oracle PL/SQL Programming, 2nd. Ed. Guide to Oracle 8i Features Oracle Built-in Packages Advanced PL/SQL Programming with Packages Oracle Web Applications Oracle PL/SQL Language Pocket Reference Oracle PL/SQL Built-ins Pocket Reference