FIX: A gradual increase in memory consumption for the USERSTORE_TOKENPERM cache store occurs in SQL Server 2005

Article translations Article translations
Article ID: 933564 - View products that this article applies to.
Bug: #50000945 (SQL Hotfix)
Microsoft distributes Microsoft SQL Server 2005 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 2005 fix release.
Expand all | Collapse all

On This Page

SUMMARY

This article describes the following about this hotfix release:
  • The issues that are fixed by this 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

When a custom application that is running on Microsoft SQL Server 2005 uses features that trigger frequent database protection timestamp changes, a gradual increase in memory consumption for the USERSTORE_TOKENPERM cache store occurs. Additionally, many duplicate TokenAccessResult entries have a class of 65535 in the sys.dm_os_memory_cache_entries dynamic management view.

For more information about the issue and about conditions that cause protection timestamp changes for a database, see the "More information" section.

CAUSE

This problem occurs because the cumulative permission check of a query is stored in the USERSTORE_TOKENPERM cache store as a TokenAccessResult entry that has a class of 65535. TokenAccessResult entries use the protection timestamp to determine whether security changes have occurred that would invalidate the cache entry. Every time that the protection timestamp changes, the old cache entries cannot be reused because the old entries may not be current. Therefore, a new cache entry must be inserted. However, an old entry is not removed until SQL Server experiences memory pressure. This problem can lead to an increase in memory consumption by the USERSTORE_TOKENPERM cache store.

RESOLUTION

Service Pack information

This problem is fixed in SQL Server 2005 Service Pack 3. For more information about how to obtain SQL Server 2005 Service Pack 3, click the following article number to view the article in the Microsoft Knowledge Base:
913089 How to obtain the latest service pack for SQL Server 2005

Hotfix information

A supported hotfix is available from Microsoft. However, this hotfix is intended to correct only the problem that is described in this article. Apply this hotfix only to systems that are experiencing the problem described in this article. This hotfix might receive additional testing. Therefore, if you are not severely affected by this problem, we recommend that you wait for the next software update that contains this hotfix.

If the hotfix is available for download, there is a "Hotfix download available" section at the top of this Knowledge Base article. If this section does not appear, contact Microsoft Customer Service and Support to obtain the hotfix.

Note If additional issues occur or if any troubleshooting is required, you might have to create a separate service request. The usual support costs will apply to additional support questions and issues that do not qualify for this specific hotfix. For a complete list of Microsoft Customer Service and Support telephone numbers or to create a separate service request, visit the following Microsoft Web site:
http://support.microsoft.com/contactus/?ws=support
Note The "Hotfix download available" form displays the languages for which the hotfix is available. If you do not see your language, it is because a hotfix is not available for that language.

Prerequisites

You must have Microsoft SQL Server 2005 Service Pack 2 (SP2) installed to apply this hotfix.

For more information about how to obtain SQL Server 2005 Service Pack 2, click the following article number to view the article in the Microsoft Knowledge Base:
913089 How to obtain the latest service pack for SQL Server 2005

Restart information

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

Registry information

You do not have to 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 of 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 2005, 32-bit versions
Collapse this tableExpand this table
File nameFile versionFile sizeDateTimePlatform
Microsoft.sqlserver.maintenanceplantasks.dll9.0.3153.0296,30408-Mar-200700:38x86
Msmdlocal.dll9.0.3153.015,930,22408-Mar-200700:38x86
Sqlaccess.dll2005.90.3153.0350,57608-Mar-200700:38x86
Sqlservr.exe2005.90.3153.029,190,51208-Mar-200700:38x86
SQL Server 2005, 64-bit versions
Collapse this tableExpand this table
File nameFile versionFile sizeDateTimePlatform
Microsoft.sqlserver.maintenanceplantasks.dll9.0.3153.0296,30408-Mar-200700:38x86
Msmdlocal.dll9.0.3153.015,930,22408-Mar-200700:38x86
Sqlaccess.dll2005.90.3153.0357,74408-Mar-200710:53x86
Sqlservr.exe2005.90.3153.038,638,96008-Mar-200710:53x64

STATUS

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

MORE INFORMATION

You can use the following two queries to determine whether you are experiencing this issue.
  • When you run the following query, you notice that memory consumption by the USERSTORE_TOKENPERM cache increases:
    select sum(single_pages_kb+multi_pages_kb) 'total memory for tokenperm' from sys.dm_os_memory_clerks where type = 'USERSTORE_TOKENPERM'
  • When you run the following query, you receive many entries in the Store Address column and in the ID column:
    select [Store Address], [id], count (*) 'number of entries'
    from  
    	(select 
    		 cast(entry_data as xml).value ('(//@store_address)[1]', 'varchar (100)') as [Store Address],
    		 cast(entry_data as xml).value ('(//@id)[1]', 'bigint') as [id]
    		 from sys.dm_os_memory_cache_entries
    		where type = 'USERSTORE_TOKENPERM' and cast(entry_data as xml).value ('(//@name)[1]', 'varchar (100)') = 'TokenAccessResult' and 
    			cast(entry_data as xml).value('(//@class)[1]', 'bigint') = 65535
    	) R 
    group by [Store Address], [id] 
    having count (*) > 1
    order by count (*) desc
    
    If this query produces no results, you are not experiencing the issue that this article describes.
Many conditions change the database protection timestamp. For example, most Data Definition Language (DDL) operations change the protection timestamp.

The Create Table DDL operation and the Drop Table DDL operation for temporary tables changes the protection timestamp in the tempdb database.

The following DDL operations are Transact-SQL statements. These operations change the protection timestamp in the master database:
  • Create Login
  • Alter Login
  • Drop Login
  • Create Endpoint
  • Alter Endpoint
  • Drop Endpoint
The following DDL operations are related to user objects, such as the table object. These operations change the protection timestamp in any database. These databases include the master database and the tempdb database.
  • Create
  • Alter
  • Drop
The following DDL operations are related to security. All security-related operations change the protection timestamp in any database. These databases include the master database and the tempdb database. The following list names some examples of security-related DDL operations.
  • Create
  • Alter
  • Drop user
  • Role
  • Application role
  • Certificate
  • Schema
  • Symmetric keys
  • Asymmetric keys
Additionally, operations that grant, revoke, or deny permissions on an object are related to security. These operations also change the protection timestamp in any database. These databases include the master database and the tempdb database.

Other conditions can also cause the USERSTORE_TOKENPERM cache to grow over time. The fix that this article describes is for a very specific condition. That is, a change in the protection timestamp causes the cache store to grow. For more information about the USERSTORE_TOKENPERM cache, click the following article number to view the article in the Microsoft Knowledge Base:
927396 Ad hoc queries take a longer time to finish running when the size of the TokenAndPermUserStore cache grows in SQL Server 2005
After you install this hotfix, a new attribute that is named timestamp is added to entry_data columns in the sys.dm_os_memory_cache_entries view. This attribute specifies the number of times that SQL Server checks the permissions on each plan. When a plan is newly compiled or is recompiled, the timestamp is 1. This value is recalculated if the protection timestamp changes. You can use the following query to take snapshots of the timestamp:
select [store_address], [timestamp], count (*) 'number of entries'  from  
	(select 
 cast(entry_data as xml).value ('(//@store_address)[1]', 'varchar(100)')  as store_address ,
case cast(entry_data as xml).value ('(//@timestamp)[1]', 'int') when  1 then 1 
		else  null 
		end as [timestamp]
		 from sys.dm_os_memory_cache_entries
		where type = 'USERSTORE_TOKENPERM' and cast(entry_data as xml).value ('(//@name)[1]', 'varchar (100)') = 'TokenAccessResult' and 
			cast(entry_data as xml).value('(//@class)[1]', 'bigint') = 65535
	) R 
group by [store_address], [timestamp]
order by count (*) desc
If over time you see many timestamps of 1 for each store_address column, an application has a high rate of ad hoc queries or of recompile operations. You must slow down the rate of the ad hoc queries or of the recompile operations. Alternatively, you can address the issue by applying trace flag 4618 to limit the number of entries per user cache store. Using trace flag 4618 can incur a small CPU overhead because this trace flag removes old cache entries as new entries are inserted. The trace flag performs this action to limit the size of the cache store growth. However, the CPU overhead is spread over time.

MORE INFORMATION

For more information, click the following article number to view the article in the Microsoft Knowledge Base:
959823 How to customize the quota for the TokenAndPermUserStore cache store in SQL Server 2005 Service Pack 3
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

Properties

Article ID: 933564 - Last Review: April 28, 2010 - Revision: 3.0
APPLIES TO
  • Microsoft SQL Server 2005 Developer Edition
  • Microsoft SQL Server 2005 Enterprise Edition
  • Microsoft SQL Server 2005 Enterprise X64 Edition
  • Microsoft SQL Server 2005 Standard Edition
  • Microsoft SQL Server 2005 Standard X64 Edition
Keywords: 
kbautohotfix kbqfe kbhotfixserver kbsql2005engine kbprb KB933564

Give Feedback

 

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