Finding the value with the lowest absolute difference in a range

RainGauge

New Member
Joined
Jul 15, 2021
Messages
6
Office Version
  1. 2016
Platform
  1. Windows
I'm attempting to find the value with the lowest absolute difference of C1 (the Anchor Value) in a range (B3:F3).

The best I can produce is what might be part of a solution:
Excel Formula:
{=MIN(ABS(B3:F3-C1))}
This returns the lowest absolute difference, not the value that has the lowest absolute difference.

The expected value produced by a working formula would be 3. -1 also meets the criteria but since 3 is the left-most value that meets the criteria, it is the value I would like chosen.

Thank you for taking the time to look over my problem and hopefully I was clear enough with what I'm looking for.
If further clarification is required, let me know.
 

Attachments

  • Question_Diagram.png
    Question_Diagram.png
    4.6 KB · Views: 10

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
How about
Excel Formula:
=INDEX(B3:F3,MATCH(MIN(ABS(B3:F3-C1)),ABS(B3:F3-C1),0))
 
Upvote 0
Solution
How about
Excel Formula:
=INDEX(B3:F3,MATCH(MIN(ABS(B3:F3-C1)),ABS(B3:F3-C1),0))
Thank you, this works as I wanted.
I figured I needed an INDEX MATCH but couldn't wrap my sleep-deprived head around it.
 
Upvote 0
This may work:
Excel Formula:
=INDEX(B3:F3,MATCH(MIN(ABS(B3:F3-$C$1)),ABS(B3:F3-$C$1),0))
Sorry, my page just refreshed and I saw Fluff got you the same answer.
 
Upvote 0
Glad we could help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,224,828
Messages
6,181,201
Members
453,022
Latest member
RobertV1609

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