INDEX & MATCH - getting #N/A

itr674

Well-known Member
Joined
Apr 10, 2002
Messages
1,786
Office Version
  1. 2016
Platform
  1. Windows
I have built the example as indicated at http://www.mrexcel.com/tip021.shtml, but am getting #N/A when using the Index-Match function?

It appears the formula is looking is column B for the Match which is OK, I'm just trying to determin why it is not working.

Also, would the tables need to be sorted for this to work?
Book1
ABCD
1EmpNameDept
2A204SmithAccoutning
3A206DoeOperations
4A208MillerMIS
5A210WhiteAccounting
6A212YoungManufacturing
7
8
9EmpDept
10A208MIS
11A208#N/A
12
Sheet1
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
em said:
I have built the example as indicated at http://www.mrexcel.com/tip021.shtml, but am getting #N/A when using the Index-Match function?

It appears the formula is looking is column B for the Match which is OK, I'm just trying to determin why it is not working.

The Index/Match equivalent of

=VLOOKUP(A10,$A$2:$C$6,3)

would be:

=INDEX($C$2:$C$6,MATCH(A10,$A$2:$A$6))

The equivalent of:

=VLOOKUP(A10,$A$2:$C$6,3,0)

=INDEX($C$2:$C$6,MATCH(A10,$A$2:$A$6,0))

Note that 0 means the same thing in this formulas (that's, match-type = exact) as FALSE.

Also, would the tables need to be sorted for this to work?

Not necessarily. If the table is sorted on the match column (i.e., column A for both formulas above), then you can omit 0/FALSE.
 
Upvote 0
In INDEX/MATCH, think of that 1st array as being the equal of the array you'd use as the 2nd argument in the VLOOKUP statement. Mike's got your formula.
 
Upvote 0
To avoid the #NA error if there is no value in A11:
=IF(ISNA(INDEX($A$2:$B$6,MATCH(A11,$A$2:$A$6,0),2)),"No Value",INDEX($A$2:$B$6,MATCH(A11,$A$2:$A$6,0),2))

A similar error trapping formula could be used for your Vlookup formula.

Regards,

Mike
 
Upvote 0
Ekim said:
To avoid the #NA error if there is no value in A11:
=IF(ISNA(INDEX($A$2:$B$6,MATCH(A11,$A$2:$A$6,0),2)),"No Value",INDEX($A$2:$B$6,MATCH(A11,$A$2:$A$6,0),2))

A similar error trapping formula could be used for your Vlookup formula...

You must have exhanged your hat if any against a teacher's hat:

Why not more direct and not refer to only what is relevant, although the OP asked for none,...

=IF(ISNUMBER(MATCH(A11,$A$2:$A$6,0)),INDEX($B$2:$B$6,MATCH(A11,$A$2:$A$6,0)),"No Value")

Besides, there are better ways:

http://www.mrexcel.com/board2/viewtopic.php?t=62102
 
Upvote 0

Forum statistics

Threads
1,213,497
Messages
6,113,999
Members
448,541
Latest member
iparraguirre89

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