help with vlookup table_array

Honey

New Member
Joined
Sep 22, 2006
Messages
4
Hi,

I'm trying to build a macro that uses a vlookup without using a set table array...since the numbers of rows i'm using to lookup would change monthly. Is it possible for me to set a variable to the table array and then call the variable inside the vlookup formula?

In my macro I'm using the following:
=VLOOKUP(A91,'Current Crosstab'!A1:P200,16,FALSE)

However, next month...this current crosstab worksheet may have up to 300 rows. I don't want to hardcode a large number, I want to be able to count the rows in Current Crosstab and then have the P column update itself in the vlookup formula. Any ideas on how to best accomplish this?

Thanks in advance for your help.
Honey
 

Excel Facts

How can you turn a range sideways?
Copy the range. Select a blank cell. Right-click, Paste Special, then choose Transpose.
I'm no expert but can you name the range for the data output and then refer to the named range in the vlookup. As you add rows in they are included in the named range however not sure if it will work with "an update", If you have a feel for likely number of rows output you could simply name a larger range?
 
Upvote 0
Hi Honey
Welcome to the board

If you are doing it in vba why the vlookup? In this case you don't need worksheet functions. Consider using the Find method.

This example considers the table with a variable number of rows. Looks for A91 of the active sheet in the Worksheet "Current Crosstab" in the range from A1 to the last cell in A with data, and returns the value in the row of the found value in column P.

Code:
Dim rFound As Range, vRes

With Worksheets("Current Crosstab")
    Set rFound = .Range("A1:A" & .Range("A" & .Rows.Count).End(xlUp).Row) _
          .Find(what:=Range("A91").Value, LookIn:=xlValues, lookat:=xlWhole)
    If rFound Is Nothing Then
        vRes = "Not found"
    Else
        vRes = .Cells(rFound.Row, "P").Value
    End If
End With

Hope this helps
PGC
 
Upvote 0

Forum statistics

Threads
1,214,918
Messages
6,122,249
Members
449,075
Latest member
staticfluids

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