Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Last Non-Zero Value in a Row.
Written by Allen Wyatt (last updated January 31, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003
Brian has a row of numbers with 240 cells. In this row, the numbers are steadily declining and will eventually, at some point in those 240 cells, become 0. The zeroes will continue to fill the remaining cells in the row. Brian needs to write an equation that will return the last non-zero value in the row.
There are a variety of ways that the desired value can be returned. (Doesn't that always seem to be the case with Excel? You can come up with lots of ways to get a result.) In general, you could use a regular formula or an array formula.
If you want to use a regular formula, here's one you can try:
=OFFSET(A6,0,(COUNT(A6:IF6)-COUNTIF(A6:IF6,0))-1)
The COUNTIF function counts the number of zero values and the COUNT function determines the number of cells in the range. Subtracting one from the other and adjusting by 1 gives the OFFSET value into the "array" of cells where the last non-zero value lies. This formula assumes that the values begin in column A; if they begin in a different column then you'll need to adjust the value provided by the COUNT/COUNTIF portion of the formula to represent the offset from the first column.
Here's a shorter variation of the formula, based on doing an offset from the right side of the range rather than the left side:
=OFFSET(IF6,0,-COUNTIF(A6:IF6,0))
In this instance it is important that IF6 be the actual right end of the range. The formula works by counting the number of zero values in the range (all at the right side of the range) and then computing the cell address of the last cell (IF6) minus the number of zeros.
Here is a version that uses the INDEX function, instead:
=INDEX(A6:IF6,,MATCH(0,A6:IF6,0)-1)
This version is even shorter, using the LOOKUP function:
=LOOKUP(1,1/(6:6>0),6:6)
Array formulas can also be used. (Array formulas are entered by pressing Ctrl+Shift+Enter.) This one uses the INDIRECT function:
=INDIRECT("R6C" & MAX((A6:IF6>0)*COLUMN(A6:IF6)),FALSE)
This array formula uses an interesting implementation of the LOOKUP function to find the correct result:
=LOOKUP(9.99999999999999E+307,IF(A6:IF6<>0,A6:IF6))
Here's another array formula that can be used, this time using the OFFSET function to find the last non-zero value in row 6:
=OFFSET(A6,0,MIN(IF(6:6=0,COLUMN(6:6),300))-2)
Here's an even shorter variation:
=MIN(IF(A6:IF6>0,A6:IF6))
All of these formulas presented so far depend on the fact that the numbers in the row actually do decline—they go from whatever the beginning number is and steadily go toward zero. If the numbers don't decline, then you can use a different type of array formula to determine the last non-zero value in the row:
=INDEX(6:6,MAX(IF(A6:IF6<>0,COLUMN(A6:IF6))))
The formula first determines the maximum column in the row (in this case row 6) that has a value not equal to zero, then it uses the INDEX function to get the value from that column in that row.
As you can tell, there are quite a few ways to find the last non-zero value in a row. Pick the one that strikes your fancy; there is no right or wrong in this instance.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3785) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Last Non-Zero Value in a Row.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
Need to know a count of unique values in a range of cells? There are a couple of ways you can tackle the problem.
Discover MoreWhen you create references to cells in other workbooks, Excel, by default, makes the references absolute. This makes it ...
Discover MoreIf you have a mixture of numbers and letters in a cell, you may be looking for a way to access and use the numeric ...
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 menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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