Vlookup on two criteria assistance

jski

Board Regular
Joined
Jan 11, 2006
Messages
118
Good morning Mr. Excel team,

I'm trying to develop a formula that would permit me to lookup a value within a dollar range (Revenue Growth), a percentage range (% Growth), and return in an award amount (Payout). The table looks like this:


Revenue Growth% Growth Payout
From (A3) To
From

<tbody>
</tbody>
To
$500,000 $749,999 15.00% 1000000% 3.75%
$500,000 $749,999 10.00% 14.99% 2.75%
$500,000 $749,999 8.00% 9.99% 2.25%
$500,000 $749,999 7.00% 7.99% 1.75%
$500,000 $749,999 6.00% 6.99% 1.50%
$500,000 $749,999 0% 5.99% 0%
$750,000 $999,999 11.00% 14.99% 3.75%
$750,000 $999,999 7.00%10.99% 2.75%
$750,000 $999,999 6.00%6.99% 2.25%
$750,000 $999,999 5.00%5.99%1.75%
$750,000 $999,999 4.00%4.99%1.50%
$750,000

<tbody>
</tbody>
$999,999 0%3.99%0%
$1,000,000 100,000,000 10.00%11%3.75%
$1,000,000 100,000,000 6.00%9.99%2.75%
$1,000,000 100,000,000 5.00%5.99%2.25%
$1,000,000 100,000,000 4.00%4.99%1.75%
$1,000,000 100,000,000 3.00%3.99%1.50% (E20)
I assume an array formula? Thanks.















<tbody>
</tbody><colgroup><col><col span="4"></colgroup>
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
try this


Excel 2012
ABCDE
1Revenue Growth% GrowthPayout
2From (A3)ToFromTo
3500,000749,99915.00%1000000%3.75%
4500,000749,99910.00%14.99%2.75%
5500,000749,9998.00%9.99%2.25%
6500,000749,9997.00%7.99%1.75%
7500,000749,9996.00%6.99%1.50%
8500,000749,9990%5.99%0%
9750,000999,99911.00%14.99%3.75%
10750,000999,9997.00%10.99%2.75%
11750,000999,9996.00%6.99%2.25%
12750,000999,9995.00%5.99%1.75%
13750,000999,9994.00%4.99%1.50%
14750,000999,9990%3.99%0%
151,000,000100,000,00010.00%11%3.75%
161,000,000100,000,0006.00%9.99%2.75%
171,000,000100,000,0005.00%5.99%2.25%
181,000,000100,000,0004.00%4.99%1.75%
191,000,000100,000,0003.00%3.99%1.50%
20
21850,00012.00%3.75%
Sheet1
Cell Formulas
RangeFormula
C21=SUMPRODUCT(((A3:A19<=A21)*(B3:B19>=A21)),((C3:C19<=B21)*(D3:D19>=B21)),E3:E19)
 
Upvote 0
or


Excel 2010
ABCDEFGHI
1
2Revenue Growth% GrowthPayout
3From (A3)ToFromTo
4$500,000$749,99915.00%1000000%3.75%Revenue Growth% GrowthPayout
5$500,000$749,99910.00%14.99%2.75%$876,2216.22%2.25%
6$500,000$749,9998.00%9.99%2.25%
7$500,000$749,9997.00%7.99%1.75%
8$500,000$749,9996.00%6.99%1.50%
9$500,000$749,9990%5.99%0%
10$750,000$999,99911.00%14.99%3.75%
11$750,000$999,9997.00%10.99%2.75%
12$750,000$999,9996.00%6.99%2.25%
13$750,000$999,9995.00%5.99%1.75%
14$750,000$999,9994.00%4.99%1.50%
15$750,000$999,9990%3.99%0%
16$1,000,000100,000,00010.00%11%3.75%
17$1,000,000100,000,0006.00%9.99%2.75%
18$1,000,000100,000,0005.00%5.99%2.25%
19$1,000,000100,000,0004.00%4.99%1.75%
20$1,000,000100,000,0003.00%3.99%1.50%
Sheet4
Cell Formulas
RangeFormula
I5=SUMIFS($E$4:$E$20,$A$4:$A$20,"<="&G5,$B$4:$B$20,">"&G5,$C$4:$C$20,"<="&H5,$D$4:$D$20,">="&H5)
 
Upvote 0
or

Excel 2010
ABCDEFGHI
1
2Revenue Growth% GrowthPayout
3From (A3)ToFromTo
4$500,000 $749,999 15.00%1000000%3.75%Revenue Growth% GrowthPayout
5$500,000 $749,999 10.00%14.99%2.75%$876,221 6.22%2.25%
6$500,000 $749,999 8.00%9.99%2.25%
7$500,000 $749,999 7.00%7.99%1.75%
8$500,000 $749,999 6.00%6.99%1.50%
9$500,000 $749,999 0%5.99%0%
10$750,000 $999,999 11.00%14.99%3.75%
11$750,000 $999,999 7.00%10.99%2.75%
12$750,000 $999,999 6.00%6.99%2.25%
13$750,000 $999,999 5.00%5.99%1.75%
14$750,000 $999,999 4.00%4.99%1.50%
15$750,000 $999,999 0%3.99%0%
16$1,000,000 100,000,00010.00%11%3.75%
17$1,000,000 100,000,0006.00%9.99%2.75%
18$1,000,000 100,000,0005.00%5.99%2.25%
19$1,000,000 100,000,0004.00%4.99%1.75%
20$1,000,000 100,000,0003.00%3.99%1.50%

<colgroup><col><col><col><col><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet4

Worksheet Formulas
CellFormula
I5=SUMIFS($E$4:$E$20,$A$4:$A$20,"<="&G5,$B$4:$B$20,">"&G5,$C$4:$C$20,"<="&H5,$D$4:$D$20,">="&H5)

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>



Thanks sheetspread! the IFSUMS great worked on my sheetspread! :LOL:
 
Upvote 0

Forum statistics

Threads
1,216,095
Messages
6,128,795
Members
449,468
Latest member
AGreen17

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