VBA Rounding Dilemma - Easier than I think?

Sphinx404

Board Regular
Joined
May 2, 2015
Messages
186
Office Version
  1. 365
Platform
  1. Windows
Hi Guys,

I have a weight on 2 different sheets. One sheet reports it in KG the other reports it in LBS

With my limited knowledge of VBA I have tried writing the following code:

Code:
[COLOR=#008000]'returns weight measurement with 2 decimals - [B]WORKS[/B][/COLOR]
sheet2.Range("Z2").Formula = _
    "=VLOOKUP(U2,'DG by Flt Totals'!$A$2:$BA$" & sheet1.Cells(Rows.Count, 1).End(xlUp).row & ",53,0)"
sheet2.Range("Z2:Z" & sheet2.Cells(Rows.Count, 1).End(xlUp).row).FillDown


[COLOR=#008000]'returns measurement standard (i.e. KG or Liters) - [B]WORKS[/B][/COLOR]
sheet2.Range("AA2").Formula = _
    "=VLOOKUP(U2,'DG by Flt Totals'!$A$2:$BB$" & sheet1.Cells(Rows.Count, 1).End(xlUp).row & ",54,0)"
sheet2.Range("AA2:AA" & sheet2.Cells(Rows.Count, 1).End(xlUp).row).FillDown


[COLOR=#008000]'IF formula asking IF Z2 = "KG" then multiply weight (Z2) by 2.204...., if not then ""(blank) - [B]DOES NOT WORK[/B][/COLOR]
sheet2.Range("Z2").Formula = [COLOR=#ff0000]"=IF(AA2=""KG"",sum(Z2*2.204),"")"[/COLOR]  [COLOR=#008000]' <----- [B]DOES NOT WORK[/B][/COLOR]
sheet2.Range("Z2:Z" & sheet2.Cells(Rows.Count, 1).End(xlUp).row).FillDown


[COLOR=#008000]'IF formula asking IF the weight in AB matches the weight in O2[/COLOR]
sheet2.Range("AB2").Formula = "=IF(AB2=O2,TRUE, FALSE)"  [COLOR=#008000]'<--- [B]WILL ALWAYS RETURN FALSE[/B][/COLOR]
sheet2.Range("AB2:AB" & sheet2.Cells(Rows.Count, 1).End(xlUp).row).FillDown

There are 2 problems

1. My first IF formula does not work
2. Even if the first IF formula worked, the second IF formula wouldn't because it could have any number of decimal places. Thus not finding a perfect match in O2 (which has 2 decimal places). Even if I bring them down to have the same amount of decimals, it still might not match, so it's just easier to round up or down.

Can I find an exact match by rounding up or down? If so, how do I write that in?
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
try this

Code:
'returns weight measurement with 2 decimals - WORKS
sheet2.Range("Z2").Formula = _
    "=VLOOKUP(U2,'DG by Flt Totals'!$A$2:$BA$" & sheet1.Cells(Rows.Count, 1).End(xlUp).row & ",53,0)"
sheet2.Range("Z2:Z" & sheet2.Cells(Rows.Count, 1).End(xlUp).row).FillDown




'returns measurement standard (i.e. KG or Liters) - WORKS
sheet2.Range("AA2").Formula = _
    "=VLOOKUP(U2,'DG by Flt Totals'!$A$2:$BB$" & sheet1.Cells(Rows.Count, 1).End(xlUp).row & ",54,0)"
sheet2.Range("AA2:AA" & sheet2.Cells(Rows.Count, 1).End(xlUp).row).FillDown




'IF formula asking IF Z2 = "KG" then multiply weight (Z2) by 2.204...., if not then ""(blank) - DOES NOT WORK
sheet2.Range("Z2").Formula = "=IF(AA2=""KG"",sum(Z2*2.204),"""")"  ' <----- Should work know you were missing double quotes
sheet2.Range("Z2:Z" & sheet2.Cells(Rows.Count, 1).End(xlUp).row).FillDown




'IF formula asking IF the weight in AB matches the weight in O2
sheet2.Range("AB2").Formula = "=IF(ROUND(AB2,2)=ROUND(O2,2),TRUE, FALSE)"  '<--- Should work... I think
sheet2.Range("AB2:AB" & sheet2.Cells(Rows.Count, 1).End(xlUp).row).FillDown
 
Upvote 0
Untested, however, try replacing just that code above with:
Code:
    Dim x       As Long
    Dim arr()   As Variant
    Dim temp    As Variant
    Dim dic     As Object
    Const DELIM As String = "|"
    
    Set dic = CreateObject("Scripting.Dictionary")
    
    With Sheet1
        x = .Cells(.Rows.count, 1).End(xlUp).row
        arr = .Cells(2, 1).Resize(x - 1, 53).Value
    End With
    
    For x = LBound(arr, 1) To UBound(arr, 1)
        dic(arr(x, 1)) = arr(x, 53) & DELIM & arr(x, 54)
    Next x
    Erase arr
    
    With Sheet2
        x = .Cells(.Rows.count, 1).End(xlUp).row
        With .Cells(2, 26).Resize(, 3)
            .ClearContents
            .NumberFormat = "General"
        End With
        arr = .Cells(2, 21).Resize(x, 2).Value
        For x = LBound(arr, 1) To UBound(arr, 1)
            temp = arr(x, 1)
            arr(x, 1) = dic(Split(temp, DELIM)(0))
            arr(x, 2) = dic(Split(temp, DELIM)(1))
            arr(x, 1) = arr(x, 1) * IIf(arr(x, 2) = "KG", 2.204, 0)
        Next x
        .Cells(2, 26).Resize(UBound(arr, 1), UBound(arr, 2)).Value = arr
        Erase arr
        .Cells(2, 28).Resize(x).Formula = "=O2=AB2"
    End With
    
    Set dic = Nothing
 
Upvote 0

Forum statistics

Threads
1,217,181
Messages
6,135,061
Members
449,909
Latest member
CCaff

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