IfNa+Vlookup lead to an error 1004

Saab95

New Member
Joined
Mar 26, 2021
Messages
23
Office Version
  1. 365
Platform
  1. Windows
Hi there,

I tried to do a VBA that insert a formula into a specific cell.

Formula is:
Range("Y2").Formula = "=IfNa(VLOOKUP(X2,ECB!$A$2:$AA$10000,25,FALSE),"")"
Range("Y2").AutoFill Range("Y2:Y20000")

But I get an run time error 1004 Application defined or object defined error.

I have also tried with :
Sub Test()
With Worksheets("Master Sheet").Range("V2").Formula = "=IFNA(VLOOKUP(U2,'Collateral UCCS'!A1:R20000,18,FALSE,"")"
End With
End Sub

This time no error but nothing is inserted in the cell.

Been thru many threads but can't get a solution.

Strangely I had no issue with a simple VLOOKUP with no IfNa
Range("R2").Formula = "=VLOOKUP(A2,'PALA QLR'!$A$2:$F$4998,2,0)"
Range("R2").AutoFill Range("R2:R20000")

If you can help.
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
36,748
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2010
Platform
  1. Windows
  2. MacOS
You need to double up any quotes within the quoted formula string:

Code:
Range("Y2").Formula = "=IfNa(VLOOKUP(X2,ECB!$A$2:$AA$10000,25,FALSE),"""")"
 
Solution

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,969
Office Version
  1. 365
Platform
  1. Windows
Hi & welcome to MrExcel.
You need to double-up on the quotes inside the formula like
VBA Code:
Range("Y2").Formula = "=IfNa(VLOOKUP(X2,ECB!$A$2:$AA$10000,25,FALSE),"""")"
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,969
Office Version
  1. 365
Platform
  1. Windows
Glad we could help & thanks for the feedback.
 

Watch MrExcel Video

Forum statistics

Threads
1,130,323
Messages
5,641,530
Members
417,215
Latest member
Diaryman

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
Top