In Pre 8.1, execution of every SQL statement
embedded in the PL/SQL programs involves a context switch between
the PL/SQL engine and SQL engine. This results in performance
penalty. If we could avoid this switch or maximize processing
during the switch, efficiencies are gained. By using BULK BIND we
can maximize the performance of time spent in the SQL context.
The new Bulk Binds feature in PL/SQL 8.1 allows us
to operate on multiple rows in a single DML statement.
Typical Performance Improvement achieved by WITH
BULK BINDS feature vs WITHOUT BULK BINDS are listed below :
Note : The following figures are representative of
the gains that might be had by passing parameters WITH BULK BINDS
mechanism verses WITHOUT BULK BINDS mechanism. Actual timings can
vary depending on the machine type and load etc.
Task |
WITHOUT BULK BINDS |
WITH BULK BINDS |
Time Units |
( Secs ) |
( Secs ) |
Inserting 10000 Records |
77 |
8 |
Querying 10000 Records |
19 |
12 |
Technique:
The example below use the following type
definitions for the nested tables into which the bulk binds are
performed:
/*--------------------------------------------------------------------*/
/* Nested Table type for storing opening,closing and high
values */
/*--------------------------------------------------------------------*/
CREATE TYPE nt_values AS TABLE OF NUMBER(8,2)
/
/*--------------------------------------------------------------------*/
/* Nested Table type for storing
volume */
/*--------------------------------------------------------------------*/
CREATE TYPE
nt_volume AS TABLE OF NUMBER(12)
/
/*--------------------------------------------------------------------*/
/* Nested Table type for storing stock
names */
/*--------------------------------------------------------------------*/
CREATE TYPE nt_stknames AS TABLE OF VARCHAR2(30)
/
Typical parameter definitions would then become:
stock_name
nt_stknames,
stk_open_vals nt_values,
high nt_values,
stk_close_vals nt_values,
vol nt_volume,
To use the bulk binds feature in Oracle8i you will
convert code of the form:
FOR l_i IN
1..stk_open_vals.COUNT
LOOP
INSERT INTO Stock_History VALUES (stock_name(l_i),stk_open_vals(l_i),
high(l_i), stk_close_vals(l_i), vol(l_i),NULL, SYSDATE - 1);
END LOOP;
Into code using the bulk binds feature such as:
FORALL l_i
IN 1..stk_open_vals.COUNT
INSERT INTO Stock_History VALUES (stock_name(l_i),stk_open_vals(l_i),
high(l_i), stk_close_vals(l_i), vol(l_i),NULL, SYSDATE);
Both code fragments are essentially identical
except the non-bulk bind example uses a standard FOR loop
construct while the bulk bind example replaces this with the
FORALL loop.
Similar code techniques can be used for SELECT,
UPDATE and DELETE as well, for example for SELECT not using BULK
bind:
CURSOR
l_c1 IS
SELECT stock_name,AVG(VOLUME) FROM Stock_History
GROUP BY stock_name
ORDER BY stock_name;
BEGIN
OPEN l_c1;
LOOP
l_averages.EXTEND;
l_stock_names.EXTEND;
FETCH l_c1 INTO l_stock_names(l_i),l_averages(l_i);
EXIT WHEN l_c1%NOTFOUND;
l_i := l_i + 1;
END LOOP;
CLOSE l_c1;
END;
For SELECT using BULK bind:
CURSOR
l_c1 IS
SELECT stock_name,AVG(VOLUME) FROM Stock_History
GROUP BY stock_name
ORDER BY stock_name;
BEGIN
/* Use BULK FETCHING */
OPEN l_c1;
FETCH l_c1 BULK COLLECT INTO l_stock_names,l_averages;
CLOSE l_c1;
END;
Notice in the SELECT example the bulk bind is
implemented through the FETCH?BULK COLLECT INTO construct.
In the next example the use of FORALL and an
UPDATE statement is demonstrated:
BEGIN
/* Bulk Update Statement */
FORALL l_j IN 1..100
UPDATE stock_history
SET stock_group = 'L'
WHERE volume <= 500 AND stock_name =
all_stock_names(l_j) AND
to_char(Trade_Date,'DD-MON-YYYY') =
to_char(SYSDATE,'DD-MON-YYYY');