Find closest values

jokei

New Member
Joined
Aug 5, 2015
Messages
8
Hi,
I'm new to macros and can't find a good starting point for my problem.

I want to loop through a row in a table looking for the 3 closest numbers (column D) to a value in a given cell (N5) and set the corresponding row to "yes" in column B.
So if the 3 closest values is found in D3, D6 and D7 I want B3, B6 and B7 to say "Yes" and then filter my list accordingley.

Help appreciated.

Regard Jokei
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
You could use this.
VBA Code:
Sub test()
    Dim targetValue As Double
    Dim dblDist1 As Double, dblDist2 As Double, dblDist3 As Double
    Dim dblWorking As Double
    Dim oneCell As Range, rngData As Range
    Dim strFormula As String
    targetValue = Val(CStr(Range("N5").Value))
    dblDist1 = 9E+99
    dblDist2 = dblDist1
    dblDist3 = dblDist1
    With Range("D:D")
        Set rngData = Range(.Cells(1, 1), .Cells(Rows.Count, 1).End(xlUp))
    End With
    For Each oneCell In rngData
        dblWorking = Abs(Val(CStr(oneCell.Value)) - targetValue)
        
        If dblWorking < dblDist1 Then
            dblDist3 = dblDist2
            dblDist2 = dblDist1
            dblDist1 = dblWorking
        ElseIf dblWorking < dblDist2 Then
            dblDist3 = dblDist2
            dblDist2 = dblWorking
        ElseIf dblWorking < dblDist3 Then
            dblDist3 = dblWorking
        End If
    Next oneCell
    strFormula = "=IF(ABS(RC[1]-(" & targetValue & "))<=" & dblDist3 & ",""yes"","""")"
    With rngData.Offset(0, -1)
        .FormulaR1C1 = strFormula
        .Value = .Value
    End With

End Sub
 
Upvote 0
Hi,
This was almost perfect.
Only issue I get is that I'm not able to use a different column as a range, cause it only works with offseting -1 column for the "Yes".
I want to edit it so I can run it on other columns also but need to offset more then one column for the result.
And also it should not clear the target column cause I might have "yes" from other results which I want to keep.

And one last thing, how do I make it skip the two first rows which is headings?

Thanks!
 
Upvote 0
That is not working, I tried offset(0,-5) and it gives #value or just blank. It seems to only work with -1. It returns #value if I adjust with -1 and blank if I adjust with more.
Also how do I avoid formula blanking if there is already "yes"?
 
Upvote 0
When adjusting the Offset, the formula needs to be adjiusted as well

Rich (BB code):
strFormula = "=IF(ABS(RC[1]-(" & targetValue & "))<=" & dblDist3 & ",""yes"","""")"
    With rngData.Offset(0, -1)
        .FormulaR1C1 = strFormula
        .Value = .Value
    End With
 
Upvote 0
Data in F and writing to E which works well. But I wanted to apply same code to K and still write to E without overwriting if there was a "yes" from the code run on F. I clear everything with a separate code which I managed to do myself.
 
Upvote 0
Perhaps this will work for you
VBA Code:
Sub test()
    Dim rngDestination As Range
    Dim dblTargetValue As Double
    Dim rngData As Range
    Dim lngDataCount As Long
    Dim dblAbsTarget As Double
    Dim strFormula As String
    Dim arrResult() As String
    Dim oneCell As Range, oneCol As Variant
    Dim i As Long
    
    Set rngDestination = Range("C1")
    dblTargetValue = Val(CStr(Range("N5").Value))
    
    ReDim arrResult(1 To 1)
    
    For Each oneCol In Array(Range("D:D"), Range("K:K"))
        With oneCol.EntireColumn
            Set rngData = Range(.Cells(1, 1), .Cells(Rows.Count, 1).End(xlUp))
            strFormula = .Cells(1, 1).Address(False, False, xlR1C1, True, rngDestination)
        End With
        
        lngDataCount = rngData.Rows.Count
        With rngDestination.Resize(lngDataCount, 1)
            .FormulaR1C1 = "=ABS(" & strFormula & "-" & dblTargetValue & ")"
            dblAbsTarget = WorksheetFunction.Small(.Cells, 3)
        End With
        
        If UBound(arrResult, 1) < lngDataCount Then ReDim Preserve arrResult(1 To lngDataCount)

        For i = 1 To lngDataCount
            If rngDestination.Cells(i, 1) <= dblAbsTarget Then
                arrResult(i) = Trim(arrResult(i) & " Yes") & Split(rngData.Address(True, False), "$")(0)
            End If
        Next i
    Next oneCol
    rngDestination.Offset(0, -1).Resize(UBound(arrResult), 1).Value = Application.Transpose(arrResult)
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,848
Members
452,361
Latest member
d3ad3y3

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