FIX: The performance of a DML operation that fires a trigger may decrease when the trigger execution plan recompiles repeatedly

This article has been archived. It is offered "as is" and will no longer be updated.
Bug #: 470083 (SQL Server 8.0)
Summary
This article describes the following about this hotfix release:
  • The issues that are fixed by this hotfix package.
  • The prerequisites for installing the hotfix package.
  • Whether you must restart your computer after you install the hotfix package.
  • Whether the hotfix package is replaced by any other hotfix package.
  • Whether you must make any registry changes.
  • The files that are contained in the hotfix package.
back to the top
Symptoms
When you run a data manipulation language (DML) statement such as an UPDATE, INSERT, or DELETE statement that fires a trigger, the Microsoft SQL Server program recompiles the trigger execution plan to improve the performance of the trigger execution. However, the repeated recompilation of the trigger execution plan may decrease the performance of the trigger execution.

The repeated recompilation of the trigger execution plan may occur when the following conditions are true:
  • You run the DML statement multiple times.
  • The number of rows that are affected by the DML statement differs every time that the DML statement is run.
For a list of previous hotfixes, see the "Microsoft SQL Server 2000 post-Service Pack 3 or Microsoft SQL Server 2000 post-Service Pack 3a hotfixes" section in the following Microsoft Knowledge Base article:
290211 How to obtain the most recent SQL Server 2000 service pack
back to the top
Resolution

Service pack information

To resolve this problem, obtain the latest service pack for Microsoft SQL Server 2000. For more 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

Prerequisites

This hotfix requires Microsoft SQL Server 2000 Service Pack 3 (SP3). For additional information about how to obtain SQL Server 2000 Service Pack 3, click the following article number to view the article in the Microsoft Knowledge Base:
290211 How to obtain the most recent SQL Server 2000 service pack
back to the top

Restart information

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

Note After you apply this hotfix, you must restart your SQL Server 2000 program that is running on your computer.

back to the top

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 tool in Control Panel.
    Date         Time   Version       Size       File name   ------------------------------------------------------------------   18-Jun-2004  14:14  2000.80.954.0    664,128  Autoplt.dll         18-Jun-2004  14:14  2000.80.954.0     78,400  Console.exe         18-Jun-2004  14:14  2000.80.954.0    315,968  Custtask.dll        18-Jun-2004  14:14  2000.80.954.0     33,340  Dbmslpcn.dll        08-Apr-2004  09:12                   786,432  Distmdl.ldf   08-Apr-2004  09:12                 2,359,296  Distmdl.mdf   10-Oct-2003  06:18                       180  Drop_repl_hotfix.sql   18-Jun-2004  14:14  2000.80.954.0  1,905,216  Dtspkg.dll          18-Jun-2004  14:14  2000.80.954.0    528,960  Dtspump.dll         18-Jun-2004  14:14  2000.80.954.0  1,557,052  Dtsui.dll           18-Jun-2004  14:14  2000.80.954.0    639,552  Dtswiz.dll          10-Oct-2003  06:18                   747,927  Instdist.sql   10-Oct-2003  06:18                     1,581  Inst_repl_hotfix.sql   18-Jun-2004  14:14  2000.80.954.0    352,828  Isqlw.exe           18-Jun-2004  14:14  2000.80.954.0     82,492  Itwiz.exe           18-Jun-2004  14:14  2000.80.954.0     90,692  Msgprox.dll         19-May-2004  11:13  8.11.40209.0     209,408  Mssdi98.dll         18-Jun-2004  14:14  2000.80.954.0     62,024  Odsole70.dll        18-Jun-2004  14:15  2000.80.954.0     25,144  Opends60.dll        18-Jun-2004  14:14  2000.80.954.0     57,904  Osql.exe            18-Jun-2004  14:14  2000.80.954.0    279,104  Pfutil80.dll        10-Oct-2003  06:07                   550,780  Procsyst.sql   08-Apr-2004  09:12                    12,305  Qfe469315.sql   08-Apr-2004  09:12                    19,195  Qfe469571.sql   17-Jun-2004  02:42                 1,105,167  Replmerg.sql   18-Jun-2004  14:14  2000.80.954.0    221,768  Replprov.dll        18-Jun-2004  14:14  2000.80.954.0    307,784  Replrec.dll         16-Jun-2004  14:07  2000.80.954.0    159,813  Replres.rll   10-Oct-2003  06:18                 1,087,150  Replsys.sql   10-Oct-2003  06:18                   986,603  Repltran.sql   18-Jun-2004  14:14  2000.80.954.0    287,304  Rinitcom.dll        18-Jun-2004  14:14  2000.80.954.0     78,416  Sdiclnt.dll         18-Jun-2004  14:14  2000.80.954.0     66,112  Semmap.dll          18-Jun-2004  14:14  2000.80.954.0     57,916  Semnt.dll           18-Jun-2004  14:14  2000.80.954.0    492,096  Semobj.dll          16-Jun-2004  14:44  2000.80.954.0    172,032  Semobj.rll   18-Jun-2004  14:14  2000.80.954.0     53,832  Snapshot.exe        11-Mar-2004  14:40                   117,834  Sp3_serv_uni.sql   18-Jun-2004  14:13  2000.80.954.0     28,672  Sqlagent.dll        18-Jun-2004  14:14  2000.80.954.0    311,872  Sqlagent.exe        18-Jun-2004  14:13  2000.80.954.0    168,001  Sqlakw32.dll        18-Jun-2004  14:14  2000.80.954.0     33,344  Sqlctr80.dll        18-Jun-2004  14:14  2000.80.954.0  4,215,360  Sqldmo.dll          18-Jun-2004  14:14                    25,172  Sqldumper.exe       16-Jun-2004  13:54  2000.80.954.0     28,672  Sqlevn70.rll   18-Jun-2004  14:14  2000.80.954.0    180,792  Sqlmap70.dll        18-Jun-2004  14:14  2000.80.954.0    188,992  Sqlmmc.dll          16-Jun-2004  14:52  2000.80.954.0    479,232  Sqlmmc.rll   18-Jun-2004  14:14  2000.80.954.0    401,984  Sqlqry.dll          18-Jun-2004  14:14  2000.80.954.0     57,920  Sqlrepss.dll        18-Jun-2004  14:14  2000.80.954.0  7,581,777  Sqlservr.exe        18-Jun-2004  14:14  2000.80.954.0    590,396  Sqlsort.dll         18-Jun-2004  14:14  2000.80.954.0     45,644  Sqlvdi.dll          18-Jun-2004  14:14  2000.80.954.0    106,588  Sqsrvres.dll        18-Jun-2004  14:14  2000.80.954.0     33,340  Ssmslpcn.dll        18-Jun-2004  14:14  2000.80.954.0     82,492  Ssnetlib.dll        18-Jun-2004  14:14  2000.80.954.0     25,148  Ssnmpn70.dll        18-Jun-2004  14:14  2000.80.954.0    123,456  Stardds.dll         18-Jun-2004  14:14  2000.80.954.0    158,240  Svrnetcn.dll        18-Jun-2004  14:14  2000.80.954.0     76,416  Svrnetcn.exe        18-Jun-2004  14:14  2000.80.954.0     49,228  Ums.dll             18-Jun-2004  14:14  2000.80.954.0     98,872  Xpweb70.dll      
Note Because of file dependencies, the most recent hotfix that contains these files may also contain additional files.back to the top
Status
Microsoft has confirmed that this is a bug 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.

back to the top
More information
This hotfix update improves the thresholds at which the execution plan of a trigger is recompiled. For thresholds improvement to take effect, you must enable SQL Server trace flag 9055 after you install this hotfix. To enable trace flag 9055 for an instance of SQL Server, use one of the following methods:
  • Run the following Transact-SQL statement in SQL Query Analyzer on the instance of SQL Server:
    DBCC TRACEON (9055, -1)
  • Add -T9055 to the SQL Server startup parameters.

Steps to reproduce the behavior

To reproduce a scenario that causes a trigger execution plan recompilation, follow these steps:
  1. Start SQL Query Analyzer, and then connect to an instance of SQL Server 2000.
  2. Create a table and an update trigger on the table. Name the table as cache_test and name the update trigger as cache_test_update. To do this, run the following Transact-SQL statements:
    use pubsgoset nocount ongoif exists (select 1 from sysobjects where id = object_id('dbo.cache_test'))drop table dbo.cache_testgocreate table dbo.cache_test(id int not null,descr varchar(30) not null,rowcreateddt datetime not null default getdate(),rowcreatedby varchar(30) not null default right(system_user,30),testcolumn varchar(30) null,primary key (id))gocreate trigger dbo.cache_test_updateon dbo.cache_testfor updateasif exists ( select 1 from inserted where id = 98654 )print 'test'returngo
  3. Insert some records in the cache_test table, and then remove all elements from the procedure cache. To do this, run the following Transact-SQL statements:
    insert into cache_test (id, descr, testcolumn) select 1,'Descr 1','Test 1'insert into cache_test (id, descr, testcolumn) select 2,'Descr 2','Test 2'insert into cache_test (id, descr, testcolumn) select 3,'Descr 3','Test 3'insert into cache_test (id, descr, testcolumn) select 4,'Descr 4','Test 4'insert into cache_test (id, descr, testcolumn) select 5,'Descr 5','Test 5'insert into cache_test (id, descr, testcolumn) select 6,'Descr 6','Test 6'insert into cache_test (id, descr, testcolumn) select 7,'Descr 7','Test 7'insert into cache_test (id, descr, testcolumn) select 8,'Descr 8','Test 8'insert into cache_test (id, descr, testcolumn) select 9,'Descr 9','Test 9'insert into cache_test (id, descr, testcolumn) select 10,'Descr 10','Test 10'godbcc freeproccache
  4. Update a single row in the table cache_test, and then see the plan for this single row update that is in the cache. To do this, run the following Transact-SQL statements:
    update cache_testset testcolumn = 'testing '+cast(id as varchar)where id between 1 and 1goselect SetOpts,UseCounts,* from master..SyscacheObjects where ObjId=Object_ID('cache_test_update') order by SetOpts, CacheObjTypego
    You notice an output that is similar to the following:
    SetOpts UseCounts bucketid cacheobjtype     objtype  objid      dbid dbidexec uid refcounts usecounts pagesused lasttime maxexectime avgexectime lastreads lastwrites setopts langid dateformat status sqlbytes sql5371	1	  10394	   Compiled Plan    Trigger  1029578706	5    5	      1	  2	    1	      1	        0	 0	     0	         0	   0	      5371    0	     1	        0	34	cache_test_update5371	1	  10394	   Executable Plan  Trigger  1029578706	5    5	      1	  1	    1	      1	        0	 0	     0	         0	   0	      5371    0	     1	        0	34	cache_test_update
  5. Update four rows in the cache_test table, and then see the plan for this multiple-row update that is in the cache. To do this, run the following Transact-SQL statements:
    update cache_testset testcolumn = 'testing '+cast(id as varchar)where id between 1 and 4goselect SetOpts,UseCounts,* from master..SyscacheObjects where ObjId=Object_ID('cache_test_update') order by SetOpts, CacheObjTypego
    You will notice an output that is similar to the following:
    SetOpts UseCounts bucketid cacheobjtype     objtype  objid      dbid dbidexec uid refcounts usecounts pagesused lasttime maxexectime avgexectime lastreads lastwrites setopts langid dateformat status sqlbytes sql4347	1	  10394	   Compiled Plan    Trigger  1029578706	5    5	      1	  2	    1	      1	        0	 0	     0	         0	   0	      4347    0	     1	        0	34	cache_test_update4347	1	  10394	   Executable Plan  Trigger  1029578706	5    5	      1	  1	    1	      1	        0	 0	     0	         0	   0	      4347    0	     1	        0	34	cache_test_update5371	1	  10394	   Compiled Plan    Trigger  1029578706	5    5	      1	  2	    1	      1	        0	 0	     0	         0	   0	      5371    0	     1	        0	34	cache_test_update5371	1	  10394	   Executable Plan  Trigger  1029578706	5    5	      1	  1	    1	      1 	0	 0	     0	         0	   0	      5371    0	     1	        0	34	cache_test_update
  6. Update five rows) in the cache_test table, and then see the plan for this multiple-row update that is in the cache. To do this, run the following Transact-SQL statements:
    update cache_testset testcolumn = 'testing '+cast(id as varchar)where id between 1 and 5goselect SetOpts,UseCounts,* from master..SyscacheObjects where ObjId=Object_ID('cache_test_update') order by SetOpts, CacheObjTypego
    You notice an output that is similar to the following:
    SetOpts UseCounts bucketid cacheobjtype     objtype  objid      dbid dbidexec uid refcounts usecounts pagesused lasttime maxexectime avgexectime lastreads lastwrites setopts langid dateformat status sqlbytes sql4347	1	  10394	   Compiled Plan    Trigger  1029578706	5    5	      1	  2	    1	      1	        0	 0	     0	         0	   0	      4347    0	     1	        0	34	cache_test_update4347	2	  10394	   Executable Plan  Trigger  1029578706	5    5	      1	  1	    2	      1	        0	 0	     0	         0	   0	      4347    0	     1	        0	34	cache_test_update

    If you compare this output with the output in step 5, you may notice the following conditions that could lead to the decrease in performance of the trigger execution:
    • The execution plan that corresponds to the multiple row update in the output of step 5 is deleted. This behavior occurs because the execution plan that corresponds to the multiple row update is recompiled to create a new execution plan.
    • Even though the execution plan appears to have been recompiled, the usecounts column indicates that the Executable Plan has been used two times. That is not correct.
    • Additionally, the execution plan that corresponds to the single row update has been deleted from the cache.
back to the top
References
For more information, visit the following Microsoft Developer Network (MSDN) Web site: For additional information about the naming schema for Microsoft SQL Server updates, click the following article number to view the article in the Microsoft Knowledge Base:
822499 New naming schema for Microsoft SQL Server software update packages
For additional information about the terminology that Microsoft uses when correcting software after it is released, 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
For additional information, click the following article number to view the article in the Microsoft Knowledge Base:
263889 SQL blocking due to [[COMPILE]] locks
back to the top
Triggers Execution Plan Recompile Multiple Row Update
Properties

Article ID: 870972 - Last Review: 01/17/2015 08:43:47 - Revision: 3.0

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

  • kbnosurvey kbarchive kbtrigger kbbug kbfix kbsqlserv2000presp4fix kbHotfixServer kbqfe KB870972
Feedback
ERROR: at System.Diagnostics.Process.Kill() at Microsoft.Support.SEOInfrastructureService.PhantomJS.PhantomJSRunner.WaitForExit(Process process, Int32 waitTime, StringBuilder dataBuilder, Boolean isTotalProcessTimeout)