XL: How to Determine Top/Bottom Used Cells in a Sparse Array

Article translations Article translations
Article ID: 142526 - View products that this article applies to.
This article was previously published under Q142526
This article has been archived. It is offered "as is" and will no longer be updated.
Expand all | Collapse all

On This Page

Summary

This article discusses how you can determine the beginning and end used rows of a range by using the IF, ISBLANK, MAX, MIN, and ROW functions. The results can provide information to other functions and can help you to determine variable ranges. This article provides formulas for finding the first and last rows, plus an example of how you can select a variable range using these formulas. The following example assumes that there is at least one used cell. Complications caused by empty ranges are beyond the scope of this article.

More information

First Row

The formula to return the row number of the first used cell in a range is as follows:
   =MIN(IF(ISBLANK(A2:A400),17000,ROW(A2:A400)))
				
As an alternative, to return the row of the first number, the formula is as follows:
   =MIN(IF(ISNUMBER(A2:A400),ROW(A2:A400),17000))
				

Last Row

The formula to return the row number of the last used cell in a range is as follows:
   =MAX(IF(ISBLANK(A2:A400),0,ROW(A2:A400)))
				
As an alternative, to return the row of the last number, the formula is as follows:
   =MAX(IF(ISNUMBER(A2:A400),ROW(A2:A400),0))
				

How to Use the Results of These Formulas

Because the answers returned by the formulas are the rows meeting the IF condition statements, you can select the range from the top numerical cell to the bottom numerical cell, excluding cells above and below that used range. Note that unused cells can be inside the range and will not be excluded by the example. The example looks for a number, therefore you need to use the alternate formulas (that is, the formulas to find the row of the first number and the row of the last number).

To determine the range, type all of the following into a single cell outside the range A2:A400:
   =SUM(OFFSET(A1,MIN(IF(ISNUMBER(A2:A400),ROW(A2:A400),17000)),0,
      MAX(IF(ISNUMBER(A2:A400),ROW(A2:A400),0))-
      MIN(IF(ISNUMBER(A2:A400),ROW(A2:A400),17000))+1,1))
				
NOTE: There are no spaces in the above formula; multiple lines are used only to fit the formula into this document. Do not include any spaces as you type it into the cell.

All of the above are array formulas and may require the Array entry. If you are using Microsoft Windows, press CTRL+SHIFT+ENTER. If you are using a Macintosh computer, press COMMAND+RETURN.

If you use an array range in excess of 2,730 cells, you may receive an error because array management is limited to one segment of memory (64K). Some versions of Microsoft Excel may be able to use larger arrays, depending on the internal length the code uses for number storage. (Programs using 16-bit code can use larger arrays than programs using 32- bit code.) This is by design in Microsoft Excel.

For additional information about this behavior in Microsoft Excel, click the article number below to view the article in the Microsoft Knowledge Base:
137921 XL: Error If Array Contains More Than 2730 Elements

References

Excel 97 and Later

For more information about arrays, click Microsoft Excel Help on the Help menu, type what is an array in the Office Assistant or the Answer Wizard, and then click Search to view the topics returned.

Excel 7.0

For more information about arrays in Microsoft Excel 7.0, click Answer Wizard on the Help menu, and type:
What is an array?

Properties

Article ID: 142526 - Last Review: October 26, 2013 - Revision: 2.0
Applies to
  • Microsoft Excel 97 Standard Edition
  • Microsoft Excel 95 Standard Edition
  • Microsoft Excel 5.0 Standard Edition
  • Microsoft Excel 2001 for Mac
  • Microsoft Excel 98 for Macintosh
  • Microsoft Excel 5.0 for Macintosh
Keywords: 
kbnosurvey kbarchive kbhowto kbinfo KB142526

Give Feedback

 

Contact us for more help

Contact us for more help
Connect with Answer Desk for expert help.
Get more support from smallbusiness.support.microsoft.com