Vlookup within a vlookup? Is there such a thing?

creator007

New Member
Joined
Jun 29, 2010
Messages
23
Is there such a formula for a vlookup within a vlookup?

I have data located on the left. On the right, I want to create a formula to where I can generate the price, which is dependent on the region, state and the type of package.

Please help. Thanks,
 
Last edited:

Excel Facts

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.
<br /><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th><th>H</th><th>I</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">2</td><td style="font-weight: bold;;">Region</td><td style="font-weight: bold;;">State</td><td style="font-weight: bold;;">Package</td><td style="font-weight: bold;;">Price</td><td style="text-align: right;;"></td><td style="font-weight: bold;;">Region</td><td style="font-weight: bold;;">State</td><td style="font-weight: bold;;">Package</td><td style="font-weight: bold;;">Price</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">Eastern</td><td style=";">MA</td><td style=";">Plastic</td><td style="text-align: right;;"> $ 1.00 </td><td style="text-align: right;;"></td><td style=";">Eastern</td><td style=";">MA</td><td style=";">Foam</td><td style="text-align: right;background-color: #FFFF99;;"> $ 2.00 </td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">Eastern</td><td style=";">MA</td><td style=";">Foam</td><td style="text-align: right;;"> $ 2.00 </td><td style="text-align: right;;"></td><td style=";">Eastern</td><td style=";">MA</td><td style=";">Plastic</td><td style="text-align: right;background-color: #FFFF99;;"> $ 1.00 </td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">Eastern</td><td style=";">CT</td><td style=";">Metal</td><td style="text-align: right;;"> $ 3.00 </td><td style="text-align: right;;"></td><td style=";">Eastern</td><td style=";">CT</td><td style=";">Metal</td><td style="text-align: right;background-color: #FFFF99;;"> $ 3.00 </td></tr></tbody></table><br /><br /><table cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">I3</th><td style="text-align:left">{=INDEX(<font color="Blue">$D$3:$D$5,MATCH(<font color="Red">1,(<font color="Green">$A$3:$A$5=F3</font>)*(<font color="Green">$B$3:$B$5=G3</font>)*(<font color="Green">$C$3:$C$5=H3</font>),0</font>)</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">I4</th><td style="text-align:left">{=INDEX(<font color="Blue">$D$3:$D$5,MATCH(<font color="Red">1,(<font color="Green">$A$3:$A$5=F4</font>)*(<font color="Green">$B$3:$B$5=G4</font>)*(<font color="Green">$C$3:$C$5=H4</font>),0</font>)</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">I5</th><td style="text-align:left">{=INDEX(<font color="Blue">$D$3:$D$5,MATCH(<font color="Red">1,(<font color="Green">$A$3:$A$5=F5</font>)*(<font color="Green">$B$3:$B$5=G5</font>)*(<font color="Green">$C$3:$C$5=H5</font>),0</font>)</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />
 
Upvote 0
If there is only one price for each product in each state try

=SUMPRODUCT(--(A3:A10=G3),--(B3:B10=H3),--(C3:C10=I3),(D3:D10))
with the range changed to suit your data
 
Upvote 0
Try This
<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th><th>H</th><th>I</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">2</td><td style="font-weight: bold;border-top: 1px solid black;background-color: #FFFFFF;;">Region</td><td style="font-weight: bold;border-top: 1px solid black;background-color: #FFFFFF;;">State</td><td style="font-weight: bold;border-top: 1px solid black;background-color: #FFFFFF;;">Package</td><td style="font-weight: bold;border-top: 1px solid black;background-color: #FFFFFF;;">Price</td><td style="text-align: right;border-top: 1px solid black;background-color: #FFFFFF;;"></td><td style="font-weight: bold;border-top: 1px solid black;background-color: #FFFFFF;;">Region</td><td style="font-weight: bold;border-top: 1px solid black;background-color: #FFFFFF;;">State</td><td style="font-weight: bold;border-top: 1px solid black;background-color: #FFFFFF;;">Package</td><td style="font-weight: bold;border-top: 1px solid black;border-right: 1px solid black;background-color: #FFFFFF;;">Price</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="background-color: #FFFFFF;;">Eastern</td><td style="background-color: #FFFFFF;;">MA</td><td style="background-color: #FFFFFF;;">Plastic</td><td style="text-align: right;background-color: #FFFFFF;;">$ 1.00</td><td style="text-align: right;background-color: #FFFFFF;;"></td><td style="background-color: #FFFFFF;;">Eastern</td><td style="background-color: #FFFFFF;;">MA</td><td style="background-color: #FFFFFF;;">Foam</td><td style=";">$ 2.00</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="background-color: #FFFFFF;;">Eastern</td><td style="background-color: #FFFFFF;;">MA</td><td style="background-color: #FFFFFF;;">Foam</td><td style="text-align: right;background-color: #FFFFFF;;">$ 2.00</td><td style="text-align: right;background-color: #FFFFFF;;"></td><td style="background-color: #FFFFFF;;">Eastern</td><td style="background-color: #FFFFFF;;">MA</td><td style="background-color: #FFFFFF;;">Plastic</td><td style=";">$ 1.00</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="border-bottom: 1px solid black;background-color: #FFFFFF;;">Eastern</td><td style="border-bottom: 1px solid black;background-color: #FFFFFF;;">CT</td><td style="border-bottom: 1px solid black;background-color: #FFFFFF;;">Metal</td><td style="text-align: right;border-bottom: 1px solid black;background-color: #FFFFFF;;">$ 3.00</td><td style="text-align: right;border-bottom: 1px solid black;background-color: #FFFFFF;;"></td><td style="border-bottom: 1px solid black;background-color: #FFFFFF;;">Eastern</td><td style="border-bottom: 1px solid black;background-color: #FFFFFF;;">CT</td><td style="border-bottom: 1px solid black;background-color: #FFFFFF;;">Metal</td><td style=";">$ 3.00</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">I3</th><td style="text-align:left">=LOOKUP(<font color="Blue">2,1/(<font color="Red">(<font color="Green">$A$3:$A$5=F3</font>)*(<font color="Green">$B$3:$B$5=G3</font>)*(<font color="Green">$C$3:$C$5=H3</font>)</font>),$D$3:$D$5</font>)</td></tr></tbody></table></td></tr></table><br />
 
Upvote 0

Forum statistics

Threads
1,224,541
Messages
6,179,418
Members
452,912
Latest member
alicemil

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