Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Finding the Address of the Lowest Value in a Range.
Written by Allen Wyatt (last updated April 24, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003
When writing a macro, you can find the lowest value in a range of cells by using the WorksheetFunction method to apply the MIN worksheet function. You may need, however, to not only find the lowest value in the range, but also the address of the first cell that contains that value.
One simple way is to simply step through the range you want to examine and derive both the lowest value and the address of the cell being examined, as in the following:
Function FindLowestAddr(pRng As Range) As String
Application.Volatile
MinVal = pRng.Cells(1).Value
MinAddr = pRng.Cells(1).Address
For Each c in pRng
If c.Value < MinVal Then
MinVal = c.Value
MinAddr = c.Address
End If
Next c
FindLowestAddr = MinAddr
End Function
Note that this approach doesn't rely upon the MIN worksheet function at all. There is a drawback to it, however—it doesn't differentiate between cells that contain numeric values and those that don't. In other words, if the range passed to the function contains a blank cell, that cell is considered to contain a zero value, which may very well be the lowest value in the range.
One way around this is to rely upon worksheet functions from within the macro. The following macro uses both the MIN and MATCH worksheet functions to determine the location of the minimum value and then the index (offset) of that cell within the range.
Function GetAddr(rng As Range) As String
Dim dMin As Double
Dim lIndex As Long
Dim sAddress As String
Application.Volatile
With Application.WorksheetFunction
dMin = .Min(rng)
lIndex = .Match(dMin, rng, 0)
End With
GetAddr = rng.Cells(lIndex).Address
End Function
It should be noted that if you are using the macro only to discover the address because you figured there was no way to derive the desired information without the macro, then you can do away with the macro entirely by using a worksheet formula. For instance, if you want to determine the address of the lowest-valued cell in the named range MyRange, you could use the following:
=ADDRESS(ROW(MyRange)+MATCH(MIN(MyRange),MyRange,0)-1,COLUMN(MyRange))
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (7140) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Finding the Address of the Lowest Value in a Range.
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!
Using a formula to find information in a text value is easy. Using a formula to find either of two text values within a ...
Discover MoreMany businesses organize information according to calendar quarters, especially when it comes to fiscal information. ...
Discover MoreExcel makes it easy to concatenate (or combine) different values into a single cell. If you need to combine a different ...
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 menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments