Programmer's Guide to the Oracle Precompilers, 1.8 | Library |
Product |
Contents |
Index |
Using arrays can boost the performance of your application. Arrays let you manipulate an entire collection of data items with a single SQL statement. Thus, Oracle communication overhead is reduced markedly, especially in a networked environment. For example, suppose you want to insert information about 300 employees into the EMP table. Without arrays your program must do 300 individual INSERTs--one for each employee. With arrays, only one INSERT need be done.
EXEC SQL BEGIN DECLARE SECTION;
emp_name (50) CHARACTER(20);
emp_number (50) INTEGER;
salary (50) REAL;
EXEC SQL END DECLARE SECTION;
EXEC SQL BEGIN DECLARE SECTION;
hi_lo_scores (25, 25) INTEGER; -- not allowed
EXEC SQL END DECLARE SECTION;
Note: When MODE=ANSI14, array operations are not allowed. In other words, you can reference host arrays in a SQL statement only when MODE={ANSI|ANSI13|ORACLE}.
The syntax used for host arrays and simple host variables is nearly the same. One difference is the optional FOR clause, which lets you control array processing. Also, there are restrictions on mixing host arrays and simple host variables in a SQL statement.
The following sections illustrate the use of host arrays in data manipulation statements.
EXEC SQL BEGIN DECLARE SECTION;
emp_name (50) CHARACTER(20);
emp_number (50) INTEGER;
salary (50) REAL;
EXEC SQL END DECLARE SECTION;
EXEC SQL SELECT ENAME, EMPNO, SAL
INTO :emp_name, :emp_number, :salary
FROM EMP
WHERE SAL > 1000;
In this example, the SELECT statement returns up to 50 rows. If there are fewer than 50 eligible rows or you want to retrieve only 50 rows, this method will suffice. However, if there are more than 50 eligible rows, you cannot retrieve all of them this way. If you reexecute the SELECT statement, it just returns the first 50 rows again, even if more are eligible. You must either dimension a larger array or declare a cursor for use with the FETCH statement.
If a SELECT INTO statement returns more rows than the number of elements you dimensioned, Oracle issues the error message
SQL-02112: SELECT...INTO returns too many rows
unless you specify SELECT_ERROR=NO. For more information about the option SELECT_ERROR, see page 6 - 34.
EXEC SQL BEGIN DECLARE SECTION;
emp_number (20) INTEGER;
salary (20) REAL;
EXEC SQL END DECLARE SECTION;
EXEC SQL DECLARE emp_cursor CURSOR FOR
SELECT EMPNO, SAL FROM EMP;
EXEC SQL OPEN emp_cursor;
EXEC SQL WHENEVER NOT FOUND DO ...
LOOP
EXEC SQL FETCH emp_cursor INTO :emp_number, :salary;
-- process batch of rows
ENDLOOP;
EXEC SQL OPEN cursor1;
EXEC SQL OPEN cursor2;
EXEC SQL FETCH cursor1 INTO :array_of_20;
-- now running total in SQLERRD(3) is 20
EXEC SQL FETCH cursor2 INTO :array_of_30;
-- now running total in SQLERRD(3) is 30, not 50
EXEC SQL FETCH cursor1 INTO :array_of_20;
-- now running total in SQLERRD(3) is 40 (20 + 20)
EXEC SQL FETCH cursor2 INTO :array_of_30;
-- now running total in SQLERRD(3) is 60 (30 + 30)
Table 9 - 1 shows which uses of host arrays are valid in a SELECT INTO statement:
INTO Clause | WHERE Clause | Valid? |
array | array | no |
scalar | scalar | yes |
array | scalar | yes |
scalar | array | no |
When DBMS=V7, if you select or fetch a null into a host array that lacks an indicator array, Oracle stops processing, sets SQLERRD(3) to the number of rows processed, and issues the following error message:
ORA-01405: fetched column value is NULL
ORA-01406: fetched column value was truncated
You can check SQLERRD(3) for the number of rows processed before the truncation occurred. The rows-processed count includes the row that caused the truncation error.
When MODE=ANSI, truncation is not considered an error, so Oracle continues processing.
Again, when doing array selects and fetches, always use indicator arrays. That way, if Oracle assigns one or more truncated column values to an output host array, you can find the original lengths of the column values in the associated indicator array.
An example of inserting with host arrays follows:
EXEC SQL BEGIN DECLARE SECTION;
emp_name (50) CHARACTER(20);
emp_number (50) INTEGER;
salary (50) REAL;
EXEC SQL END DECLARE SECTION;
-- populate the host arrays
EXEC SQL INSERT INTO EMP (ENAME, EMPNO, SAL)
VALUES (:emp_name, :emp_number, :salary);
The cumulative number of rows inserted can be found in SQLERRD(3).
Although functionally equivalent to the following statement, the INSERT statement in the last example is much more efficient because it issues only one call to Oracle:
FOR i = 1 TO array_dimension
EXEC SQL INSERT INTO EMP (ENAME, EMPNO, SAL)
VALUES (:emp_name[i], :emp_number[i], :salary[i]);
ENDFOR;
In this imaginary example (imaginary because host variables cannot be subscripted in a SQL statement), you use a FOR loop to access all array elements in sequential order.
EXEC SQL BEGIN DECLARE SECTION;
emp_number (50) INTEGER;
salary (50) REAL;
EXEC SQL END DECLARE SECTION;
-- populate the host arrays
EXEC SQL UPDATE EMP SET SAL = :salary WHERE EMPNO = :emp_number;
The cumulative number of rows updated can be found in SQLERRD(3). The number does not include rows processed by an update cascade.
If some elements in the arrays are irrelevant, you can use the FOR clause to limit the number of rows updated.
The last example showed a typical update using a unique key (emp_number). Each array element qualified just one row for updating. In the following example, each array element qualifies multiple rows:
EXEC SQL BEGIN DECLARE SECTION;
job_title (10) CHARACTER(10);
commission (50) REAL;
EXEC SQL END DECLARE SECTION;
-- populate the host arrays
EXEC SQL UPDATE EMP SET COMM = :commission WHERE JOB = :job_title;
You cannot use host arrays with the CURRENT OF clause in an UPDATE statement. For an alternative, see "Mimicking CURRENT OF" .
Table 9 - 2 shows which uses of host arrays are valid in an UPDATE statement:
SET Clause | WHERE Clause | Valid? |
array | array | yes |
scalar | scalar | yes |
array | scalar | no |
scalar | array | no |
EXEC SQL BEGIN DECLARE SECTION;
...
emp_number (50) INTEGER;
EXEC SQL END DECLARE SECTION;
-- populate the host array
EXEC SQL DELETE FROM EMP WHERE EMPNO = :emp_number;
The cumulative number of rows deleted can be found in SQLERRD(3). That number does not include rows processed by a delete cascade.
The last example showed a typical delete using a unique key (emp_number). Each array element qualified just one row for deletion. In the following example, each array element qualifies multiple rows:
EXEC SQL BEGIN DECLARE SECTION;
...
job_title (10) CHARACTER(10);
EXEC SQL END DECLARE SECTION;
-- populate the host array
EXEC SQL DELETE FROM EMP WHERE JOB = :job_title;
EXEC SQL BEGIN DECLARE SECTION;
emp_number (50) INTEGER;
dept_number (50) INTEGER;
commission (50) REAL;
ind_comm (50) SMALLINT; -- indicator array
EXEC SQL END DECLARE SECTION;
-- populate the host arrays
-- populate the indicator array; to insert a null into
-- the COMM column, assign -1 to the appropriate element in
-- the indicator array
EXEC SQL INSERT INTO EMP (EMPNO, DEPTNO, COMM)
VALUES (:emp_number, :dept_number, :commission:ind_comm);
The dimension of the indicator array cannot be smaller than the dimension of the host array.
EXEC SQL BEGIN DECLARE SECTION;
emp_name (100) CHARACTER(20);
salary (100) REAL;
rows_to_insert INTEGER;
EXEC SQL END DECLARE SECTION;
-- populate the host arrays
set rows_to_insert = 25; -- set FOR-clause variable
EXEC SQL FOR :rows_to_insert -- will process only 25 rows
INSERT INTO EMP (ENAME, SAL)
VALUES (:emp_name, :salary);
The FOR clause must use an integer host variable to count array elements. For example, the following statement is illegal:
EXEC SQL FOR 25 -- illegal
INSERT INTO EMP (ENAME, EMPNO, SAL)
VALUES (:emp_name, :emp_number, :salary);
The FOR-clause variable specifies the number of array elements to be processed. Make sure the number does not exceed the smallest array dimension. Also, the number must be positive. If it is negative or zero, no rows are processed.
PCC-E-0056: FOR clause not allowed on SELECT statement at ...
The FOR clause is not allowed in SELECT statements because its meaning is unclear. Does it mean "execute this SELECT statement n times"? Or, does it mean "execute this SELECT statement once, but return n rows"? The problem in the former case is that each execution might return multiple rows. In the latter case, it is better to declare a cursor and use the FOR clause in a FETCH statement, as follows:
EXEC SQL FOR :limit FETCH emp_cursor INTO ...
EXEC SQL DECLARE emp_cursor CURSOR FOR
SELECT ENAME, SAL FROM EMP WHERE EMPNO = :emp_number;
...
EXEC SQL OPEN emp_cursor;
...
EXEC SQL FETCH emp_cursor INTO :emp_name, :salary;
...
EXEC SQL UPDATE EMP SET SAL = :new_salary
WHERE CURRENT OF emp_cursor;
However, you cannot use the FOR clause with the CURRENT OF clause. The following statements are invalid because the only logical value of limit is 1 (you can only update or delete the current row once):
EXEC SQL FOR :limit UPDATE EMP SET SAL = :new_salary
WHERE CURRENT OF emp_cursor;
...
EXEC SQL FOR :limit DELETE FROM EMP
WHERE CURRENT OF emp_cursor;
PCC-S-0055: Array <name> not allowed as bind variable at ...
For example, assuming the declarations
EXEC SQL BEGIN DECLARE SECTION;
mgr_number (50) INTEGER;
job_title (50) CHARACTER(20);
EXEC SQL END DECLARE SECTION;
it would be ambiguous if the statement
EXEC SQL SELECT MGR INTO :mgr_number FROM EMP
WHERE JOB = :job_title;
were treated like the imaginary statement
FOR i = 1 TO 50
SELECT MGR INTO :mgr_number[i] FROM EMP
WHERE JOB = :job_title[i];
ENDFOR;
because multiple rows might meet the WHERE-clause search condition, but only one output variable is available to receive data. Therefore, an error message is issued.
On the other hand, it would not be ambiguous if the statement
EXEC SQL UPDATE EMP SET MGR = :mgr_number
WHERE EMPNO IN (SELECT EMPNO FROM EMP WHERE JOB = :job_title);
were treated like the imaginary statement
FOR i = 1 TO 50
UPDATE EMP SET MGR = :mgr_number[i]
WHERE EMPNO IN
(SELECT EMPNO FROM EMP WHERE JOB = :job_title[i]);
ENDFOR;
because there is a mgr_number in the SET clause for each row matching job_title in the WHERE clause, even if each job_title matches multiple rows. All rows matching each job_title can be SET to the same mgr_number. So, no error message is issued.
EXEC SQL BEGIN DECLARE SECTION;
emp_name (25) CHARACTER(20);
job_title (25) CHARACTER(15);
old_title (25) CHARACTER(15);
row_id (25) CHARACTER(18);
EXEC SQL END DECLARE SECTION;
...
EXEC SQL DECLARE emp_cursor CURSOR FOR
SELECT ENAME, JOB, ROWID FROM EMP;
...
EXEC SQL OPEN emp_cursor;
EXEC SQL WHENEVER NOT FOUND GOTO ...
...
LOOP
EXEC SQL FETCH emp_cursor
INTO :emp_name, :job_title, :row_id;
...
EXEC SQL DELETE FROM EMP
WHERE JOB = :old_title AND ROWID = :row_id;
EXEC SQL COMMIT WORK;
ENDLOOP;
However, the fetched rows are not locked because no FOR UPDATE OF clause is used. So, you might get inconsistent results if another user changes a row after you read it but before you delete it.
When using host arrays with FETCH, to find the number of rows returned by the most recent iteration, subtract the current value of SQLERRD(3) from its previous value (stored in another variable). In the following example, you determine the number of rows returned by the most recent fetch:
EXEC SQL BEGIN DECLARE SECTION;
emp_number (100) INTEGER;
emp_name (100) CHARACTER(20);
EXEC SQL END DECLARE SECTION;
...
rows_to fetch INTEGER;
rows_before INTEGER;
rows_this_time INTEGER;
...
EXEC SQL DECLARE emp_cursor CURSOR FOR
SELECT EMPNO, ENAME
FROM EMP
WHERE DEPTNO = 30;
EXEC SQL OPEN emp_cursor;
EXEC SQL WHENEVER NOT FOUND CONTINUE;
...
-- initialize loop variables
set rows_to_fetch = 20; -- number of rows in each "batch"
set rows_before = 0; -- previous value of sqlerrd(3)
set rows_this_time = 20;
WHILE rows_this_time = rows_to_fetch
LOOP
EXEC SQL FOR :rows_to_fetch
FETCH emp_cursor
INTO :emp_number, :emp_name;
set rows_this_time = sqlca.sqlerrd(3) - rows_before;
set rows_before = sqlca.sqlerrd(3);
ENDLOOP;
ENDWHILE;
SQLERRD(3) is also useful when an error occurs during an array operation. Processing stops at the row that caused the error, so SQLERRD(3) gives the number of rows processed successfully.
Prev Next |
Copyright © 1996 Oracle Corporation. All Rights Reserved. |
Library |
Product |
Contents |
Index |