Exceljet

Quick, clean, and to the point

Last n rows

Excel formula: Last n rows
Generic formula 
=ROW()-ROW(rng.firstcell)+1>ROWS(rng)-n
Explanation 

To flag the last n rows in a range, you can use helper column with a formula based on the ROW and ROWS functions. In the example shown, the formula in cell E5, copied down, is:

=ROW()-ROW(INDEX(data,1,1))+1>ROWS(data)-n

where data (B5:E15) and n (G5) are named ranges.

This formula returns TRUE if a row is a "last n row", and FALSE if not.

How this formula works

The core of this formula is based on another formula that calculates the "current row" in a range:

=ROW()-ROW(rng.firstcell)+1

In brief, we get the current row in the workbook, then subtract the first row number of the range plus 1. The result is an adjusted row number that begins at 1. The INDEX function is simply one way get the first cell in a given range:

ROW(INDEX(data,1,1) // first cell

This is for convenience only. The formula could be re-written like as:

=ROW()-ROW($E$5)+1

Once we have a current row number, we can compare the row number to the total rows in the data less n:

current_row > ROWS(data)-n

If this expression returns TRUE, the current row is one of the last n rows we are looking for.

Last n rows in a table

If data is in an Excel table, the formula can be adapted like this:

=ROW()-@ROW(Table1)+1>ROWS(Table1)-n

Formula for last n rows in a Table

The logic is exactly the same, but we use a slightly different approach to get the first cell in the table:

@ROW(Table1)

You can think of the @ character as indicating "single":

=ROW(Table1) // returns {5;6;7;8;9;10;11;12;13;14;15}
=@ROW(Table1) // returns {5}

As before, the table formula returns TRUE in "last n rows" and FALSE in others.

Last row only

To test for the last row only, you can use a slightly simplified version of the formula:

=ROW()-ROW(rng.first)+1=ROWS(rng)
Author 
Dave Bruns

Excel Formula Training

Formulas are the key to getting things done in Excel. In this accelerated training, you'll learn how to use formulas to manipulate text, work with dates and times, lookup values with VLOOKUP and INDEX & MATCH, count and sum with criteria, dynamically rank values, and create dynamic ranges. You'll also learn how to troubleshoot, trace errors, and fix problems. Instant access. See details here.