Address of a Cell in Which a Threshold is Exceeded

Written by Allen Wyatt (last updated December 24, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


1

In column A Ron has a series of numeric values sorted in ascending order. (The values are the results of formulas.) He would like to use a different formula to return the address of the first cell in column A in which the value exceeds a threshold that is found in cell E3. The problem is, Ron has no idea on how to put together such a formula.

There are multiple formulaic approaches you can take to this issue, and the one you choose can depend on the nature of the data you are analyzing. If you want the address of the cell in which the threshold is first met or first exceeded, then these formulas will do fine:

=ADDRESS(ROW(XLOOKUP(E3,A:A,A:A,,1)),1)
=ADDRESS(XMATCH(E3,A:A,1),1)

If, however, you want the address of the first cell in which the threshold is first truly exceeded (in other words, matches with the threshold are not counted), then the following formulas will work:

=ADDRESS(MATCH(E3,A:A,1)+1,1)
=ADDRESS(ROW(XLOOKUP(E3+0.001,A:A,A:A,,1)),1)
=ADDRESS(XMATCH(E3+0.001,A:A,1),1)
=ADDRESS(MATCH(E3,A:A,1)+1,COLUMN(A:A))
="A" & MATCH(E3,A:A,1)+1
=CELL("address",INDEX($A:$A,MATCH(E3,$A:$A,1)+1))

If nothing in column A exceeds the threshold in E3, then none of the above formulas work—they simply return the address of the cell in column A that is one row beyond the last value. That is similar to what happens with the following formulas:

=CELL("address",INDEX(A:A,MATCH(TRUE,INDEX(A:A>E3,0),)))
=ADDRESS(MATCH(MIN(IF(A:A>E3,A:A)),A:A,0),1)
=ADDRESS(MATCH(1,--(A:A>E3),0),COLUMN(A:A),4)
=SUBSTITUTE(CELL("address",INDEX(A:A,MATCH(1,--(A:A>E3),0))),"$","")

The difference with these formulas is that they don't return an erroneous address when the threshold is not exceeded by any value, but instead returns an #N/A error. This means that any of them could be wrapped within an IFNA function that "catches" the error condition and allows you to indicate what should be done. Here's an example of one of the formulas thusly wrapped:

=IFNA(ADDRESS(MATCH(MIN(IF(A:A>E3,A:A)),A:A,0),1),"Threshold not Exceeded")

This wrapping obviously makes the formulas a bit longer, but it makes the results of the formula more understandable.

Finally, it should be noted that all of these formulas should work just fine in Excel 2019 or later versions. In earlier versions, most of the formulas need to be entered as array formulas using Ctrl+Shift+Enter. (You should be able to look at the results returned by the formula and tell if you should enter it as an array formula.)

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12999) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Matching At the Beginning or End of a Word

The pattern matching capabilities of Word's search engine are quite powerful. You can tailor your search pattern so that ...

Discover More

Putting Shift+F4 On the Quick Access Toolbar

The Shift+F4 shortcut is very helpful when you want to repeat an action, such as finding the next occurrence of whatever ...

Discover More

Changing the Cycling Sequence for the F4 Cell Reference Shortcut

When editing a formula, the F4 shortcut key can be helpful. It may not, however, be helpful in all instances. This tip ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (ribbon)

Patterns of Numbers with a Formula

Want to create a sequential pattern using formulas? It's easy to do if you take a look at how your data repeats. This tip ...

Discover More

Summing Based on Part of a Control Cell

When analyzing data, you may have a need to calculate a sum based on just part of a particular cell. This tip examines ...

Discover More

Evaluating Formulas

Need a bit of help in figuring out how Excel is evaluating a particular formula? It's easy to figure out if you use the ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is one more than 7?

2022-12-26 10:12:33

J. Woolley

According to Microsoft, XLOOKUP requires Excel 2016 or later, but XMATCH requires Excel 2021 or later.
Since none of these formulas return an array, do any of them need to be entered using Ctrl+Shift+Enter? (If you have Excel pre-2021, please reply.)


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.