Summary

To match the first value that does not begin with a specific string, you can use an array based on the MATCH and LEFT functions. In the example shown, the formula in F5 is:

{=MATCH(TRUE,IF(LEFT(code,1)<>"N",TRUE),0)}

where "code" is the named range B5:B12.

Note: this is an array formula and must be entered with control + shift + enter.

Generic formula

{=MATCH(TRUE,IF(LEFT(range,1)<>"N",TRUE),0)}

Explanation 

The key to this formula is the array or TRUE and FALSE values constructed with this expression:

LEFT(code,1)<>"N"

Here, each value in the named range "code" is evaluated with the logical test "first letter is not N". The result is an array or TRUE and FALSE values like this:

{FALSE;FALSE;FALSE;FALSE;TRUE;FALSE;FALSE;TRUE}

This array is fed into the MATCH function as the lookup array. The lookup value is TRUE, and match type is set to zero to force an exact match. The MATCH function returns the position of the first value that does not begin with the letter "N" (Z09876), which is 5.

INDEX and MATCH

To retrieve a value associated with the position returned by MATCH, you can add the INDEX function. In example shown, the formula in F6 is:

{=INDEX(value,MATCH(TRUE,LEFT(code,1)<>"N",0))}

Note we are using the same MATCH formula above to provide a row number to INDEX, with the array set to the named range "value". As before, MATCH returns 5. INDEX then returns the value at that position, -23.

As before, this is an array formula and must be entered with control + shift + enter.

Dave Bruns Profile Picture

AuthorMicrosoft Most Valuable Professional Award

Dave Bruns

Hi - I'm Dave Bruns, and I run Exceljet with my wife, Lisa. Our goal is to help you work faster in Excel. We create short videos, and clear examples of formulas, functions, pivot tables, conditional formatting, and charts.