PL/SQL User's Guide and Reference 10g Release 1 (10.1) Part Number B10807-01 |
|
|
View PDF |
Oracle implicitly opens a cursor to process each SQL statement not associated with an explicit cursor. In PL/SQL, you can refer to the most recent implicit cursor as the SQL
cursor, which always has the attributes %FOUND
, %ISOPEN
, %NOTFOUND
, and %ROWCOUNT
. They provide information about the execution of data manipulation statements. The SQL
cursor has additional attributes, %BULK_ROWCOUNT
and %BULK_EXCEPTIONS
, designed for use with the FORALL
statement. For more information, see "Querying Data with PL/SQL".
Syntax
Keyword and Parameter Description
A composite attribute designed for use with the FORALL
statement. This attribute acts like an index-by table. Its ith element stores the number of rows processed by the ith execution of an UPDATE
or DELETE
statement. If the ith execution affects no rows, %BULK_ROWCOUNT(i)
returns zero.
An associative array that stores information about any exceptions encountered by a FORALL
statement that uses the SAVE EXCEPTIONS
clause. You must loop through its elements to determine where the exceptions occurred and what they were. For each index value i
between 1 and SQL%BULK_EXCEPTIONS.COUNT
, SQL%BULK_EXCEPTIONS(i).ERROR_INDEX
specifies which iteration of the FORALL
loop caused an exception. SQL%BULK_EXCEPTIONS(i).ERROR_CODE
specifies the Oracle error code that corresponds to the exception.
Returns TRUE
if an INSERT
, UPDATE
, or DELETE
statement affected one or more rows or a SELECT
INTO
statement returned one or more rows. Otherwise, it returns FALSE
.
Always returns FALSE
, because Oracle closes the SQL
cursor automatically after executing its associated SQL statement.
The logical opposite of %FOUND
. It returns TRUE
if an INSERT
, UPDATE
, or DELETE
statement affected no rows, or a SELECT
INTO
statement returned no rows. Otherwise, it returns FALSE
.
Returns the number of rows affected by an INSERT
, UPDATE
, or DELETE
statement, or returned by a SELECT
INTO
statement.
The name of the Oracle implicit cursor.
Usage Notes
You can use cursor attributes in procedural statements but not in SQL statements. Before Oracle opens the SQL
cursor automatically, the implicit cursor attributes return NULL
.
The values of cursor attributes always refer to the most recently executed SQL statement, wherever that statement appears. It might be in a different scope. If you want to save an attribute value for later use, assign it to a Boolean variable immediately.
If a SELECT
INTO
statement fails to return a row, PL/SQL raises the predefined exception NO_DATA_FOUND
, whether you check SQL%NOTFOUND
on the next line or not. A SELECT
INTO
statement that calls a SQL aggregate function never raises NO_DATA_FOUND
, because those functions always return a value or a null. In such cases, SQL%NOTFOUND
returns FALSE
.
%BULK_ROWCOUNT
is not maintained for bulk inserts; that would be redundant. For example, the following FORALL
statement inserts one row per iteration. After each iteration, %BULK_ROWCOUNT
returns 1:
CREATE TABLE num_table (n NUMBER); DECLARE TYPE NumList IS TABLE OF NUMBER; nums NumList := NumList(1,3,5,7,11,13,17); BEGIN FORALL i IN nums.FIRST .. nums.LAST INSERT INTO num_table (n) VALUES (nums(i)); FOR i IN nums.FIRST .. nums.LAST LOOP dbms_output.put_line('Inserted ' || SQL%BULK_ROWCOUNT(i) || ' row(s)' || ' on iteration ' || i); END LOOP; END; / DROP TABLE num_table;
You can use the scalar attributes %FOUND
, %NOTFOUND
, and %ROWCOUNT
with bulk binds. For example, %ROWCOUNT
returns the total number of rows processed by all executions of the SQL statement.
Although %FOUND
and %NOTFOUND
refer only to the last execution of the SQL statement, you can use %BULK_ROWCOUNT
to infer their values for individual executions. For example, when %BULK_ROWCOUNT(i)
is zero, %FOUND
and %NOTFOUND
are FALSE
and TRUE
, respectively.
Examples
The following example inserts a new row only if an update affects no rows:
CREATE TABLE visitors (email VARCHAR2(128), pages_visited INTEGER DEFAULT 1); CREATE OR REPLACE PROCEDURE someone_visited (visitor_email visitors.email%TYPE) AS BEGIN UPDATE visitors SET pages_visited = pages_visited + 1 WHERE email = visitor_email; IF SQL%NOTFOUND THEN INSERT INTO visitors (email) VALUES (visitor_email); dbms_output.put_line('Adding ' || visitor_email || ' to the table.'); ELSE dbms_output.put_line('Incremented counter for ' || visitor_email || '.'); END IF; END; / DECLARE visitor_email visitors.email%TYPE := 'fred@fictional_domain.com'; BEGIN someone_visited(visitor_email); someone_visited(visitor_email); END; / DROP TABLE visitors; DROP PROCEDURE someone_visited;
The following example raises an exception if more than 10 rows are deleted:
CREATE TABLE temp AS SELECT object_name name FROM user_objects; DECLARE large_deletion EXCEPTION; rows_deleted NUMBER; BEGIN DELETE FROM temp WHERE name LIKE '%A%'; rows_deleted := SQL%ROWCOUNT; COMMIT; IF rows_deleted > 10 THEN RAISE large_deletion; END IF; dbms_output.put_line('Nothing unusual detected.'); EXCEPTION WHEN large_deletion THEN dbms_output.put_line('Recording deletion of ' || rows_deleted || ' rows in case of error.'); END; / DROP TABLE temp;
The following example uses %BULK_ROWCOUNT
. After the FORALL
statement completes, the program checks how many rows were updated by the third UPDATE
:
CREATE TABLE num_table (n NUMBER); DECLARE TYPE NumList IS TABLE OF NUMBER; nums NumList := NumList(1,3,5,5,11,5,5); BEGIN FORALL i IN nums.FIRST .. nums.LAST INSERT INTO num_table (n) VALUES (nums(i)); -- All the numbers in the table will be squared. -- Some updates will affect more rows than others. FORALL j IN nums.FIRST .. nums.LAST UPDATE num_table SET n = n * n WHERE n = nums(j); FOR k IN nums.FIRST .. nums.LAST LOOP dbms_output.put_line('Update #' || k || ' affected ' || SQL%BULK_ROWCOUNT(k) || ' rows.'); END LOOP; END; / DROP TABLE num_table;
Related Topics
Cursors, Cursor Attributes, FORALL Statement, "Handling FORALL Exceptions with the %BULK_EXCEPTIONS Attribute"