rounding in vba

MetLife

Active Member
Joined
Jul 2, 2012
Messages
283
Hi,

I am a little confused by the following rounding

tt = Round(1915.5 * 3.27, 2)

1915.5 * 3.27 = 6263.685

so the rounding should round up 5 to 6263.69 but I am getting 6263.68

What is happening?

This is excel 2016

Thanks
 

Excel Facts

Return population for a City
If you have a list of cities in A2:A100, use Data, Geography. Then =A2.Population and copy down.
The VBA Round function rounds down on a 5, while the worksheet Round function rounds up on a 5.

From the VBE Immediate Window:

?Round(6263.685,2)
6263.68
?worksheetfunction.Round(6263.685,2)
6263.69
 
Upvote 0
So i have to go through my entire code and change

Round to
Application.round?

It seems strange the functions work in different ways
 
Upvote 0
It might seem strange, but that's the way it is. VBA Round is called "banker's rounding".

But JoeMo described VBA Round incorrectly. It does not always round 5 down. Instead, it rounds to even. So Round(123.5) is 124. And Round (122.5) is 122.
 
Last edited:
Upvote 0
It might seem strange, but that's the way it is. VBA Round is called "banker's rounding".

But JoeMo described VBA Round incorrectly. It does not always round 5 down. Instead, it rounds to even. So Round(123.5) is 124. And Round (122.5) is 122.
To follow up on joeu2004's comment, VBA uses Banker's Rounding for all rounding that it does, even implicit rounding (such as assigning a floating point number to an integer variable as but one example), except for one lone function... the Format function... it does the same kind of rounding as Excel's worksheet functions. So, if you change this code line...

tt = Round(1915.5 * 3.27, 2)

to this either this...

tt = Format(1915.5 * 3.27, "0.##")

or this...

tt = Format(1915.5 * 3.27, "0.00")

(depending on whether the output needs to contain 2 visible decimal places or not) you will get the rounded result you are looking for.
 
Upvote 0

Forum statistics

Threads
1,214,646
Messages
6,120,715
Members
448,985
Latest member
chocbudda

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