Index / Match Help

tidnab312

New Member
Joined
Jun 23, 2011
Messages
10
So I got the Index Match function to work, with one arguement:
Looks like this:
=INDEX($E$8:$E$100,MATCH(A4,$A$8:$A$100,FALSE))

works great, problem is the second argument comes from the B4 cell and the arguement needs to match BOTH A4 and B4 as there's duplicate data. I get a #REF! error

=INDEX($E$8:$E$100,MATCH(A4,$A$8:$A$100,FALSE),MATCH(B4,$C$8:$C$100,FALSE))

Also tried it this way: gives me a #VALUE error
=INDEX($E$8:$E$100,MATCH(A4&B4,$A$8:$A$100&$C$8:$C$100,FALSE),1)

I haven't used these functions much and got this far just by research... but now I'm stuck:(

thanks in advance for any help :biggrin:
 

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.
Try this small modification in your formula (array formula - use Ctrl+Shift+Enter and not only Enter):

<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: center;;">Name01</td><td style="text-align: center;;">Data01</td><td style="text-align: center;;">30</td><td style="text-align: center;;">20</td><td style="text-align: center;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: center;background-color: #FFFF00;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;"></td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: center;background-color: #FFFF00;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;"></td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: center;background-color: #FFFF00;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Data01</td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;">20</td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: center;background-color: #FFFF00;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;"></td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: center;background-color: #FFFF00;;">Name01</td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;">30</td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style="text-align: center;background-color: #FFFF00;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;"></td></tr><tr ><td style="color: #161120;text-align: center;">14</td><td style="text-align: center;background-color: #FFFF00;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;"></td></tr><tr ><td style="color: #161120;text-align: center;">15</td><td style="text-align: center;background-color: #FFFF00;;">Name01</td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Data01</td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">16</td><td style="text-align: center;background-color: #FFFF00;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;"></td></tr><tr ><td style="color: #161120;text-align: center;">17</td><td style="text-align: center;background-color: #FFFF00;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;"></td></tr><tr ><td style="color: #161120;text-align: center;">18</td><td style="text-align: center;background-color: #FFFF00;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;"></td></tr><tr ><td style="color: #161120;text-align: center;">19</td><td style="text-align: center;background-color: #FFFF00;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;"></td></tr><tr ><td style="color: #161120;text-align: center;">20</td><td style="text-align: center;background-color: #FFFF00;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #00B050;;"></td></tr><tr ><td style="color: #161120;text-align: center;">21</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">22</td><td style="text-align: center;;">********</td><td style="text-align: center;;">********</td><td style="text-align: center;;">********</td><td style="text-align: center;;">********</td><td style="text-align: center;;">********</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet3</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C4</th><td style="text-align:left">=INDEX(<font color="Blue">E8:E20,MATCH(<font color="Red">A4,A8:A20,0</font>)</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">D4</th><td style="text-align:left">=INDEX(<font color="Blue">E8:E20,MATCH(<font color="Red">B4,C8:C20,0</font>)</font>)</td></tr></tbody></table></td></tr></table><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">E4</th><td style="text-align:left">{=INDEX(<font color="Blue">$E$8:$E$20,MATCH(<font color="Red">A4&B4,$A$8:$A$20&$C$8:$C$20,0</font>)</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />
Markmzz
 
Upvote 0
I was tryin to use CTRL SHIFT ENTER and it didn't do anything... until i double clicked on the cell THEN it worked... so it was not my formula (which works now THANKS) I just wasn't gettin how the ctrl shift enter thing worked..:rofl:

anyway... it works now.. thanks !!
 
Upvote 0
I was tryin to use CTRL SHIFT ENTER and it didn't do anything... until i double clicked on the cell THEN it worked... so it was not my formula (which works now THANKS) I just wasn't gettin how the ctrl shift enter thing worked..:rofl:

anyway... it works now.. thanks !!

Tidnab312,,

Your formula was ok, the small modification that I said was the Ctrl+Shift+Enter.

Markmzz<?xml:namespace prefix = o ns = "urn:schemas-microsoft-com:office:office" /><o:p></o:p>
 
Last edited:
Upvote 0
Yep Thanks...

Unfortunately I thought the code was working but it's only 1/2 working

{=INDEX($E$11:$E$103,MATCH($B$6,$A$11:$A$103,FALSE),MATCH($C$6,$C$11:$C$103,FALSE))}


so my variables are $B$6 & $C$6 that works fine, but in the row below it I want the Data for $B$6 & $C$7 that does not work I get the #REF! error

What's even stranger is if I put the value of C7 in B7 it breaks that index as well... with that said the index is retrieving the first record that matches the first variable and stopping. I need it to bring up the data where it matches BOTH variables... if that makes sense...
 
Upvote 0
The correct array formula is

{=INDEX($E$11:$E$103,MATCH($B$6&$C$6,$A$11:$A$103&$C$11:$C$103,FALSE))}

and not

{=INDEX($E$11:$E$103,MATCH($B$6,$A$11:$A$103,FALSE),MATCH($C$6,$C$11:$C$103,FALSE))}

Look at this:

So I got the Index Match function to work, with one arguement:
Looks like this:
=INDEX($E$8:$E$100,MATCH(A4,$A$8:$A$100,FALSE))

works great, problem is the second argument comes from the B4 cell and the arguement needs to match BOTH A4 and B4 as there's duplicate data. I get a #REF! error

=INDEX($E$8:$E$100,MATCH(A4,$A$8:$A$100,FALSE),MATCH(B4,$C$8:$C$100,FALSE))

Also tried it this way: gives me a #VALUE error
=INDEX($E$8:$E$100,MATCH(A4&B4,$A$8:$A$100&$C$8:$C$100,FALSE),1)

I haven't used these functions much and got this far just by research... but now I'm stuck:(

thanks in advance for any help :biggrin:

Could you post a small example of your data?

Put borders around a small range of the cells.
Then copy the range and paste them here.

Markmzz
 
Upvote 0

Forum statistics

Threads
1,224,514
Messages
6,179,223
Members
452,896
Latest member
IGT

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