Find Text With INDEX and MATCH

Find Text With INDEX and MATCH

Is there a harder working team in Excel, than the reliable duo of INDEX and MATCH? These functions work beautifully together, with MATCH identifying the location of an item, and INDEX pulling the results out from the murky depths of data.

Last week, Jodie asked if I could help with a problem, and INDEX and MATCH came to the rescue again.

Find the Text in a String

Jodie sent me a picture of her worksheet, with text strings in column A and codes in column D. Each text string contained one of the codes, and Jodie wanted that code to appear in column B.

Would you use INDEX and MATCH to find the code, or another method? Keep reading to see my solution, and please share your ideas, if you have other ways to solve this.

indexmatchtextstring01

Count the Occurrences With COUNTIF

When you want to find text that’s buried somewhere in a string, the * wildcard character is useful. We can use the wildcard with COUNTIF, to see if the string is found somewhere in the text.

I entered this test formula in cell B1. This formula needs to be array-entered, so press Ctrl + Shift + Enter.

=COUNTIF(A1,”*” & $D$1:$D$3 & “*”)

indexmatchtextstring02
There are wildcard characters before and after the cell references to D1:D3, so the text will be found anywhere within the text string.

To see the results of the array formula, click in the formula bar, and press the F9 key. The array shows 0;1;0 so it found a match for CAT, which is in the second cell in the range.

indexmatchtextstring03

Get the Position With MATCH

Press the Esc key, to exit the formula without saving the calculated results.
Next, you can add the MATCH function, to get the position of the “1” in the results. Remember to press Ctrl + Shift + Enter.

=MATCH(1,COUNTIF(A1,”*”&$D$1:$D$3&”*”),0)

indexmatchtextstring04

The result is 2, so the code “CAT” was found in cell A1.

Get the Code With INDEX

Next, the INDEX function can return the code that is at the position that the MATCH function identified. Press Ctrl + Shift + Enter to see the result.

=INDEX($D$1:$D$3,MATCH(1,COUNTIF(A1,”*”&$D$1:$D$3&”*”),0))

indexmatchtextstring05

The result is CAT, so the formula is working correctly.

Prevent Error Results With IFERROR

There should be a valid code in each text string, but sometimes the data doesn’t cooperate. Just in case there are text strings without a code, or more than one instance of the code, you can use IFERROR to show an empty string, instead of an error. (Excel 2007 and later versions)

=IFERROR(INDEX($D$1:$D$3,MATCH(1,COUNTIF(A1,”*”&$D$1:$D$3&”*”),0)),””)

Enter with Ctrl + Shift + Enter, and then copy the formula down to row 10.

indexmatchtextstring06

In cell B6, the formula returns an empty string, and the cell looks blank, because none of the valid codes are in the text that’s in cell A6.

Use a Named Range

Instead of referring to range $D$1:$D$3, you could name that range, and use the name in the INDEX/MATCH formula. That would make it easier to maintain, if the size of the codes list will change.

indexmatchtextstring07

Download the Find Text With INDEX and MATCH Sample File

To see how the formula works, click here to download the Find Text With INDEX and MATCH sample file. The zipped file is in xlsx format, and does not contain macros.

More INDEX and MATCH Examples

There are more examples of using INDEX and MATCH in the 30 Excel Functions in 30 Days series:
30 Excel Functions in 30 Days – INDEX
30 Excel Functions in 30 Days – MATCH
____________________________

Find Text With INDEX and MATCH