Formula Works In Worksheet, NOT In Macro

clarkerots

New Member
Joined
Mar 29, 2019
Messages
10
I'm using a INDEX/MATCH formula to pull data over from one Excel spreadsheet to another. My goal is that when data ends up as an #NA or #REF , the cell stays blank. I'm using IFERROR for that part. When I enter the formula in the cell, it works fine. When I enter the formula in a macro and run, I get an object error.

The formula in the worksheet is:
=IFERROR(INDEX('[Basketball Scoresheet-Gameday.xlsm]Sheet1'!$AZ$3:$AZ$14,MATCH(A2,'[Basketball Scoresheet-Gameday.xlsm]Sheet1'!$C$3:$C$14,0)),"")

That takes my data in A2, matches it, and displays the data I'm looking to pull. Also, the range on my final worksheet is C2:C22.

In my Macro, called Test, the formula is the following:
Sub Test()

Range("C2:C22").Formula = "=IFERROR(INDEX('[Basketball Scoresheet-Gameday.xlsm]Sheet1'!$AZ$3:$AZ$14,MATCH(A2,'[Basketball Scoresheet-Gameday.xlsm]Sheet1'!$C$3:$C$14,0)),"")"

End Sub

When I run the Macro I get a Run-Time error '1004': Application-defined or object-defined error.

Why would a formula run on a worksheet, and the same exact formula give me an error in a macro?

Any help appreciated. Thank you.
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
You need to double-up on the quotes inside the formula like
Code:
Range("C2:C22").Formula = "=IFERROR(INDEX('[Basketball  Scoresheet-Gameday.xlsm]Sheet1'!$AZ$3:$AZ$14,MATCH(A2,'[Basketball  Scoresheet-Gameday.xlsm]Sheet1'!$C$3:$C$14,0)),"[COLOR=#ff0000]""[/COLOR]")"
 
Upvote 0

Forum statistics

Threads
1,213,490
Messages
6,113,957
Members
448,535
Latest member
alrossman

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