Bewerken

Delen via


SqlBulkCopy Class

Definition

Caution

Use the Microsoft.Data.SqlClient package instead.

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

public ref class SqlBulkCopy sealed : IDisposable
public sealed class SqlBulkCopy : IDisposable
[System.Obsolete("Use the Microsoft.Data.SqlClient package instead.")]
public sealed class SqlBulkCopy : IDisposable
type SqlBulkCopy = class
    interface IDisposable
[<System.Obsolete("Use the Microsoft.Data.SqlClient package instead.")>]
type SqlBulkCopy = class
    interface IDisposable
Public NotInheritable Class SqlBulkCopy
Implements IDisposable
Inheritance
SqlBulkCopy
Attributes
Implements

Examples

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

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;";
    }
}
Imports System.Data.SqlClient

Module Module1
    Sub Main()
        Dim connectionString As String = GetConnectionString()

        ' Open a connection to the AdventureWorks database.
        Using sourceConnection As SqlConnection = _
           New SqlConnection(connectionString)
            sourceConnection.Open()

            ' Perform an initial count on the destination table.
            Dim commandRowCount As New SqlCommand( _
            "SELECT COUNT(*) FROM dbo.BulkCopyDemoMatchingColumns;", _
                sourceConnection)
            Dim countStart As Long = _
               System.Convert.ToInt32(commandRowCount.ExecuteScalar())
            Console.WriteLine("Starting row count = {0}", countStart)

            ' Get data from the source table as a SqlDataReader.
            Dim commandSourceData As New SqlCommand( _
               "SELECT ProductID, Name, ProductNumber " & _
               "FROM Production.Product;", sourceConnection)
            Dim reader As SqlDataReader = 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 destinationConnection As SqlConnection = _
                New SqlConnection(connectionString)
                destinationConnection.Open()

                ' Set up the bulk copy object. 
                ' 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 bulkCopy As SqlBulkCopy = _
                  New SqlBulkCopy(destinationConnection)
                    bulkCopy.DestinationTableName = _
                    "dbo.BulkCopyDemoMatchingColumns"

                    Try
                        ' Write from the source to the destination.
                        bulkCopy.WriteToServer(reader)

                    Catch ex As Exception
                        Console.WriteLine(ex.Message)

                    Finally
                        ' Close the SqlDataReader. The SqlBulkCopy
                        ' object is automatically closed at the end
                        ' of the Using block.
                        reader.Close()
                    End Try
                End Using

                ' Perform a final count on the destination table
                ' to see how many rows were added.
                Dim countEnd As Long = _
                    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()
            End Using
        End Using
    End Sub

    Private Function GetConnectionString() As String
        ' 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;"
    End Function
End Module

Remarks

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.

Constructors

SqlBulkCopy(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.

SqlBulkCopy(SqlConnection)

Initializes a new instance of the SqlBulkCopy class using the specified open instance of SqlConnection.

SqlBulkCopy(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.

SqlBulkCopy(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.

Properties

BatchSize

Number of rows in each batch. At the end of each batch, the rows in the batch are sent to the server.

BulkCopyTimeout

Number of seconds for the operation to complete before it times out.

ColumnMappings

Returns a collection of SqlBulkCopyColumnMapping items. Column mappings define the relationships between columns in the data source and columns in the destination.

DestinationTableName

Name of the destination table on the server.

EnableStreaming

Enables or disables a SqlBulkCopy object to stream data from an IDataReader object.

NotifyAfter

Defines the number of rows to be processed before generating a notification event.

Methods

Close()

Closes the SqlBulkCopy instance.

Equals(Object)

Determines whether the specified object is equal to the current object.

(Inherited from Object)
GetHashCode()

Serves as the default hash function.

(Inherited from Object)
GetType()

Gets the Type of the current instance.

(Inherited from Object)
MemberwiseClone()

Creates a shallow copy of the current Object.

(Inherited from Object)
ToString()

Returns a string that represents the current object.

(Inherited from Object)
WriteToServer(DataRow[])

Copies all rows from the supplied DataRow array to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.

WriteToServer(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.

WriteToServer(DataTable)

Copies all rows in the supplied DataTable to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.

WriteToServer(DbDataReader)

Copies all rows from the supplied DbDataReader array to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.

WriteToServer(IDataReader)

Copies all rows in the supplied IDataReader to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.

WriteToServerAsync(DataRow[], CancellationToken)

The asynchronous version of WriteToServer(DataRow[]), 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.

WriteToServerAsync(DataRow[])

The asynchronous version of WriteToServer(DataRow[]), which copies all rows from the supplied DataRow array to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.

WriteToServerAsync(DataTable, CancellationToken)

The asynchronous version of WriteToServer(DataTable), 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.

WriteToServerAsync(DataTable, DataRowState, CancellationToken)

The asynchronous version of WriteToServer(DataTable, DataRowState), 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.

WriteToServerAsync(DataTable, DataRowState)

The asynchronous version of WriteToServer(DataTable, DataRowState), 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.

WriteToServerAsync(DataTable)

The asynchronous version of WriteToServer(DataTable), which copies all rows in the supplied DataTable to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.

WriteToServerAsync(DbDataReader, CancellationToken)

The asynchronous version of WriteToServer(DbDataReader), which copies all rows from the supplied DbDataReader array to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.

WriteToServerAsync(DbDataReader)

The asynchronous version of WriteToServer(DbDataReader), which copies all rows from the supplied DbDataReader array to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.

WriteToServerAsync(IDataReader, CancellationToken)

The asynchronous version of WriteToServer(IDataReader), 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.

WriteToServerAsync(IDataReader)

The asynchronous version of WriteToServer(IDataReader), which copies all rows in the supplied IDataReader to a destination table specified by the DestinationTableName property of the SqlBulkCopy object.

Events

SqlRowsCopied

Occurs every time that the number of rows specified by the NotifyAfter property have been processed.

Explicit Interface Implementations

IDisposable.Dispose()

Releases all resources used by the current instance of the SqlBulkCopy class.

Applies to

See also