Written by Allen Wyatt (last updated January 7, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Cedric has a need to determine the value of the second-to-last cell in column to which he routinely adds values. He has seen formulas for grabbing the last value, but not the second-to-last.
There are many formulatic ways you could approach this need. In many respects, the method you choose will depend on the characteristics of the data in the column. Let's assume that your data is in column A, that it is numeric, and that there are no blanks in any of the cells in the column. In that case, you could use the following formula:
=INDEX(A:A,COUNT(A:A)-1)
Note that this formula will not return the correct result if there are any text values in column A—even if that text value is in a heading. If you want to compensate for the heading, you could modify the formula in this manner. (Note that it only checks the range of A2:A1000. If your data extends beyond row 1,000, then you'll need to modify the range specified.)
=INDEX(A2:A1000,COUNT(A2:A1000)-1)
If your numeric data may contain empty cells, then any of the following formulas will work just fine:
=OFFSET(INDIRECT("A"&MATCH(9^9,A:A)),-1,0) =INDEX(A:A,MATCH(9.9E+23,A:A,1)-1,1) =INDEX(A:A,(MATCH(LOOKUP(10000,A:A),A:A)-1),1) =INDEX(A:A,AGGREGATE(14,6,ROW(A:A)*A:A/A:A,2))
You should recognize that if the second-to-last cell in the column is empty, then these formulas will return 0. (Well, except for the formula that uses the AGGREGATE function. It returns the value in the first non-empty cell before the second-to-last cell.)
If your data in column A can contain either numbers or text (but still no empty cells), then you need a different formula. Either of these will do:
=INDEX(A:A,COUNTA(A:A)-1,1) =INDIRECT("A"&COUNTA(A:A)-1)
If there may be empty cells in your data, then you could use either of the following:
=INDEX(A:A,MATCH(LOOKUP(2,1/(A:A<>""),A:A),A:A,0)-1) =INDEX(A:A,LOOKUP(2,1/(A:A<>""),ROW(A:A))-1)
Again, if the second-to-last cell is empty, then the formula returns 0.
Finally, you could also use the following type of formula, provided that your cells in the column use a named range (in this case MyData). Remember, though, that as you add more information to the column, you'll need to make sure that the named range includes the added data.
=INDEX(MyData,ROWS(MyData)-1)
You should note that virtually all of the formulas mentioned in this tip use a -1 in them. This indicates you don't want the last cell in the range, but the second-to-last ("one up" from the bottom of the range). If you want a different offset from the bottom of the range, you can change this portion of each formula. For instance, if you wanted 2 cells up from the bottom of the range, you would change all instances of -1 to -2.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (1523) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
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!
Summing data is a common need in Excel. Summing lots of data based on a condition that needs to be met can be a bit more ...
Discover MoreWhen you construct a formula and click on a cell in a different workbook, an absolute reference to that cell is placed in ...
Discover MoreExcel provides worksheet functions that make it easy to count things. What if you want to count records that match more ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments