Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Retrieving the Last Value in a Column.
Written by Allen Wyatt (last updated September 26, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
You may wonder if there is a way to return the last (not largest) value in a column. For instance, if there are values in A1 through A5, then you may want the value in A5 returned. Later, if values were added in A6 through A8, then the value in A8 should be returned.
There are a couple of ways that a solution can be approached. The first is to use a formula such as the following:
=INDEX(A:A,COUNT(A:A))
This formula returns the last numeric value in a column, providing that the values begin at (in this case) A1. This approach only works if all the values in the column are numeric. If the values are non-numeric, or if there are blank cells intermixed with the values, then a different approach is necessary. One way is to copy the following formula into column B, just to the right of the cells that may contain values:
=IF(ISNUMBER(A2),IF(A2<>0,ROW(A2),""),"")
In this case, the formula returns the row number of any cell in A which contains a numeric value greater than zero. The following formula can then be used to retrieve the last value in column A:
=INDEX(A:A,MAX(B:B))
This formula works because it returns the largest row number from column B, and then uses that as an index to return the corresponding value from column A.
If you don't want to use a helper column (as is done here in column B), you can use the following formula if there is a mix of numeric and non-numeric values in column A:
=LOOKUP(2,1/(1-ISBLANK(A:A)),A:A)
This formula may need a bit of explaining. The ISBLANK(A:A) portion returns an array that lists a FALSE value in each spot corresponding to a cell in column A that contains a value and a TRUE value in each spot corresponding to a cell in column A that is blank. These TRUE/FALSE values are then subtracted from 1 so that it changes to 0/1 values instead of TRUE/FALSE values.
This array is then "inverted" by dividing 1 by the 0/1 values, resulting in an array that contains a 1 wherever there's a value in column A and a #DIV/0! error wherever column A has a blank cell. Finally, the LOOKUP function looks for the value 2 in the array. It won't find it (there are only 1s and errors in the array), so it returns the last "1" in the list and thereby fetches the last non-blank value from the column.
As you can tell, returning the last value in a column can get a bit tricky at times. A clean approach is to simply develop your own VBA function that returns the desired value. In this case you can program the function to return any value—not just numeric values.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9008) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Retrieving the Last Value in a Column.
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!
If you have a lot of values in a single row, you might want to pull the last non-zero value from that row. There are a ...
Discover MoreWhen you are editing a formula, Excel helpfully outlines the cells referenced in the formula. If you want this capability ...
Discover MoreWhen processing data in a worksheet, you may have a need to know what the smallest (lowest) even value in a range is. You ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-09-27 12:38:34
JMJ
I remember that someone (Ron de Bruin?) in this forum suggested this great formula:
=LOOKUP(2,1/(A:A<>""),A:A)
It works about the same way as Abraham's, just a little shorter :-)
2020-09-26 08:05:55
Abraham Nesselroth
I think the best formula for the value of last non blank cell is:
={INDIRECT("A"&MAX(IF(A:A<>"",ROW(A:A),"")))}
2020-09-26 07:49:48
Alex Blakenburg
The formula =LOOKUP(2,1/(1-ISBLANK(A:A)),A:A) will return the last non-blank cell not the last numeric value cell.
For the last numeric value cell you could use either:-
=LOOKUP(2,1/ISNUMBER(A:A),A:A)
=XLOOKUP(1,--ISNUMBER(A:A),A:A,"No Numeric Values",0,-1)
("No Numeric Values" is an optional return value if there are no numbers in the column)
PS: Both of these can be modified if you want to cater for excluding the value zero
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