Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Office 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Finding the Smallest Even Value.

Finding the Smallest Even Value

by Allen Wyatt
(last updated September 7, 2019)

1

Emin has a range of cells in which there can be either text or numbers. He needs a way to determine the smallest even number in the range. Emin wonders if this can be done with a formula, or if he needs a user-defined function.

There are a couple of ways you can approach this problem. One method you can try is to use the DMIN function. All that you need is to make sure that you have a header on your data column (such as "MyData") and then create a small criteria field in some out-of-the-way place. For instance, you might want to create the criteria field by placing a header (such as "Min Even") in cell F1 and place the formula =ISEVEN(MyData) in cell F2. Cell F2 evaluates to an #VALUE! error, but that is fine in this case. You can then use the following formula in a different cell:

=DMIN(A1:A100, 1, F1:F2)

If you prefer, you can use an array formula to figure out the lowest even value. Because your data range can contain text as well as numbers, not all array formulas will work, however. For instance, the following will generate an error if there is anything but numbers in the data range:

=MIN(IF(MOD(A1:A100,2)=0,A1:A100))

To make sure you don't get the errors, you need to do some checking in the formula:

=MIN(IF(ISNUMBER(A1:A100),IF(NOT(MOD(A1:A100,2)=0),"",A1:A100)))

Again, remember that this is an array formula, so you need to enter it using Shift+Ctrl+Enter.

If you prefer, you can create a user-defined function that will return the desired value:

Function MinEven(rng As Range)
    Dim rCell As Range
    Dim bNotFound As Boolean

    Application.Volatile
    MinEven = 9.99 * 10 ^ 307
    bNotFound = True
    For Each rCell In rng
        If Application.WorksheetFunction.IsNumber(rCell) Then
            If rCell Mod 2 = 0 Then
                If rCell < MinEven Then
                    MinEven = rCell
                    bNotFound = False
                End If
            End If
        End If
    Next
    If bNotFound Then MinEven = CVErr(xlErrNum)
End Function

To use this macro, simply use the following with a cell of your worksheet:

=MinEven(A1:A100)

If there are no even numbers in the range, the function will return a #Num error.

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 (124) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 365. You can find a version of this tip for the older menu interface of Excel here: Finding the Smallest Even Value.

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

Turning Off Track Changes Change Bars

Word includes a feature that allows you to track changes made to a document. One of the ways in which Word marks your ...

Discover More

Friendly and Informative Error Handling

When creating macros, it is helpful to know what is going on within the macro itself in case an error crops up. Here's ...

Discover More

Searching for Multi-Byte Hex Codes

Need to find a character for which you only know the hex code? There are a few ways you can search for the information, ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (ribbon)

Adding Up Tops and Bottoms

When you are working with sequenced values in a list, you’ll often want to take some action based on the top X or ...

Discover More

Adding Area Codes to Phone Numbers

If you keep phone numbers in an Excel worksheet, you may need a way to add an area code to the beginning of all of the ...

Discover More

Deriving Monthly Median Values

When processing huge amounts of data, it can be a challenge to figure out how to derive the aggregate values you need. ...

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}] 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 seven more than 6?

2019-09-07 09:18:59

Willy Vanhaelen

Here is a shorter version of the array formula:
=MIN(IF(ISNUMBER(A1:A100),IF(MOD(A1:A100,2)=0,A1:A100)))

The user defined function (UDF) in this tip is quite complicated and can be replaced by this tiny one-liner:

Function MinEven(rng As Range)
MinEven = Evaluate(Replace("MIN(IF(ISNUMBER(@),IF(MOD(@,2)=0,@)))", "@", rng.Address))
End Function

This is in fact the VBA implementation of the array formula of this tip.
Instead of entering
     =MIN(IF(ISNUMBER(A1:A100),IF(NOT(MOD(A1:A100,2)=0),"",A1:A100)))
followed by Ctrl+Shift+Enter, you can simply enter:
     =MinEven(A1:A100)
with a regular Enter.



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.