Querying Access table from Excel

ITWater

Board Regular
Joined
Jan 10, 2006
Messages
59
Hi

I am trying to query an MS Access table from Excel.

In Access I have 3 fields, A, B and C. 1.8 million rows, hence cannot just bring it into Excel.

In Excel I have A and B, I want to return C from the Access table.

Any ideas?

Thanks
 

Excel Facts

How to create a cell-sized chart?
Tiny charts, called Sparklines, were added to Excel 2010. Look for Sparklines on the Insert tab.
Hi

This is some code posted previously on this board (I think by dk - not 100% sure about this) that you can use in a worksheet formula to return values:

Code:
Dim adoCN As ADODB.Connection
Dim strSQL As String

Const DatabasePath As String = "C:\MyDatabase.mdb"  'amend as required

'Function argument descriptions
'LookupFieldName - the field you wish to search
'LookupValue - the value in LookupFieldName you're searching for
'ReturnField - the matching field containing the value you wish to return

Public Function DBVLookUp(TableName As String, _
                          LookUpFieldName As String, _
                          LookupValue As String, _
                          ReturnField As String) As Variant
    Dim adoRS As ADODB.Recordset
    If adoCN Is Nothing Then SetUpConnection

    Set adoRS = New ADODB.Recordset
    strSQL = "SELECT " & LookUpFieldName & ", " & ReturnField & _
             " FROM " & TableName & _
             " WHERE " & LookUpFieldName & "='" & LookupValue & "';"
             ' If lookup value is a number then remove the two '
    adoRS.Open strSQL, adoCN, adOpenForwardOnly, adLockReadOnly
    If adoRS.BOF And adoRS.EOF Then
        DBVLookUp = "Value not Found"
    Else
        DBVLookUp = adoRS.Fields(ReturnField).Value
    End If
    adoRS.Close
End Function

Sub SetUpConnection()
    On Error GoTo ErrHandler
    Set adoCN = New Connection
    adoCN.Provider = "Microsoft.Jet.OLEDB.4.0"  'Change to 3.51 for Access 97
    adoCN.ConnectionString = "Data Source=" & DatabasePath & ";Jet OLEDB:Database Password=finance;"
    adoCN.Open
    Exit Sub
ErrHandler:
    MsgBox Err.Description, vbExclamation, "An error occurred"
End Sub

Paste this into a module in your workbook and set a reference to ADo (via Tools>References and check Microsost ActiveX Data Objects 2.X).

Use in your worksheet like:

=DBVLOOKUP(TableName,LookupFieldName,LookupValue,ReturnField)

You will need to amend the database path at the top of the code.
 
Upvote 0

Forum statistics

Threads
1,215,575
Messages
6,125,631
Members
449,241
Latest member
NoniJ

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top