Writing BLOB Values to a Database

You can write a binary large object (BLOB) to a database as either binary or character data, depending on the type of field at your data source. To write a BLOB value to your database, issue the appropriate INSERT or UPDATE statement and pass the BLOB value as an input parameter (see Using Stored Procedures with a Command). If your BLOB is stored as text, such as a SQL Server text field, you can pass the BLOB as a string parameter. If the BLOB is stored in binary format, such as a SQL Server image field, you can pass an array of type byte as a binary parameter.

Note   A BLOB may be quite large and thus may consume extensive system memory when written as a single value, resulting in decreased application performance. To reduce the amount of memory used when writing a BLOB value, you can write the BLOB to the database in "chunks". The process of writing a BLOB to a database in this way depends on the capabilities of your data source. For an example of writing a BLOB value to SQL Server in "chunks", see Conserving Resources When Writing BLOB Values to SQL Server.

The following code example adds employee information to the Employees table in the Northwind database. A photo of the employee is read from a file and added to the Photo field in the table, which is an image field.

Imports System
Imports System.Data
Imports System.Data.SqlClient
Imports System.IO

Public Class EmployeeData

  Public Shared Sub Main()
    Dim hireDate As DateTime = DateTime.Parse("5/21/99")
    AddEmployee("Jones", "Mary", "Sales Representative", hireDate, 5, "jones.bmp")
  End Sub

  Public Shared Sub AddEmployee(lastName As String, firstName As String, title As String, hireDate As DateTime, _
                                reportsTo As Integer, photoFilePath As String)

    Dim photo() as Byte = GetPhoto(photoFilePath)

    Dim nwindConn As SqlConnection = New SqlConnection("Data Source=localhost;Integrated Security=SSPI;Initial Catalog=Northwind;")

    Dim addEmp As SqlCommand = New SqlCommand("INSERT INTO Employees (LastName, FirstName, Title, HireDate, ReportsTo, Photo) " & _
                                              "Values(@LastName, @FirstName, @Title, @HireDate, @ReportsTo, @Photo)", nwindConn) 

    addEmp.Parameters.Add("@LastName",  SqlDbType.NVarChar, 20).Value = lastName
    addEmp.Parameters.Add("@FirstName", SqlDbType.NVarChar, 10).Value = firstName
    addEmp.Parameters.Add("@Title",     SqlDbType.NVarChar, 30).Value = title
    addEmp.Parameters.Add("@HireDate",  SqlDbType.DateTime).Value     = hireDate
    addEmp.Parameters.Add("@ReportsTo", SqlDbType.Int).Value          = reportsTo

    addEmp.Parameters.Add("@Photo",     SqlDbType.Image, photo.Length).Value = photo

    nwindConn.Open()

    addEmp.ExecuteNonQuery()

    nwindConn.Close()
  End Sub

  Public Shared Function GetPhoto(filePath As String) As Byte()
    Dim fs As FileStream = new FileStream(filePath, FileMode.Open, FileAccess.Read)
    Dim br As BinaryReader = new BinaryReader(fs)

    Dim photo() As Byte = br.ReadBytes(fs.Length)

    br.Close()
    fs.Close()

    Return photo
  End Function
End Class
[C#]
using System;
using System.Data;
using System.Data.SqlClient;
using System.IO;

public class EmployeeData
{
  public static void Main()
  {
    DateTime hireDate = DateTime.Parse("5/21/99");
    AddEmployee("Jones", "Mary", "Sales Representative", hireDate, 5, "jones.bmp");
  }

  public static void AddEmployee(string lastName, string firstName, string title, DateTime hireDate , int reportsTo, string photoFilePath)
  {
    byte[] photo = GetPhoto(photoFilePath);

    SqlConnection nwindConn = new SqlConnection("Data Source=localhost;Integrated Security=SSPI;Initial Catalog=Northwind;");

    SqlCommand addEmp = new SqlCommand("INSERT INTO Employees (LastName, FirstName, Title, HireDate, ReportsTo, Photo) " +
                                       "Values(@LastName, @FirstName, @Title, @HireDate, @ReportsTo, @Photo)", nwindConn); 

    addEmp.Parameters.Add("@LastName",  SqlDbType.NVarChar, 20).Value = lastName;
    addEmp.Parameters.Add("@FirstName", SqlDbType.NVarChar, 10).Value = firstName;
    addEmp.Parameters.Add("@Title",     SqlDbType.NVarChar, 30).Value = title;
    addEmp.Parameters.Add("@HireDate",  SqlDbType.DateTime).Value     = hireDate;
    addEmp.Parameters.Add("@ReportsTo", SqlDbType.Int).Value          = reportsTo;

    addEmp.Parameters.Add("@Photo",     SqlDbType.Image, photo.Length).Value = photo;

    nwindConn.Open();

    addEmp.ExecuteNonQuery();

    nwindConn.Close();
  }

  public static byte[] GetPhoto(string filePath)
  {
    FileStream fs = new FileStream(filePath, FileMode.Open, FileAccess.Read);
    BinaryReader br = new BinaryReader(fs);

    byte[] photo = br.ReadBytes((int)fs.Length);

    br.Close();
    fs.Close();

    return photo;
  }
}

See Also

Using .NET Framework Data Providers to Access Data | Obtaining BLOB Values from a Database | OleDbCommand Class | OdbcCommand Class | SqlCommand Class