FormulaR1C1 with Index

twikken

New Member
Joined
Jul 12, 2010
Messages
3
Code:
ActiveCell.FormulaR1C1 = "=INDEX(Sales!$B$2:$ZZ$5000,MATCH($A10,Sales!$A$2:$A$5000,0),MATCH(B$9,Sales!$B$1:$ZZ$1,0)))

Can someone please help me with the above? The formula works when I enter it directly into a cell but I can't get it to work when I assign it in vba. I'm sure I'm not using the formula attribute right but can't seem to tweak it to get it to work.

To expand on what I want to do here... I have a sheet that may contain as many as 5000 rows and as many as 400 columns but will usually contain less. What I would like to do is just let the INDEX sit in each cell and only be active when needed but I've found if I fill all these cells with the formula above my computer implodes. Now I'm attempting to use an IF to check whether or not to place the formula in the cell.... Is there a better way.
 
Last edited:

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
When using the .FormulaR1C1 property the R1C1 formula would be something like this.
Code:
ActiveCell.FormulaR1C1 = _
 "=INDEX(Sales!R2C2:R5000C256,MATCH(R[9]C1,Sales!R2C1:R5000C1,0),MATCH(R9C[-1],Sales!R1C2:R1C256,0))"
the relative addresses in brackets may need to be adjusted.
 
Upvote 0

Forum statistics

Threads
1,214,925
Messages
6,122,301
Members
449,078
Latest member
nonnakkong

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