FIX: DMO BulkCopy Fails to Copy Data When Column Names Contain the Space Character

This article was previously published under Q299865
This article has been archived. It is offered "as is" and will no longer be updated.
BUG #: 351486 (SHILOH_BUGS)
SYMPTOMS
Using the SQL Distributed Management Objects (DMO) BulkCopy object to import data into a SQL Server table that contains a column with a space embedded in the column name may fail with no rows copied.
CAUSE
By default, the BulkCopy object uses a second connection which does not inherit properties, such as QuotedIdentifiers, from the original connection.
RESOLUTION
To resolve this problem, obtain the latest service pack for SQL Server 2000. For additional information, click the following article number to view the article in theMicrosoft Knowledge Base:
290211 INF: How to Obtain the Latest SQL Server 2000 Service Pack
WORKAROUND
You can work around this problem in the following ways:
  • Make sure that the SQL-DMO BulkCopy object reuses the existing connection by setting the UseExistingConnection property to True.
  • Remove the embedded space in the column name.
STATUS
Microsoft has confirmed that this is a problem in SQL Server 2000. This problem was first corrected in SQL Server 2000 Service Pack 1.
MORE INFORMATION

Steps to Reproduce Behavior

  1. Create the source and destination SQL Server tables in the sample Northwind database:
    create table BulkCopyFrom ( c1 int)gocreate table BulkCopyTo ( [c1 copy] int )goinsert BulkCopyFrom values (1)					
  2. Use the following Microsoft Visual Basic/SQL-DMO code to demonstrate the problem:
    Public Sub Main()On Error GoTo ErrHandlerDim server As New SQLDMO.SQLServerDim blk As New SQLDMO.BulkCopyDim db As SQLDMO.DatabaseDim tblSrc As SQLDMO.TableDim tblDst As SQLDMO.TableDim lRowsExported As LongDim lRowsImported As Longserver.LoginSecure = Trueserver.EnableBcp   = Trueserver.Connect "."                   'Uses the default SQL Server instanceserver.QuotedIdentifier = TrueSet db = server.Databases("northwind")Set tblSrc = db.Tables("BulkCopyFrom")Set tblDst = db.Tables("BulkCopyTo")'blk.UseExistingConnection = True    'Uncomment this line to reuse connectionblk.DataFilePath  = "C:\TEMP\exported.dat"blk.ErrorFilePath = "C:\TEMP\exported.err"blk.LogFilePath   = "C:\TEMP\exported.log"blk.DataFileType          = SQLDMODataFile_NativeFormatblk.UseBulkCopyOption     = Trueblk.IncludeIdentityValues = Trueblk.SetCodePage SQLDMOBCP_RAWlRowsExported = tblSrc.ExportData(blk)MsgBox "Exported " & lRowsExported & " rows"blk.ErrorFilePath = "C:\TEMP\imported.err"blk.LogFilePath   = "C:\TEMP\imported.log"lRowsImported     = tblDst.ImportData(blk)MsgBox "Imported " & lRowsImported & " rows"server.DisConnectSet blk = NothingSet server = NothingExit SubErrHandler:MsgBox "Error " & Err.Number & vbclr & Err.DescriptionResume NextEnd Sub					
    This code results in 0 rows imported into the destination table BulkCopyTo.

    To work around the problem, uncomment the code line to reuse the existing connection.
Properties

Article ID: 299865 - Last Review: 01/16/2015 22:46:45 - Revision: 3.2

  • Microsoft SQL Server 2000 Standard Edition
  • kbnosurvey kbarchive kbbug kbfix kbsqlserv2000sp1fix KB299865
Feedback