FIX: Multiple Calls To a User Defined Function Within an Aggregate Function May Return Incorrect Results (288957)



The information in this article applies to:

  • Microsoft SQL Server 2000 (all editions)

This article was previously published under Q288957
BUG #: 236595 (SHILOH_BUGS)

SYMPTOMS

SQL Server may return incorrect results for a query if all of the following conditions are true:
  • The query contains two or more references to the same aggregate function.
  • These aggregate functions take as their parameter the results from a call to the same user defined function (UDF).
  • The calls to the UDF pass the same first parameter.
  • The UDF takes two or more parameters, and the results that it returns are dependent on the value of those secondary parameters.

CAUSE

The optimizer attempts to find duplicate aggregate functions in the query so that each unique aggregate is only calculated once. That code fails to take into account the secondary parameters that are being passed to a UDF and might incorrectly identify two aggregates as equivalent.

RESOLUTION

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 INF: How to Obtain the Latest SQL Server 2000 Service Pack

Hotfix

NOTE: The following hotfix was created prior to Microsoft SQL Server 2000 Service Pack 1.

The English version of this fix should have the following file attributes or later:
   Version      File name       Platform
   -------------------------------------

   8.00.251     s80251i.exe     x86

				

STATUS

Microsoft has confirmed that this is a problem in the Microsoft products that are listed at the beginning of this article. This problem was first corrected in Microsoft SQL Server 2000 Service Pack 1.

MORE INFORMATION

The following example demonstrates the problem.

CREATE TABLE functest (c1 int NULL, c2 int NULL, c3 int NULL,
 c4 int NULL, c5 int NULL, c6 int NULL)
GO
INSERT INTO functest VALUES(1,2,3,4,5,6)
go
CREATE FUNCTION t3 (@one int, @two int, @three int) RETURNS int AS
BEGIN
  RETURN (@one*@two*@three)
END
GO
--This works correctly, returns 720
SELECT avg(dbo.t3(c1,c2,c3)) * avg(dbo.t3(c4,c5,c6)) correct FROM functest
go
--This is incorrect, returns 36, should be 180
SELECT avg(dbo.t3(c1,c2,c3)) * avg(dbo.t3(c1,c5,c6)) incorrect FROM functest
go
--If you swap c1 and c6, the results are correct! (180)
SELECT avg(dbo.t3(c1,c2,c3)) * avg(dbo.t3(c6,c5,c1)) correct FROM functest
				
Note how you obtain incorrect results only if both references to the UDF pass the same first parameter, either as a column name or literal value, to the function.

Modification Type:MajorLast Reviewed:11/6/2003
Keywords:kbBug kbfix kbQFE kbSQLServ2000sp1fix KB288957