The identity column of the destination table does not contain the same identity values as the source table after you use SQL Server Management Studio to import data or to export data in Microsoft SQL Server 2005

Article translations Article translations
Article ID: 952111 - View products that this article applies to.
Expand all | Collapse all

SYMPTOMS

Consider the following scenario:
  • In Microsoft SQL Server 2005, you use SQL Server Management Studio to import data or to export data from a source table to a destination table.
  • Both the source table and the destination table include an identity column.
  • You enable the Enable identity insert option for the source table.
  • In the SQL Server Import and Export Wizard, you enable the Optimize for many tables option.
In this scenario, after you finish importing or exporting the data, you find that the identity column of the destination table does not contain the same identity values as the source table. Instead, the identity column of the destination table contains resequenced identity values.

Note This problem does not occur in Microsoft SQL Server 2000.

CAUSE

This problem occurs because the SQL Server Import and Export Wizard does not set the IDENTITY_INSERT property for the table if the Optimize for many tables option is enabled. The IDENTITY_INSERT property can be set for only one table at a time. If you enable the Optimize for many tables option in the wizard, the copy operation is performed for several tables on several threads at the same time. Therefore, the SQL Server Import and Export Wizard does not set the IDENTITY_INSERT property.

RESOLUTION

To resolve this problem, do not enable the Optimize for many tables option in the SQL Server Import and Export Wizard.

If you do not enable the Optimize for many tables option, the data operation may take a longer time to finish. If you want to preserve the identity values when you import or export a large amount of data, we recommend that you use one of the following methods:
  • Use the bcp utility together with the –E switch to transfer the table.

    For example, first run a command that resembles the following command to export data from the source table to a .txt file:
    Bcp.exe SourceTable out C:\FileName.txt -S. -T -c –E
    Then, run a command that resembles the following command to import data to the destination table:
    Bcp.exe DestinationTable in C:\FileName.txt -S. -T -c -E
  • Detach the database, and then attach the database to the destination server.

MORE INFORMATION

If you enable the Enable identity insert option for the source table, the SQL Server Import and Export Wizard should execute the SET IDENTITY_INSERT ON statement for each table that contains an identity column. Then, after the identity values are inserted to the destination table, the SQL Server Import and Export Wizard should execute the SET IDENTITY_INSERT OFF statement. However, these operations do not occur correctly if the Optimize for many tables option is enabled.

STATUS

Microsoft has confirmed that this is a problem in the Microsoft products that are listed in the "Applies to" section.

Properties

Article ID: 952111 - Last Review: May 5, 2008 - Revision: 1.1
APPLIES TO
  • Microsoft SQL Server 2005 Standard Edition
  • Microsoft SQL Server 2005 Developer Edition
  • Microsoft SQL Server 2005 Enterprise Edition
  • Microsoft SQL Server 2005 Standard X64 Edition
  • Microsoft SQL Server 2005 Enterprise X64 Edition
  • Microsoft SQL Server 2005 Standard Edition for Itanium-based Systems
  • Microsoft SQL Server 2005 Enterprise Edition for Itanium-based Systems
Keywords: 
kbtshoot kbexpertiseadvanced kbsql2005tool kbprb KB952111

Give Feedback

 

Contact us for more help

Contact us for more help
Connect with Answer Desk for expert help.
Get more support from smallbusiness.support.microsoft.com