ACC2000: How to Use Parameters with ActiveX Data Objects (ADO) and Jet

ID: Q225897


The information in this article applies to:
  • Microsoft Access 2000

Advanced: Requires expert coding, interoperability, and multiuser skills.

This article applies to a Microsoft Access database (.mdb) and a Microsoft Access project (.adp).


SUMMARY

This article shows you how to use explicit and implicit parameters with ActiveX Data Objects (ADO) and Microsoft Jet.


MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support professionals 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 needs. If you have limited programming experience, you may want to contact a Microsoft Certified Solution Provider or the Microsoft fee-based consulting line at (800) 936-5200. For more information about Microsoft Certified Solution Providers, please see the following page on the World Wide Web:

http://www.microsoft.com/mcsp/
For more information about the support options available from Microsoft, please see the following page on the World Wide Web:

http://www.microsoft.com/support/supportnet/overview/overview.asp
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 need to reference the Microsoft ActiveX Data Objects 2.1 Library.

NOTE: The sample code in this article also uses ADO Extensions for DDL and Security. For this code to run properly, you need to reference the Microsoft ADO Ext. 2.1 for DDL and Security.

CAUTION: Following the steps in this example will modify the sample database Northwind.mdb. You may want to back up the Northwind.mdb file and perform these steps on a copy of the database.

Method 1: Manually Creating an Explicit Parameter in a Query

  1. Open the sample database Northwind.mdb.


  2. Create the following new query name MyQuery1:


  3. 
       Query: MyQuery1
       -------------------
       Type: Select Query
    
       Field: CustomerID
       Table: Customers
       Criteria: [MyParam]
    
       Field: CompanyName
       Table: Customers 
  4. On the Query menu, click Parameters.


  5. In the Query Parameters dialog box, type MyParam under Parameter and enter Text under Data Type.


  6. Save the query and run it.


  7. When you are prompted for the parameter, MyParam, type ALFKI in the Enter Parameter Value dialog box. Note that the query returns one record.


  8. Create a new module and type the following procedure:


  9. 
    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 
  10. Type the following line in the Immediate window, and then press ENTER:
    
    TestParam 
    Note that the following line is returned in the Immediate window:


  11. 
       ALFKI         Alfreds Futterkiste 

Method 2: Creating an Explicit Parameter Through ADO Before You Refer to It.

  1. Open the sample database Northwind.mdb.


  2. Create the following new query named MyQuery2:


  3. 
       Query: MyQuery2
       --------------------
       Type: Select Query
    
       Field: CustomerID
       Table: Customers
       Criteria: [MyParam]
    
       Field: CompanyName
       Table: Customers 
  4. Create a new module and type the following procedure:


  5. 
    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 
  6. Type the following line in the Immediate window, and then press ENTER:
    
    SetParam 
    Note that the following line is returned in the Immediate window:


  7. 
       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.
  1. Open the sample database Northwind.mdb.


  2. Create the following new query named MyQuery3:


  3. 
       Query: MyQuery3
       -------------------
       Type: Select Query
    
       Field: CompanyID
       Table: Customers
       Criteria: [MyParam]
    
       Field: CompanyName
       Table: Customers 
  4. Save the query and run it.


  5. 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.


  6. Create a new module and type the following procedure:


  7. 
    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 
  8. Type the following line in the Immediate window, and then press ENTER:
    
    ImplicitParam 
    Note that the following line is returned in the Immediate window:


  9. 
       ALFKI         Alfreds Futterkiste 

Additional query words: inf

Keywords : kbdta AccCon
Version : WINDOWS:2000
Platform : WINDOWS
Issue type : kbhowto


Last Reviewed: September 14, 1999
© 2000 Microsoft Corporation. All rights reserved. Terms of Use.