Bulk Processing - Inserting Rows Using Collections of Objects
Example Description
- A table is created to store the data (the same table as the previous example).
- An object type as collection element and the collection table type is created.
- The bulk 'FORALL' command inserts all rows at once.
- A timer+counter determines the performance.
Create Table Statement
Table : BULK_PROCESSING_TABLE
create table bulk_processing_table
(
n number not null,
d date not null,
s varchar2(100) not null
);
User Defined Type of Type Object
Object Type Specification : BULK_OBJECT
/**
* Object type with three fields of number, date and varchar2.
*/
create or replace type bulk_object force as object (
n number,
d date,
s varchar2(100)
);
User Defined Type of Collection of Element Type Object
Collection Table Type : BULK_TABLE_OBJECT
/**
* Table of object bulk_object
*/
create or replace type bulk_table_object force as table of bulk_object;
PL/SQL Procedure
The procedure 'BULK_COLLECTION_OBJECT' works on an input collections and saves exception in an output collection.PL/SQL Function : BULK_COLLECTION_OBJECT
create or replace procedure bulk_collection_object(i_col_object in bulk_table_object)
/**
* Bulk collection demo with input parameter as a collection of object.
*
* @param i_col_object List of object type values to insert into table 'bulk_processing_table'.
*/
is
begin
forall i in 1..i_col_object.count
insert into bulk_processing_table
(n,d,s)
values
(i_col_object(i).n, i_col_object(i).d, i_col_object(i).s);
end bulk_collection_object;
Factory API : Calling the PL/SQL package
Using the static factory to get the remote service.Java Calling Class : BulkCollectionObjectsFactoryApi.java
package plsql_workbench_examples.factoryapi;
import java.sql.Date;
import java.util.ArrayList;
import java.util.List;
import java.util.UUID;
import factory.ExamplesRPCFactory;
import plsql_workbench_examples.timer.TimerCounter;
import service.BulkCollectionObjectService;
import transferobject.BulkObject;
public class BulkCollectionObjectsFactoryApi {
private final static int ELEMENTS = 50000;
public static void main(String[] args)
{
try {
// set database credentials and configuration parameters
System.setProperty("dbw_examples.url", "jdbc:oracle:thin:@192.168.0.109:1521/orcl");
System.setProperty("dbw_examples.username", "dbw_examples");
System.setProperty("dbw_examples.password", "dbw_examples");
// getting the service
BulkCollectionObjectService service = ExamplesRPCFactory.getBulkCollectionObjectService();
// generating 50000 elements to transfer to the stored procedure
List<BulkObject> objectList = new ArrayList<>(ELEMENTS);
for (int i = 0; i < ELEMENTS; i++) {
BulkObject o = new BulkObject();
o.d = new Date(System.currentTimeMillis() + (long) (Math.random() * Integer.MAX_VALUE));
o.s = UUID.randomUUID().toString();
o.n = (int) (Math.random() * Integer.MAX_VALUE);
objectList.add(o);
}
// timer to check the throughput
TimerCounter tc = new TimerCounter();
// calling the stored procedure
service.call(objectList);
// print out throughput
System.out.println(tc.perSecond("objects bulk performance (first call)", ELEMENTS));
// calling the stored procedure
service.call(objectList);
// print out throughput
System.out.println(tc.perSecond("objects bulk performance (second call)", ELEMENTS));
}
catch (Exception e) {
e.printStackTrace();
}
}
}
Spring API : Calling the PL/SQL package
Using Spring annotation to inject the service and call the remote service.Java Calling Class : BulkCollectionObjectsSpringApi.java
package plsql_workbench_examples.springapi;
import java.sql.Date;
import java.util.ArrayList;
import java.util.List;
import java.util.UUID;
import org.springframework.beans.factory.annotation.Autowired;
import org.springframework.context.support.GenericApplicationContext;
import org.springframework.stereotype.Component;
import plsql_workbench_examples.timer.TimerCounter;
import service.BulkCollectionObjectService;
import transferobject.BulkObject;
@Component
public class BulkCollectionObjectsSpringApi {
private final static int ELEMENTS = 50000;
@Autowired
private BulkCollectionObjectService bulkCollectionObjectService;
public static void main(String[] args)
{
// set database credentials and configuration parameters
System.setProperty("dbw_examples.url", "jdbc:oracle:thin:@192.168.0.109:1521/orcl");
System.setProperty("dbw_examples.username", "dbw_examples");
System.setProperty("dbw_examples.password", "dbw_examples");
// Register Spring Beans, Spring Context and call demo method
try (GenericApplicationContext ctx = BaseSpringConfig.getCtx(BulkCollectionObjectsSpringApi.class)) {
ctx.getBean(BulkCollectionObjectsSpringApi.class).runDemo();
}
}
private void runDemo()
{
try {
// generating 50000 elements to transfer to the stored procedure
List<BulkObject> objectList = new ArrayList<>(ELEMENTS);
for (int i = 0; i < ELEMENTS; i++) {
BulkObject o = new BulkObject();
o.setD(new Date(System.currentTimeMillis() + (long) (Math.random() * Integer.MAX_VALUE)));
o.setS(UUID.randomUUID().toString());
o.setN((int) (Math.random() * Integer.MAX_VALUE));
objectList.add(o);
}
// timer to check the throughput
TimerCounter tc = new TimerCounter();
// calling the stored procedure
bulkCollectionObjectService.call(objectList);
// print out throughput
System.out.println(tc.perSecond("objects bulk performance (first call)", ELEMENTS));
// calling the stored procedure
bulkCollectionObjectService.call(objectList);
// print out throughput
System.out.println(tc.perSecond("objects bulk performance (second call)", ELEMENTS));
}
catch (Exception e) {
e.printStackTrace();
}
}
}