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:

Some videos you may like

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,769
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.
 

Subscribe on YouTube

Watch MrExcel Video

Forum statistics

Threads
1,106,212
Messages
5,509,865
Members
408,757
Latest member
Jamarr123

This Week's Hot Topics

  • Turn fraction around
    Hello I need to turn a fraction around, for example I have 1/3 but I need to present as 3/1
  • TIme Clock record reformatting to ???
    Hello All, I'd like some help formatting this (Tbl-A)(Loaded via Power Query) [ATTACH type="full" width="511px" alt="PQdata.png"]22252[/ATTACH]...
  • TextBox Match
    hi, I am having a few issues with my code below, what I need it to do is when they enter a value in textbox8 (QTY) either 1,2 or 3 the 3 textboxes...
  • Using Large function based on Multiple Criteria
    Hello, I can't seem to get a Large formula to work based on two criteria's. I can easily get a oldest value based one value, but I'm struggling...
  • Can you check my code please
    Hi, Im going round in circles with a Compil Error End With Without With Here is the code [CODE=rich] Private Sub...
  • Combining 2 pivot tables into 1 chart
    Hello everyone, My question sounds simple but I do not know the answer. I have 2 pivot tables and 2 charts that go with this. However I want to...
Top