Written by Allen Wyatt (last updated May 7, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Alec has a range of cells that can contain both integer (23) and decimal (23.4) values. He needs a formula that will return the minimum value of only the integers within the range. Any decimal number within the range should be ignored by the formula completely. It needs to be a formula; a macro would not be viable for Alec's needs.
If you don't mind using a helper column, you could easily figure out if the value is an interger or not. All you need to do is use a formula such as this in the helper column:
=IF(A1=INT(A1),A1,"")
What you end up with is only the integers, with decimal values replaced by blanks. You can then use the MIN function on the helper column to determine the minimum of those integer values.
If you cannot use a helper column, then the best way to go is with an array formula. Assume, for a moment, that your range of cells is A1:A100. You could use either of the following formulas:
=MIN(IF(INT(A1:A100)=A1:A100,A1:A100))
Remember that this is an array formula. This means that you should not enter it by pressing Enter, but should instead use Ctrl+Shift+Enter.
If you prefer to not use array formulas and you are using Excel 2010 or a later version, then you could use a formula based on the AGGREGATE function:
=AGGREGATE(15,6,A1:A100/(A1:A100=INT(A1:A100)),1)
The various parameters possible to use with the AGGREGATE function are too many to list here, but in this the case the first parameter (15) indicates you want the SMALL function applied, the second parameter (6) indicates you want error values ignored, the third parameter is the array to evaluate, and the fourth parameter (1) indicates we want the first result for SMALL returned.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (655) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
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!
When working with data in Excel, you might want to figure out which rows of data represent duplicates of other rows. If ...
Discover MoreWith a long list of items in a worksheet, you may want to determine the last time a particular item appeared in the list. ...
Discover MoreExcel can be used to generate random testing data that you can use in any way you deem necessary. This tip provides ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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