Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Office 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Finding the Address of the Lowest Value in a Range.

Finding the Address of the Lowest Value in a Range

by Allen Wyatt
(last updated September 15, 2018)

1

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
    Dim MinVal As Double
    Dim MinAddr As String
    Dim c As Range

    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

    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:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12744) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 365. You can find a version of this tip for the older menu interface of Excel here: Finding the Address of the Lowest Value in a Range.

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

Converting a Text Box to a Frame

These days, most people using Word know what text boxes are but have no idea about frames. Yet, for some purposes, frames ...

Discover More

Displaying the Navigation Pane when Opening a Document

The Navigation pane can be a big help in moving around a document. If you want to make sure it is always displayed for ...

Discover More

Excel 2010 Filters and Filtering (Table of Contents)

Excel provides two ways to filter your data so that only what you want to see is displayed. Discover how filtering works ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Finding the Sum of a Sequential Integer Range

In mathematics, the sum of a range of sequential integers, starting with 1, is known as a triangular number or Gaussian ...

Discover More

Referencing the Last Six Items in a Formula

If you have a list of data in a column, you may want to determine an average of whatever the last few items are in the ...

Discover More

Finding the First Non-Digit in a Text Value

If you have a string of text that is composed of digits and non-digits, you may want to know where the digits stop and ...

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}] 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 four more than 3?

2018-09-18 09:14:46

David Robinson

That last formula will only work if your range is in a single column.

I can suggest another method that doesn't involve using a macro... If you create a "helper" row and column. It will only work if the smallest value is unique however, because it doesn't do well with ties.

Below (or above) your data range, enter a formula that finds the MIN value in each column of the range, and fill this formula across. Call this HelperRow. Do the same to the right (or left) of your data range, finding the MIN in each row. Call this HelpCol. Then you can return the address by seeking the MIN value in the whole range in each helper column individually, namely

=ADDRESS(ROW(MyRange) + MATCH(MIN(MyRange), HelperCol,0)-1, COLUMN(MyRange) + MATCH(MIN(MyRange),HelperRow,0)-1)

It can't cope with ties because it finds the column with min value and row with min value and assumes the intersection of these is the lowest value, which may not be the case with multiple smallest values.


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.