Consulting

Results 1 to 4 of 4

Thread: Look up values of Excel in Access table

  1. #1
    VBAX Newbie
    Joined
    Jan 2005
    Posts
    1
    Location

    Look up values of Excel in Access table

    Dear All,

    I have a list of product codes in Excel (column A) and I need for each one of them to connect to an Access database and retrieve the corresponding sales value and have it in column B.

    I have tried exporting the table from Access to Excel but then the vlookup takes a long time. The opposite, importing the product codes in Access, is even harder because I have 50 worksheets where the field name is not always the same and sometimes the lookup value is in different columns.

    I was looking for a query on Access that would have as criteria-input the cells of Excel where the product codes are.

    TIA,

    cosalex

  2. #2
    BoardCoder
    Licensed Coder
    VBAX Expert mark007's Avatar
    Joined
    May 2004
    Location
    Leeds, UK
    Posts
    622
    Location
    Something like the following in a code module:


    Dim c As ADODB.Connection
    Dim r As ADODB.Recordset
    Const DB_PATH As String = "C:\mydb.mdb"
    
    Sub Auto_Open()
        Set c = New ADODB.Connection
        c.Open "Provider=Microsoft.Jet.OLEDB.4.0;Data Source=" & DB_PATH
    End Sub
    
    Sub Auto_Close()
        If c.State = adStateOpen Then
            c.Close
        End If
        Set c = Nothing
    End Sub
    
    
    Function SalesValue(ProductCode As String) As Double
    If c.State = adStateClosed Then
            Auto_Open
        End If
    Set r = c.Execute("select SalesValue from AccessTableName where ProductCode=" & ProductCode)
        SalesValue = CDbl(r.Fields(0).Value)
    End Function
    You will need to edit the SQL query slightly to fit your table and column names and also set the DB_PATH constant for your db. Additionally I have assumed that sales value is a decimal amount and used a double to return it. Change as appropriate.

    You can then call the funcytion in colB using
    =SalesValue(A1).
    "Computers are useless. They can only give you answers." - Pablo Picasso
    Mark Rowlinson FIA | The Code Net

  3. #3
    Site Admin
    Urban Myth
    VBAX Guru
    Joined
    May 2004
    Location
    Oregon, United States
    Posts
    4,940
    Location
    Moved thread to Excel Help forum leaving Redirect in Access Help forum for cross-forum applicability.

  4. #4
    Moderator VBAX Guru Ken Puls's Avatar
    Joined
    Aug 2004
    Location
    Nanaimo, BC, Canada
    Posts
    4,001
    Location
    FYI, in order to use Mark's code, you will need to set a reference to the "Microsoft ActiveX Data Objects Library (pick the most recent you have access to.)

    HTH,
    Ken Puls, CMA - Microsoft MVP (Excel)
    I hate it when my computer does what I tell it to, and not what I want it to.

    Learn how to use our KB tags! -||- Ken's Excel Website -||- Ken's Excel Forums -||- My Blog -||- Excel Training Calendar

    This is a shameless plug for my new book "RibbonX - Customizing the Office 2007 Ribbon". Find out more about it here!

    Help keep VBAX clean! Use the 'Thread Tools' menu to mark your own threads solved!





Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •