ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   Find the closest match to a reference number in a row of unsorted (https://www.excelbanter.com/excel-worksheet-functions/62640-find-closest-match-reference-number-row-unsorted.html)

Nick Krill

Find the closest match to a reference number in a row of unsorted
 
Data is random in nature and unsorted. Generally between 10 and 100, two
decimal precision (see below). How do I find the position of the entry
closest a given value, say 45.11

45.54 45.56 45.32 45.5 45.42 45.35 45.46 45.4 44.97 45 45.05


Niek Otten

Find the closest match to a reference number in a row of unsorted
 
With your data in A1:K1:

=MATCH(MIN(A1:K1-45.11),A1:K1-45.11,0)

Array-entered, which means commit with CTRL+SHIFT+ENTER instead of just with
ENTER

In the formula bar, the formula will appear in curly brackets, to prove it
is an array formula

--
Kind regards,

Niek Otten

"Nick Krill" wrote in message
...
Data is random in nature and unsorted. Generally between 10 and 100, two
decimal precision (see below). How do I find the position of the entry
closest a given value, say 45.11

45.54 45.56 45.32 45.5 45.42 45.35 45.46 45.4 44.97 45 45.05




Sandy Mann

Find the closest match to a reference number in a row of unsorted
 
Neik,

Your formula returns the position of the lowest number for me even if one of
the given numbers is 45.11. Should the range subtractions not be enclosed
in ABS() functions as in:

=MATCH(MIN(ABS(A1:K1-45.11)),ABS(A1:K1-45.11),0)


--
Regards

Sandy

with @tiscali.co.uk


"Niek Otten" wrote in message
...
With your data in A1:K1:

=MATCH(MIN(A1:K1-45.11),A1:K1-45.11,0)

Array-entered, which means commit with CTRL+SHIFT+ENTER instead of just
with ENTER

In the formula bar, the formula will appear in curly brackets, to prove it
is an array formula

--
Kind regards,

Niek Otten

"Nick Krill" wrote in message
...
Data is random in nature and unsorted. Generally between 10 and 100, two
decimal precision (see below). How do I find the position of the entry
closest a given value, say 45.11

45.54 45.56 45.32 45.5 45.42 45.35 45.46 45.4 44.97 45 45.05






Niek Otten

Find the closest match to a reference number in a row of unsorted
 
Absolutely right, Sandy!

Thanks for the correction.

--
Kind regards,

Niek Otten

"Sandy Mann" wrote in message
...
Neik,

Your formula returns the position of the lowest number for me even if one
of the given numbers is 45.11. Should the range subtractions not be
enclosed in ABS() functions as in:

=MATCH(MIN(ABS(A1:K1-45.11)),ABS(A1:K1-45.11),0)


--
Regards

Sandy

with @tiscali.co.uk


"Niek Otten" wrote in message
...
With your data in A1:K1:

=MATCH(MIN(A1:K1-45.11),A1:K1-45.11,0)

Array-entered, which means commit with CTRL+SHIFT+ENTER instead of just
with ENTER

In the formula bar, the formula will appear in curly brackets, to prove
it is an array formula

--
Kind regards,

Niek Otten

"Nick Krill" wrote in message
...
Data is random in nature and unsorted. Generally between 10 and 100, two
decimal precision (see below). How do I find the position of the entry
closest a given value, say 45.11

45.54 45.56 45.32 45.5 45.42 45.35 45.46 45.4 44.97 45 45.05









All times are GMT +1. The time now is 01:59 PM.

Powered by vBulletin® Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
ExcelBanter.com