VBA - Xlookup to Get Data From External Workbook

Dubbii

New Member
Joined
Aug 27, 2023
Messages
3
Office Version
  1. 2021
Platform
  1. Windows
Hi,

I'm having trouble retrieving data from an external workbook using Xlookup in VBA. I can get the code to work with a worksheet in the same workbook, but not another workbook. The error message is 1004 Application-defined or object-defined error and its showing on the .formula line.

I'm trying to import the related data from the "TbClaims" table using the reference numbers in column A of both sheets. The code is still incomplete as I'll need to add the data from the other related columns from "TbClaims".

I would like to use column headers as lookup values because the column positions may change. Also if there are any suggestions as to changing other parts of the code to reference the column headers, it would be very much appreciated.

I'm very new to VBA. Here is the code:

VBA Code:
Sub IMPORT_DATA_CLAIMS()

    Dim ewb As Workbook, twb As Worksheet, ews As Worksheet
    Dim lr As Long, i As Long
    Dim TableName As ListObject
 
    Set twb = ThisWorkbook.Sheets("Minutes")
    Set ewb = Workbooks.Open("Excel - Claim reg demo.xlsx")
    Set ews = ewb.Worksheets("Claims")
    Set TableName = ews.ListObjects("TbClaims")
 
    lr = twb.Range("A" & Rows.Count).End(xlUp).Row
 
    For i = 1 To lr
        If Range("G" & i).Value = "" Then
            With Range("J" & i)
                .Formula = "=XLOOKUP([@Ref],TableName[Reference],TableName[Amount Granted],"""")"
                .Value = .Value
            End With
        End If
    Next i
 
    ewb.Close
 
End Sub
 

Attachments

  • MinutesTable.png
    MinutesTable.png
    12.5 KB · Views: 56
  • TbClaims.png
    TbClaims.png
    25.5 KB · Views: 54

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
Try...

VBA Code:
.Formula = "=XLOOKUP([@Ref]," & TableName.Name & "[Reference]," & TableName.Name & "[Amount Granted],"""")"

Or, alternatively...

VBA Code:
.Formula = "=XLOOKUP([@Ref],TbClaims[Reference],TbClaims[Amount Granted],"""")"

Hope this helps!
 
Upvote 0
Try...

VBA Code:
.Formula = "=XLOOKUP([@Ref]," & TableName.Name & "[Reference]," & TableName.Name & "[Amount Granted],"""")"

Or, alternatively...

VBA Code:
.Formula = "=XLOOKUP([@Ref],TbClaims[Reference],TbClaims[Amount Granted],"""")"

Hope this helps!
Hi Domenic,

Thanks for taking the time to respond. Unfortunately, the code is still not working. I think I might just look for an alternate approach without using tables.

Thanks for your help.
 
Upvote 0
You need to include the workbook name in the formula (just as you would manually) if the table is in a different workbook:

VBA Code:
.Formula = "=XLOOKUP([@Ref],'" & ewb.name & "'!" & TableName.Name & "[Reference],'" & ewb.name & "'!" & & TableName.Name & "[Amount Granted],"""")"
 
Upvote 0
Solution
You need to include the workbook name in the formula (just as you would manually) if the table is in a different workbook:

VBA Code:
.Formula = "=XLOOKUP([@Ref],'" & ewb.name & "'!" & TableName.Name & "[Reference],'" & ewb.name & "'!" & & TableName.Name & "[Amount Granted],"""")"
Hi Rory,

Awesome! Thank you that worked.
 
Upvote 0

Forum statistics

Threads
1,223,162
Messages
6,170,432
Members
452,326
Latest member
johnshaji

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