Total Visual SourceBook

Total Visual SourceBook CD and Printed Manual

Microsoft Access/ Office 2016, 2013, 2010, and 2007 Version
is Shipping!

New features in Total Visual SourceBook for Access, Office 2007 and VB6

Supports Access/Office 2016, 2013, 2010 and 2007, and Visual Basic 6.0!

Separate version for Access/Office 2003, 2002, and 2000.

Separate version for:
Access 97/95


View all FMS products for Microsoft AccessAll Our Microsoft Access Products

SourceBook Info:

Why SourceBook?

 

"The code is exactly how I would like to write code and the algorithms used are very efficient and well-documented."

Van T. Dinh, Microsoft MVP

 

 

 

Microsoft Access, Office/VBA, VB6 Modules royalty-free source code libraryMicrosoft Access Modules royalty-free source code libraryMicrosoft Access VBA and VB6 Module Library Free trial of Total Visual SourceBook for Microsoft Access, Office, VB6 and VBA

Module: QueriesADO in Category Access/Jet Databases : Table and Records from Total Visual SourceBook

Create, execute, and browse Microsoft Access queries in the current project using ADO for MDB, ACCDB and ADP formats in Access VBA.

Procedure List

Procedure Name

Type

Description

(Declarations) Declarations Declarations and private variables for the modQueriesADO module
ExecuteQuerySQLADO Procedure Run a saved action query or SQL string in the current database.
ExecuteQueryParameterADO Procedure Run a query that requires a parameter (the query must be an action query).
ExecuteQueryParametersADO Procedure Run a query that requires multiple parameters (the query must be an action query).
OpenRecordsetSQLADO Procedure Open a ADO recordset to a SQL string that retrieves records (can't be an action query).
OpenRecordsetQueryADO Procedure Open a ADO recordset on a query that retrieves records (can't be an action query).
OpenRecordsetParameterADO Procedure Open an ADO recordset on a query that requires a parameter and retrieves records (can't be an action query).
OpenRecordsetParametersADO Procedure Open an ADO recordset on a query that uses multiple parameters and retrieves records (can't be an action query).

Example Code for Using Module: QueriesADO

' Example of modQueriesADO
'
' To try this example, do the following:
' 1. Create a new user form in the sample database: C:\Total Visual SourceBook 2013\Samples\Sample.mdb
'    This example assumes that it is being run inside the Sample.mdb database that is installed with Total Visual SourceBook.
'    To run it in another database, create the following objects in the current database:
'    Object Type     Name                     Details
'    -----------------------------------------------------------------------------------------------
'    Table           Customers                Import from C:\Total Visual SourceBook 2013\Samples\Sample.mdb
'    Query           qryDeleteTest_Prm        DELETE * FROM FMS_TEST WHERE country = [prmCountry]
'    Query           qryDeleteTest_Prms       DELETE * FROM FMS_TEST WHERE country = [prmCountry1] OR country = [prmCountry2]
'    Query           qrySelectCustomers_Prm   SELECT Customers.CustomerID, Customers.CompanyName FROM Customers WHERE Customers.Country=[prmCountry]
'    Query           qrySelectCustomers_Prms  SELECT Customers.CustomerID, Customers.CompanyName FROM Customers WHERE Customers.Country=[prmCountry] AND Customers.Region = [prmState]
' 2. Create a command button 'cmdTest'
' 3. Paste this code into the form's module

Private Sub cmdTest_Click()

  Dim rst As New ADODB.Recordset
  Dim strSQL As String
  Dim lngAffected As Long
  Dim astrParamNames(0 To 1) As String
  Dim avarParamVals(0 To 1) As Variant
  Dim aeParamDataTypes(0 To 1) As ADODB.DataTypeEnum
  Dim alngParamSizes(0 To 1) As Long
  Dim intCounter As Integer

  On Error GoTo PROC_ERR

  ' Example of ExecuteQuerySQLADO to create a new table with records from the customers table (MAKE TABLE query)
  ' Make sure FMS_TEST table does not exist before running this
  strSQL = "SELECT Customers.CustomerID, Customers.CompanyName, Customers.ContactName, Customers.ContactTitle, Customers.Address, " & _
           "Customers.City, Customers.Region, Customers.PostalCode, Customers.Country, Customers.Phone, Customers.Fax " & _
           "INTO FMS_TEST FROM Customers"
  Debug.Print "Testing ExecuteQuerySQLADO..."
  lngAffected = ExecuteQuerySQLADO(strSQL)
  Debug.Print lngAffected & " records affected."

  ' Example of ExecuteQueryParameterADO
  ' SQL string for qryDeleteTest_Prm is: "DELETE * FROM FMS_TEST WHERE country = [prmCountry]"
  Debug.Print "Testing ExecuteQueryParameterADO..."
  lngAffected = ExecuteQueryParameterADO("qryDeleteTest_Prm", "prmCountry", "Germany", adVarChar, 50)
  Debug.Print lngAffected & " records affected."

  ' Example of ExecuteQueryParametersADO
  ' SQL string for qryDeleteTest_Prms is: "DELETE * FROM FMS_TEST WHERE country = [prmCountry1] OR country = [prmCountry2]"
  astrParamNames(0) = "prmCountry1"
  avarParamVals(0) = "UK"
  astrParamNames(1) = "prmCountry2"
  avarParamVals(1) = "Spain"
  aeParamDataTypes(0) = adVarChar
  aeParamDataTypes(1) = adVarChar
  alngParamSizes(0) = 50
  alngParamSizes(1) = 50
  Debug.Print "Testing ExecuteQueryParametersADO..."
  lngAffected = ExecuteQueryParametersADO("qryDeleteTest_Prms", astrParamNames, avarParamVals, aeParamDataTypes, alngParamSizes)
  Debug.Print lngAffected & " records affected."

  ' Example of OpenRecordsetSQLADO
  strSQL = "SELECT Customers.CustomerID, Customers.CompanyName FROM Customers"
  Debug.Print "Testing OpenRecordsetSQLADO..."
  If OpenRecordsetSQLADO(strSQL, rst) Then
    Debug.Print "OpenRecordsetSQLADO: First 2 Results for Recordset:"
    For intCounter = 1 To 2
      Debug.Print "   " & intCounter & ". " & rst![CustomerID] & " - " & rst![CompanyName]
      rst.MoveNext
    Next intCounter
  Else
    Debug.Print "OpenRecordsetSQLADO failed."
  End If

  ' Example of OpenRecordsetQueryADO
  ' SQL string for qrySelectCustomers is: "SELECT Customers.CustomerID, Customers.CompanyName FROM Customers"
  Debug.Print "Testing OpenRecordsetQueryADO..."
  If OpenRecordsetQueryADO("qryFMSSelect1", rst) Then
    Debug.Print "OpenRecordsetQueryADO: First 2 Results for Recordset:"
    For intCounter = 1 To 2
      Debug.Print "   " & intCounter & ". " & rst![CustomerID] & " - " & rst![CompanyName]
      rst.MoveNext
    Next intCounter
  Else
    Debug.Print "OpenRecordsetQueryADO failed."
  End If

  ' Example of OpenRecordsetParameterADO
  ' SQL String for qrySelectCustomers_Prm is "SELECT Customers.CustomerID, Customers.CompanyName FROM Customers WHERE Customers.Country=[prmCountry]"
  If OpenRecordsetParameterADO("qrySelectCustomers_Prm", "prmCountry", "USA", adVarChar, 50, rst) Then
    Debug.Print "OpenRecordsetParameterADO: First 2 Results for Recordset:"
    For intCounter = 1 To 2
      Debug.Print "   " & intCounter & ". " & rst![CustomerID] & " - " & rst![CompanyName]
      rst.MoveNext
    Next intCounter
  Else
    Debug.Print "OpenRecordsetParameterADO failed."
  End If

  ' Example of OpenRecordsetParametersADO
  ' SQL String for qrySelectCustomers_Prms is "SELECT Customers.CustomerID, Customers.CompanyName FROM Customers WHERE Customers.Country=[prmCountry] AND Customers.Region = [prmState]"
  astrParamNames(0) = "prmCountry"
  avarParamVals(0) = "USA"
  astrParamNames(1) = "prmState"
  avarParamVals(1) = "WA"
  aeParamDataTypes(0) = adVarChar
  aeParamDataTypes(1) = adVarChar
  alngParamSizes(0) = 50
  alngParamSizes(1) = 50
  If OpenRecordsetParametersADO("qrySelectCustomers_Prms", astrParamNames, avarParamVals, aeParamDataTypes, alngParamSizes, rst) Then
    Debug.Print "OpenRecordsetParametersADO: First 2 Results for Recordset:"
    For intCounter = 1 To 2
      Debug.Print "   " & intCounter & ". " & rst![CustomerID] & " - " & rst![CompanyName]
      rst.MoveNext
    Next intCounter
  Else
    Debug.Print "OpenRecordsetParametersADO failed."
  End If

PROC_EXIT:
  Exit Sub

PROC_ERR:
  MsgBox "Error: " & Err.Number & ". " & Err.Description
  Resume PROC_EXIT
End Sub

Microsoft Access Module LibraryOverview of Total Visual SourceBook

The source code in Total Visual SourceBook includes modules and classes for Microsoft Access, Visual Basic 6 (VB6), and Visual Basic for Applications (VBA) developers. Easily add this professionally written, tested, and documented royalty-free code into your applications to simplify your application development efforts.

Additional Resources