Notice: This website is an unofficial Microsoft Knowledge Base (hereinafter KB) archive and is intended to provide a reliable access to deleted content from Microsoft KB. All KB articles are owned by Microsoft Corporation. Read full disclaimer for more details.

XL2000: How to Return the Address of the Cell with the Largest or Smallest Value


View products that this article applies to.

Summary

This article demonstrates two ways that you can find the address of the cell containing the largest or smallest value in a range of cells in a Microsoft Excel worksheet. 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 need to create a custom Microsoft Visual Basic for Applications function. For examples of both methods, see the "More Information" section.

↑ Back to the top


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 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 is 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 a Microsoft Certified Partner or Microsoft Advisory Services. For more information, visit these Microsoft Web sites:

Microsoft Certified Partners - https://partner.microsoft.com/global/30000104

Microsoft Advisory Services - http://support.microsoft.com/gp/advisoryservice

For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site: http://support.microsoft.com/default.aspx?scid=fh;EN-US;CNTACTMS

To return the cell address of the largest value in an adjacent range that is larger than a single column or row, use the following custom 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 sample function:
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
				

↑ Back to the top


References

For additional information about getting help with Visual Basic forApplications, click the article number below to view the article in the Microsoft Knowledge Base:
226118 OFF2000: Programming Resources for Visual Basic for Applications

↑ Back to the top


Keywords: KB213375, kbprogramming, kbinfo, kbhowto

↑ Back to the top

Article Info
Article ID : 213375
Revision : 8
Created on : 11/23/2006
Published on : 11/23/2006
Exists online : False
Views : 305