Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 2021, 2024, 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: Determining "Highest Since" or "Lowest Since".
Written by Allen Wyatt (last updated November 4, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365
Alex routinely analyzes the latest building industry data and needs to write articles about the data. Frequently he needs to highlight some new piece of data, such as "industrial building construction was the lowest since August 2019." Alex wondered if there was a way to automate this type of highlighting; if column A contains the month and year and column B contains the values for those periods, Alex would like a formula in column C that indicates "this value is the highest since April 2019" or "this value is the lowest since November 2016."
Assuming that the month and year listed in column A is really an Excel date value (and not text), getting the desired information can be done with a formula, though it is not a simple process. If you are using Excel 2021, 2024, or Microsoft 365, here's a formula you can place in cell C2 that will do the heavy lifting:
=LET(curVal, B2, curDate, A2, priorMask, A$2:A2<curDate, pVals, FILTER(B$2:B2, priorMask), pDates, FILTER(A$2:A2, priorMask), maxP, IFERROR(MAX(pVals), NA()), minP, IFERROR(MIN(pVals), NA()), lastHigh, IFERROR(MAX(FILTER(pDates, pVals>=curVal)), ""), lastLow, IFERROR(MAX(FILTER(pDates, pVals<=curVal)), ""), IF(ISNA(maxP), "", IF(curVal>=maxP, "highest since "&IF(lastHigh="","start of series", TEXT(lastHigh, "mmmm yyyy")), IF(curVal<=minP, "lowest since "&IF(lastLow="", "start of series", TEXT(lastLow,"mmmm yyyy")), ""))))
This is a single (long) formula that should be entered all on one line. Copy the formula down as many rows as necessary and it should provide the desired info. If you are using an older version of Excel, you can generate the same information by taking a different formulaic approach in C2:
=IF(ROW(B2)=2,"",IF(B2>MAX($B$1:B1), "this value is the highest since " & TEXT(INDEX($A$1:A1,MATCH(MAX( $B$1:B1),$B$1:B1,0)), "mmmm yyyy"), IF(B2<MIN($B$1:B1), "this value is the lowest since " & TEXT(INDEX($A$1:A1, MATCH(MIN($B$1:B1),$B$1:B1,0)), "mmmm yyyy"),"")))
Remember that this is a single formula and should be entered all on one line. You can copy the formula down as many rows as necessary in column C, and it should provide the desired information. It only makes a notation in column C if the value in column B is greater than the maximum or less than the minimum of all the foregoing values in column B.
If you have quite a bit of data in your worksheet, you could notice that the formula results in long recalculation times. If this is the case, then you may want to consider using a macro that will do the desired analysis and provide the appropriate information. The following macro looks backward through the information in column B and provides both a "lowest since" and "highest since" result in columns C and D.
Sub FindHiLow()
Dim orig_cell As Range
Dim orig_val As Integer
Dim orig_row As Integer
Dim rownum As Integer
Dim newcell As Range
Dim new_val As Integer
Dim lowrow As Integer
Dim hirow As Integer
Set orig_cell = ActiveCell
orig_row = ActiveCell.Row
orig_val = orig_cell.Value
' find lowest
lowrow = 0
For rownum = orig_cell.Row - 1 To 1 Step -1
Set newcell = Cells(rownum, 2)
new_val = newcell.Value
If orig_val >= new_val Then
lowrow = rownum
Exit For
End If
Next
If lowrow = 0 Then lowrow = 1
Cells(orig_row, 3).Value = "Lowest since " & Cells(lowrow, 1)
' find highest
hirow = 0
For rownum = orig_cell.Row - 1 To 1 Step -1
Set newcell = Cells(rownum, 2)
new_val = newcell.Value
If orig_val <= new_val Then
hirow = rownum
Exit For
End If
Next
If hirow = 0 Then hirow = 1
Cells(orig_row, 4).Value = "Highest since " & Cells(hirow, 1)
End Sub
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10183) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Determining "Highest Since" or "Lowest Since".
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Need to sum a series of cells that fits some regular pattern? Here are several ways that you can get the summation that ...
Discover MoreWhen you edit a worksheet, adding and deleting rows and columns, Excel automatically updates references to cells ...
Discover MoreWant to know the letters assigned by Excel to a particular column? Excel normally deals with column numbers, but you can ...
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 © 2025 Sharon Parq Associates, Inc.
Comments