Results 1 to 5 of 5
  1. #1
    UTLee is offline Advanced Beginner
    Windows 7 64bit Access 2010 64bit
    Join Date
    Aug 2013
    Posts
    73

    Help with Rounding in Visual Basic


    I have the following query that pulls certain account information out of our Access database and puts it into an excel template:

    Code:
    Function arrAccounts()    Dim arrAccts()
        Dim i As Integer
        Dim rsAccounts As New ADODB.Recordset
        Dim strSql As String
        Dim intNumAccounts As Integer
        strSql = "SELECT tblClients.client, tblClients.qtrlyFeePercent As qtrlyFeePercent, tblAccountHistory.AccountID As AccountId, tblAccounts.account as AccountName, tblAccounts.billToAccount As BillToAccount, tblAccountHistory.EndingBal As EndingBal, tblAccountHistory.TransDate "
        strSql = strSql & "FROM (tblClients INNER JOIN tblAccountHistory ON tblClients.client=tblAccountHistory.ClientID) INNER JOIN tblAccounts ON (tblClients.client=tblAccounts.client) AND (tblAccountHistory.AccountID=tblAccounts.accountID) "
        strSql = strSql & "WHERE (((tblAccountHistory.TransDate) = #" & Me.ReportDate & "#) AND (tblClients.client = '" & Me.Client & "')) ORDER BY tblAccounts.account;"
        
        rsAccounts.Open strSql, cn, adOpenForwardOnly, adLockReadOnly
        If rsAccounts.BOF And rsAccounts.EOF Then
            
            ReDim arrAccts(1, 6)
            arrAccts(0, 0) = "_"
            arrAccts(0, 1) = "_"
            arrAccts(0, 2) = 0
            arrAccts(0, 3) = 0
            arrAccts(0, 4) = 0
            arrAccts(0, 5) = "_"
            arrAccounts = arrAccts
            Exit Function
        End If
        
        Do While Not rsAccounts.EOF
            intNumAccounts = intNumAccounts + 1
            rsAccounts.MoveNext
        Loop
        rsAccounts.MoveFirst
        Dim j As Integer
        ReDim arrAccts(intNumAccounts - 1, 6)
        Do While Not rsAccounts.EOF
            arrAccts(j, 0) = rsAccounts("AccountName")
            arrAccts(j, 1) = rsAccounts("AccountId")
            arrAccts(j, 2) = rsAccounts("EndingBal")
            arrAccts(j, 3) = rsAccounts("qtrlyFeePercent")
            arrAccts(j, 4) = rsAccounts("EndingBal") * rsAccounts("qtrlyFeePercent")
            arrAccts(j, 5) = rsAccounts("BillToAccount")
            
            j = j + 1
            rsAccounts.MoveNext
        Loop
        arrAccounts = arrAccts
            
    End Function
    When the code calculates:
    arrAccts(j, 4) = rsAccounts("EndingBal") * rsAccounts("qtrlyFeePercent")
    there can sometimes be many decimal places and since these are dollar value calculations, I'd like to round the calculation to 2 decimal places. I understand I can change this part of the code to:
    arrAccts(j, 4) = Round(rsAccounts("EndingBal") * rsAccounts("qtrlyFeePercent"),2)
    but this doesn't seem to work properly in certain instances. For example, if endingbal = 9,754 and qtrylfeepercent = .0025, the unrounded answer is 24.385 and when I round it to two decimal places it should display 24.39 but instead its showing 24.38...

    Any ideas what is going on here??

  2. #2
    pbaldy's Avatar
    pbaldy is offline Who is John Galt?
    Windows XP Access 2007
    Join Date
    Feb 2010
    Location
    Nevada, USA
    Posts
    22,652
    The reason why (bankers rounding, in the middle of the page) and some alternatives:

    http://allenbrowne.com/round.html
    Paul (wino moderator)
    MS Access MVP 2007-2019
    www.BaldyWeb.com

  3. #3
    June7's Avatar
    June7 is offline VIP
    Windows 7 64bit Access 2010 32bit
    Join Date
    May 2011
    Location
    The Great Land
    Posts
    53,770
    Round() function in Access and VBA does not follow same rules as Round() function in Excel used in cells (VBA in Excel uses bankers). Thank you M$.

    To avoid bankers rounding I built a custom function for rounding.
    Code:
    Function RRound(FieldValue As Variant, Optional intPos As Integer = 0) As Variant
    '--------------------------------------------------
    ' Function RRound() rounds value to designated decimal position.
    ' If argument does not contain data, RRound returns null.
    ' Use because intrinsic Round uses even/odd (banker's) rounding.
    ' Also, Format and FormatNumber functions don't use even/odd but
    ' generate a string result which is often inconvenient.
    '--------------------------------------------------
    Dim strZeros As String
    Dim i As Integer
    If intPos = 0 Then
        strZeros = 0
    Else
        For i = 1 To intPos
            strZeros = strZeros & 0
        Next
        strZeros = "0." & strZeros
    End If
    RRound = IIf(Not IsNull(FieldValue), Val(Format(FieldValue, strZeros)), Null)
    End Function
    How to attach file: http://www.accessforums.net/showthread.php?t=70301 To provide db: copy, remove confidential data, run compact & repair, zip w/Windows Compression.

  4. #4
    UTLee is offline Advanced Beginner
    Windows 7 64bit Access 2010 64bit
    Join Date
    Aug 2013
    Posts
    73
    Thank you both for your quick replies! I will try these first thing tomorrow am...

  5. #5
    pbaldy's Avatar
    pbaldy is offline Who is John Galt?
    Windows XP Access 2007
    Join Date
    Feb 2010
    Location
    Nevada, USA
    Posts
    22,652
    No problem.
    Paul (wino moderator)
    MS Access MVP 2007-2019
    www.BaldyWeb.com

Please reply to this thread with any new information or opinions.

Similar Threads

  1. Visual Basic
    By Darth21 in forum Access
    Replies: 4
    Last Post: 08-11-2014, 06:18 AM
  2. Visual Basic
    By kwooten in forum Queries
    Replies: 2
    Last Post: 01-25-2012, 08:22 AM
  3. trying to learn visual basic
    By darklite in forum Programming
    Replies: 7
    Last Post: 08-24-2011, 02:18 PM
  4. Can't find Visual Basic
    By Art Burger in forum Programming
    Replies: 0
    Last Post: 04-20-2011, 05:35 PM
  5. Query in visual basic
    By Lucas83 in forum Programming
    Replies: 1
    Last Post: 06-10-2010, 11:00 AM

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  
Other Forums: Microsoft Office Forums