大容量复制操作的顺序提示

适用于 .NET Framework .NET .NET Standard

下载 ADO.NET

大容量复制操作与其他用于将数据加载到 SQL Server 表中的方法相比,具有显著的性能优势。 使用顺序提示可以进一步增强性能。 为大容量复制操作指定顺序提示可以降低将排序数据插入具有聚集索引的表中的时间。

默认情况下,大容量插入操作假设传入数据未排序。 SQL Server 在大容量加载之前强制执行此数据的中间排序。 如果你知道传入数据已排序,则可以使用顺序提示来告诉大容量复制操作有关聚集索引中的任何目标列的排序顺序。

向大容量复制操作添加顺序提示

以下示例将数据从“AdventureWorks”示例数据库中的源表大容量复制到同一个数据库中的目标表。 SqlBulkCopyColumnOrderHint 对象会被创建,用于定义目标表中“ProductNumber”列的排序顺序。 然后,顺序提示会被添加到 SqlBulkCopy 实例,此操作会将相应的顺序提示参数追加到生成的 INSERT BULK 查询。

using System;
using System.Data;
using Microsoft.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();

            // Set up the bulk copy object.
            using (SqlBulkCopy bulkCopy =
                       new SqlBulkCopy(connectionString))
            {
                bulkCopy.DestinationTableName =
                    "dbo.BulkCopyDemoMatchingColumns";

                // Setup an order hint for the ProductNumber column.
                SqlBulkCopyColumnOrderHint hintNumber =
                    new SqlBulkCopyColumnOrderHint("ProductNumber", SortOrder.Ascending);
                bulkCopy.ColumnOrderHints.Add(hintNumber);

                // Write from the source to the destination.
                try
                {
                    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;";
    }
}

后续步骤