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: Determining "Highest Since" or "Lowest Since".
Written by Allen Wyatt (last updated February 5, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003
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 2007." 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 2007" or "this value is the lowest since November 2004."
Assuming that the month and year listed in column A is really an Excel date value (and not text), you can easily create a formula to return the desired information. If you have row 1 occupied with headings for your columns, enter the following in cell 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 macro that will do the desired analysis and provide the appropriate information. The following macro provides 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 (3138) 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: Determining "Highest Since" or "Lowest Since".
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 365 applications with VBA programming. Written in clear terms and understandable language, the book includes systematic tutorials and contains both intermediate and advanced content for experienced VB developers. Designed to be comprehensive, the book addresses not just one Office application, but the entire Office suite. Check out Mastering VBA for Microsoft Office 365 today!
Replacing one character in a text value with another character is easy. All you need to do is use the SUBSTITUTE ...
Discover MoreWhen you discover that there is an invalid reference in a workbook, you can have a bear of a time tracking down the ...
Discover MoreExcel makes it easy to concatenate (or combine) different values into a single cell. If you need to combine a different ...
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 © 2025 Sharon Parq Associates, Inc.
Comments