Bulk Insert and Bulk Update in Oracle Database

I will explain Bulk Insert and Bulk Update in Oracle Database in this article.

 

Bulk Insert and Bulk Update in Oracle

You can read the following article if you want to learn more details about Performance Tuning tips and Tricks.

SQL Tuning Tips and Tricks Tutorial in Oracle -2

 

 

 

 

Bulk Insert in Oracle

You should use Bulk Insert,Delete and Update instead of Single Insert,Delete and Update if you are executing Bulk operation.

Bulk insert,Delete and Update will give your system a huge performance boost.

 

 

If you insert high volume data serial,  you should switch this insert operation to the Bulk Insert.

For example; you can insert all MSD.TEST_TABLE records to the MSD.TEST_TABLE_NEW serial as follows.

insert into MSD.TEST_TABLE_NEW select * from MSD.TEST_TABLE;
commit;

 

But if MSD.TEST_TABLE count is very big, then you should use Cursor and Forall to perform Bulk Insert as follows.

 

DECLARE
CURSOR c_liste
IS
select * from MSD.TEST_TABLE;

TYPE TListe IS TABLE OF MSD.TEST_TABLE%ROWTYPE;

r_liste TListe;
l_hata VARCHAR2 (20000);
BEGIN
OPEN c_liste;

LOOP
FETCH c_liste
BULK COLLECT INTO r_liste
LIMIT 1000;

EXIT WHEN r_liste.COUNT () = 0;

BEGIN
FORALL i IN 1 .. r_liste.LAST
insert into MSD.TEST_TABLE_NEW
VALUES r_liste (i);
END;

COMMIT;
END LOOP;

COMMIT;

CLOSE c_liste;
END;
/

 

This Bulk Insert operation speed up to 30 times faster according to Serial Insert.

 

 

Bulk Update in Oracle

 

Likewise you can perform bulk update as follows.

SET TIMING ON

DECLARE
CURSOR c_liste
IS
SELECT /*+ PARALLEL(TT, 8) */ * FROM MSD.TEST_TABLE TT
WHERE TT.SUBSCRIPTION_ID IS NOT NULL;

TYPE TListe
IS TABLE OF MSD.TEST_TABLE%ROWTYPE;

r_liste TListe;
l_hata VARCHAR2 (2000);
BEGIN
OPEN c_liste;

LOOP
FETCH c_liste
BULK COLLECT INTO r_liste
LIMIT 1000;

EXIT WHEN r_liste.COUNT () = 0;

BEGIN
FORALL i IN 1 .. r_liste.LAST
UPDATE PR_OSB_CUSTOM.SEQUENCING_RUNTIME_MAIN SEQ
SET SEQ.MESSAGE = updateXML(SEQ.MESSAGE, '//*:businessID/text()', 'MSD-'||r_liste (i).SUBSCRIPTION_ID|| '_' || r_liste (i).SYSTEM_NAME),
SEQ.BUSINESS_ID = 'MSD-'||r_liste (i).SUBSCRIPTION_ID|| '_' || r_liste (i).SYSTEM_NAME
WHERE SEQ.ID = r_liste (i).ID
AND seq.BUSINESS_ID NOT LIKE 'MSD%';

END;

COMMIT;
END LOOP;

COMMIT;

CLOSE c_liste;
END;
/

 

If you are processing ( DML ) high volume data, you should use Bulk Insert or Bulk Update or Bulk Delete instead of Serial Insert, update and delete.

 

 

 

 Do you want to learn Top 30 SQL Tuning Tips and Tricks, then Click this link adn read the articles.

SQL Tuning Tips and Tricks Tutorial in Oracle -2

 

About Mehmet Salih Deveci

I am Founder of SysDBASoft IT and IT Tutorial and Certified Expert about Oracle & SQL Server database, Goldengate, Exadata Machine, Oracle Database Appliance administrator with 10+years experience.I have OCA, OCP, OCE RAC Expert Certificates I have worked 100+ Banking, Insurance, Finance, Telco and etc. clients as a Consultant, Insource or Outsource.I have done 200+ Operations in this clients such as Exadata Installation & PoC & Migration & Upgrade, Oracle & SQL Server Database Upgrade, Oracle RAC Installation, SQL Server AlwaysOn Installation, Database Migration, Disaster Recovery, Backup Restore, Performance Tuning, Periodic Healthchecks.I have done 2000+ Table replication with Goldengate or SQL Server Replication tool for DWH Databases in many clients.If you need Oracle DBA, SQL Server DBA, APPS DBA,  Exadata, Goldengate, EBS Consultancy and Training you can send my email adress [email protected].-                                                                                                                                                                                                                                                 -Oracle DBA, SQL Server DBA, APPS DBA,  Exadata, Goldengate, EBS ve linux Danışmanlık ve Eğitim için  [email protected] a mail atabilirsiniz.

Leave a Reply

Your email address will not be published. Required fields are marked *