Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Finding the Address of the Lowest Value in a Range

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.

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))

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.

Related Tips:

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!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

Comments for this tip:

Fred Burg    31 Oct 2015, 07:24
Hi Allen,

The formula approach only seems to work when MyRange is limited to a single row or column. Otherwise, the formula returns the #N/A error.

I've done something like this but had to get the address or the row and col separately.

Fred
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.