• User Defined Function To Sum And Round To Two Decimal Places

    Macro Purpose:
    • To round a Sum formula to two decimal places

    Examples of where this function shines:
    • When you are feeling really lazy, and don't want to type =Round(Sum(A1:A3),2), you can just type =Sumr(A1:A3)

    Macro Weakness(es):
    • Will calculate slower than the nested Round and Sum combination. Performance degridation most likely won't be noticed if it is only used a few times, but if hundreds of formulas are used, it may slow the calculation down noticeably.
    • Only accepts range arguments, not values.
    • Only accept one contiguous range (not multiple ranges).

    Versions Tested:
    This function has been tested with Excel 2003. It should not have any issues running from any of the Office applications from 97 or higher, but to date this has not been tested.

    VBA Code Required:
    • Place the following code in a standard module
      Code:
      Function SumR(rng As Range) As Double
      'Author       : Ken Puls (www.excelguru.ca)
      'With thanks to Remco Boom for the "\1" method
      'Macro Purpose: Rounds the Sum'd range to 2 decimals
           SumR = ((100 * Application.WorksheetFunction.Sum(rng.Cells) + 0.01) \ 1) / 100
      End Function

    How to use the code:
    • Once the code is in a standard module, use it as a regular formula in a worksheet cell, as shown below
      <img src="/images/VBA06-01.jpg">

    How it works:
    • The uses Excel's native SUM formula to sum up the range, multiplies it by 100 and adds .01. At this point it then rounds it off to no decimal places, and divides it by 100 to get the result.
    • The \1 operator rounds the amount to zero decimal places. The .01 addition in the middle of the formula corrects an issue with the rounding of this function, as it rounds 0.5 down to zero.

    The End Result:
    • The sum of the range is returned, rounded to 2 decimal places.

    An Alternative:
    • The SumRDown function, shown below, will always round the value down to 2 decimal places.
      Code:
      Function SumRDown(rng As Range) As Double
      'Author       : Ken Puls (www.excelguru.ca)
      'Macro Purpose: Rounds the Sum'd range down to 2 decimals
           SumRDown = Int(100 * Application.WorksheetFunction.Sum(rng.Cells)) / 100
      End Function
      <img src="/images/VBA06-02.jpg">

     

    I'm afraid that you must be logged in to comment or leave a testimonial. I wish it could be otherwise, but I'm trying to keep my site spam free for everyone's benefit. If you don't yet have an account it's completely free to sign up, and a very quick process. Simply click here to Register. Not only can you post a comment here, but it gives you full access to posts questions in our forum as well!

     

    If you already have an account, and just haven't logged in yet, what are you waiting for? Login Now!

  • MVP Logo
  • Recent Forum Posts

    p45cal

    Need help with total monthly hours

    Enter times as follows: If it's 2:05 in the afternoon enter as 2:05 PM or 14:05.
    The attached should handle times across midnight, but check....

    p45cal Yesterday, 11:22 PM Go to last post
    dcope7

    Need help with total monthly hours

    I took the 12 out and if you key in 0:30 it row 12 it still subtracts from row 16 which is what it is supposed to do. I've tried every format I could...

    dcope7 Yesterday, 07:05 PM Go to last post
    p45cal

    Need help with total monthly hours

    It does not! it adds the value 12 and doesn't even look at row 12! In this context it adds 12 days (=288 hours). Barmy.
    Until you get formulae right...

    p45cal Yesterday, 06:02 PM Go to last post
    dcope7

    Need help with total monthly hours

    Ok row 16 calculates rows 11 and 15, plus it subtracts row 12 and yes I know I have it adding but if you actually add 0:30 in row 12 it will subtract...

    dcope7 Yesterday, 05:23 PM Go to last post
    p45cal

    Need help with total monthly hours

    I'm talking about row 16, NOT ROW 12!
    The 12 is a hard-coded 12 in the formula, and it adds (not subtracts) 12. The formula in cell D16 (yes, the...

    p45cal Yesterday, 05:10 PM Go to last post