Export (0) Print
Expand All

SqlBulkCopy Class

Lets you efficiently bulk load a SQL Server table with data from another source.

System.Object
  System.Data.SqlClient.SqlBulkCopy

Namespace:  System.Data.SqlClient
Assembly:  System.Data (in System.Data.dll)

public sealed class SqlBulkCopy : IDisposable

The SqlBulkCopy type exposes the following members.

  NameDescription
Public methodSqlBulkCopy(SqlConnection)Initializes a new instance of the SqlBulkCopy class using the specified open instance of SqlConnection.
Public methodSqlBulkCopy(String)Initializes and opens a new instance of SqlConnection based on the supplied connectionString. The constructor uses the SqlConnection to initialize a new instance of the SqlBulkCopy class.
Public methodSqlBulkCopy(String, SqlBulkCopyOptions)Initializes and opens a new instance of SqlConnection based on the supplied connectionString. The constructor uses that SqlConnection to initialize a new instance of the SqlBulkCopy class. The SqlConnection instance behaves according to options supplied in the copyOptions parameter.
Public methodSqlBulkCopy(SqlConnection, SqlBulkCopyOptions, SqlTransaction)Initializes a new instance of the SqlBulkCopy class using the supplied existing open instance of SqlConnection. The SqlBulkCopy instance behaves according to options supplied in the copyOptions parameter. If a non-null SqlTransaction is supplied, the copy operations will be performed within that transaction.
Top

  NameDescription
Public propertyBatchSizeNumber of rows in each batch. At the end of each batch, the rows in the batch are sent to the server.
Public propertyBulkCopyTimeoutNumber of seconds for the operation to complete before it times out.
Public propertyColumnMappingsReturns a collection of SqlBulkCopyColumnMapping items. Column mappings define the relationships between columns in the data source and columns in the destination.
Public propertyDestinationTableNameName of the destination table on the server.
Public propertyEnableStreamingEnables or disables a SqlBulkCopy object to stream data from an IDataReader object
Public propertyNotifyAfterDefines the number of rows to be processed before generating a notification event.
Top

  NameDescription
Public methodCloseCloses the SqlBulkCopy instance.
Public methodEquals(Object)Determines whether the specified object is equal to the current object. (Inherited from Object.)
Public methodGetHashCodeServes as the default hash function. (Inherited from Object.)
Public methodGetTypeGets the Type of the current instance. (Inherited from Object.)
Public methodToStringReturns a string that represents the current object. (Inherited from Object.)
Public methodWriteToServer(DataRow[])Copies all rows from the supplied DataRow array to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.
Public methodWriteToServer(DataTable)Copies all rows in the supplied DataTable to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.
Public methodWriteToServer(IDataReader)Copies all rows in the supplied IDataReader to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.
Public methodWriteToServer(DataTable, DataRowState)Copies only rows that match the supplied row state in the supplied DataTable to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.
Public methodWriteToServerAsync(DataRow[])The asynchronous version of WriteToServer, which copies all rows from the supplied DataRow array to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.
Public methodWriteToServerAsync(DataTable)The asynchronous version of WriteToServer, which copies all rows in the supplied DataTable to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.
Public methodWriteToServerAsync(IDataReader)The asynchronous version of WriteToServer, which copies all rows in the supplied IDataReader to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.
Public methodWriteToServerAsync(DataRow[], CancellationToken)The asynchronous version of WriteToServer, which copies all rows from the supplied DataRow array to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.The cancellation token can be used to request that the operation be abandoned before the command timeout elapses. Exceptions will be reported via the returned Task object.
Public methodWriteToServerAsync(DataTable, DataRowState)The asynchronous version of WriteToServer, which copies only rows that match the supplied row state in the supplied DataTable to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.
Public methodWriteToServerAsync(DataTable, CancellationToken)The asynchronous version of WriteToServer, which copies all rows in the supplied DataTable to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.The cancellation token can be used to request that the operation be abandoned before the command timeout elapses. Exceptions will be reported via the returned Task object.
Public methodWriteToServerAsync(IDataReader, CancellationToken)The asynchronous version of WriteToServer, which copies all rows in the supplied IDataReader to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.The cancellation token can be used to request that the operation be abandoned before the command timeout elapses. Exceptions will be reported via the returned Task object.
Public methodWriteToServerAsync(DataTable, DataRowState, CancellationToken)The asynchronous version of WriteToServer, which copies only rows that match the supplied row state in the supplied DataTable to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.The cancellation token can be used to request that the operation be abandoned before the command timeout elapses. Exceptions will be reported via the returned Task object.
Top

  NameDescription
Public eventSqlRowsCopiedOccurs every time that the number of rows specified by the NotifyAfter property have been processed.
Top

  NameDescription
Explicit interface implemetationPrivate methodIDisposable.DisposeReleases all resources used by the current instance of the SqlBulkCopy class.
Top

Microsoft SQL Server includes a popular command-prompt utility named bcp for moving data from one table to another, whether on a single server or between servers. The SqlBulkCopy class lets you write managed code solutions that provide similar functionality. There are other ways to load data into a SQL Server table (INSERT statements, for example), but SqlBulkCopy offers a significant performance advantage over them.

The SqlBulkCopy class can be used to write data only to SQL Server tables. However, the data source is not limited to SQL Server; any data source can be used, as long as the data can be loaded to a DataTable instance or read with a IDataReader instance.

SqlBulkCopy will fail when bulk loading a DataTable column of type SqlDateTime into a SQL Server column whose type is one of the date/time types added in SQL Server 2008.

The following console application demonstrates how to load data using the SqlBulkCopy class. In this example, a SqlDataReader is used to copy data from the Production.Product table in the SQL Server AdventureWorks database to a similar table in the same database.

Important noteImportant

This sample will not run unless you have created the work tables as described in Bulk Copy Example Setup. This code is provided to demonstrate the syntax for using SqlBulkCopy only. If the source and destination tables are in the same SQL Server instance, it is easier and faster to use a Transact-SQL INSERT … SELECT statement to copy the data.

using System.Data.SqlClient;

class Program
{
    static void Main()
    {
        string connectionString = GetConnectionString();
        // Open a sourceConnection to the AdventureWorks database. 
        using (SqlConnection sourceConnection =
                   new SqlConnection(connectionString))
        {
            sourceConnection.Open();

            // Perform an initial count on the destination table.
            SqlCommand commandRowCount = new SqlCommand(
                "SELECT COUNT(*) FROM " +
                "dbo.BulkCopyDemoMatchingColumns;",
                sourceConnection);
            long countStart = System.Convert.ToInt32(
                commandRowCount.ExecuteScalar());
            Console.WriteLine("Starting row count = {0}", countStart);

            // Get data from the source table as a SqlDataReader.
            SqlCommand commandSourceData = new SqlCommand(
                "SELECT ProductID, Name, " +
                "ProductNumber " +
                "FROM Production.Product;", sourceConnection);
            SqlDataReader reader =
                commandSourceData.ExecuteReader();

            // Open the destination connection. In the real world you would  
            // not use SqlBulkCopy to move data from one table to the other  
            // in the same database. This is for demonstration purposes only. 
            using (SqlConnection destinationConnection =
                       new SqlConnection(connectionString))
            {
                destinationConnection.Open();

                // Set up the bulk copy object.  
                // Note that the column positions in the source 
                // data reader match the column positions in  
                // the destination table so there is no need to 
                // map columns. 
                using (SqlBulkCopy bulkCopy =
                           new SqlBulkCopy(destinationConnection))
                {
                    bulkCopy.DestinationTableName =
                        "dbo.BulkCopyDemoMatchingColumns";

                    try
                    {
                        // Write from the source to the destination.
                        bulkCopy.WriteToServer(reader);
                    }
                    catch (Exception ex)
                    {
                        Console.WriteLine(ex.Message);
                    }
                    finally
                    {
                        // Close the SqlDataReader. The SqlBulkCopy 
                        // object is automatically closed at the end 
                        // of the using block.
                        reader.Close();
                    }
                }

                // Perform a final count on the destination  
                // table to see how many rows were added. 
                long countEnd = System.Convert.ToInt32(
                    commandRowCount.ExecuteScalar());
                Console.WriteLine("Ending row count = {0}", countEnd);
                Console.WriteLine("{0} rows were added.", countEnd - countStart);
                Console.WriteLine("Press Enter to finish.");
                Console.ReadLine();
            }
        }
    }

    private static string GetConnectionString()
        // To avoid storing the sourceConnection string in your code,  
        // you can retrieve it from a configuration file. 
    {
        return "Data Source=(local); " +
            " Integrated Security=true;" +
            "Initial Catalog=AdventureWorks;";
    }
}

.NET Framework

Supported in: 4.5.2, 4.5.1, 4.5, 4, 3.5, 3.0, 2.0

.NET Framework Client Profile

Supported in: 4, 3.5 SP1

Windows 8.1, Windows Server 2012 R2, Windows 8, Windows Server 2012, Windows 7, Windows Vista SP2, Windows Server 2008 (Server Core Role not supported), Windows Server 2008 R2 (Server Core Role supported with SP1 or later; Itanium not supported)

The .NET Framework does not support all versions of every platform. For a list of the supported versions, see .NET Framework System Requirements.

Any public static (Shared in Visual Basic) members of this type are thread safe. Any instance members are not guaranteed to be thread safe.
Was this page helpful?
(1500 characters remaining)
Thank you for your feedback
Show:
© 2014 Microsoft