Difficult Excel Formula

LisaVelthuizen

New Member
Joined
Nov 14, 2017
Messages
4
I am making a calculator for my website (i make the calculator in the program excel), but i don't know which formula i must take and how to fill it in.

It is a formula where the answer depends on the input and bandwidth of the input.

Below the input en output:

Input: ≤30.000 --> the answer must be 800.

between 30.000 and 60.000 -> every 1.000 upon the 30.000, but till an input of 60.000 --> the answer increases with 19,5 upon the first 800. So 60.000 must have the answer 800+ (30*19.5) = 1.385

Between 60.001 and 100.000 -> every 1.000 upon the 60.000, but till an input of 100.000 --> the answer increases with 15,60 upon the 1.385. So 100.000 must have the answer 800+ (40*15.60) = 2.009.

This principle continues. In numbers:

Input: Output:
≤30.000 -> answer = 800
30.001 - 60.000-> per 1.000 upon the input, the answer increases with 19.50 above the first 800.
60.001 - 100.000 > per 1.000 upon the input, the answer increases with 15.60 above the first 800+19.50 per 1.000(see line before).
100.001 - 200.000 -> per 1.000 upon the input, the answer increases with 7.80 above the first 800+19.50 per 1.000+ 15.6 per 1.000(see line before).
200.001 - 500.000 -> +5.85 per 1.000 ( but again above the first answers)
500.001 - 1.000.000 -> + 4.875 per 1.000 (but again above the first answers)
1.000.001 and higher -> +2.925 per 1.000 (but again above the first answers)

These numbers has to fill in one formula. Does anybody know which formula i can use and how i use it?
 

Excel Facts

Convert text numbers to real numbers
Select a column containing text numbers. Press Alt+D E F to quickly convert text to numbers. Faster than "Convert to Number"

Excel 2010
ABCDEFG
11,000,000.006,981.50BracketRaterDiff
2or6,981.5002.67%2.67%
3300001.95%-0.72%
4600001.56%-0.39%
51000000.78%-0.78%
62000000.59%-0.20%
75000000.49%-0.10%
810000000.29%-0.20%
3a
Cell Formulas
RangeFormula
B1=(A1>0)*MAX(800,SUMPRODUCT(--(A1>rB),A1-rB,rDiff))
B2=(A1>0)*MAX(800,SUMPRODUCT(--(A1>{0;30000;60000;100000;200000;500000;1000000}),A1-{0;30000;60000;100000;200000;500000;1000000},{0.0266666666666667;-0.00716666666666667;-0.0039;-0.0078;-0.00195;-0.000974999999999999;-0.00195}))
F2=800/30000
G2=F2-N(F1)
Named Ranges
NameRefers ToCells
rB='3a'!$E$2:$E$8
rDiff='3a'!$G$2:$G$8
 
Last edited:
Upvote 0
Same idea, slightly different implementation:

ABCDE
Valuelimitratedifferential rate
Output

<tbody>
[TD="align: center"]1[/TD]

[TD="align: right"][/TD]

[TD="align: center"]2[/TD]
[TD="align: right"]1000000[/TD]
[TD="align: right"][/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]

[TD="align: center"]3[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"]30000[/TD]
[TD="align: right"]19.5[/TD]
[TD="align: right"]19.5[/TD]

[TD="align: center"]4[/TD]

[TD="align: right"][/TD]
[TD="align: right"]60000[/TD]
[TD="align: right"]15.6[/TD]
[TD="align: right"]-3.9[/TD]

[TD="align: center"]5[/TD]
[TD="align: right"]6981.5[/TD]
[TD="align: right"][/TD]
[TD="align: right"]100000[/TD]
[TD="align: right"]7.8[/TD]
[TD="align: right"]-7.8[/TD]

[TD="align: center"]6[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"]200000[/TD]
[TD="align: right"]5.85[/TD]
[TD="align: right"]-1.95[/TD]

[TD="align: center"]7[/TD]
[TD="align: right"]6981.5[/TD]
[TD="align: right"][/TD]
[TD="align: right"]500000[/TD]
[TD="align: right"]4.875[/TD]
[TD="align: right"]-0.975[/TD]

[TD="align: center"]8[/TD]
[TD="align: right"]6981.5[/TD]
[TD="align: right"][/TD]
[TD="align: right"]1000000[/TD]
[TD="align: right"]2.925[/TD]
[TD="align: right"]-1.95[/TD]

</tbody>
Sheet1

[TABLE="width: 85%"]
<tbody>[TR]
[TD]Worksheet Formulas[TABLE="width: 100%"]
<tbody>[TR="bgcolor: #DAE7F5"]
[TH]Cell[/TH]
[TH="align: left"]Formula[/TH]
[/TR]
[TR]
[TH="bgcolor: #DAE7F5"]A5[/TH]
[TD="align: left"]=800+SUMPRODUCT((A2-C2:C8)/1000,E2:E8,--(A2 > C2:C8))[/TD]
[/TR]
[TR]
[TH="bgcolor: #DAE7F5"]A7[/TH]
[TD="align: left"]=800+SUMPRODUCT((A2-{0,30000,60000,100000,200000,500000,1000000})/1000,{0,19.5,-3.9,-7.8,-1.95,-0.975,-1.95},--(A2 > {0,30000,60000,100000,200000,500000,1000000}))[/TD]
[/TR]
[TR]
[TH="bgcolor: #DAE7F5"]A8[/TH]
[TD="align: left"]=800+SUMPRODUCT((A2/1000-{0,30,60,100,200,500,1000}),{0,19.5,-3.9,-7.8,-1.95,-0.975,-1.95},--(A2/1000 > {0,30,60,100,200,500,1000}))[/TD]
[/TR]
[TR]
[TH="bgcolor: #DAE7F5"]E3[/TH]
[TD="align: left"]=D3-D2[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
</tbody>[/TABLE]





It's easiest to maintain the formula if you put the values in a table. The A2 formula does that using C1:E8. If you really want, you can embed the table within the formula, like A7 or A8.

Also, I'm not sure where you are located, but you may need to change the delimiters within the formulas from a comma (,) to a semicolon ( ; ).
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,848
Members
452,361
Latest member
d3ad3y3

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