Dynamically changing vlookup table

snoh8r

New Member
Joined
Jan 30, 2018
Messages
22
Office Version
  1. 365
Platform
  1. Windows
Every month I run a report whereas the table size changes. I need to be able to account for that.

I recorded this:
Code:
<code>Range("B1").FormulaR1C1 = _
        "=IF(VLOOKUP(RC1,sorted!R3C1:R35C33,8,FALSE)="""","""",VLOOKUP(RC1,sorted!R3C1:R35C33,8,FALSE))"</code>
I need to have it update dynamically.
I found this (modified for my needs), but I'm not sure what to put in the "?" fields. Hopefully I'm on the right track:
Code:
With Worksheets("Move to New")
<code>.Range("B1").Offset(x, 0) = Application.WorksheetFunction.VLookup( _
         .Range("?").Offset(x, 0), _
         Worksheets("sorted").Range("?", .Range("?").End(xlDown)), 8, False)</code>

I'm just not sure what R3C1:R35C33 is pointing at. Do I even need the above code or could I just update to R3C1:R350C33 as the row count should never get higher than 350. I'm assuming that is the row count.

Thanks.
 

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
The RC reference is your table array that you used in the VLOOKUP you recorded. It stands for row3 column1 (A3) to row35 column33 (AG35). Anyway you could maybe get away using a column ref

Code:
Range("B1").FormulaR1C1 = "=IF(VLOOKUP(RC1,sorted!C1:C33,8,FALSE)="""","""",VLOOKUP(RC1,sorted!C1:C33,8,FALSE))"

or maybe this:

Code:
lr = Sheets("sorted").Range("A" & Rows.Count).End(xlUp).Row
Range("B1").FormulaR1C1 = "=IF(VLOOKUP(RC1,sorted!R3C1:R" & lr & "C33,8,FALSE)="""","""",VLOOKUP(RC1,sorted!R3C1:R" & lr & "C33,8,FALSE))"

Look at the formulas they create to see which one works for you.
 
Upvote 0

Forum statistics

Threads
1,223,909
Messages
6,175,312
Members
452,634
Latest member
cpostell

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