Rounding options in a formula

Caly

Board Regular
Joined
Jul 19, 2015
Messages
90
Office Version
  1. 365
  2. 2013
  3. 2011
  4. 2010
  5. 2007
Platform
  1. Windows
Hi I have multiple dollar value ranges and am trying to apply one formula for each option but is there a better way to write the formula below?

=if(and(A2>10,000,A2<100,000),roundup(A2,-4),
if(and(A2>100,000,A2<1,000,000),roundup(A2,-5),
if(and(A2>1,000,000,A2<1,000,000,000),roundup(A2,-6),
Roundup(A2,-7))))

Column A - Dollars
$12,036,219.22
$437,379.70
$11,737.18
$180,595.28
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).

offthelip

Well-known Member
Joined
Dec 23, 2017
Messages
2,280
Office Version
  1. 2010
Platform
  1. Windows
try this:
Excel Formula:
=ROUNDUP(A2,-INT(LOG10(A2)))
 
Solution

Caly

Board Regular
Joined
Jul 19, 2015
Messages
90
Office Version
  1. 365
  2. 2013
  3. 2011
  4. 2010
  5. 2007
Platform
  1. Windows
Thank you. That works great. Just one thing for the first number $12,036,219.22, I want it to say $13,000,000 but it is coming out to $20,000,000. Is there a way for it to return that?
 

MySpreadsheetLab

New Member
Joined
Jan 4, 2014
Messages
7
If it's an exception only for that range ($12,036,219.22 to $13,000,000) then this should work:
=ROUNDUP(A2,IF(-INT(LOG10(A2))=-7,-6,-INT(LOG10(A2))))
 

Caly

Board Regular
Joined
Jul 19, 2015
Messages
90
Office Version
  1. 365
  2. 2013
  3. 2011
  4. 2010
  5. 2007
Platform
  1. Windows

ADVERTISEMENT

Thank you. Wow that worked perfectly.

Is this the accurate way of understanding the formula logic. Is it saying to roundup to the nearest 6 digits where the next whole number is 7 characters and then if taht is not true then the last statement will bring it to the next whole number?
 

MySpreadsheetLab

New Member
Joined
Jan 4, 2014
Messages
7
Yes I think so. The IF function adds the one exception that you need (otherwise it calculates as per original solution). By the way, the solution from offthelip is amazing! Thanks for the question Caly!
 

Caly

Board Regular
Joined
Jul 19, 2015
Messages
90
Office Version
  1. 365
  2. 2013
  3. 2011
  4. 2010
  5. 2007
Platform
  1. Windows

ADVERTISEMENT

Yes awesome- thank you both so much. This worked perfectly. Appreciate the help and support.
 

MySpreadsheetLab

New Member
Joined
Jan 4, 2014
Messages
7
You could also use this formula:
=ROUNDUP(A2,INDEX({0;-1;-2;-3;-4;-5;-6;-6},MATCH(-INT(LOG10($A2)),{0;-1;-2;-3;-4;-5;-6;-7},0)))
It's flexible if you end up with more exceptions (note the 2nd "-6" in the INDEX part accommodates your current exception).
 

offthelip

Well-known Member
Joined
Dec 23, 2017
Messages
2,280
Office Version
  1. 2010
Platform
  1. Windows
an even shorter way of doing that is:
Excel Formula:
=ROUNDUP(A2,-MIN(6,INT(LOG10(A2))))
 

Caly

Board Regular
Joined
Jul 19, 2015
Messages
90
Office Version
  1. 365
  2. 2013
  3. 2011
  4. 2010
  5. 2007
Platform
  1. Windows
Thank you both - this works perfect and I was able to use in multiple projects thank you
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,151,962
Messages
5,767,344
Members
425,405
Latest member
jaskimo

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
Top