Return value greater than in LOOKUP

B

Brian

I am trying to use the lookup function to return the next value greater than
the lookup value in a vector. However, the only thing that the lookup
function will do is return the next value that is less than or equal to. Is
there a way to get it to return the value greater than.

I am using: LOOKUP(25.4,M10:M150,M10:M150)

....and want to return the first value greater than 25.4 in the vector M10:M150
 
T

T. Valko

return the next value greater than the lookup value

Do you really mean greater than or equal to?

Try this for **greater than** :

=INDEX(M10:M150,MATCH(TRUE,INDEX(M10:M150>25.4,0),0))

Note that if there isn't a value greater than the lookup value you'll get an
error.
 
M

Mike H

Brian,

If your data are sorted you can use

=INDEX(M10:M150,COUNTIF(M10:M150,"<"&24.5)+1)

If it isn't sorted then this ARRAY formula

=INDEX(M10:M150,MATCH(SMALL(M10:M150,COUNTIF(M10:M150,"<"&24.5)+1),M10:M150,0))


This is an array formula which must be entered by pressing CTRL+Shift+Enter
'and not just Enter. If you do it correctly then Excel will put curly brackets
'around the formula {}. You can't type these yourself. If you edit the formula
'you must enter it again with CTRL+Shift+Enter.
--
Mike

When competing hypotheses are otherwise equal, adopt the hypothesis that
introduces the fewest assumptions while still sufficiently answering the
question.
 
B

Brian

Thanks,

That is exactly what I needed. Cuts my work down from several hours to
several minutes.

Brian
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top