Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 

Bulk UPDATE Operations


Oracle Tips by Burleson Consulting

 

The following Tip is from the outstanding book "Oracle PL/SQL Tuning: Expert Secrets for High Performance Programming" by Dr. Tim Hall, Oracle ACE of the year, 2006:

The forall_test table is used to compare the performance of individual updates against bulk updates using the update_forall.sql script listed below.  Notice the use of the ROW keyword in the bulk operation.  This keyword was introduced in Oracle9i Release 2 to allow updates using record definitions without needing to reference individual elements of the record, making bulk operations significantly simpler.

update_forall.sql

SET SERVEROUTPUT ON
DECLARE
  TYPE t_id_tab IS TABLE OF forall_test.id%TYPE;
  TYPE t_forall_test_tab IS TABLE OF forall_test%ROWTYPE;

  l_id_tab  t_id_tab          := t_id_tab();
  l_tab     t_forall_test_tab := t_forall_test_tab ();
  l_start   NUMBER;
  l_size    NUMBER            := 10000;
BEGIN
  -- Populate collections.
  FOR i IN 1 .. l_size LOOP
    l_id_tab.extend;
    l_tab.extend;

    l_id_tab(l_id_tab.last)       := i;
    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;

  -- Time regular updates.

  l_start := DBMS_UTILITY.get_time;

  FOR i IN l_tab.first .. l_tab.last LOOP
    UPDATE forall_test
    SET    ROW = l_tab(i)
    WHERE  id  = l_tab(i).id;
  END LOOP; 

  DBMS_OUTPUT.put_line('Normal Updates : ' ||
                       (DBMS_UTILITY.get_time - l_start));

  l_start := DBMS_UTILITY.get_time;

  -- Time bulk updates.

  FORALL i IN l_tab.first .. l_tab.last
    UPDATE forall_test
    SET    ROW = l_tab(i)
    WHERE  id  = l_id_tab(i);

  DBMS_OUTPUT.put_line('Bulk Updates   : ' ||
                       (DBMS_UTILITY.get_time - l_start));

  COMMIT;
END;
/

The update_forall.sql script has a similar internal structure to the insert_forall.sql script described earlier.  The main difference is the update statement requires a WHERE clause that references the tables ID column allowing individual rows to be targeted.  If the bulk operation was altered to reference the ID column within the collection, the following compilation error would be produced.

  -- Incorrect bulk operation.

  FORALL i IN l_tab.first .. l_tab.last
    UPDATE forall_test
    SET    ROW = l_tab(i)
    WHERE  id  = l_tab(i).id;

Errors for PROCEDURE UPDATE_FORALL:

LINE/COL ERROR
-------- -----------------------------------------------------------
36/5     PL/SQL: SQL Statement ignored
38/18    PL/SQL: ORA-22806: not an object or REF
38/18    PLS-00382: expression is of wrong type
38/18    PLS-00436: implementation restriction: cannot reference
         fields of BULK In-BIND table of records

Before running the script make sure the FORALL_TEST table is populated using the insert_forall.sql script or there will be no records to update. The results from the update_forall.sql script are listed below.

SQL> @update_forall.sql
Normal Updates : 202
Bulk Updates   : 104

PL/SQL procedure successfully completed.

In this example, the bulk operation is approximately twice the speed of the conventional update.

The update_forall_8i.sql script shows how this operation would be coded prior to Oracle9i Release 2.  Notice that a separate collection is defined for each column referenced in the bind operation.

update_forall_8i.sql

SET SERVEROUTPUT ON
DECLARE
  TYPE t_id_tab IS TABLE OF forall_test.id%TYPE;
  TYPE t_code_tab IS TABLE OF forall_test.code%TYPE;
  TYPE t_desc_tab IS TABLE OF forall_test.description%TYPE;

  l_id_tab    t_id_tab   := t_id_tab();
  l_code_tab  t_code_tab := t_code_tab();
  l_desc_tab  t_desc_tab := t_desc_tab();
  l_start     NUMBER;
  l_size      NUMBER     := 10000;
BEGIN
  -- Populate collections.
  FOR i IN 1 .. l_size LOOP
    l_id_tab.extend;
    l_code_tab.extend;
    l_desc_tab.extend;

    l_id_tab(l_id_tab.last)     := i;
    l_code_tab(l_code_tab.last) := TO_CHAR(i);
    l_desc_tab(l_desc_tab.last) := 'Description: ' || TO_CHAR(i);
  END LOOP;

  -- Time regular updates.

  l_start := DBMS_UTILITY.get_time;

  FOR i IN l_id_tab.first .. l_id_tab.last LOOP
    UPDATE forall_test
    SET    id          = l_id_tab(i),
           code        = l_code_tab(i),
           description = l_desc_tab(i)
    WHERE  id          = l_id_tab(i);
  END LOOP; 

  DBMS_OUTPUT.put_line('Normal Updates : ' ||
                       (DBMS_UTILITY.get_time - l_start));

  l_start := DBMS_UTILITY.get_time;

  -- Time bulk updates.

  FORALL i IN l_id_tab.first .. l_id_tab.last
    UPDATE forall_test
    SET    id          = l_id_tab(i),
           code        = l_code_tab(i),
           description = l_desc_tab(i)
    WHERE  id          = l_id_tab(i); 

  DBMS_OUTPUT.put_line('Bulk Updates  : ' ||
                       (DBMS_UTILITY.get_time - l_start));

  COMMIT;
END;
/

Once again it is apparent that the bulk operation is the more efficient of the two.

SQL> @update_forall.sql
Normal Updates : 201
Bulk Updates   : 104

PL/SQL procedure successfully completed.

The following section compares the performance of conventional operations with bulk delete operations.

Bulk DELETE Operations

The bulk delete operation is the same regardless of server version.  Using the forall_test table, a single predicate is needed in the WHERE clause, but for this example both the ID and CODE columns are included as if they represented a concatenated key.

The delete_forall.sql script listed below is used for this test.  The script contains rollback statements, which are necessary to make sure the bulk operation has something to delete.  Since the script uses separate collections for each bind, it is suitable for all versions of Oracle that support bulk operations.

delete_forall.sql

SET SERVEROUTPUT ON
DECLARE
  TYPE t_id_tab IS TABLE OF forall_test.id%TYPE;
  TYPE t_code_tab IS TABLE OF forall_test.code%TYPE;

  l_id_tab    t_id_tab   := t_id_tab();
  l_code_tab  t_code_tab := t_code_tab();
  l_start     NUMBER;
  l_size      NUMBER     := 10000;
BEGIN
  -- Populate collections.
  FOR i IN 1 .. l_size LOOP
    l_id_tab.extend;
    l_code_tab.extend;

    l_id_tab(l_id_tab.last)     := i;
    l_code_tab(l_code_tab.last) := TO_CHAR(i);
  END LOOP;

  -- Time regular updates.
  l_start := DBMS_UTILITY.get_time;

  FOR i IN l_id_tab.first .. l_id_tab.last LOOP
    DELETE FROM forall_test
    WHERE  id   = l_id_tab(i)
    AND    code = l_code_tab(i);
  END LOOP;

  ROLLBACK;

  DBMS_OUTPUT.put_line('Normal Deletes : ' ||
                       (DBMS_UTILITY.get_time - l_start));

  l_start := DBMS_UTILITY.get_time;

  -- Time bulk updates.

  FORALL i IN l_id_tab.first .. l_id_tab.last
    DELETE FROM forall_test
    WHERE  id   = l_id_tab(i)
    AND    code = l_code_tab(i); 

  DBMS_OUTPUT.put_line('Bulk Deletes   : ' ||
                       (DBMS_UTILITY.get_time - l_start));

  ROLLBACK;
END;
/

Before running the delete_forall.sql script make sure the forall_test table is populated using the insert_forall.sql script or there will be no records to delete.

SQL> @delete_forall.sql
Normal Deletes : 416
Bulk Deletes   : 204

PL/SQL procedure successfully completed.

The performance of the bulk delete is similar to the performance of the bulk update; the bulk operation is approximately twice the speed of the conventional operation.

In the next section, methods for handling sparse collections available in Oracle 10g are presented.

This is an excerpt from the bestselling book "Oracle PL/SQL Tuning: Expert Secrets for High Performance Programming" by Dr. Tim Hall, Oracle ACE of the year, 2006.

You can buy the book for only $23.95 (30%-off) when you buy directly from the publisher, and you also get instant access to the code depot of PL/SQL tuning scripts:


 

 
��
 
 
 
 

 
 
 

 
Oracle performance tuning software 
 
oracle dba poster
Oracle Linux poster
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright 1996 -  2014

All rights reserved by Burleson

Oracle is the registered trademark of Oracle Corporation.