FIX: Update Query Does Not Execute Correctly (293328)



The information in this article applies to:

  • Microsoft SQL Server 2000 (all editions)

This article was previously published under Q293328
BUG #: 351450 (SHILOH_bugs)

SYMPTOMS

The execution of a stored procedure that includes the following statement to update a remote table over a linked server does not work correctly:
 UPDATE [RemoteServer].pubs.dbo.RemoteTable SET  Name = @Name WHERE  MyID = @ID
				
When the stored procedure is executed the first time, the target table is modified correctly; however, the following executions are not able to modify that table.

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 the Microsoft Knowledge Base:

290211 INF: How to Obtain the Latest SQL Server 2000 Service Pack

WORKAROUND

To work around this problem either:
  • Run the stored procedure with the WITH RECOMPILE option or use the WITH RECOMPILE option when you create the stored procedure.
    exec usp_TestUpdate 1, 'SecondRun' with recompile
    						
    -or-
  • Create a dynamic execution for the UPDATE statement in the stored procedure. For example:
    Use pubs
    go
    Create   PROCEDURE usp_TestUpdate
    
            @ID int, 
            @Name varchar(12) 
     
    AS 
    declare @Mylog char(10)
    set @Mylog = cast(@ID as char(10))
    exec("UPDATE [RemoteServer].pubs.dbo.RemoteTable SET  Name = '" + @Name+"' WHERE  MyID = " + @Mylog) 
    
    					

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

The following code demonstrates the problem.
  1. Create a table named RemoteTable on a linked server and populate the table with a row:
    
    Use pubs
    go
    Create table RemoteTable
    (
         MyID     int  primary key, 
         Name  varchar(12)
    )
    go
    insert into RemoteTable values(1,'abc')
    					
  2. Create a stored procedure on the local server that contains an UPDATE statement to a table created on the linked server:
    Use pubs
    go
    Create   PROCEDURE usp_TestUpdate
    
            @ID int, 
            @Name varchar(12) 
     
    AS 
    
    UPDATE [RemoteServer].pubs.dbo.RemoteTable SET  Name = @Name WHERE  MyID = @ID
    					
  3. Run the stored procedure:
    exec usp_TestUpdate 1, 'firstRun'
    go
    select * from remoteserver.pubs.dbo.RemoteTable
    					
    The result is:
    Output
    =====
    MyID 		Name
    1		firstRun
    					
    Run the stored procedure again:
    exec usp_TestUpdate 1, 'SecondRun'
    go
    select * from remoteserver.pubs.dbo.RemoteTable
    					
    This time the result is:
    Output
    =====
    MyID 		Name
    1		firstRun    
    					

Modification Type:MajorLast Reviewed:11/5/2003
Keywords:kbBug kbfix kbSQLServ2000sp1fix KB293328