Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> Re: insert and commit 1000 records at a time
sfaroult_at_oriole.com wrote:
> Mladen Gogala wrote:
>
>>I believe that this would be the best solution: >>DECLARE >> RowCount NUMBER := 0; >> >>BEGIN >> /* This will work if the RESOURCE table has the "parallel" >> attribute set. In 8i, table needs to be partitioned as well */ >> >> EXECUTE IMMMEDIATE 'ALTER SESSION ENABLE PARALLEL DML'; >> SELECT Count(*) >> INTO RowCount >> FROM RQMT; >> >> IF RowCount > 0 THEN >> >> INSERT /*+ APPEND */ INTO RESOURCE >> SELECT Resource_Id, Classification >> FROM RQMT; >> >> RowCount := SQL%RowCount; >> >> DBMS_OUTPUT.PUT_LINE ('TABLE Resource: ' || RowCount || ' >>Rows >>transitioned.'); >> COMMIT; >> ELSE >> DBMS_OUTPUT.PUT_LINE ('TABLE Resource is empty. No data >>transitioned.'); >> END IF; >> >> EXCEPTION >> WHEN OTHERS THEN >> Raise NOT_LOGGED_ON; >>END; >>/ >>On 10/16/2003 01:29:33 PM, rgaffuri_at_cox.net wrote: >> >>>yeah dont commit every 1000 records and do it in one shot. this is >>>going to be much slower. >>> >>>why do you want to do it this way? Ive done 100m inserts with just an >>>insert select and one commit. >>> >>>>From: Maryann Atkinson <maryann_30_at_yahoo.com> >>>>Date: 2003/10/16 Thu AM 11:54:33 EDT >>>>To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> >>>>Subject: insert and commit 1000 records at a time >>>> >>>>I have 2 tables, Rqmt and Resource, same structure. >>>> >>>>I need to take all almost-one-million records from Rqmt and >>>>insert them to Resource. So far this worked ok: >>>> >>>>DECLARE >>>> RowCount NUMBER := 0; >>>> >>>>BEGIN >>>> SELECT Count(*) >>>> INTO RowCount >>>> FROM RQMT; >>>> >>>> IF RowCount > 0 THEN >>>> >>>> INSERT INTO RESOURCE >>>> SELECT Resource_Id, Classification >>>> FROM RQMT; >>>> >>>> RowCount := SQL%RowCount; >>>> >>>> DBMS_OUTPUT.PUT_LINE ('TABLE Resource: ' || RowCount || ' >>> >>>Rows >>> >>>>transitioned.'); >>>> COMMIT; >>>> ELSE >>>> DBMS_OUTPUT.PUT_LINE ('TABLE Resource is empty. No data >>>>transitioned.'); >>>> END IF; >>>> >>>> EXCEPTION >>>> WHEN OTHERS THEN >>>> Raise; >>>>END; >>>>/ >>>> >>>> >>>>But now I need to commit every 1000 records. Any suggestions as to >>>>what would be the best way? I dont think ROWNUM would help here, >>>>because it would pick the same 1000 records every time, causing >>>>primary key violation... >>>> >>>> >>>>thx >>>>maa >>>> >>>>-- >>>>Please see the official ORACLE-L FAQ: http://www.orafaq.net >>>>-- >>>>Author: Maryann Atkinson >>>> INET: maryann_30_at_yahoo.com >>>> >>>
The array fetch in OCI is equivalent to FETCH ... BULK COLLECT INTO ... in PL/SQL. The array insert in OCI is equivalent to FORALL i IN 1..1000 INSERT INTO ... in PL/SQL. IMHO, doing it in OCI won't be faster than the solution proposed by Stephen Lee using the COPY FROM command in SQL*Plus while setting copycommit to 1000, which essentially does the same thing. Doing it in PL/SQL won't be faster either because while PL/SQL code runs in-process with the database, it's not compiled like the OCI solution. So if the OP really wants to commit the insert every 1000 rows, IMHO the easiest and fastest solution would be to use COPY FROM in SQL*Plus.
-- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Dave Hau INET: davehau123_at_netscape.net Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services --------------------------------------------------------------------- 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 Thu Oct 16 2003 - 20:54:24 CDT
![]() |
![]() |