Bulk Data Insertion into Oracle Database in C#



Introduction

Bulk insertion of data into database table is a big overhead in application development. An approach would be to insert the records into the table using a loop in the application, this round trip approach consumes network and CPU resources and as such is not recommended. Microsoft ADO.Net provides the SqlBulkCopy class that lets you efficiently bulk load a SQL Server table with data from another source, but bulk loading an Oracle table can be done through the use of Oracle Data Provider for .Net (ODP.Net).

Bulk Insertion with ODP.Net

ODP.Net has an array binding feature in which the records to be inserted are put in arrays and the arrays are passed to the ODP.Net OracleCommand class for insertion into the database table.This blog post would use a simple application that insert multiple customer records into a Customer table in an Oracle database. The source code is below.

// A customer DTO 
public class CustomerDTO
 {	 
	public string Surname{get;set;}
	public string FirstName{get;set;}
	public string EmailAddress{get;set;} 	
 }
  


The OracleDbConnector class that serves as wrapper around ODP.net to perform bulk insertion of data.

public class OracleDbConnector
 {
		private OracleConnection oracleConnection;
		private OracleConnectionStringBuilder stringBuilder;

		public OracleDbConnector(string dbUsername, string dbPassword, string dbServer)
		{
			stringBuilder = new OracleConnectionStringBuilder();
			stringBuilder.DataSource = dbServer;
			stringBuilder.UserID = dbUsername;
			stringBuilder.Password = dbPassword;
			oracleConnection = new OracleConnection();
			oracleConnection.ConnectionString = stringBuilder.ConnectionString;
		}
		
		public bool UploadBulkData(List<CustomerDTO> bulkData)
		{
			bool returnValue = false;
			try
			{

				string query = @"insert into PCMS.Customer ( surname, firstName, emailAddress) values 
								(:surname, :firstName, :emailAddress)";
				oracleConnection.Open();
				using (var command = oracleConnection.CreateCommand())
				{
					command.CommandText = query;
					command.CommandType = CommandType.Text;
					command.BindByName = true;
				  // In order to use ArrayBinding, the ArrayBindCount property
				  // of OracleCommand object must be set to the number of records to be inserted
					command.ArrayBindCount = bulkData.Count;
					command.Parameters.Add(":surname", OracleDbType.Varchar2, bulkData.Select(c => c.Surname).ToArray(), ParameterDirection.Input);
					command.Parameters.Add(":firstName", OracleDbType.Varchar2, bulkData.Select(c => c.FirstName).ToArray(), ParameterDirection.Input);
					command.Parameters.Add(":emailAddress", OracleDbType.Varchar2, bulkData.Select(c => c.EmailAddress).ToArray(), ParameterDirection.Input);
					int result = command.ExecuteNonQuery();
					if (result == bulkData.Count)
						returnValue = true;
				}

			}
			catch (OracleException ex)
			{
				//Log error thrown
			}
			finally
			{
				oracleConnection.Close();
			}
			return returnValue;
		}
 }
  


An NUnit test case for the OracleDbConnector class.

using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Threading.Tasks;
using NUnit.Framework;

	[TestFixture]
	public class OracleDbConnectorTest
	{
		private OracleConnector oracleConnector;
		[TestFixtureSetUp]
		public void SetUpTest()
		{
			oracleConnector = new OracleConnector("UserId", "Password", "serverAddress");
		}

		[Test]
		public void TestUploadBulkData()
		{
			List<CustomerDTO> bulkData= new List<CustomerDTO>();
			bulkData.Add(new CustomerDTO("Ayobami","Adewole","[email protected]"));
			bulkData.Add(new CustomerDTO("John","Peter","[email protected]"));
			bulkData.Add(new CustomerDTO("Tunji","James","[email protected]"));
			Assert.IsTrue(oracleConnector.UploadBulkData(bulkData));
		}

		[TestFixtureTearDown]
		public void TearDownTest()
		{
			oracleConnector = null;
		}
	}
}
  




Share this page on


  9 People Like(s) This Page   Permalink  

 Click  To Like This Page

comments powered by Disqus

page