double vlookup help please

tenone60

New Member
Joined
Apr 28, 2016
Messages
9
Hello,

Can anyone suggest a formula for the cells shaded in yellow in my screen shot? The answers I expect from the formula are also listed below in range C8:C11. Thank you.

Cell Formulas
RangeFormula
A1Product Code
A2123
A3123
A4456
A5456
B1Date Sold
B242384
B342430
B442425
B542468
C1Selling Price
C7answers s/b
C8125
C9130
C10215
C11215
F1Product Code
F2123
F3123
F4456
F5456
G1Price Effective Date
G242339
G342430
G442370
G542475
H1Price
H2125
H3130
H4215
H5245
 

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.
Important: As this is an array formula you need to press "Ctrl+Shift+Enter" after entering the formula in the cell.


Excel 2016
ABCDEFGH
1Product CodeDate SoldSelling PriceProduct CodePrice Effective DatePrice
212301/15/2016$ 125.0012312/01/2015$ 125.00
312303/01/2016$ 130.0012303/01/2016$ 130.00
445602/25/2016$ 215.0045601/01/2016$ 215.00
545604/08/2016$ 215.0045604/15/2016$ 245.00
6
Sheet3
Cell Formulas
RangeFormula
C2=INDEX($H$2:$H$5,MATCH(B2*A2,$G$2:$G$5*$F$2:$F$5,1))
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Last edited:
Upvote 0
In C2 control+shift+enter, not just enter, and copy down:

=MIN(IF($F$2:$F$6=$A2,IF($G$2:$G$6<=$B2,$H$2:$H$6)))

With some control...

=IFERROR(1/(1/MIN(IF($F$2:$F$6=$A2,IF($G$2:$G$6<=$B2,$H$2:$H$6)))),"")
 
Upvote 0
Thanks! The formula returned the correct answer in all cells except C3. Could it be that the portion of the formula where G2:G5 <=B3 is deemed “true” for both dates 12/1/15 and 3/1/16 so the answer defaults to the first “true” it encounters or does the answer default to the MIN price when there are two “true” possibilities? Thanks again!

Unknown
ABCDEFGH
1Product CodeDate SoldSelling PriceProduct CodePrice Effective DatePrice
21231/15/201612512312/1/2015$ 125.00
31233/1/20161251233/1/2016$ 130.00
44562/25/20162154561/1/2016$ 215.00
54564/8/20162154564/15/2016$ 245.00
Sheet1
Cell Formulas
RangeFormula
C2{=MIN(IF($F$2:$F$5=A2,IF($G$2:$G$5<=B2,$H$2:$H$5)))}
C3{=MIN(IF($F$2:$F$5=A3,IF($G$2:$G$5<=B3,$H$2:$H$5)))}
C4{=MIN(IF($F$2:$F$5=A4,IF($G$2:$G$5<=B4,$H$2:$H$5)))}
C5{=MIN(IF($F$2:$F$5=A5,IF($G$2:$G$5<=B5,$H$2:$H$5)))}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
This worked perfectly but I confess, I don't understand it, especially the part that follows MATCH(A2*B2... Can you explain how it works? Thanks for the formula.
 
Upvote 0
Is price effective date always productwise in ascending order? That is, the following is impossible?

Row\Col
F​
G​
H​
2​
123
3/1/2016
$130.00
3​
123
12/1/2015
$125.00
 
Upvote 0
Thanks! The formula returned the correct answer in all cells except C3. Could it be that the portion of the formula where G2:G5 <=B3 is deemed “true” for both dates 12/1/15 and 3/1/16 so the answer defaults to the first “true” it encounters or does the answer default to the MIN price when there are two “true” possibilities? Thanks again!
Unknown
ABCDEFGH
1Product CodeDate SoldSelling PriceProduct CodePrice Effective DatePrice
21231/15/201612512312/1/2015 $ 125.00
31233/1/20161251233/1/2016 $ 130.00
44562/25/20162154561/1/2016 $ 215.00
54564/8/20162154564/15/2016 $ 245.00

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Array Formulas
CellFormula
C2{=MIN(IF($F$2:$F$5=A2,IF($G$2:$G$5<=B2,$H$2:$H$5)))}
C3{=MIN(IF($F$2:$F$5=A3,IF($G$2:$G$5<=B3,$H$2:$H$5)))}
C4{=MIN(IF($F$2:$F$5=A4,IF($G$2:$G$5<=B4,$H$2:$H$5)))}
C5{=MIN(IF($F$2:$F$5=A5,IF($G$2:$G$5<=B5,$H$2:$H$5)))}

<thead>
</thead><tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>

Control+shift+enter, not just enter, and copy down:

=SMALL(IF($F$2:$F$5=$A2,IF($G$2:$G$5<=$B2,$H$2:$H$5)),MIN(COUNTIFS($A$2:A2,A2),MAX(FREQUENCY(IF($A$2:$A$5=A2,$B$2:$B$5),$G$2:$G$5))))

which is appears to be robust.
 
Upvote 0
Should I sort my data in columns F-H in a certain order? On 12/1/15, my selling price for Product 123 was$125 but on 3/1/16, I raised my price on Product 123 to $130.
 
Upvote 0

Forum statistics

Threads
1,217,023
Messages
6,134,070
Members
449,858
Latest member
mangjuan

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