Written by Allen Wyatt (last updated July 17, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Marc has a worksheet in which he keeps produce prices for a community group. Each row represents a produce item (apples, carrots, lettuce, etc.) and each column represents a purchase date. Thus, the intersection of each row and column represents the price at which a produce item was purchased on a particular date. Not all items are purchased on any given date. Marc needs a formula that will, for a particular produce item, return the rightmost value (price) for that item.
An easy way to handle this is to use the LOOKUP function. Let's say that your dates columns are B:N. If you want to figure out the latest price (rightmost value) in row 2, you could use the following:
=LOOKUP(999,B2:N2)
This works because LOOKUP will work with only two parameters. The first is the value you want to look up and the second is the array (range of cells) in which to look for the value. If the value in the first parameter is found, then the value is returned. In other words, if you had the value 999 in one of the cells B2:N2, then 999 is returned.
However, the trick here is to specify a value in the first parameter that is much larger than the largest anticipated purchase price. If you anticipated that you might purchase something for $999 or more, then you could simply increase the value in the first parameter:
=LOOKUP(9^9,B2:N2)
When LOOKUP cannot find the desired value, it returns the last value in the array—the last price shown in the range of cells.
The biggest drawback to this approach is that you'll need to remember to update the range of cells when you add more columns of data. You could get around this by simply making the range much larger than what you need, as shown here:
=LOOKUP(9^9,B2:AZ2)
Of course, if you ever go past column AZ with your data, you still run into the same need to update the range specification. If you don't want to worry about needing to do this, you could combine use of the INDEX and MATCH functions, in this manner:
=INDEX(2:2,MATCH(9^9,2:2))
In this formula, the MATCH function tries to match, within row 2, a value that equals 9^9. If that cannot be located, then MATCH returns the column number of the last value in the row. This is then used as an offset for the INDEX function, which returns the value at the cell offset in row 2. This is, of course, the very rightmost value in the row.
For additional possible formula ideas, see this tip:
https://tips.net/T11250
The biggest difference between the ideas in that tip and this one is that it needs to account for the possibility of zero-value formula results being in the rightmost cells of a row, whereas Marc's situation doesn't. (This means that Marc can use simpler formulas than are included in the other tip.)
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13884) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
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!
If you have a list of names in a column, and you want to separate those names into individual cells, there are several ...
Discover MoreFormulas are made up of operands that separate a series of terms acted upon by the operands. You may want to know, for ...
Discover MoreIf you want to add a dynamic statement to a worksheet that indicates how many rows are in a data table, you might be at a ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-07-17 18:59:52
Roy
For the "I need a number higher than any possible number that could be there" problem, one can just use a function instead:
MAX(Range)+1
Admittedly, that will fail if the largest value Excel can use is already in the "Range" but then no other number would work either so...
The one way in which it seriously fails is if there could be errors in the "Range" and switching it to LARGE() doesn't help. So if a range is not well-behaved enough to be sure there are no errors, this won't be very helpful. The traditional method of selecting some humungous value WILL work though being sure it's high enough is probably usually no more certain than that the range is well-behaved enough to have no errors. Probably. I imagine.
(How did I not see that there could be no 0's as cell values when I read the email Help section? Ah well, "reading for comprehension" is still alive and well in the repertoires of successful people I guess...)
2021-07-17 10:19:04
Tomek
To avoid the drawback mentioned by Allen, include an empty column to the right of the data, and include it in the formula. That way, if you insert additional columns before that empty one, the formulas will adjust appropriately.
2021-07-17 07:05:44
Here is a macro solution.
Does not matter how many rows or columns in the worksheet.
====================================================
Sub LastValueInColumn()
Dim iRowCount As Long
Dim i As Long
Dim lcol As Long
Dim ColumnLetter As String
' get the last row in column "A" that is not blank
iRowCount = Cells(Rows.Count, 1).End(xlUp).Row
' get the row number to search
i = InputBox("Enter row number between 2 and " & iRowCount, "Get row number.")
' get the last column in row "i" that is not blank
lcol = Cells(i, Columns.Count).End(xlToLeft).Column
' convert column number to a letter
ColumnLetter = Split(Cells(1, lcol).Address, "$")(1)
MsgBox Cells(i, 1) & " - " & Format(Cells(i, lcol), "$.00") & " in cell " & """" & ColumnLetter & i & """" & " on " & Cells(1, lcol)
End Sub
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