XL: Returning Address of the Cell with Largest or Smallest Value

ID: Q139574


The information in this article applies to:
  • Microsoft Excel for Windows, versions 5.0, 5.0c
  • Microsoft Excel for Windows 95, version 7.0
  • Microsoft Excel 97 for Windows
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a
  • Microsoft Excel 98 Macintosh Edition


SUMMARY

The examples in the "More Information" section of this article demonstrate two ways you can find the address of the cell containing the largest or smallest value in a range of cells. If you are using a single row or column of data, you can use a worksheet formula. If you are using multiple rows or columns of adjacent data, you will need to create a custom Visual Basic for applications function. For examples of both methods, see the "More Information" section of this article.


MORE INFORMATION

Using Formulas

You can return the address of the cell with the largest or smallest value in a column or row by using the CELL(), OFFSET(), and MATCH() functions along with the MAX()or the MIN() function.

If there are multiple occurrences of the largest or smallest value, the following formulas will return the cell address of the first occurrence of the value. If there is only one occurrence of the value, the address of the cell containing that value will be returned.

To return the address of a cell in a column (in this example, column A, cells A1:A10), use the appropriate formula in the following table.

   For this
   address      Use this formula
   ------------------------------------------------------------------------
   Cell with
   largest
   value        =CELL("address",OFFSET(A1,MATCH(MAX(A1:A10),A1:A10,0)-1,0))

   Cell with
   smallest
   value        =CELL("address",OFFSET(A1,MATCH(MIN(A1:A10),A1:A10,0)-1,0)) 
To return the address of a cell in a row (in this example, column A, cells A1:J1), use the appropriate formula in the following table.

   For this
   address      Use this formula
   ------------------------------------------------------------------------
   Cell with
   largest
   value        =CELL("address",OFFSET(A1,0,MATCH(MAX(A1:J1),A1:J1,0)-1))

   Cell with
   smallest
   value        =CELL("address",OFFSET(A1,0,MATCH(MIN(A1:J1),A1:J1,0)-1)) 

Using Custom Functions

Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support professionals can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/overview/overview.asp
To return the cell address of the largest value in an adjacent range that is larger than a single column or row, you can create a custom Microsoft Visual Basic for Applications function.

     Function MaxAddress(The_Range)

      ' Sets variable equal to maximum value in the input range.
      MaxNum = Application.Max(The_Range)
      ' Loop to check each cell in the input range to see if equals the
      ' MaxNum variable.
      For Each cell In The_Range
         If cell = MaxNum Then
            ' If the cell value equals the MaxNum variable it
            ' returns the address to the function and exits the loop.
            MaxAddress = cell.Address
            Exit For
         End If
      Next cell

   End Function 
To find the cell address of the smallest value in an adjacent range, substitute the Min() function for the Max() function as in the following example:

   Function MinAddress(The_Range)

      ' Sets variable equal to minimum value in the input range.
      MinNum = Application.Min(The_Range)
      ' Loop to check each cell in the input range to see if equals the
      ' min variable.
      For Each cell In The_Range
         If cell = MinNum Then
            ' If the cell value equals the max variable it
            ' returns the address to the function and exits the loop
            MinAddress = cell.Address
            Exit For
         End If
      Next cell

   End Function 


REFERENCES

For additional information about getting help with Visual Basic for Applications, please see the following article in the Microsoft Knowledge Base:

Q163435 VBA: Programming Resources for Visual Basic for Applications

Additional query words: 8.00 adjacent contiguous nonadjacent noncontiguous discontiguous discontinuous maximum minimum greatest least

Keywords : kbprg kbdta PgmHowto xlformula KbVBA
Version : MACINTOSH:5.0,5.0a,98; WINDOWS:5.0,5.0c,7.0
Platform : MACINTOSH WINDOWS
Issue type :


Last Reviewed: November 9, 1999
© 2000 Microsoft Corporation. All rights reserved. Terms of Use.