Introduction
After being legged-up for a good couple of hours by this the other day, I'm writing this quick note to try and prevent other people from nearly throwing their PC out of the window in frustration. It concerns using named query parameters with the Oracle Data Provider for .NET (ODP.NET).
The Problem
Consider the following simple data-retrieval operation:
using (OracleConnection connection = new OracleConnection
(ConfigurationManager.ConnectionStrings["OracleExpress"].ConnectionString))
{
string query = "SELECT SOME_COLUMN, ANOTHER_COLUMN, THIRD_COLUMN FROM SOME_TABLE
WHERE ANOTHER_COLUMN = :SomeParam AND THIRD_COLUMN = :AnotherParam";
OracleCommand command = new OracleCommand(query, connection)
{ CommandType = CommandType.Text };
command.Parameters.Add(":AnotherParam", OracleDbType.Varchar2).Value = "Ping";
command.Parameters.Add(":SomeParam", OracleDbType.Varchar2).Value = "Foo";
connection.Open();
IDataReader reader = command.ExecuteReader();
while (reader.Read())
{
int someColumn = reader.GetInt32(reader.GetOrdinal("SOME_COLUMN"));
string anotherColumn = reader.GetString(reader.GetOrdinal("ANOTHER_COLUMN"));
string thirdColumn = reader.GetString(reader.GetOrdinal("THIRD_COLUMN"));
Console.WriteLine(String.Format("{0}: {1}, {2}", someColumn,
anotherColumn, thirdColumn));
}
}
Using connection As OracleConnection = New OracleConnection_
(ConfigurationManager.ConnectionStrings("OracleExpress").ConnectionString)
Dim query As String = "SELECT SOME_COLUMN, ANOTHER_COLUMN, _
THIRD_COLUMN FROM SOME_TABLE WHERE ANOTHER_COLUMN = _
:SomeParam AND THIRD_COLUMN = :AnotherParam"
Dim command As OracleCommand = New OracleCommand(query, connection) _
With {.CommandType = CommandType.Text}
command.Parameters.Add(":AnotherParam", OracleDbType.Varchar2).Value = "Ping"
command.Parameters.Add(":SomeParam", OracleDbType.Varchar2).Value = "Foo"
connection.Open()
Dim reader As IDataReader = command.ExecuteReader()
While reader.Read()
Dim someColumn As Integer = reader.GetInt32(reader.GetOrdinal("SOME_COLUMN"))
Dim anotherColumn As String = _
reader.GetString(reader.GetOrdinal("ANOTHER_COLUMN"))
Dim thirdColumn As String = reader.GetString(reader.GetOrdinal("THIRD_COLUMN"))
Console.WriteLine(String.Format("{0}: {1}, {2}", someColumn, _
anotherColumn, thirdColumn))
End While
End Using
Now, assuming that the data in our table is as follows:
SOME_COLUMN | ANOTHER_COLUMN | THIRD_COLUMN |
1 | Foo | Ping |
2 | Bar | Pong |
3 | Baz | Ping |
We should get back a single row from the database, right? Wrong! Actually what we get back is nothing. Why is this? If we run this query in another tool of our choice (SQL+, TOAD, etc.), we find it works as expected.
The Solution
After some scouring of Google, I eventually tracked down what was causing the problem. It turns out that unlike, for example the SQL-Server data provider, the Oracle data provider always binds parameters by position unless told otherwise. So, even though we have named parameters in our query, and we have added named parameters to the OracleCommand
object, the data provider still binds the parameters by position; and as we have added the parameters in the 'wrong' order (albeit deliberately in this example) the query doesn't throw an exception, it merely returns an empty result set as the query received by the database is the equivalent of:
SELECT SOME_COLUMN, ANOTHER_COLUMN, THIRD_COLUMN
FROM SOME_TABLE
WHERE ANOTHER_COLUMN = 'Ping'
AND THIRD_COLUMN = 'Foo'
The solution: This isn't made entirely clear on the Oracle documentation, but there is an additional property, BindByName
, on the OracleCommand
object, which must be set to true in order to bind parameters by name:
OracleCommand command = new OracleCommand(query, connection)
{ CommandType = CommandType.Text, BindByName = true };
Dim command As OracleCommand = New OracleCommand(query, connection) _
With {.CommandType = CommandType.Text, .BindByName = True}
The above query should now work as expected.
CodeProject