FIX: Rows are unexpectedly deleted when you run a distributed query to delete or to update a linked server table

This article has been archived. It is offered "as is" and will no longer be updated.
Bug #: 469673 (SQL Server 8.0)
SYMPTOMS
When you run a distributed query that uses a four-part name to delete or to update rows on a linked server table in a Microsoft SQL Server 2000 database, the rows in the linked server table that do not satisfy the join condition are also deleted. This problem may occur if the DELETE Transact-SQL statement or the UPDATE Transact-SQL statement in the distributed query involves a join and uses non-ANSI syntax. This problem may not occur if you run a distributed query that uses the same instance of SQL Server as the linked server in the distributed query.
RESOLUTION

Service pack information

To resolve this problem, obtain the latest service pack for Microsoft SQL Server 2000. For additional information, click the following article number to view the article in the Microsoft Knowledge Base:
290211 How to obtain the latest SQL Server 2000 service pack

Hotfix information

The English version of this hotfix has the file attributes (or later file attributes) that are listed in the following table. The dates and times for these files are listed in Coordinated Universal Time (UTC). When you view the file information, it is converted to local time. To find the difference between UTC and local time, use the Time Zone tab in the Date and Time tool in Control Panel.
   Date         Time   Version            Size    File name   ---------------------------------------------------------------------   31-May-2003  06:15  2000.80.818.0      78,400  Console.exe         24-Jun-2003  12:31  2000.80.818.0      33,340  Dbmslpcn.dll        24-Apr-2003  13:42                    786,432  Distmdl.ldf   24-Apr-2003  13:42                  2,359,296  Distmdl.mdf   29-Jan-2003  13:25                        180  Drop_repl_hotfix.sql   23-Jun-2003  10:10  2000.80.837.0   1,557,052  Dtsui.dll           23-Jun-2003  10:10  2000.80.837.0     639,552  Dtswiz.dll          23-Apr-2003  14:21                    747,927  Instdist.sql   02-May-2003  13:26                      1,581  Inst_repl_hotfix.sql   07-Feb-2003  18:10  2000.80.765.0      90,692  Msgprox.dll         31-Mar-2003  13:37                      1,873  Odsole.sql   04-Apr-2003  13:16  2000.80.800.0      62,024  Odsole70.dll        07-May-2003  08:11  2000.80.819.0      25,144  Opends60.dll        02-Apr-2003  09:18  2000.80.796.0      57,904  Osql.exe            02-Apr-2003  10:45  2000.80.797.0     279,104  Pfutil80.dll        22-May-2003  10:27                     19,195  Qfe469571.sql   11-Jul-2003  04:34                  1,084,147  Replmerg.sql   04-Apr-2003  09:23  2000.80.798.0     221,768  Replprov.dll        07-Feb-2003  18:10  2000.80.765.0     307,784  Replrec.dll         11-Jul-2003  04:26                  1,085,925  Replsys.sql   31-May-2003  12:31  2000.80.818.0     492,096  Semobj.dll          31-May-2003  05:57  2000.80.818.0     172,032  Semobj.rll   28-May-2003  11:59                    115,944  Sp3_serv_uni.sql   31-May-2003  12:31  2000.80.818.0   4,215,360  Sqldmo.dll          07-Apr-2003  05:14                     25,172  Sqldumper.exe       19-Mar-2003  05:50  2000.80.789.0      28,672  Sqlevn70.rll   01-Jul-2003  11:48  2000.80.834.0     180,736  Sqlmap70.dll        07-Feb-2003  18:10  2000.80.765.0      57,920  Sqlrepss.dll        21-Jul-2003  07:24  2000.80.842.0   7,553,105  Sqlservr.exe        07-Feb-2003  18:10  2000.80.765.0      45,644  Sqlvdi.dll          24-Jun-2003  12:31  2000.80.818.0      33,340  Ssmslpcn.dll        31-May-2003  12:31  2000.80.818.0      82,492  Ssnetlib.dll        31-May-2003  12:31  2000.80.818.0      25,148  Ssnmpn70.dll        31-May-2003  12:31  2000.80.818.0     158,240  Svrnetcn.dll        31-May-2003  06:29  2000.80.818.0      76,416  Svrnetcn.exe        30-Apr-2003  11:22  2000.80.816.0      45,132  Ums.dll             01-Jul-2003  11:49  2000.80.834.0      98,816  Xpweb70.dll   
Note Because of file dependencies, the most recent hotfix or feature that contains these files may also contain additional files.
WORKAROUND
To work around this problem, follow these steps:
  1. Create a unique index on the linked server table that the distributed query deletes or updates.
  2. Replace the non-ANSI syntax of the DELETE Transact-SQL statement or of the UPDATE Transact-SQL statement in the distributed query with ANSI syntax.
The following example re-creates the problem condition:
  1. Create a test database on your instance of SQL Server that is to be used as the source server.
  2. Add a computer that is running SQL Server as a linked server to your instance of SQL Server.
  3. On the computer that is running SQL Server and that was added as a linked server, run the following Transact-SQL script to create two tables:
    CREATE TABLE ct_batch ([BAT_PKEY] int NOT NULL ,[BTYP_KEY] int NOT NULL ,[BAT_START_DT] datetime NULL,[BAT_END_DT] datetime NULL,[BAT_STATUS] varchar(50) NULL,[BAT_DO_WORK_FLAG] int NULL)CREATE TABLE ct_batch_element ( [BAT_KEY] int NOT NULL ,[BECC_KEY] int NOT NULL ,[BE_LINK_KEY] int NOT NULL ,[BE_CUST_STRING] varchar(20) NULL,[BE_CUST_VALUE] float NULL)GO
  4. Run the following Transact-SQL script to populate the test data in the tables that you created in step 3:
    DECLARE @count intSET @count = 0WHILE @count < 100BEGININSERT INTO ct_batch VALUES (@count,2,GETDATE(),GETDATE(),'closed',0)INSERT INTO ct_batch_element VALUES (100,1,@count,null,null)SET @count = @count + 1ENDINSERT INTO ct_batch VALUES (100,2,GETDATE(),GETDATE(),'current',0)GO
  5. On the source SQL Server database, run the following Transact-SQL script:
    DELETE Linked Server Name.pubs.dbo.ct_batch_element FROM Linked Server Name.pubs.dbo.ct_batch_element A JOIN Linked Server Name.pubs.dbo.ct_batch BON A.bat_key=B.bat_pkey WHERE A.be_link_key = 1
    Note One hundred rows may be deleted instead of only one row.
To work around the problem that occurs in the previous example, follow these steps:
  1. On the computer that is running SQL Server and that was added as a linked server, run the following Transact-SQL script to repopulate the test data that was deleted:
    DECLARE @count intSET @count = 0WHILE @count < 100BEGININSERT INTO ct_batch VALUES (@count,2,GETDATE(),GETDATE(),'closed',0)INSERT INTO ct_batch_element VALUES (100,1,@count,null,null)SET @count = @count + 1ENDINSERT INTO ct_batch VALUES (100,2,GETDATE(),GETDATE(),'current',0)GO
  2. On the computer that is running SQL Server and that was added as a linked server, run the following Transact-SQL script:
    CREATE UNIQUE INDEX idx1 ON ct_batch_element(be_link_key)
  3. On the source SQL Server database, run the following Transact-SQL script:
    DELETE Linked Server Name.pubs.dbo.ct_batch_element FROM Linked Server Name.pubs.dbo.ct_batch_element AWHERE A.be_link_key = 1 AND EXISTS ( SELECT * 	     FROM Linked Server Name.pubs.dbo.ct_batch B 	     WHERE B.bat_pkey = A.bat_key )
    Note Only one row is deleted, as specified in the filter condition in the query.
STATUS
Microsoft has confirmed that this is a problem in the Microsoft products that are listed in the "Applies to" section.This problem was first corrected in Microsoft SQL Server 2000 Service Pack 4.
MORE INFORMATION
For additional information, click the following article number to view the article in the Microsoft Knowledge Base:
824684 Description of the standard terminology that is used to describe Microsoft software updates
INNER JOIN linked server distributed query
Properties

Article ID: 825043 - Last Review: 01/17/2015 05:20:13 - Revision: 4.3

Microsoft SQL Server 2000 Developer Edition, Microsoft SQL Server 2000 Standard Edition, Microsoft SQL Server 2000 Enterprise Edition, Microsoft SQL Server 2000 Personal Edition, Microsoft SQL Server 2000, Workgroup Edition, Microsoft SQL Server 2000 Desktop Engine (Windows), Microsoft SQL Server 2000 Enterprise Edition 64-bit

  • kbnosurvey kbarchive kbhotfixserver kbqfe kbqfe kbtsql kbserver kbdatabase kbremoting kbquery kbsqlserv2000presp4fix kbfix kbbug KB825043
Feedback