Variable VLookup based on Cell Value

BishopDesigns

New Member
Joined
Oct 14, 2015
Messages
10
Hello Everyone

Can anyone help me with my formula

I need to do a VLookup on a Cell but the Table Array needs to be different based on the Value of another Cell.

=IF(B5="Office",VLOOKUP($B$9,matrix!$D$2:$F$100,2,FALSE),IF(B5="Production",VLOOKUP($B$9,matrix!$AG$2:$AJ$100,2,FALSE),"0"))

Any suggestions/assistance would be greatly appreciated!
 

Some videos you may like

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
12,594
Office Version
  1. 2007
Platform
  1. Windows
Do you have other information besides "Office" and "Production"?

If so, you can create a table with item and its respective Table Array


<b>Table Item-Table Array</b><br /><br /><table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:80px;" /><col style="width:145px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >G</td><td >H</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >Office</td><td >matrix!$D$2:$F$100</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >Production</td><td >matrix!$AG$2:$AJ$100</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td > </td><td > </td></tr></table> <br /><br />




Try this

<b></b><br /><br /><table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:80px;" /><col style="width:146px;" /><col style="width:80px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td > </td><td >Office</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >9</td><td > </td><td >data</td><td >result</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >C9</td><td >=VLOOKUP(B9,INDIRECT(VLOOKUP(B5,G1:H4,2,0)),2,0)</td></tr></table></td></tr></table> <br /><br />
 

BishopDesigns

New Member
Joined
Oct 14, 2015
Messages
10
I do not have any other values. Office and Production are the only 2 values
I created the Table as suggested and pointed the Formula at it

Code:
=VLOOKUP(B9,INDIRECT(VLOOKUP(B5,J3:K6,2,0)),2,0)

but still no go :(
 
Last edited by a moderator:

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
53,203
Office Version
  1. 365
Platform
  1. Windows
In what way doesn't your formula work?

Also please do not quote entire posts, as it just clutters up the thread.
 

bosco_yip

Well-known Member
Joined
Dec 2, 2002
Messages
1,938
Office Version
  1. 2019
Platform
  1. Windows

ADVERTISEMENT

Or,

=IFERROR(VLOOKUP($B$9,IF(B5="Office",matrix!$D$2:$F$100,matrix!$AG$2:$AJ$100),2,FALSE),0)

Regards
Bosco
 

bosco_yip

Well-known Member
Joined
Dec 2, 2002
Messages
1,938
Office Version
  1. 2019
Platform
  1. Windows

ADVERTISEMENT

If you want return #N/A, just remove the IFERROR part and become :

=VLOOKUP($B$9,IF(B5="Office",matrix!$D$2:$F$100,matrix!$AG$2:$AJ$100),2,FALSE)

Regards
Bosco
 
Last edited:

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
12,594
Office Version
  1. 2007
Platform
  1. Windows
Hello Everyone

Can anyone help me with my formula

I need to do a VLookup on a Cell but the Table Array needs to be different based on the Value of another Cell.

=IF(B5="Office",VLOOKUP($B$9,matrix!$D$2:$F$100,2,FALSE),IF(B5="Production",VLOOKUP($B$9,matrix!$AG$2:$AJ$100,2,FALSE),"0"))

Any suggestions/assistance would be greatly appreciated!


Then you can explain what you need?
Or what problem do you have with your formula?
 

Watch MrExcel Video

Forum statistics

Threads
1,123,125
Messages
5,599,841
Members
414,342
Latest member
K Darrell Smith

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
Top