First Value Less Than or Equal to 100

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


5

Kenny has a row where the cells can be either blank or contain a value ranging from 1 to 135. He needs a formula that will return the address of the first cell in the row that contains a value (not a blank) that is less than or equal to 100.

There are a number of different ways this could be approached. Assuming the values are in row 8, the following formula provides a relatively concise way of deriving the address:

=ADDRESS(8,MATCH(1,(8:8<=100)*ISNUMBER(8:8),0),4,1)

Here's a variation that is just a bit shorter because it doesn't include the ISNUMBER function:

=ADDRESS(ROW(8:8),MATCH(1,(8:8<>"")*(8:8<=100),0))

Notice all the instances of 8 in these formulas. If your data is in a different row, then you should change each "8" to a number that represents the desired row. Plus, if you are using an older version of Excel that requires special treatment of array formulas, you'll want to enter these formulas using Ctrl+Shift+Enter.

You can also, if desired, create a user-defined function that will return the address. Here's an example of one that will work just fine:

Function FirstLE100(R As Long) As String
    Dim C As Long

    Application.Volatile

    C = 1
    FirstLE100 = "Not Found"

    Do While C <= 16384
        If Cells(R, C).Value <= 100 And Not IsEmpty(Cells(R, C).Value) Then
            FirstLE100 = Cells(R, C).Address
            Exit Do
        End If
        C = C + 1
    Loop
End Function

The function accepts, as a parameter, a row number to be evaluated. So, for instance, if you wanted to work with row 9, you would use the following in your worksheet:

=FirstLE100(9)

The function returns the address of the first cell in the row that has a non-empty cell where the value contained is less than or equal to 100. It also works just fine with negative values.

If you don't want a full row evaluated, then you can modify the function so that it works just fine with a range instead:

Function FirstLE100(MyRange As Range) As String
    Dim C As Range

    Application.Volatile

    FirstLE100 = "Not Found"

    For Each C In MyRange.Cells
        If C.Value <= 100 And Not IsEmpty(C.Value) Then
            FirstLE100 = C.Address
            Exit For
        End If
    Next C
End Function

In order to use this version you would simply supply a range that you want evaluated:

=FirstLE100(D5:AY5)

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (1232) 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

Putting a Bullet in the Middle of a Sentence

Need a special character (such as a bullet) in the middle of your text? Here are two quick ways to enter the character ...

Discover More

Controlling the Behavior of the Mouse Wheel

The mouse wheel, by default, controls scrolling vertically through your worksheet. If you don't want the wheel to control ...

Discover More

Converting Conditional Formatting to Regular Formatting

Conditional formatting allows you to change how information is displayed based on rules you define. What if you want to ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!

More ExcelTips (ribbon)

Counting Asterisks in a Column

Excel can be used as a simple database program. If you use asterisks in a column of your database to designate ranking of ...

Discover More

Finding Odd Values Greater Than 50

If you have a special need to find cell values that meet two different criteria, where to start can be daunting. This tip ...

Discover More

Hiding Rows Based on Two Values

It's easy to use filtering to hide rows based on the value in a cell, but how do you hide rows based on the values in two ...

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 2 + 2?

2024-02-28 14:06:26

J. Woolley

In my most recent comment below I said, "...a formula that includes an array but returns a single value does not need to be entered using Ctrl+Shift+Enter in any version of Excel." I guess it depends on the formula, but determining which formulas qualify is too confusing. Therefore, for versions prior to Excel 2021 you should use Ctrl+Shift+Enter if the formula involves an array. This conforms to the advice of the current Tip and others like it. I apologize for my previous poor advice regarding this subject.
Excel's array formulas and functions are very useful, but their implementation in older versions is too cumbersome; therefore, I suggest anyone who is serious about Excel should upgrade to Excel 2021 or a newer version.


2023-10-30 10:20:51

J. Woolley

@Kiwerry
Thank you. As expected, a formula that includes an array but returns a single value does not need to be entered using Ctrl+Shift+Enter in any version of Excel.
The previous statement has a corollary that is also applicable to any version of Excel. If you select a SINGLE CELL and use Ctrl+Shift+Enter to enter a formula that returns an array like
=ISNUMBER(8:8)
the result is a single value which is the first element of the returned array.


2023-10-29 13:11:53

Kiwerry

@J . Woolley:
I copied =INDEX(ISNUMBER(8:8),1,1) into a cell in Excel 2010 and simply pressed Enter;
it worked as expected (Cell A8 contained a number, result TRUE), even when I changed the last argument to 2 (Cell B8 contained text, result FALSE). HTH.


2023-10-28 11:28:30

J. Woolley

The Tip does not explain how its first two formulas work. Using its second formula for example:
The array (8:8<>"")*(8:8<=100) contains 1 for each cell in row 8 that is not blank and is <=100; otherwise, it contains 0 for that cell. (The numeric value of TRUE is -1 and FALSE is 0. Multiplication converts TRUE AND TRUE to 1; if either is FALSE, the result is 0.)
MATCH(1,(8:8<>"")*(8:8<=100),0) returns the column number of the first cell in array (8:8<>"")*(8:8<=100) that is exactly 1 (TRUE AND TRUE).
ROW(8:8) returns row number 8.
ADDRESS(ROW(8:8),MATCH(...)) returns the final result in absolute A1 style (like $E$8). For relative A1 style, use ADDRESS(ROW(8:8),MATCH(...),4).


2023-10-28 10:47:23

J. Woolley

Excel 365 and 2021+ support dynamic arrays. I have a question about older versions that do not.
Each of the Tip's first two formulas include an array but return a single result. Do they really need to be entered using Ctrl+Shift+Enter in older versions of Excel?
I recognize this formula
    =ISNUMBER(8:8)
returns an array with 1 row and all columns, so in older versions it must be entered by first selecting all of row 8 then pressing Ctrl+Shift+Enter.
But the following formula returns a single result from the array:
=INDEX(ISNUMBER(8:8),1,1)
Do similar formulas that include an array but return a single result need to be entered using Ctrl+Shift+Enter in older versions of Excel? I ask this question because my Excel 365 supports dynamic array formulas, but I wonder how older versions work. Will someone with an older version please try the last example and report their result?


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.