Microsoft KB Archive/917606

From BetaArchive Wiki

Article ID: 917606

Article Last Modified on 11/2/2007



APPLIES TO

  • Microsoft SQL Server 2000 Developer Edition
  • Microsoft SQL Server 2000 Enterprise Edition
  • Microsoft SQL Server 2000 Standard Edition
  • Microsoft SQL Server 2000 Personal Edition



Bug #: 527 (SQL Hotfix)

Microsoft distributes Microsoft SQL Server 2000 fixes as one downloadable file. Because the fixes are cumulative, each new release contains all the hotfixes and all the security fixes that were included with the previous SQL Server 2000 fix release.

SUMMARY

This article describes the following about this hotfix release:

  • The issues that are fixed by the hotfix package
  • The prerequisites for applying the hotfix package
  • Whether you must restart the computer after you apply the hotfix package
  • Whether the hotfix package is replaced by any other hotfix package
  • Whether you must make any registry changes after you apply the hotfix package
  • The files that are contained in the hotfix package


SYMPTOMS

Consider the following scenario. You upgrade from Microsoft SQL Server 2000 Service Pack 3 (SP3) to Microsoft SQL Server 2000 Service Pack 4 (SP4). Then, you run a query that uses the UNION ALL operator. In this scenario, you may notice a decrease in performance.

This problem may occur if the following conditions are true:

  • You query data from joined tables.
  • The joined tables contain columns that use constraints.
  • The joined tables contain lots of records.

Additionally, this problem occurs in the original release version of SQL Server 2000, in SQL Server 2000 build 8.00.850, and in SQL Server 2000 builds later than build 8.00.850.

For a list of all publicly released SQL Server 2000 post-service pack hotfixes, click the following article number to view the article in the Microsoft Knowledge Base:

894905 Cumulative list of the hotfixes that are available for SQL Server 2000 Service Pack 4


CAUSE

This problem occurs because SQL Server generates an inefficient execution plan that has redundant cluster index scans.

RESOLUTION

The installer does not install this hotfix correctly on x64-based systems. This installation issue occurs when the following conditions are true:

  • The system uses the Advanced Micro Devices (AMD) AMD64 processor architecture or the Intel Extended Memory 64 Technology (EM64T) processor architecture.


Note This issue does not occur on systems that use the Intel Itanium processor architecture.

  • The system is running a 64-bit version of the Microsoft Windows Server operating system.
  • The system is running a 32-bit version of SQL Server 2000.

We have corrected this installation issue in later builds of SQL Server 2000, starting with version 8.00.2244. When a customer who is running SQL Server 2000 on an x64-based system requests this hotfix, we will provide a build that includes this hotfix and that can be installed correctly on an x64-based system. The build that we provide will be version 8.00.2244 or a later version.

Hotfix information

A supported hotfix is now available from Microsoft, but it is only intended to correct the problem that is described in this article. Only apply it to systems that are experiencing this specific problem. This hotfix may receive additional testing. Therefore, if you are not severely affected by this problem, we recommend that you wait for the next SQL Server 2000 service pack that contains this hotfix.

To resolve this problem immediately, contact Microsoft Product Support Services to obtain the hotfix. For a complete list of Microsoft Product Support Services telephone numbers and information about support costs, visit the following Microsoft Web site:

Note In special cases, charges that are ordinarily incurred for support calls may be canceled if a Microsoft Support Professional determines that a specific update will resolve your problem. The usual support costs will apply to additional support questions and issues that do not qualify for the specific update in question.

Prerequisites

  • Microsoft SQL Server 2000 Service Pack 4 (SP4)

    For information about how to obtain SQL Server 2000 SP4, 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

Restart information

You do not have to restart the computer after you apply this hotfix.

Registry information

You do not have change the registry.

Hotfix file information

This hotfix contains only those files that are required to correct the issues that this article lists. This hotfix may not contain all the files that you must have to fully update a product to the latest build.

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 item in Control Panel.

SQL Server 2000, 32-bit x86 versions
File name File version File size Date Time Platform
80sp4-tools.sql Not Applicable 134,628 19-Feb-2006 01:40 Not Applicable
Dtsui.dll 2000.80.2192.0 1,593,344 04-Apr-2006 06:00 x86
Impprov.dll 2000.80.2192.0 102,400 04-Apr-2006 06:00 x86
Msgprox.dll 2000.80.2192.0 94,208 04-Apr-2006 06:00 x86
Msrpjt40.dll 4.10.9424.0 188,473 24-Jan-2006 08:13 x86
Mssdi98.dll 8.11.50523.0 239,104 06-Jun-2005 22:46 x86
Ntwdblib.dll 2000.80.2192.0 290,816 04-Apr-2006 06:00 x86
Odsole70.dll 2000.80.2192.0 69,632 04-Apr-2006 06:00 x86
Osql.exe 2000.80.2192.0 57,344 04-Apr-2006 02:28 x86
Pfclnt80.dll 2000.80.2192.0 430,080 04-Apr-2006 06:00 x86
Procsyst.sql Not Applicable 552,068 17-Jun-2005 00:15 Not Applicable
Replmerg.exe 2000.80.2192.0 163,840 04-Apr-2006 02:49 x86
Replmerg.sql Not Applicable 1,151,450 04-Apr-2006 01:56 Not Applicable
Replprov.dll 2000.80.2192.0 237,568 04-Apr-2006 06:00 x86
Replrec.dll 2000.80.2192.0 315,392 04-Apr-2006 06:00 x86
Replsub.dll 2000.80.2192.0 270,336 04-Apr-2006 06:00 x86
Repltran.sql Not Applicable 1,000,634 02-Feb-2006 21:59 Not Applicable
Semexec.dll 2000.80.2192.0 856,064 04-Apr-2006 06:00 x86
Sp4_serv_qfe.sql Not Applicable 18,810 17-Jun-2005 00:15 Not Applicable
Sqlagent.exe 2000.80.2192.0 323,584 04-Apr-2006 01:48 x86
Sqldiag.exe 2000.80.2192.0 118,784 04-Apr-2006 04:33 x86
Sqldmo.dll 2000.80.2192.0 4,362,240 04-Apr-2006 06:00 x86
Sqlevn70.rll 2000.80.2192.0 45,056 04-Apr-2006 06:00 Not Applicable
Sqlfth75.dll 2000.80.2192.0 102,400 04-Apr-2006 02:22 x86
Sqlservr.exe 2000.80.2192.0 9,162,752 04-Apr-2006 05:59 x86
Sqlsort.dll 2000.80.2192.0 589,824 04-Apr-2006 06:00 x86
Stardds.dll 2000.80.2192.0 176,128 04-Apr-2006 06:00 x86
Svrnetcn.dll 2000.80.2192.0 110,592 04-Apr-2006 06:00 x86
Ums.dll 2000.80.2192.0 35,328 04-Apr-2006 06:00 x86
Xpstar.dll 2000.80.2192.0 311,296 04-Apr-2006 06:00 x86
SQL Server 2000, Itanium architecture version
File name File version File size Date Time Platform
Impprov.dll 2000.80.2192.0 244,736 06-Apr-2006 11:16 IA-64
Msgprox.dll 2000.80.2192.0 188,416 06-Apr-2006 11:16 IA-64
Mssdi98.dll 8.11.50523.0 758,784 06-Apr-2006 11:16 IA-64
Msvcr71.dll 7.10.3052.4 348,160 06-Apr-2006 11:16 x86
Odsole70.dll 2000.80.2192.0 150,528 06-Apr-2006 11:16 IA-64
Osql.exe 2000.80.2192.0 149,504 06-Apr-2006 11:16 IA-64
Pfclnt80.dll 2000.80.2192.0 1,187,840 06-Apr-2006 11:16 IA-64
Procsyst.sql Not Applicable 552,068 06-Apr-2006 11:16 Not Applicable
Replmerg.exe 2000.80.2192.0 375,296 06-Apr-2006 11:16 IA-64
Replmerg.sql Not Applicable 1,151,450 06-Apr-2006 11:16 Not Applicable
Replprov.dll 2000.80.2192.0 538,624 06-Apr-2006 11:16 IA-64
Replprov2.dll 2000.80.2192.0 538,624 06-Apr-2006 11:16 IA-64
Replrec.dll 2000.80.2192.0 775,168 06-Apr-2006 11:16 IA-64
Replrec2.dll 2000.80.2192.0 775,168 06-Apr-2006 11:16 IA-64
Replsub.dll 2000.80.2192.0 641,024 06-Apr-2006 11:16 IA-64
Repltran.sql Not Applicable 1,000,634 06-Apr-2006 11:16 Not Applicable
Sqlagent.exe 2000.80.2192.0 1,061,376 06-Apr-2006 11:16 IA-64
Sqldiag.exe 2000.80.2192.0 334,336 06-Apr-2006 11:16 IA-64
Sqldmo.dll 2000.80.2192.0 13,860,352 06-Apr-2006 11:16 IA-64
Sqlevn70.rll 2000.80.2192.0 35,328 06-Apr-2006 11:16 Not Applicable
Sqlfth75.dll 2000.80.2192.0 246,784 06-Apr-2006 11:16 IA-64
Sqlservr.exe 2000.80.2192.0 24,932,864 06-Apr-2006 11:16 IA-64
Sqlsort.dll 2000.80.2192.0 617,472 06-Apr-2006 11:16 IA-64
Svrnetcn.dll 2000.80.2192.0 427,520 06-Apr-2006 11:16 IA-64
Xpstar.dll 2000.80.2192.0 873,472 06-Apr-2006 11:16 IA-64


STATUS

Microsoft has confirmed that this is a problem in the Microsoft products that are listed in the "Applies to" section.

MORE INFORMATION

For more 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


Steps to reproduce the problem

  1. In SQL Server 2000 SP4, run the following statements by using SQL Query Analyzer.

    use master
    go
    
    create database repro
    go
    
    use repro
    go
    
    create table t1 (i int constraint pkt1 primary key check ((i>11) and (i< 15)), j int )
    create table t2 (a int constraint pkt2 primary key check ((a>15) and (a< 20)), b int)
    create table t3 (c int constraint pkt3 primary key check ((c>7) and (c< 13)), d int)
    create table t4 (e int constraint pkt4 primary key check ((e>19) and (e< 24)), f int)
    create table s1 (i int constraint pkt5 primary key, j int)
    create table s2 (a int constraint pkt6 primary key, b int)
    create table s3 (c int constraint pkt7 primary key, d int)
    create table s4 (e int constraint pkt8 primary key, f int)
    go
    
    create view v1 as
    select t1.* from
    t1 inner join s1 on t1.i = s1.i
    union all
    select t2.* from
    t2 inner join s2 on t2.a = s2.a
    go
    
    create view v2 as
    select t3.* from
    t3 inner join s3 on t3.c = s3.c
    union all
    select t4.* from
    t4 inner join s4 on t4.e = s4.e
    go
  2. To make SQL Server return execution information, run the following statements.

    set showplan_text on
    go
  3. Run the following statements, and then examine the output.

    select * from v1 inner join v2 on i = c
    where i = 12 or i = 17
    go

    The following inefficient execution plan is displayed in the output.

    StmtText                                                                                                                
    ----------------------------------------------------------------------------------------------------------------------- 
      |--Concatenation
           |--Nested Loops(Inner Join, WHERE:([t3].[c]=[t1].[i]))
           |    |--Nested Loops(Inner Join)
           |    |    |--Clustered Index Seek(OBJECT:([Repro].[dbo].[s1].[pkt5]), SEEK:([s1].[i]=12) ORDERED FORWARD)
           |    |    |--Clustered Index Seek(OBJECT:([Repro].[dbo].[t1].[pkt1]), SEEK:([t1].[i]=12) ORDERED FORWARD)
           |    |--Nested Loops(Inner Join, OUTER REFERENCES:([t3].[c]))
           |         |--Clustered Index Scan(OBJECT:([Repro].[dbo].[t3].[pkt3]))
           |         |--Clustered Index Seek(OBJECT:([Repro].[dbo].[s3].[pkt7]), SEEK:([s3].[c]=[t3].[c]) ORDERED FORWARD)
           |--Nested Loops(Inner Join, WHERE:([t4].[e]=[t2].[a]))
                |--Nested Loops(Inner Join)
                |    |--Clustered Index Seek(OBJECT:([Repro].[dbo].[s2].[pkt6]), SEEK:([s2].[a]=17) ORDERED FORWARD)
                |    |--Clustered Index Seek(OBJECT:([Repro].[dbo].[t2].[pkt2]), SEEK:([t2].[a]=17) ORDERED FORWARD)
                |--Nested Loops(Inner Join, OUTER REFERENCES:([t4].[e]))
                     |--Clustered Index Scan(OBJECT:([Repro].[dbo].[t4].[pkt4]))
                     |--Clustered Index Seek(OBJECT:([Repro].[dbo].[s4].[pkt8]), SEEK:([s4].[e]=[t4].[e]) ORDERED FORWARD)
    
    (15 row(s) affected)

When you follow these steps in SQL Server 2000 SP3, the following efficient execution plan is displayed in the output.

StmtText                                                                                                                
----------------------------------------------------------------------------------------------------------------------- 
  |--Concatenation
       |--Nested Loops(Inner Join, OUTER REFERENCES:([s3].[c]))
       |    |--Nested Loops(Inner Join, OUTER REFERENCES:([t1].[i]))
       |    |    |--Nested Loops(Inner Join)
       |    |    |    |--Clustered Index Seek(OBJECT:([Repro].[dbo].[s1].[pkt5]), SEEK:([s1].[i]=12) ORDERED FORWARD)
       |    |    |    |--Clustered Index Seek(OBJECT:([Repro].[dbo].[t1].[pkt1]), SEEK:([t1].[i]=12) ORDERED FORWARD)
       |    |    |--Clustered Index Seek(OBJECT:([Repro].[dbo].[s3].[pkt7]), SEEK:([s3].[c]=[t1].[i]) ORDERED FORWARD)
       |    |--Filter(WHERE:(STARTUP EXPR([s3].[c]<13 AND [s3].[c]>7)))
       |         |--Clustered Index Seek(OBJECT:([Repro].[dbo].[t3].[pkt3]), SEEK:([t3].[c]=[s3].[c]) ORDERED FORWARD)
       |--Nested Loops(Inner Join, OUTER REFERENCES:([s4].[e]))
            |--Nested Loops(Inner Join, OUTER REFERENCES:([t2].[a]))
            |    |--Nested Loops(Inner Join)
            |    |    |--Clustered Index Seek(OBJECT:([Repro].[dbo].[s2].[pkt6]), SEEK:([s2].[a]=17) ORDERED FORWARD)
            |    |    |--Clustered Index Seek(OBJECT:([Repro].[dbo].[t2].[pkt2]), SEEK:([t2].[a]=17) ORDERED FORWARD)
            |    |--Clustered Index Seek(OBJECT:([Repro].[dbo].[s4].[pkt8]), SEEK:([s4].[e]=[t2].[a]) ORDERED FORWARD)
            |--Filter(WHERE:(STARTUP EXPR([s4].[e]<24 AND [s4].[e]>19)))
                 |--Clustered Index Seek(OBJECT:([Repro].[dbo].[t4].[pkt4]), SEEK:([t4].[e]=[s4].[e]) ORDERED FORWARD)

(17 row(s) affected)


Additional query words: index scan runtime partition elimination

Keywords: kbhotfixserver kbqfe kbpubtypekc KB917606