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.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
If you have a bunch of ZIP Codes or part numbers in a list, you may want to "condense" the list so that sequential series ...
Discover MoreFor some operations and functions, Excel allows you to use wild card characters. One such character is an asterisk. What ...
Discover MoreAdding row numbers to a column of your worksheet is easy; you just need to use a formula to do it. Here's a quick look at ...
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 © 2023 Sharon Parq Associates, Inc.
Comments