FIX: SP2 Regression - Update Queries with Hash Joins Do Not Update Any Rows

Article translations Article translations
Article ID: 276529 - View products that this article applies to.
This article was previously published under Q276529
This article has been archived. It is offered "as is" and will no longer be updated.
BUG #: 58263 (SQLBUG_70)
Expand all | Collapse all

On This Page

SYMPTOMS

Certain update queries that use hash joins may fail to update any rows even though the rows qualify for the update. Instead of updating the rows, the query may complete without any error messages.

The problem does not occur on SQL Server 7.0 RTM or Service Pack 1, but does occur on Service Pack 2.

WORKAROUND

To prevent this problem, you can do one of the following:
  1. Build an index on the column that is included in the WHERE clause in the UPDATE statement to eliminate the table scan. For example (see the related reproduction scenario in the "More Information" section):
    CREATE TABLE [dbo].[a] ( [a1] [nvarchar] (4) NULL , [a2] [smallint] NULL , [a3] [nvarchar] (2) NULL ) ON [PRIMARY] 
    go
    CREATE NONCLUSTERED INDEX idx ON a(a3)
    						
    Force a Merge or Loop Join.
  2. Force a Merge or Loop Join.

STATUS

Microsoft has confirmed this to be a problem in SQL Server 7.0. This problem has been corrected in U.S. Service Pack 3 for Microsoft SQL Server 7.0. For more information, click the following article number to view the article in the Microsoft Knowledge Base:
274799 INF: How to Obtain Service Pack 3 for Microsoft SQL Server 7.0 and Microsoft Data Engine (MSDE) 1.0
For more information, contact your primary support provider.

MORE INFORMATION

Reproduction Scenario

CREATE TABLE [dbo].[a] (
	[a1] [nvarchar] (4) NULL ,
	[a2] [smallint] NULL ,
	[a3] [nvarchar] (2) NULL 
) ON [PRIMARY]
GO

CREATE TABLE [dbo].[b] (
	[b1] [nvarchar] (4) NULL ,
	[b2] [smallint] NULL 
) ON [PRIMARY]
GO

CREATE TABLE [dbo].[c] (
	[c1] [nvarchar] (4) NULL ,
	[c2] [smallint] NULL 
) ON [PRIMARY]
GO

declare @i int
set @i=0
while @i!=1500
begin
insert into a values ('ddd',@i,10)
insert into a values ('aaa',@i,10)
insert into a values ('aaa',@i,10)
insert into a values ('bbb',@i,10)
insert into a values ('bbb',@i,09)

insert into b values ('bbb',@i)
insert into b values ('bbb',@i)
insert into b values ('aaa',@i)
insert into b values ('ddd',@i)

insert into c values ('aaa',@i)
insert into c values ('ccc',@i)
insert into c values ('ddd',@i)
set @i=@i+1
end
The following select query returns 4500 rows, but the corresponding update query does not update any rows. In this scenario, if the number of rows that qualify for the update is fewer than 4500, the problem does not appear.
select *
FROM  a      
	INNER JOIN  b
	ON a.a1 = b.b1
	AND a.a2 = b.b2
	INNER JOIN c
	ON a.a1 = c.c1
	AND a.a2 = c.c2
WHERE a.a3 = '10'
option (hash join)
				
(4500 row(s) affected)
				
update a  set a.a3='08'
FROM  a      
	INNER JOIN  b
	ON a.a1 = b.b1
	AND a.a2 = b.b2
	INNER JOIN c
	ON a.a1 = c.c1
	AND a.a2 = c.c2
WHERE a.a3 = '10'
option (hash join)
				
The command(s) completed successfully.
				
SELECT * FROM a WHERE a3 ='08'
				
a1   a2     a3   
---- ------ ---- 

(0 row(s) affected)
				

Properties

Article ID: 276529 - Last Review: February 28, 2014 - Revision: 5.2
APPLIES TO
  • Microsoft SQL Server 7.0 Service Pack 2
Keywords: 
kbnosurvey kbarchive kbbug kbfix KB276529

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