PRB: Call to SQL Stored Procedure Returns 'Invalid Column Name' (222664)
The information in this article applies to:
- Microsoft Data Access Components 1.5
- Microsoft Data Access Components 2.0
- Microsoft Data Access Components 2.1
- Microsoft Data Access Components 2.5
- Microsoft Data Access Components 2.6
- Microsoft Data Access Components 2.7
- Microsoft SQL Server 6.5
This article was previously published under Q222664 SYMPTOMS When calling a SQL Server stored procedure that uses
Exec('string') syntax, you may get an error returned to the calling client if
you are referencing values using double quotes. The error that is returned to
the calling client is: -2147217900 -- [Microsoft][ODBC
SQL Server Driver][SQL Server]Invalid column name 'Column'.
This error is being raised because the SQL Server driver is interpreting the
value inside of the double quotes as a column name instead of a field value.
The cause of this problem most likely is the SQL Server driver defaulting to
setting the QUOTED_IDENTIFIER option to 'on'. RESOLUTION There are three ways to avoid this problem: - The best solution to this problem is to substitute two
single quotes for each of the double quotes in the stored procedure. This tells
SQL Server not to treat these quotes as the ending single quote for the
EXEC('') statement. For example, the following code:
DROP PROC sptest
go
CREATE PROC sptest as
EXEC('SELECT au_id, au_lname, au_fname = (
CASE
when au_lname = "Ringer" then "value1"
else "default"
END
)
FROM Authors')
changes to this code:
DROP PROC sptest
go
CREATE PROC sptest as
EXEC('SELECT au_id, au_lname, au_fname = (
CASE
when au_lname = ''Ringer'' then ''value1''
else ''default''
END
)
FROM Authors')
- Execute the connection level option SET QUOTED_IDENTIFIER
OFF immediately after establishing the connection with the database.
- If you are using the Microsoft OLEDB Provider for ODBC
Drivers, you can add the following to the end of you connection string:
'QuotedID=No'.
- If you are using a DSN connection to SQL Server you can
also set Quoted Identifiers off by deselecting the option 'Use ANSI Quoted
Identifiers' in the ODBC Administrator when you are creating or configuring the
DSN to SQL Server. This accomplishes the same thing as using the 'QuotedID=No'
option in the connection string, as shown in the third work around.
The latter two of these work arounds are demonstrated in the
code example in the MORE INFORMATION section. STATUS This behavior is by design. REFERENCES For additional information, see Microsoft SQL Server Books
Online For more information, please see the following article(s) in
the Microsoft Knowledge Base:
For additional information, click the following article numbers to view the articles in the Microsoft Knowledge Base:
156501
INF: QUOTED_IDENTIFIER and Strings with Single Quotation Marks
135531 PRB: Double
Quotation Mark Params Error w/ Quoted Identifiers
Modification Type: | Minor | Last Reviewed: | 6/23/2005 |
---|
Keywords: | kbDatabase kbprb kbStoredProc KB222664 |
---|
|