Need a formula to compare one cell to a range, then depending on the result multiply to another cell

katryte623

New Member
Joined
May 30, 2018
Messages
5
I'm going to explain this as easy as I possibly can. Cell Z4 has a fuel amount. Let's say $2.50. If that amount falls within this range, then it will multiply by that percentage. So if somebody where to change the number in Z4, the result would update. The result is going in cell Z10.

Now once the fuel surcharge is calculated, I also need the fuel calculated which is a simple Y10*1.65.

So my original calculation was:
=IF(AND(Z4>=A42,Z4<B42),Z4*D42,IF(AND(Z4>=A43,Z4<B43),Z4*D43,IF(AND(Z4>=A44,Z4<B44),Z4*D44,IF(AND(Z4>=A45,Z4<B45),Z4*D45,IF(AND(Z4>=A46,Z4<B46),Z4*D46)*IF(AND(Z4>=A47,Z4<B47),Z4*D47,IF(AND(Z4>=A48,Z4<B48),Z4*D48,IF(AND(Z4>=A49,Z4<B49),Z4*D49,IF(AND(Z4>=A50,Z4<B50),Z4*D50,IF(AND(Z4>=A51,Z4<B51),Z4*D51,IF(AND(Z4>=A52,Z4<B52),Z4*D52,IF(AND(Z4>=A53,Z4<B53),Z4*D53,IF(AND(Z4>=A54,Z4<B54),Z4*D54,IF(AND(Z4>=A55,Z4<B55),Z4*D55)))))))))))))+(X10*1.65)

but that did not work


column A column B column D
row 42 $2.60 $2.69 1%
row 43 $2.70 $2.79 2%
row 44 $2.80 $2.89 3%
row 45 $2.90 $2.99 4%
row 46 $3.00 $3.09 5%
row 47 $3.10 $3.19 6%
row 48 $3.20 $3.29 7%
row 49 $3.30 $3.39 8%
row 50 $3.40 $3.49 9%
row 51 $3.50 $3.59 10%
row 52 $3.60 $3.69 11%
row 53 $3.70 $3.79 12%
row 54 $3.80 $3.89 13%
row 55 $3.90 $3.99 14%

Thank you!
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
The formula did not copy correctly, its actually this but a longer continuance =IF(AND(Z4>=A42,Z4<B42),Z4*D42,IF(AND(Z4>=A43,Z4<B43),Z4*D43
 
Upvote 0
Hi,

Put an EXTRA SPACE in front of ALL the "less than" < symbols in your formula so it'll show properly.
 
Upvote 0
ok so I tried a different, shorter way:

=($X$10*((SUMPRODUCT(($Z$4>=$A42:$A55)*($Z$4<=$B42:$B55)*$Z$4*($D42:$D55)))))

(the formula looks right to me, I hope when I post all of the symbols don't go away)
 
Upvote 0
That's what I "thought" you were trying to do, below is "slightly" cleaned upped version of your SUMPRODUCT formula, and a LOOKUP alternative.
I don't think you were on the right tract with the Original IF/AND statement (although IF/AND could work, but I think the logic was not correct in your attempt).


Book1
ABCDEXYZAA
4$3.00
9
1099$14.85$14.85
41
42$2.60$2.691%
43$2.70$2.792%
44$2.80$2.893%
45$2.90$2.994%
46$3.00$3.095%
47$3.10$3.196%
48$3.20$3.297%
49$3.30$3.398%
50$3.40$3.499%
51$3.50$3.5910%
52$3.60$3.6911%
53$3.70$3.7912%
54$3.80$3.8913%
55$3.90$3.9914%
Sheet64
Cell Formulas
RangeFormula
Z10=$X$10*SUMPRODUCT(($Z$4>=$A42:$A55)*($Z$4<=$B42:$B55)*$Z$4*($D42:$D55))
AA10=$X$10*LOOKUP($Z$4,$A42:$A55,$D42:$D55)*$Z$4
 
Upvote 0
I see how you cleaned up the formula! Thanks! So I tried it and in my X10 I have 125 and in Z4 I have $3.307. So when I enter the formula in, the result that pops up is $33.07. But if you simply take 125 x 8% (since $3.307 falls into the 8% category - line 49) the result is $10.00
 
Upvote 0
Then why do you have *Z4 in your formula in Post #4 ???

If all you want is X10 ( 125 ) * 8%, just take out *Z4 in the formulas:


Book1
ABCDEXYZAA
4$3.307
9
10125$10.00$10.00
41
42$2.60$2.691%
43$2.70$2.792%
44$2.80$2.893%
45$2.90$2.994%
46$3.00$3.095%
47$3.10$3.196%
48$3.20$3.297%
49$3.30$3.398%
50$3.40$3.499%
51$3.50$3.5910%
52$3.60$3.6911%
53$3.70$3.7912%
54$3.80$3.8913%
55$3.90$3.9914%
Sheet64
Cell Formulas
RangeFormula
Z10=$X$10*SUMPRODUCT(($Z$4>=$A42:$A55)*($Z$4<=$B42:$B55)*($D42:$D55))
AA10=$X$10*LOOKUP($Z$4,$A42:$A55,$D42:$D55)
 
Upvote 0
You're welcome, welcome to the forum.

No problem at All, glad to help.
 
Upvote 0

Forum statistics

Threads
1,213,567
Messages
6,114,344
Members
448,570
Latest member
rik81h

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