单次批量复制操作 (ADO.NET)
执行 SQL Server 批量复制操作最简单的方法就是对数据库执行单次操作。 默认情况下,批量复制操作是作为一个独立的操作执行的:该复制操作以非事务处理方式进行,不可进行回滚。
注意 |
---|
如果需要在出错时回滚批量复制的全部或部分,可以使用 SqlBulkCopy 管理的事务,或在现有事务中执行批量复制操作。如果连接在 System.Transactions 事务中(显式或隐式)登记,SqlBulkCopy 也将适用于 System.Transactions。 有关更多信息,请参见事务和批量复制操作 (ADO.NET)。 |
执行批量复制操作的一般步骤如下所示:
连接到源服务器上并获取要复制的数据。 如果可以从 IDataReader 或 DataTable 对象检索数据,则这些数据还可能来自其他源。
连接到目标服务器(除非您希望 SqlBulkCopy 为您建立连接)。
创建一个 SqlBulkCopy 对象,设置任何必要的属性。
设置 DestinationTableName 属性以指示执行批量插入操作的目标表。
调用一个 WriteToServer 方法。
可以选择更新属性并根据需要再次调用 WriteToServer。
调用 Close,或将批量复制操作包装在 Using 语句中。
警告 |
---|
我们建议源列和目标列的数据类型匹配。如果数据类型不匹配,则 SqlBulkCopy 会尝试使用由 Value 部署的规则将每个源值转换为目标数据类型。转换可能会影响性能,还可能会导致意外的错误。例如,大多数情况下,Double 数据类型可以转换为 Decimal 数据类型,但是有时就不能。 |
示例
以下控制台应用程序演示如何使用 SqlBulkCopy 类加载数据。 在此示例中,SqlDataReader 用于将数据从 SQL Server 2005 AdventureWorks 数据库的 Production.Product 表复制到相同数据库的一个类似的表中。
重要事项 |
---|
除非如批量复制示例设置 (ADO.NET)中所述创建了工作表,否则此示例将不会运行。提供此代码是为了演示仅使用 SqlBulkCopy 时的语法。如果源表和目标表位于同一 SQL Server 实例中,则使用 Transact-SQL INSERT … SELECT 语句复制数据会更加轻松便捷。 |
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 SqlCommand = 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
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;";
}
}
使用 Transact-SQL 和命令类执行批量复制操作
如果使用 .NET Framework 1.1 或早期版本(不支持 SqlBulkCopy 类),则还可以使用 SqlCommand 对象执行 Transact-SQL BULK INSERT 语句。 注意,使用此方法与使用 SQL Server .NET Framework 数据提供程序提供的批量复制功能完全无关。
以下示例说明如何使用 ExecuteNonQuery 方法执行 BULK INSERT 语句。
注意 |
---|
数据源的文件路径相对于服务器。要成功执行批量复制操作,服务器进程必须具有对该路径的访问权限。 |
Using connection As SqlConnection = New SqlConnection(connectionString)
Dim queryString As String = _
"BULK INSERT Northwind.dbo.[Order Details] FROM " & _
"'f:\mydata\data.tbl' WITH (FORMATFILE='f:\mydata\data.fmt' )"
connection.Open()
SqlCommand command = New SqlCommand(queryString, connection);
command.ExecuteNonQuery()
End Using
using (SqlConnection connection = New SqlConnection(connectionString))
{
string queryString = "BULK INSERT Northwind.dbo.[Order Details] " +
"FROM 'f:\mydata\data.tbl' " +
"WITH ( FORMATFILE='f:\mydata\data.fmt' )";
connection.Open();
SqlCommand command = new SqlCommand(queryString, connection);
command.ExecuteNonQuery();
}