Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.
The following three methods demonstrate the use of parameters in ADO.
NOTE: The sample code in this article uses Microsoft ActiveX Data Objects. For this code to run properly, you must reference the Microsoft ActiveX Data Objects 2.x Library (where 2.x is 2.1 or later.) To do so, click
References on the
Tools menu in the Visual Basic Editor, and make sure that the
Microsoft ActiveX Data Objects 2.x Library check box is selected.
NOTE: The sample code in this article also uses ADO Extensions for DDL and Security. For this code to run properly, you must reference the Microsoft ADO Ext. 2.1 for DDL and Security.
CAUTION: If you follow the steps in this example, you modify the sample database Northwind.mdb. You may want to back up the Northwind.mdb file and follow these steps on a copy of the database.
Method 1: Manually Creating an Explicit Parameter in a Query
-
Open the sample database Northwind.mdb.
- Create the following new query name MyQuery1:
Query: MyQuery1
-------------------
Type: Select Query
Field: CustomerID
Table: Customers
Criteria: [MyParam]
Field: CompanyName
Table: Customers
-
On the Query menu, click Parameters.
-
In the Query Parameters dialog box, type MyParam under Parameter and enter Text under Data Type.
-
Save the query and run it.
-
When you are prompted for the parameter, MyParam, type ALFKI in the Enter Parameter Value dialog box. Note that the query returns one record.
-
Create a new module and type the following procedure:
Sub TestParam()
Dim cat As New ADOX.Catalog
Dim cmd As ADODB.Command
Dim rs As ADODB.Recordset
cat.ActiveConnection = CurrentProject.Connection
Set cmd = cat.Procedures("MyQuery1").Command
If Not (cmd Is Nothing) Then
cmd.Parameters("MyParam").Value = "ALFKI"
Set rs = cmd.Execute
rs.MoveFirst
Debug.Print rs!CustomerID, rs!CompanyName
rs.Close
End If
Set cmd = Nothing
End Sub
-
Type the following line in the Immediate window, and then press ENTER:
Note that the following line is returned in the Immediate window:
ALFKI Alfreds Futterkiste
Method 2: Creating an Explicit Parameter Through ADO Before You Refer to It.
-
Open the sample database Northwind.mdb.
- Create the following new query named MyQuery2:
Query: MyQuery2
--------------------
Type: Select Query
Field: CustomerID
Table: Customers
Criteria: [MyParam]
Field: CompanyName
Table: Customers
-
Create a new module and type the following procedure:
Sub SetParam()
Dim cat As New ADOX.Catalog
Dim cmd As ADODB.Command
Dim rs As ADODB.Recordset
Dim prm As ADODB.Parameter
Dim strCustID As String
strCustID = "ALFKI"
cat.ActiveConnection = CurrentProject.Connection
Set cmd = cat.Procedures("MyQuery2").Command
Set prm = cmd.CreateParameter("MyParam", adVarChar, _
adParamInput, Len(strCustID))
cmd.Parameters.Append prm
If Not (cmd Is Nothing) Then
cmd.Parameters("MyParam").Value = strCustID
Set rs = cmd.Execute
rs.MoveFirst
Debug.Print rs!CustomerID, rs!CompanyName
rs.Close
End If
Set cmd = Nothing
End Sub
-
Type the following line in the Immediate window, and then press ENTER:
Note that the following line is returned in the Immediate window:
ALFKI Alfreds Futterkiste
Method 3: Using an Implicit Parameter
NOTE: Implicit parameter names have brackets ([ ]) around them, and you must use the brackets (or the parameter's ordinal position) when referring to implicit parameters in the
Parameters collection. If you do not use the brackets, you receive the following error message:
Run-time error '3265':
ADO could not find the object in the collection corresponding to the name or ordinal reference requested by the application.
-
Open the sample database Northwind.mdb.
- Create the following new query named MyQuery3:
Query: MyQuery3
-------------------
Type: Select Query
Field: CompanyID
Table: Customers
Criteria: [MyParam]
Field: CompanyName
Table: Customers
-
Save the query and run it.
-
When you are prompted for the implicit parameter, MyParam, type ALFKI in the Enter Parameter Value dialog box. Note that the query returns one record.
-
Create a new module and type the following procedure:
Sub ImplicitParam()
Dim cat As New ADOX.Catalog
Dim cmd As ADODB.Command
Dim rs As ADODB.Recordset
cat.ActiveConnection = CurrentProject.Connection
Set cmd = cat.Procedures("MyQuery3").Command
If Not (cmd Is Nothing) Then
cmd.Parameters("[MyParam]").Value = "ALFKI"
Set rs = cmd.Execute
rs.MoveFirst
Debug.Print rs!CustomerID, rs!CompanyName
rs.Close
End If
Set cmd = Nothing
End Sub
-
Type the following line in the Immediate window, and then press ENTER:
Note that the following line is returned in the Immediate window:
ALFKI Alfreds Futterkiste