Formula for Rounding with Multiple Rules

Kenichi

New Member
Joined
Sep 17, 2009
Messages
30
Hi,

I was wondering if it's possible to incorporate a few different rules into the same rounding formula? Basically, what I'm trying to achieve is rounding based on these rules:

If number in reference cell is 0-1000
o Round up (or down) to nearest 10 increment. Instead of landing on 100 increment, end with 90.
o So: 10, 20, 30, 40, $0, 60, 70, 80, or 90.

1000-5000
o Round up (or down) to nearest 25 increment. Instead of landing on 100 increment, end with 90.
o So: 25, 50, 75, or 90.

5000+
o Round up (or down) to nearest 25 increment. At this point, can land on 100 increments.
o So: 25, 50, 75, 100

Thanks so much for you help with this! Hopefully it is possible.
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
I think I understand what you're after. I cannot for the life of me imagine why one would want to round a number like 1006 down to 990.

This formula works but could probably be improved by someone smarter than me.

Put a positive number in a1

Code:
=IF(A1>=5000,ROUND(A1/25,0)*25,IF(AND(A1>=1000,A1<5000),IF(MOD(ROUND(A1/25,0)*25,100)=0,ROUND(A1/25,0)*25-10,ROUND(A1/25,0)*25),IF(MOD(ROUND(A1/10,0)*10,100)=0,INT(A1/10)*10,ROUND(A1/10,0)*10)))
 
Upvote 0
Edit. Oops, I made a mistake. Here is the revision.

Code:
=IF(A1>=5000,ROUND(A1/25,0)*25,IF(AND(A1>=1000,A1<5000),IF(MOD(ROUND(A1/25,0)*25,100)=0,ROUND(A1/25,0)*25-10,ROUND(A1/25,0)*25),IF(MOD(ROUND(A1/10,0)*10,100)=0,ROUND(A1/10,0)*10-10,ROUND(A1/10,0)*10)))
 
Upvote 0
You could also try this which I believe gives the same results as the formula already suggested.

=MROUND(A1,IF(A1<1000,10,25))-10*(A1<5000)*(MOD(MROUND(A1,IF(A1<1000,10,25)),100)=0)
 
Upvote 0
Can anyone help with adding one more criteria to this formula?

=MROUND(A1,IF(A1<1000,10,25))-10*(A1<5000)*(MOD(MROUND(A1,IF(A1<1000,10,25)),100)=0)

I'd like for A1 (price) minus B1 (cost) to never be below 200. Is it possible to add that rule to the formula? A1-B1 should never be below 200, but it needs to still be rounded according to the rule above.

Thanks!
 
Upvote 0

Forum statistics

Threads
1,213,532
Messages
6,114,177
Members
448,554
Latest member
Gleisner2

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