SqlBulkCopyOptions Enum
Definition
Important
Some information relates to prerelease product that may be substantially modified before it’s released. Microsoft makes no warranties, express or implied, with respect to the information provided here.
Bitwise flag that specifies one or more options to use with an instance of SqlBulkCopy.
This enumeration supports a bitwise combination of its member values.
public enum class SqlBulkCopyOptions
[System.Flags]
public enum SqlBulkCopyOptions
[<System.Flags>]
type SqlBulkCopyOptions =
Public Enum SqlBulkCopyOptions
- Inheritance
-
SqlBulkCopyOptions
- Attributes
Fields
Name | Value | Description |
---|---|---|
Default | 0 | Use the default values for all options. |
KeepIdentity | 1 | Preserve source identity values. When not specified, identity values are assigned by the destination. |
CheckConstraints | 2 | Check constraints while data is being inserted. By default, constraints are not checked. |
TableLock | 4 | Obtain a bulk update lock for the duration of the bulk copy operation. When not specified, row locks are used. |
KeepNulls | 8 | Preserve null values in the destination table regardless of the settings for default values. When not specified, null values are replaced by default values where applicable. |
FireTriggers | 16 | When specified, cause the server to fire the insert triggers for the rows being inserted into the database. |
UseInternalTransaction | 32 | When specified, each batch of the bulk-copy operation will occur within a transaction. If you indicate this option and also provide a SqlTransaction object to the constructor, an ArgumentException occurs. |
AllowEncryptedValueModifications | 64 | When specified, AllowEncryptedValueModifications enables bulk copying of encrypted data between tables or databases, without decrypting the data. Typically, an application would select data from encrypted columns from one table without decrypting the data (the app would connect to the database with the column encryption setting keyword set to disabled) and then would use this option to bulk insert the data, which is still encrypted. Use caution when specifying AllowEncryptedValueModifications as this may lead to corrupting the database because the driver does not check if the data is indeed encrypted, or if it is correctly encrypted using the same encryption type, algorithm and key as the target column. |
Examples
The following console application demonstrates how to perform a bulk load that copies the value in the identity column of the source table to the corresponding column in the destination table, instead of generating a new value for each row's identity column.
To see how the option changes the way the bulk load works, run the sample with the dbo.BulkCopyDemoMatchingColumns table empty. All rows load from the source. Next, run the sample again without emptying the table. An exception is thrown, and the code writes a message to the console window notifying you that rows were not added because of primary key violations.
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;
using System.Data;
// <Snippet1>
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();
// Create the SqlBulkCopy object using a connection string
// and the KeepIdentity option.
// In the real world you would not use SqlBulkCopy to move
// data from one table to the other in the same database.
using (SqlBulkCopy bulkCopy =
new SqlBulkCopy(connectionString, SqlBulkCopyOptions.KeepIdentity))
{
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;";
}
}
// </Snippet1>
Remarks
You can use the SqlBulkCopyOptions enumeration when you construct a SqlBulkCopy instance to change how the WriteToServer methods for that instance behave.