progressive IF range2

BrutalLogiC

Active Member
Joined
Feb 26, 2006
Messages
267
Office Version
  1. 2016
Platform
  1. Windows
I'm trying to write a formula which returns a percentage value based on the IF statements below... it's the 'progressive' increase I can't master

A1 is a number I manually enter. It will only be a whole number!
  1. if A1 under 1 = 0%
  2. if A1 over 200 = 10%
but then...
if A1 is:
  1. between 1 to 5 = then the result should be a progressive range 1% to 3%.... so...
    1. if A1 was 1 then the result would be exactly 1.00%
    2. if A1 was 3 (i.e. in the middle of 1 to 5) then the percentage would be in the middle of 1% and 3% i.e. exactly 2.00%
    3. if A1 was 5 then it would be 3.00%
    4. if A1 was 2 or 4 then it would be a fraction percentage either 1.5% or 2.5%
  2. between 6 to 50 = progressive range 4% to 6%
    1. if A1 was 6 then result if 4.00%
    2. if A1 was 11 then the result would be around 4.25% (i think.. working that out in my head)
  3. between 51 to 200 = progressive range 7% to 9%
    1. if A1 was 200 then 9.00%
    2. if A1 was 201 then 10.00%
    3. if A1 was 199 then ever so slightly less than 9%
    4. if A1 was right in the middle of 51 and 200 then it would be 8%
it is a bit weird that in no circumstances can the result be between >3% and <4%...... or >6% and <7%.... or >9% and <10% but I am getting these 'rules' from a gov website and that's their scoring method so I can't change them... !

maabadi helped me yesterday with similar problem but this one is harder
 

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
Whilst I suspect there is an easier way, this seems to give the right result
Excel Formula:
=IF(A1<1,0,IF(A1<6,(A1-1)/2+1,IF(A1<51,(A1-6)/22+4,IF(A1<201,(A1-51)/74.5+7,10))))/100
 
Upvote 0
Try this but this won't work with Decimal number between 3 & 4, 6 & 7 , 50 & 51 , 200 & 201

Cell Formulas
RangeFormula
B2:B19B2=IF(A2<1, 0,IF(AND(A2>=1,A2<=5),0.01+0.02*(A2-1)/4,IF(AND(A2>=6,A2<=50),0.04+0.02*(A2-6)/44,IF(AND(A2>=51,A2<=200),0.07+0.02*(A2-51)/149,0.1))))
C2:C19C2=(IF(A2<1, 0,IF(AND(A2>=1,A2<=5),0.01+0.02*(A2-1)/4,IF(AND(A2>=6,A2<=50),0.04+0.02*(A2-6)/44,IF(AND(A2>=51,A2<=200),0.07+0.02*(A2-51)/149,0.1)))))*A2
 
Upvote 0
Upvote 0
Solution
Thank you both so much, both of these formulas seem to produce the same result and work great
 
Upvote 0
Glad we could help & thanks for the feedback.
 
Upvote 0
Hi BrutalLogic,

I know I'm late to the game but here's my offering with the CHOOSE option calculated with some finagling and the actual calculations using slope intercept formula y=mx+b

=CHOOSE((MIN(5,ROUND(SQRT(SQRT(A1)),0)))+1,0,(A1+1)/2,(A1+82)/22,(A1+470.5)/74.5,10,10)
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,255
Members
448,556
Latest member
peterhess2002

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