Oracle uses two engines to process PL/SQL code. All procedural code is handled by the PL/SQL engine while all SQL is handled by the SQL statement executor, or SQL engine.
There is an overhead associated with each context switch between the two engines. If PL/SQL code loops through a collection performing the same DML operation for each item in the collection it is possible to reduce context switches by bulk binding the whole collection to the DML statement in one operation
BULK COLLECT
Bulk binds can improve the performance when loading collections from a queries. The BULK COLLECT INTO
construct binds the output of the query to the collection. To test this create the following table.
CREATE TABLE bulk_collect_test AS
SELECT owner,
object_name,
object_id
FROM all_objects;
The following code compares the time taken to populate a collection manually and using a bulk bind.
SET SERVEROUTPUT ON
DECLARE
TYPE t_bulk_collect_test_tab IS TABLE OF bulk_collect_test%ROWTYPE;
l_tab t_bulk_collect_test_tab := t_bulk_collect_test_tab();
l_start NUMBER;
BEGIN
-- Time a regular population.
l_start := DBMS_UTILITY.get_time;
FOR cur_rec IN (SELECT *
FROM bulk_collect_test)
LOOP
l_tab.extend;
l_tab(l_tab.last) := cur_rec;
END LOOP;
DBMS_OUTPUT.put_line('Regular (' || l_tab.count || ' rows): ' ||
(DBMS_UTILITY.get_time - l_start));
-- Time bulk population.
l_start := DBMS_UTILITY.get_time;
SELECT *
BULK COLLECT INTO l_tab
FROM bulk_collect_test;
DBMS_OUTPUT.put_line('Bulk (' || l_tab.count || ' rows): ' ||
(DBMS_UTILITY.get_time - l_start));
END;
/
Regular (42578 rows): 66
Bulk (42578 rows): 4
PL/SQL procedure successfully completed.
SQL>
We can see the improvement associated with bulk operations to reduce context switches.
Note. The select list must match the collections record definition exactly for this to be successful.
Remember that collections are held in memory, so doing a bulk collect from a large query could cause a considerable performance problem. In actual fact you would rarely do a straight bulk collect in this manner. Instead you would limit the rows returned using the LIMIT
clause and move through the data processing smaller chunks. This gives you the benefits of bulk binds, without hogging all the server memory. The following code shows how to chunk through the data in a large table.
BULK COLLECT INTO
construct binds the output of the query to the collection. To test this create the following table.
Note. The select list must match the collections record definition exactly for this to be successful.
LIMIT
clause and move through the data processing smaller chunks. This gives you the benefits of bulk binds, without hogging all the server memory. The following code shows how to chunk through the data in a large table.FORALL
The FORALL
syntax allows us to bind the contents of a collection to a single DML statement, allowing the DML to be run for each row in the collection without requiring a context switch each time. To test bulk binds using records we first create a test table.
The following test compares the time taken to insert 10,000 rows using regular FOR..LOOP
and a bulk bind.
SET SERVEROUTPUT ON
DECLARE
TYPE t_forall_test_tab IS TABLE OF forall_test%ROWTYPE;
l_tab t_forall_test_tab := t_forall_test_tab();
l_start NUMBER;
l_size NUMBER := 10000;
BEGIN
-- Populate collection.
FOR i IN 1 .. l_size LOOP
l_tab.extend;
l_tab(l_tab.last).id := i;
l_tab(l_tab.last).code := TO_CHAR(i);
l_tab(l_tab.last).description := 'Description: ' || TO_CHAR(i);
END LOOP;
EXECUTE IMMEDIATE 'TRUNCATE TABLE forall_test';
-- Time regular inserts.
l_start := DBMS_UTILITY.get_time;
FOR i IN l_tab.first .. l_tab.last LOOP
INSERT INTO forall_test (id, code, description)
VALUES (l_tab(i).id, l_tab(i).code, l_tab(i).description);
END LOOP;
DBMS_OUTPUT.put_line('Normal Inserts: ' ||
(DBMS_UTILITY.get_time - l_start));
EXECUTE IMMEDIATE 'TRUNCATE TABLE forall_test';
-- Time bulk inserts.
l_start := DBMS_UTILITY.get_time;
FORALL i IN l_tab.first .. l_tab.last
INSERT INTO forall_test VALUES l_tab(i);
DBMS_OUTPUT.put_line('Bulk Inserts : ' ||
(DBMS_UTILITY.get_time - l_start));
COMMIT;
END;
/
Normal Inserts: 305
Bulk Inserts : 14
PL/SQL procedure successfully completed.
SQL>
The output clearly demonstrates the performance improvements you can expect to see when using bulk binds to remove the context switches between the SQL and PL/SQL engines.
Note. Since no columns are specified in the insert statement the record structure of the collection must match the table exactly.
FORALL
syntax allows us to bind the contents of a collection to a single DML statement, allowing the DML to be run for each row in the collection without requiring a context switch each time. To test bulk binds using records we first create a test table.FOR..LOOP
and a bulk bind.
Note. Since no columns are specified in the insert statement the record structure of the collection must match the table exactly.
0 comments:
Post a Comment