How To Execute SQL Parameterized Stored Procedures by Using the ODBC .NET Provider and Visual Basic .NET (309486)
The information in this article applies to:
- Microsoft ADO.NET (included with the .NET Framework)
- Microsoft ADO.NET (included with the .NET Framework 1.1)
- Microsoft Visual Basic .NET (2002)
- Microsoft Visual Basic .NET (2003)
This article was previously published under Q309486 For a Microsoft Visual C# .NET version of this
article, see
310130. For a Microsoft Visual C++
.NET version of this article, see
310142. This article refers
to the following Microsoft .NET Framework Class Library namespace:
IN THIS TASKSUMMARY This step-by-step describes how to call a parameterized SQL
Server stored procedure using the ODBC .NET Managed Provider and Visual Basic
.NET. Although executing a parameterized stored procedure using the
ODBC .NET Provider is slightly different from executing the same procedure
using the SQL or the OLE DB Provider, there is one important difference -- the
stored procedure must be called using the ODBC CALL syntax rather than the name
of the stored procedure. For additional information on this CALL syntax, see
the page entitled "Procedure Calls" in the ODBC Programmer's Reference in the
MSDN Library.
back to the top
Call Syntax Examples- Here is an example of the call syntax for an actual stored
procedure in the Northwind sample database that expects one input parameter:
{CALL CustOrderHist (?)}
- Here is an example of the call syntax for a stored
procedure that expects one input parameter and returns one output parameter and
a return value. The first placeholder represents the return value:
{? = CALL Procedure1 (?, ?)
- The ODBC .NET Managed Provider, like the OLE DB Provider,
processes parameters by ordinal position (zero-based) and not by
name.
back to the top
- If you have not already done so, download and install the
ODBC .NET Managed Provider from the following Microsoft Web site:
- Start Visual Studio .NET, and then create a new Visual
Basic .NET Windows Application.
- On the Project menu, click Add Reference. On the .Net tab, double-click Microsoft.Data.ODBC.dll to add a reference to the Microsoft.Data.ODBC namespace.
- At the very top of the code window, add the following
statement:
Imports Microsoft.Data.ODBC
- Add a command button to the default form from the
Toolbox.
- Double-click the command button to switch to the code
window for the button Click event. Paste the following code in the Click event
procedure, adjusting the SQL Server connection string as necessary:
Dim cn As OdbcConnection
Try
cn = New OdbcConnection("Driver={SQL Server};Server=(local);Database=Northwind;Trusted_Connection=Yes")
Dim cmd As OdbcCommand = New OdbcCommand("{call CustOrderHist (?)}", cn)
Dim prm As OdbcParameter = cmd.Parameters.Add("@CustomerID", OdbcType.Char, 5)
prm.Value = "ALFKI"
cn.Open()
Dim dr As OdbcDataReader = cmd.ExecuteReader()
While dr.Read
Console.WriteLine(dr.GetString(0))
End While
dr.Close()
Catch o As OdbcException
MsgBox(o.Message.ToString)
Finally
cn.Close()
End Try
- Run the project. This code calls the "CustOrderHist" stored
procedure, passing in the CustomerID as a single input parameter, and returns a
resultset. In the Output window, you should see the list of products ordered by
Northwind customer ALFKI.
back to the top
- Using Query Analyzer, create the following stored procedure
in the Northwind sample database. This stored procedure accepts a CustomerID as
an input parameter and returns a list of orders placed by the customer, returns
the average freight per order paid by that customer as an output parameter, and
returns the number of orders placed by the customer as a return value.
CREATE PROCEDURE usp_TestParameters
@CustID CHAR(5),
@AvgFreight MONEY OUTPUT
AS
SELECT @AvgFreight = AVG(Freight) FROM Orders WHERE CustomerID = @CustID
SELECT * FROM Orders WHERE CustomerID = @CustID
RETURN @@ROWCOUNT
- Repeat steps 1 through 6 above, substituting the following
code in the Click event procedure of the command button:
Dim cn As OdbcConnection
Try
cn = New OdbcConnection("Driver={SQL Server};Server=(local);Database=Northwind;Trusted_Connection=Yes")
Dim cmd As OdbcCommand = New OdbcCommand("{? = call usp_TestParameters (?, ?)}", cn)
Dim prm As OdbcParameter = cmd.Parameters.Add("@RETURN_VALUE", OdbcType.Int)
prm.Direction = ParameterDirection.ReturnValue
prm = cmd.Parameters.Add("@CustomerID", OdbcType.Char, 5)
prm.Value = "ALFKI"
prm = cmd.Parameters.Add("@AvgFreight", OdbcType.Double)
prm.Direction = ParameterDirection.Output
cn.Open()
Dim dr As OdbcDataReader = cmd.ExecuteReader()
While dr.Read
Console.WriteLine(dr.GetString(0))
End While
dr.Close()
Console.WriteLine("Average Freight (output param): {0}", cmd.Parameters(2).Value)
Console.WriteLine("Order Count (return value): {0}", cmd.Parameters(0).Value)
Catch o As OdbcException
MsgBox(o.Message.ToString)
Finally
cn.Close()
End Try
- Run the project. This code calls the "usp_TestParameters"
stored procedure that we created in step 1 above, passing in the CustomerID as
a single input parameter, and returns a resultset, an output parameter and a
return value. In the Output window, you should see the list of orders placed by
Northwind customer ALFKI, the average freight the customer paid per order, and
the count of orders.
back to the top
- The ADO syntax that is usually used to call stored
procedures, where the name of the procedure alone is provided as the
CommandText, cannot be used with the ODBC .NET Managed Provider.
- When a stored procedure returns a resultset, the output
parameter(s) and return value are not available until the resultset has been
accessed and closed. For example, if we omitted the line "dr.Close()" in the
second sample above, we would be unable to retrieve the values for the output
parameter and the return value.
- The ODBC .NET Managed Provider, like the OLE DB Provider,
processes parameters by ordinal position (zero-based) and not by
name.
- The ODBC .NET Managed Provider does not ship with Visual
Studio .NET, but must be downloaded separately.
back to the top
REFERENCES For additional information on the ODBC CALL syntax, see the
topic "Procedure Calls" in the ODBC Programmer's Reference in the MSDN
Library.
back to the top
Modification Type: | Minor | Last Reviewed: | 7/1/2004 |
---|
Keywords: | kbDatabase kbHOWTOmaster kbSystemData KB309486 kbAudDeveloper |
---|
|