Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 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.
Written by Allen Wyatt (last updated September 7, 2019)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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:
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 Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Finding the Smallest Even Value.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
US ZIP Codes can be of two varieties: five-digits or nine-digits. Here's how to convert longer ZIP Codes to the shorter ...
Discover MoreWhen analyzing your numeric data, you may need to figure out the largest and smallest numbers in a set of values. If you ...
Discover MoreUncovering the lowest value in a range is relatively easy; you can just use the MIN worksheet function. Discovering the ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
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.
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments