Returning the Minimum of Integers of a Range

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


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, 2021, and Excel in Microsoft 365.

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

Randomly Assigning Names to Items

If you need to randomly match up items in two lists, there are a variety of techniques you can use. Here are a couple of ...

Discover More

Changing the Default Font for Envelopes

When you create an envelope, Word assumes you want to use the font it has decided should be used for the envelope. If you ...

Discover More

Getting Files Out of Compatibility Mode

Work with a document that uses an older file format, and Word lets you know you are using compatibility mode. What is the ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (ribbon)

Deriving High and Low Non-Zero Values

When analyzing your numeric data, you may need to figure out the largest and smallest numbers in a set of values. If you ...

Discover More

Segregating Numbers According to Their Sign

Remember your number line from your early years in school? Some numbers can be below zero (negative numbers) and others ...

Discover More

Counting Consecutive Negative Numbers

If you have a range of values that can be either positive or negative, you might wonder how to determine the largest ...

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 6 - 1?

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.