Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. 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".

Determining "Highest Since" or "Lowest Since"

by Allen Wyatt
(last updated November 15, 2014)

6

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

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10183) applies to Microsoft Excel 2007, 2010, and 2013. You can find a version of this tip for the older menu interface of Excel here: Determining "Highest Since" or "Lowest Since".

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He  is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Adding a Custom Format to those Offered by Excel

Adding a custom format to Excel is easy. Having that custom format appear in all your workbooks is a different story ...

Discover More

Finding and Replacing Table Cell Color

The Find and Replace tool built into Word is quite powerful. It cannot do everything, however, as there are just some things ...

Discover More

Running a Macro when a Workbook is Closed

One of the automatic macros you can set up in Excel is one that is triggered when a workbook is closed. This tip explains how ...

Discover More

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!

More ExcelTips (ribbon)

Inserting Dashes between Letters and Numbers

If you need to add dashes between letters and numbers in a string, the work can quickly get tedious. This tip examines some ...

Discover More

Adjusting Test Scores Proportionately

Teachers often grade on what is affectionately referred to as "the curve." The problem is, it can be a bit difficult to ...

Discover More

Summing Every Fourth Cell in a Row

Need to sum a series of cells that fits some regular pattern? Here are several ways that you can get the summation that you ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is one more than 9?

2015-03-24 05:49:31

Girijesh Dubey

Really so useful..


2014-11-17 16:22:04

Bigger Don

@Neil et al

There is a simpler way, using an array Max(If()) and Min(If()) formulas.

I'll give the do-this/do that.

1. Build your data like described above, column A for dates and column B for Values (It works the other way around, too.)
2. Pick a cell for your date input. I used G1.
3. In H1 I put the min-since array formula: =MIN(IF(A1:A34>G1,B1:B34)), and H2 the max-since formula: =MAX(IF(A1:A34>G1,B1:B34))
!!! NOTE: Because these are array formulas instead of clicking ENTER alone, hold down the Control and Shift keys while clicking Enter.
4. Now for the most recent date when this high or low occurred.
In I1 "=MAX(IF(B1:B34=H1,A1:A34))" (no quotes) and CTRL-Shift-Enter again
In I2 "=MAX(IF(B1:B34=H2,A1:A34))" (no quotes) and CTRL-Shift-Enter again.

You now have the low and high since a point in time plus the date when each occurred.


2014-11-17 14:40:00

Neil

Seems like a lot of trouble to go to...I would just highlight the date I was interested in and then sort by the value of whatever metric you are concerned about. The row above (or below, depending on how you sort) the highlighted one would be the date with the next highest or lowest value.


2014-11-17 05:19:16

Lars

Correction.

"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 that is true, then it is not the lowest/highest since that date. It is the lowest/highest ever!


2014-11-17 05:17:16

Lars

"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 that is true, then it is not the lowest/highest since that date. It is the lowest ever!


2014-11-15 20:33:53

Kevin

Or Conditional formatting could be used with a helper column.
Assuming dates are in column A and numbers in column B and our control date is at E1
Add formula to helper column C. At C1 =IF(A1>$E$1,B1,"") and copy down (20 rows in example).
Conditionally format B1:B20 using “Use formula to determine which cells to format” with the formula =IF(IF(A1>$E$1,B1,"")=MAX($C$1:$C$20),MAX($C$1:$C$20),"")
And another rule with =IF(IF(A1>$E$1,B1,"")=MIN($C$1:$C$20),MIN($C$1:$C$20),"")
This method requires E1 to be the date less than the since date


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.