Wednesday 14 September 2011

An Error FORALL

Question:
We have been just amazed at how much better our programs perform when we use FORALL to do our inserts and updates. We are now building a new application on Oracle Database 10g Release 2, and we have run into a problem. In all previous usages of FORALL, we would generally take a collection that was populated with a BULK COLLECT and push it into one or more tables. Now we have a more complicated scenario, in which we must go through our collection of "candidate" data for inserts and remove some (perhaps all) of the rows before doing the insert. When we try to use FORALL, we get this error message: ORA-22160: element at index [2750] does not exist How can we avoid this error and get all our data inserted?
Answer:
I agree that FORALL is wonderful—one of the most important enhancements to PL/SQL since Oracle8i was released. And back in Oracle8i and Oracle9i Database, it is true that the only format with which you could use FORALL was this:
FORALL index_variable
IN low_value .. high_value
<DML_Statement>;
And as in a "regular" numeric FOR loop, FORALL will iterate through each integer between low_value and high_value, using that integer to identify an element in all collections that are bound into the DML statement with the index_variable. If no element exists at a particular index value, Oracle Database raises an exception, as you can see in the example in Listing 3.
Code Listing 3: Raising ORA-22160
SQL> DECLARE
2 TYPE list_of_names_t IS TABLE OF VARCHAR2 (32767)
3 INDEX BY PLS_INTEGER;
4
5 happyfamily list_of_names_t;
6 BEGIN
7 happyfamily (1) := 'Eli';
8 happyfamily (2) := 'Chris';
9 happyfamily (3) := 'Veva';
10 happyfamily (5) := 'Steven';
11 FORALL indx IN happyfamily.FIRST .. happyfamily.LAST
12 INSERT INTO first_names
13 VALUES (happyfamily (indx));
14 END;
15 /
DECLARE
*
ERROR at line 1:
ORA-22160: element at index [4] does not exist
FORALL, in other words, requires a sequentially or densely filled collection. Now if you were still running Oracle8i or Oracle9i Database and wanted to fix this problem, you would have to copy the data from your sparsely filled collection over to one without any gaps. From a performance standpoint, this is nothing to worry about; manipulating collections is very fast. But it does involve writing and maintaining even more code.
In Oracle Database 10g, Oracle added two new clauses to the FORALL statement: INDICES OF and VALUES OF. They allow you to avoid the restriction on using densely filled collections. Instead of using an IN range of values, you can point to a collection (usually, but not necessarily, the same collection that is referenced inside the FORALL's DML statement) and say, in effect, "Use only those index values defined in that other collection" (INDICES OF) or "Use only index values that are found in the elements of that other collection" (VALUES OF).
Here is a rewrite of the code in Listing 3 that avoids the ORA-22160 error (notice the boldfaced lines):
DECLARE
TYPE list_of_names_t
IS TABLE OF VARCHAR2 (32767)
INDEX BY PLS_INTEGER;

happyfamily list_of_names_t;
BEGIN
happyfamily (1) := 'Eli';
happyfamily (2) := 'Chris';
happyfamily (3) := 'Veva';
happyfamily (5) := 'Steven';

FORALL indx
IN INDICES OF happyfamily
INSERT INTO first_names
VALUES (happyfamily (indx));
END;
/
That is an example of the simplest way to apply INDICES OF: "self- reference" the same collection used within the DML statement, to easily avoid errors due to sparseness in that collection.
Now let's take a look at VALUES OF. This clause comes in very handy when you want to use only a subset of the collection to be used within the DML statement.
Suppose, for example, that I have a procedure that accepts a collection of employee records and should insert only records for employees with a salary of $10,000 or more. Listing 4 contains the package specification and the body for this employees_dml program.
Code Listing 4: Package and body for employees_dml
CREATE OR REPLACE PACKAGE employees_dml
IS
TYPE employees_aat IS TABLE OF employees%ROWTYPE
INDEX BY PLS_INTEGER;

PROCEDURE insert_some (employees_in IN employees_aat);
END employees_dml;
/

SQL>CREATE OR REPLACE PACKAGE BODY employees_dml
2 IS
3 PROCEDURE insert_some (employees_in IN employees_aat)
4 IS
5 TYPE index_values_aat IS TABLE OF PLS_INTEGER
6 INDEX BY PLS_INTEGER;
7
8 l_values_of index_values_aat;
9 l_index PLS_INTEGER;
10 BEGIN
11 -- Only insert those employees with a salary >= 10000.
12 l_index := employees_in.FIRST;
13
14 WHILE (l_index IS NOT NULL)
15 LOOP
16 IF employees_in (l_index).salary >= 10000
17 THEN
18 l_values_of (l_values_of.COUNT + 1) := l_index;
19 END IF;
20
21 l_index := employees_in.NEXT (l_index);
22 END LOOP;
23
24 FORALL indx IN VALUES OF l_values_of
25 INSERT INTO employees
26 VALUES employees_in (indx);
27 END insert_some;
28 END employees_dml;
Lines 5 through 9 in Listing 4 declare the VALUES OF collection, a collection of PLS_INTEGER values. Then in my WHILE loop (lines 14 through 22), I populate a row in l_values_of with the index value from employees_in, only if the salary in that record is at least $10,000.
Thus, when I get to the FORALL statement (lines 24 through 26), the VALUES OF clause ensures that all other employee records are ignored.
If you have the standard Oracle employees table installed with default data, you can run the script in Listing 5 to verify the behavior of the employees_dml package.
Code Listing 5: Verifying behavior of employees_dml package
SELECT COUNT(*)
FROM employees
WHERE salary < 10000
/

DECLARE
l_employees employees_dml.employees_aat;
BEGIN
SELECT *
BULK COLLECT INTO l_employees
FROM employees;

DELETE FROM employees;

employees_dml.insert_some (l_employees);
END;
/

SELECT COUNT(*)
FROM employees
WHERE salary < 10000
/

ROLLBACK
/

COUNT(*)
-------------------------
88

1 row selected.
PL/SQL procedure successfully completed.


COUNT(*)
-------------------------
0

1 row selected.
Rollback complete.
Finally, you can also use INDICES OF with an entirely different collection that serves as a kind of filter for the collections used in the DML statement.
Listing 6 shows an example of this approach.
Code Listing 6: Using INDICES OF as a filter
SQL> DECLARE
2 TYPE employee_aat IS TABLE OF employees.employee_id%TYPE
3 INDEX BY PLS_INTEGER;
4
5 l_employees employee_aat;
6
7 TYPE boolean_aat IS TABLE OF Boolean
8 INDEX BY PLS_INTEGER;
9
10 l_employee_indices boolean_aat;
11 BEGIN
12 l_employees (1) := 137;
13 l_employees (100) := 126;
14 l_employees (500) := 147;
15 --
16 l_employee_indices (1) := false;
17 l_employee_indices (500) := TRUE;
18 l_employee_indices (799) := null;
19 --
20 FORALL l_index IN INDICES OF l_employee_indices
21 BETWEEN 1 AND 500
22 UPDATE employees
23 SET salary = 10000
24 WHERE employee_id = l_employees (l_index);
25 END;
In this code, I use the index values of defined elements in the l_employee_indices collection to specify which elements of the l_employees collection to use in my update statement. Note that on line 21 of Listing 6, I include a BETWEEN clause to constrain which of the index values of l_employee_indices will be used. So INDICES OF should fix your problem in this case.

No comments:

Post a Comment