Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> Re: How to do faster updates

Re: How to do faster updates

From: Jeff Landers <jlanders_at_convergys.com>
Date: Fri, 13 Sep 2002 10:58:22 -0800
Message-ID: <F001.004CFC0D.20020913105822@fatcity.com>


Pillai, Rajesh wrote:

> Hi All,
> I've a table of 10 M records and I want to update some thousand records based on a column which is not a part of any index. Please suggest the quickest way to do this.
>
> Thanks,
> Rajesh
> --
> Please see the official ORACLE-L FAQ: http://www.orafaq.com
> --
> Author: Pillai, Rajesh
> INET: Rajesh.Pillai_at_nordstrom.com
>
> Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051
> San Diego, California -- Public Internet access / Mailing Lists
> --------------------------------------------------------------------
> To REMOVE yourself from this mailing list, send an E-Mail message
> to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
> the message BODY, include a line containing: UNSUB ORACLE-L
> (or the name of mailing list you want to be removed from). You may
> also send the HELP command for other information (like subscribing).

  Bulk collect the rowid's of the rows you want to update. Then use the forall statement to bulk update the rows. Very, very fast.

Here is an example:

set serveroutput on size 1000000
declare

        type my_array_type is table of rowid
                index by binary_integer;

        my_array        my_array_type;
        rows            natural := 15000;
        loop_count      pls_integer := 0;


        --
        --
        cursor bill_cur is
                select b.rowid from bill b where b.person_id = 'xyz';

        begin


        open bill_cur;
        loop
                fetch bill_cur bulk collect into my_array limit rows;
                exit when bill_cur%NOTFOUND;

                loop_count := loop_count + 1;
                forall indx in my_array.first..my_array.last
                        update bill set person_id = 'abc'
                                where ROWID = my_array(indx);
                commit;
                my_array.DELETE;
         end loop;

        ---

        if my_array.COUNT > 0 then
                forall indx in my_array.first..my_array.last
                update bill set person_id = 'abc'
                        where ROWID = my_array(indx);
                commit;
        end if;

        close bill_cur;
        dbms_application_info.set_client_info( Total Loops: '|| loop_count );


        exception
                when others then
                commit;

end;
/
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Jeff Landers
  INET: jlanders_at_convergys.com

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
Received on Fri Sep 13 2002 - 13:58:22 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US