Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. 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 June 28, 2014)

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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (124) applies to Microsoft Excel 2007, 2010, and 2013. 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

Deleting a Header

Each new Excel worksheet contains a page header, by default. Follow this tip to get rid of headers you don't need.

Discover More

Missing Left Border

Ever wonder why a border around a graphic doesn't print the way it looks on the screen? There are several ways to add and ...

Discover More

Printing All or Nothing

Want to make sure that when you worksheet is printed that everything in the workbook is really printed? You can accomplish ...

Discover More

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

More ExcelTips (ribbon)

Counting Records Matching Multiple Criteria

Excel provides worksheet functions that make it easy to count things. What if you want to count records that match more than ...

Discover More

Combinations for Members in Meetings

Got a large group of people listed in a worksheet and you want to make sure that each person has met with every other person ...

Discover More

Understanding Operators

At the heart of working with Excel is the process of creating formulas that calculate results based on information within a ...

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 8Mpixels. 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 7 - 0?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.