index formulas

J Lee

New Member
Joined
May 21, 2008
Messages
34
hello,

i'm having problems with the following formula:

it is used to take an index to average, and associate a "ranking" based on certain parameters (between 1-2, or 2-3, or 3-4, etc). I have used this formula in many instances with a lot of success, however, i'm having issues this one time, and can't figure out why. it's is only working when i have a value that is "greater than" (please see formula), and when the value is less than, it is giving me a "value" error, which seems to be derived from the "match" part of the formula.

=INDEX($B$21:$B$24,IF(B56>$H$21,1,MIN(MATCH((AY$19:AY$45),($H$21:$H$24),-1)+1,8)),0)

here is a "translation" of the formula:

=INDEX(value to be returned,IF(lookup value>highest # in range,1,MIN(MATCH((list of all lookup values),(minimums to qualify for the value to be returned),-1,+1,8)),0)

thanks for any help.

k
 

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.
Did you array-enter it?
 
Upvote 0
I've never had to hold ctrl+shift+enter when I enter the formula if that's what you mean...
 
Upvote 0
That formula usually needs to be array-entered, as Rory suggests. In which cell or cells are you using it?

It'll work OK if the IF function test is TRUE because that part of the formula doesn't need CSE, but the MATCH part does because MATCH normally expects a single value as the first argument, you're using a range there.

If you use the formula somewhere in rows 19 to 45 you might still get a result....but possibly not the one you want.

This version doesn't require CSE

=INDEX($B$21:$B$24,IF(B56>$H$21,1,MIN(INDEX(MATCH(AY$19:AY$45,$H$21:$H$24,-1),0)+1,8)),0)

H21:H24 should be sorted descending
 
Upvote 0
I guess one or more of your values is not matching.
 
Upvote 0

Forum statistics

Threads
1,213,563
Messages
6,114,329
Members
448,564
Latest member
ED38

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