Determining the Used Range

Written by Allen Wyatt (last updated December 30, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


4

John has data being entered in a worksheet. The real data begins in row 8. He would like, in a different cell, to use a formula to indicate the range of cells that contain data, such as A8:N112. The starting cell (A8) is static and the final column (N) is static. The biggest issue seems to be determining the number of rows.

There are several approaches you can take with your formula. As is often the case, the best solution depends on the way that your data is used within your worksheet.

The typical workhorse functions that people turn to in this situation are the COUNT and the COUNTA functions. If your data consists of numeric data, you can use COUNT; if it consists of alphanumeric data (or a mixture of numeric and alphanumeric), then you should use COUNTA. Here's the typical approach:

=ADDRESS(8,1) & ":" & ADDRESS(COUNTA(N:N)+7,14,3)

This will work just fine, with two huge caveats. First, it is critical to note that the actual count is performed on column N. If you have any blank cells in column N, then they won't be counted and, therefore, the formula won't return the correct last row in your data. If you have a different column that does have something in every cell, then you could use that one instead of column N.

The second caveat has to do with what may be in rows 1 through 7 of column N. If you have anything in those cells (including a column heading in row 7), then the formula won't give an accurate result. In that case, you'll need a more specific formula:

=ADDRESS(8,1) & ":" & ADDRESS(COUNTA(N8:N1048576)+7,14,3)

While this incarnation of the formula solves the second caveat, it doesn't solve the first one. If there are blank cells in column N, then your result will be incorrect.

If you prefer (and with the same caveats still in mind), you could shorten the formula quite a bit in this manner:

= "A8:N" & (COUNTA(N8:N1048576) + 7)

To get around both caveats, you need to use a different approach entirely in your formula. This formula doesn't care if there are blanks or not, nor does it care if there is anything in rows 1:7:

="A8:N" & MAX((A:N<>"")*(ROW(A:N)))

This formula works just fine in Excel for Microsoft 365, but if you are using an older version, you'll want to enter it as an array formula (Ctrl+Shift+Enter).

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8927) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.

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

Sizing Text Boxes and Cells the Same

Adding a text box to a worksheet is easy. Making sure that text box is the exact size of a cell in the worksheet may not ...

Discover More

Using Seek In a Macro

When reading information from a text file, your macro may need to start reading at a place other than the beginning of ...

Discover More

Cleaning Scummy Shower Doors

Do you have glass shower doors that always seem to be covered with a soapy film? Here's a great cleaning idea that can ...

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)

Strange Formula Conversions

When you are getting the hang of how to put together formulas in Excel, you might run into a situation where you open a ...

Discover More

Grabbing the Second-to-Last Value in a Column

Need to get at the next-to-last value in a column, regardless of how many cells are used within that column? This tip ...

Discover More

Deriving Antilogs

Creating math formulas is a particular strong point of Excel. Not all the functions that you may need are built directly ...

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}] (all 7 characters, in the sequence shown) 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 5 - 3?

2024-01-01 09:46:31

J. Woolley

Sorry. The LastNonBlankCellAddress UDF in my comment below should be named LastNonBlankRowColAddress because the cell might actually be blank.


2023-12-31 16:42:19

J. Woolley

The following UDF will return the absolute address of the last non-blank cell in a range of cells (Target):

Public Function LastNonBlankCellAddress(Target As Range)
    Dim R As Range, LastRow As Long, LastCol As Long
    Application.Volatile
    Set R = LastNonBlankCellIn(Target, xlFormulas, xlByRows)
    If R Is Nothing Then _
        LastNonBlankCellAddress = CVErr(xlErrNA): Exit Function
    LastRow = R.Row
    LastCol = LastNonBlankCellIn(Target, xlFormulas, xlByColumns).Column
    'dynamic array formula spill can result in cells
    'that have a value without a formula or constant
    Set R = LastNonBlankCellIn(Target, xlValues, xlByRows)
    If Not (R Is Nothing) Then
        LastRow = IIf(R.Row > LastRow, R.Row, LastRow)
        Set R = LastNonBlankCellIn(Target, xlValues, xlByColumns)
        LastCol = IIf(R.Column > LastCol, R.Column, LastCol)
    End If
    LastNonBlankCellAddress = Target.Parent.Cells(LastRow, LastCol).Address
End Function

Private Function LastNonBlankCellIn(Target As Range, _
    LookIn As XlFindLookIn, SearchOrder As XlSearchOrder) As Range
    Set LastNonBlankCellIn = Target.Find(What:="*", After:=Target(1), _
        LookAt:=xlPart, LookIn:=LookIn, MatchCase:=False, _
        SearchOrder:=SearchOrder, SearchDirection:=xlPrevious)
End Function

John could use the UDF in a cell formula like this:
    = "$A$8:" & LastNonBlankCellAddress(A:N)
If a relative address is preferred, use this:
    = "A8:" & SUBSTITUTE(LastNonBlankCellAddress(A:N), "$", "")
LastNonBlankCellAddress accounts for cells that are hidden or have a formula returning null text (""). The Tip's last formula ignores cells with null text.


2023-12-30 23:10:03

Tomek

The first two formulas work in specific circumstances, but with caveats as described. They work best if at least one column has no blank cells and the count is based on that column. The last formula given works without those caveats, but I think the worksheet can be designed in a way that may be easier to manage later, even though it is a bit more work to set it up.

My suggested approach is to first create a table for the area where the data will be entered. Such table can be created with some data already entered, including heading row with labels. After creating the table, if you wish you can turn off the auto-filter (on Data tab of the Ribbon there is an icon for that), as well as change/remove any shading and borders that are automatically imposed by Excel. The benefit of such approach is that if you enter new data in the row directly below the last row of the table, the table will expand automatically. If you enter the additional data further down the spreadsheet leaving some rows empty, the table will not expand automatically, but you can easily adjust the range of the table by dragging the small triangle at the bottom right of the table. This way you can also exclude some data from the table. And of course you can enter/update the data within the table. You can also insert or delete rows from the table except the header row, and the table range will adjust automatically.

Once you have created the table, Excel gives it a name, typically "TableN" where N is a counter of the tables created. You can find that name by clicking inside the table and opening the Table Design tab of the ribbon: the information is the the Properties group at the very left of the ribbon. Note that the table name refers to the range of the data in the table, excluding the header row.

Now, to use all that in the formula that John wanted, you can type in = "A8:N" & (ROWS(Table1) + 7). (adjust the table counter if necessary).


2023-12-30 09:39:39

J. Woolley

The Tip's last sentence says, "...if you are using an older version, you'll want to enter it as an array formula (Ctrl+Shift+Enter)." I don't think this is necessary because the formula does not return an array.


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.