FIX: Error messages when you run a query against a linked server that you create in SQL Server 2005: "Statement(s) could not be prepared" and "The column prefix '<column_prefix_name>' does not match with a table name or alias name ...

Article translations Article translations
Article ID: 936223 - View products that this article applies to.
Bug #: 50001186 (SQL Hotfix)
Expand all | Collapse all

On This Page

SYMPTOMS

Consider the following scenario. In Microsoft SQL Server 2005, you create a linked server by using the SQL Native Client OLE DB provider (SQLNCLI). The linked server is linked to a server that has Microsoft SQL Server 2000 installed. In this scenario, you receive the following error messages when you run a query against the linked server:
Error message 1
Msg 8180, Level 16, State 1, Line 1
Statement(s) could not be prepared.
Error message 2
Msg 107, Level 16, State 2, Line 1
The column prefix '<column_prefix_name>' does not match with a table name or alias name used in the query.


Note This problem also occurs in SQL Server 2008. If you experience this problem when you connect to a SQL Server 2000 server in SQL Server 2008, you must enable trace flag 4112 to resolve this problem. For more information, see the "More information" section.

CAUSE

This problem occurs because SQL Server 2005 generates an execution plan that has a remote query. SQL Server 2005 must execute the remote query against SQL Server 2000 to retrieve the required data. SQL Server 2000 cannot handle the remote query. Therefore, error 107 occurs in SQL Server 2000. Then, error 107 is propagated back to SQL Server 2005. Therefore, error 107 occurs in SQL Server 2005, and error 8180 occurs in SQL Server 2005.

RESOLUTION

Cumulative update information

The fix for this issue was first released in Cumulative Update 2. For more information about how to obtain this cumulative update package for SQL Server 2005 Service Pack 2, click the following article number to view the article in the Microsoft Knowledge Base:
936305 Cumulative update package 2 for SQL Server 2005 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 2005 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:
937137 The SQL Server 2005 builds that were released after SQL Server 2005 Service Pack 2 was released
Microsoft SQL Server 2005 hotfixes are created for specific SQL Server service packs. You must apply a SQL Server 2005 Service Pack 2 hotfix to an installation of SQL Server 2005 Service Pack 2. By default, any hotfix that is provided in a SQL Server service pack is included in the next SQL Server service pack.

WORKAROUND

To work around this problem, use Microsoft OLE DB Provider for ODBC to create the linked server against SQL Server 2000.

STATUS

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

MORE INFORMATION

The cumulative update package (build 3175) for SQL Server 2005 SP2 and SQL Server 2008 both introduce trace flag 4112. After you apply the cumulative update package (build 3175) for SQL Server 2005 SP2, you must enable trace flag 4112 to resolve this problem. For information about how to enable a trace flag in SQL Server 2005, see the "Remarks" section of the following Microsoft Developer Network (MSDN) Web site:
http://msdn2.microsoft.com/en-us/library/ms188396.aspx

Steps to reproduce the problem

  1. Start SQL Server Management Studio, and then connect to an instance of SQL Server 2005.
  2. Create a new query, and then run the following statements.
    EXEC sp_addlinkedserver
    @server = '<LinkedServerName>', 
    @provider = 'SQLNCLI', 
    @srvproduct = '', 
    @datasrc = '<InstanceName>', 
    @catalog = '<DatabaseName>' 
    
    exec sp_serveroption
    @server = '<LinkedServerName>' 
    ,@optname = 'RPC' 
    ,@optvalue = 'TRUE'
    exec sp_serveroption
    @server = '<LinkedServerName>' 
    ,@optname = 'RPC OUT' 
    ,@optvalue = 'TRUE'
    
    
    DECLARE @supervisorID varchar(40)
    set @supervisorID = 'Volume Discount'
    
    SELECT DISTINCT J.STOR_ID
    FROM   [<LinkedServerName>].[<DatabaseName>].DBO.DISCOUNTS J
    WHERE  J.DISCOUNTTYPE = @supervisorID
           AND J.DISCOUNT = (SELECT MAX(B.DISCOUNT)
                             FROM   [<LinkedServerName>].<DatabaseName>.DBO.DISCOUNTS B
                             WHERE  B.DISCOUNTTYPE = J.DISCOUNTTYPE)
    
    GO
    
    Notes
    • <LinkedServerName> is a placeholder for the name of the linked server.
    • <InstanceName> is a placeholder for the instance name for the linked server.
    • <DatabaseName> is a placeholder for the database name.
After you run these statements, you receive the error messages that are mentioned in the "Symptoms" section.

Properties

Article ID: 936223 - Last Review: October 8, 2011 - Revision: 3.0
APPLIES TO
  • Microsoft SQL Server 2005 Developer Edition
  • Microsoft SQL Server 2005 Enterprise Edition
  • Microsoft SQL Server 2005 Standard Edition
  • Microsoft SQL Server 2005 Standard X64 Edition
  • Microsoft SQL Server 2005 Standard Edition for Itanium-based Systems
  • Microsoft SQL Server 2005 Enterprise X64 Edition
  • Microsoft SQL Server 2005 Enterprise Edition for Itanium-based Systems
  • Microsoft SQL Server 2008 Developer
  • Microsoft SQL Server 2008 Enterprise
  • Microsoft SQL Server 2008 Standard
  • Microsoft SQL Server 2008 Web
  • Microsoft SQL Server 2008 Workgroup
Keywords: 
kbsql2005engine kbexpertiseadvanced kbfix kbqfe KB936223

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