FIX: The query plan for a stored procedure is not cached if the stored procedure uses a BLOB variable and the variable is used in a string function in Microsoft SQL Server 2008 or in Microsoft SQL Server 2008 R2

Article translations Article translations
Article ID: 2380435 - View products that this article applies to.
Microsoft distributes Microsoft SQL Server 2008 and Microsoft SQL Server 2008 R2 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 2008 or SQL Server 2008 R2 fix release.
Expand all | Collapse all

On This Page

SYMPTOMS

Consider the following scenario:
  • You create a stored procedure in Microsoft SQL Server 2008 or in Microsoft SQL Server 2008 R2.
  • The stored procedure uses a binary large object (BLOB) variable.
  • The BLOB variable is used in a string function.
  • You execute the stored procedure.
In this scenario, the query plan for the stored procedure is not cached.

RESOLUTION

Cumulative update information

SQL Server 2008 Service Pack 1

The fix for this issue was first released in Cumulative Update 10 for SQL Server 2008 Service Pack 1. For more information about this cumulative update package, click the following article number to view the article in the Microsoft Knowledge Base:
2279604 Cumulative update package 10 for SQL Server 2008 Service Pack 1
Note Because the builds are cumulative, each new fix release contains all the hotfixes and all the security fixes that were included with the previous SQL Server 2008 fix release. Microsoft recommends that you consider applying the most recent fix release that contains this hotfix. For more information, click the following article number to view the article in the Microsoft Knowledge Base:
970365 The SQL Server 2008 builds that were released after SQL Server 2008 Service Pack 1 was released
Microsoft SQL Server 2008 hotfixes are created for specific SQL Server service packs. You must apply a SQL Server 2008 Service Pack 1 hotfix to an installation of SQL Server 2008 Service Pack 1. By default, any hotfix that is provided in a SQL Server service pack is included in the next SQL Server service pack.

SQL Server 2008 Service Pack 2

The fix for this issue was first released in Cumulative Update 1 for SQL Server 2008 Service Pack 2. For more information about this cumulative update package, click the following article number to view the article in the Microsoft Knowledge Base:
2289254 Cumulative update 1 for SQL Server 2008 Service Pack 2
Note Because the builds are cumulative, each new fix release contains all the hotfixes and all the security fixes that were included with the previous SQL Server 2008 fix release. We recommend that you consider applying the most recent fix release that contains this hotfix. For more information, click the following article number to view the article in the Microsoft Knowledge Base:
2402659 The SQL Server 2008 builds that were released after SQL Server 2008 Service Pack 2 was released

SQL Server 2008 R2

The fix for this issue was first released in Cumulative Update 4. For more information about how to obtain this cumulative update package for SQL Server 2008 R2, click the following article number to view the article in the Microsoft Knowledge Base:
2345451 Cumulative Update package 4 for SQL Server 2008 R2
Note Because the builds are cumulative, each new fix release contains all the hotfixes and all the security fixes that were included with the previous SQL Server 2008 R2 fix release. We recommend that you consider applying the most recent fix release that contains this hotfix. For more information, click the following article number to view the article in the Microsoft Knowledge Base:
981356 The SQL Server 2008 R2 builds that were released after SQL Server 2008 R2 was released

STATUS

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

MORE INFORMATION

To reproduce this issue, follow these steps:
  1. Run the following code to create two stored procedures ("p_test1" and "p_test2"). "P_test1" uses a BLOB variable, and "p_test2" uses an nvarchar(100) variable.
    use tempdb
    go
    if OBJECT_ID('p_test1') is not null drop proc p_test1
    if OBJECT_ID('p_test2') is not null drop proc p_test2
    go
    create proc p_test1
    @s nvarchar(max)
    as
    begin
    select * from sys.objects 
    where name = UPPER(@s)
    end
    go
    create proc p_test2
    @s nvarchar(100)
    as
    begin
    select * from sys.objects 
    where name = UPPER(@s)
    end
    go
    
  2. Run the following code to clear the procedure cache and to execute the two stored procedures:
    dbcc freeproccache
    go
    exec p_test1 N'abc'
    exec p_test2 N'abc'
    go
    
  3. Run the following code to check the cached plan:
    select object_name(CONVERT(int, a.value)), cp.*
    from sys.dm_exec_cached_plans cp
    cross apply sys.dm_exec_plan_attributes(cp.plan_handle) a
    where cp.objtype = 'Proc'
    and a.attribute = 'objectid'
    
    
Note If there are many concurrent executions of this kind of stored procedure on a Microsoft SQL Server 2008 or a Microsoft SQL Server 2008 R2 instance, you may experience blocking that is caused by compile locks on the instance.

For more information about the description of SQL Server blocking caused by compile locks, see the following Microsoft Knowledge Base article:
263889 Description of SQL Server blocking caused by compile locks

REFERENCES

For more information about String functions (Transact-SQL), visit the following Microsoft website:
String functions (Transact-SQL)
For more information about the Incremental Servicing Model for SQL Server, click the following article number to view the article in the Microsoft Knowledge Base:
935897 An Incremental Servicing Model is available from the SQL Server team to deliver hotfixes for reported problems
For more information about the naming schema for 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 more information about software update terminology, 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: 2380435 - Last Review: November 15, 2010 - Revision: 3.0
APPLIES TO
  • Microsoft SQL Server 2008 Enterprise
  • Microsoft SQL Server 2008 Developer
  • Microsoft SQL Server 2008 Standard
  • Microsoft SQL Server 2008 Standard Edition for Small Business
  • Microsoft SQL Server 2008 Workgroup
  • Microsoft SQL Server 2008 R2 Datacenter
  • Microsoft SQL Server 2008 R2 Developer
  • Microsoft SQL Server 2008 R2 Enterprise
  • Microsoft SQL Server 2008 R2 Standard
  • Microsoft SQL Server 2008 R2 Workgroup
Keywords: 
kbqfe kbfix kbsurveynew kbexpertiseadvanced KB2380435

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