Highlighting Greater Than Average Dry Durations

Written by Allen Wyatt (last updated April 15, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


1

Heather has a worksheet that, in column A, has a series of dates. These represent the dates during the past 25 years on which a weather station noted at least 0.01 inches of precipitation. Thus, the duration between two consecutive dates is a "dry duration." Heather would like to highlight any dates in the list where the dry duration is greater than the average dry duration for all dates in the list.

The easiest way to do this is to add another column to your data. This one will be used to store the dry durations. Assuming your dates are sorted and in column A (beginning with cell A2), then place the following formula in cell B3:

=A3-A2

Copy this formula down for as many rows as necessary, and you now have all the dry durations. Now you can create a conditional formatting rule that will do the evaluation. Follow these steps:

  1. Select all your dates, beginning with cell A3. (I'll assume that you are selecting A3:A4750.)
  2. Make sure the Home tab of the ribbon is displayed.
  3. Click the Conditional Formatting tool, within the Styles group. Excel displays a palette of options related to conditional formatting.
  4. Click New Rule. Excel displays the New Formatting Rule dialog box.
  5. In the Select a Rule Type area at the top of the dialog box, choose Use a Formula to Determine Which Cells to Format.
  6. In the Format Values Where This Formula Is True box, enter the following: =B3>AVERAGE(B3:B4750). This formula will return True if the cell next to the date contains a value that is larger than the average dry duration.
  7. Click Format to display the Format Cells dialog box.
  8. Make any changes to the font and/or cells to highlight True values, as desired.
  9. Click OK to close the Format Cells dialog box.
  10. Click OK to close the New Formatting Rule dialog box. Excel applies the conditional format to the selected cells in column A.

If you don't want to add the dry duration column to your data, then you will benefit by using a macro to do the formatting, rather than using a conditional format. The following macro removes any explicit formatting from the cells in the range A2 through whatever is the last cell in the column. It then adds a helper column (B) and calculates the dry durations, placing them in that column. It then calculates the average of those dry periods and, if the dry period is greater than the average, it formats the date associated with that dry period as bold and red. Finally, the macro deletes the helper column it previously added.

Sub DryPeriod()
    Dim RowNum As Long
    Dim MaxRow As Long
    Dim AvDuration As Long

    Application.ScreenUpdating = False
    MaxRow = ActiveSheet.UsedRange.Rows.Count
    With Range("A2:A" & MaxRow).Font
        .ColorIndex = xlAutomatic
        .Bold = False
    End With

    Range("B1").EntireColumn.Insert
    For RowNum = 3 To MaxRow
        If Cells(RowNum, 1) > "" Then
            Cells(RowNum, 2) = Cells(RowNum, 1) - Cells(RowNum - 1, 1)
        End If
    Next RowNum

    AvDuration = Application.WorksheetFunction.Average(Range("B3:B" & MaxRow))
    For RowNum = 3 To MaxRow
        If Cells(RowNum, 2) > AvDuration Then
            Cells(RowNum, 1).Font.Color = vbRed
            Cells(RowNum, 1).Font.Bold = True
        End If
    Next RowNum

    Range("B1").EntireColumn.Delete
    Application.ScreenUpdating = True
End Sub

You can run the macro as many times as you would like, which is why it first sets the formatting in column A to the default each time it is run.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8923) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.

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

Replacing Text in a Macro

When using a macro to process text in a document, it is not unusual to replace one portion of a text string with another ...

Discover More

Using AutoShape Connectors

If you add AutoShapes to the drawing canvas, you can use connector lines between those shapes. Here's how to add them to ...

Discover More

Missing Header and Footer Toolbar

When you need to make changes to the header or footer of a document, the Header and Footer toolbar is invaluable. What if ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Applying Conditional Formatting to Multiple Worksheets

If you just updated your copy of Excel, you may have noticed some differences in how the program handles applying ...

Discover More

Conditionally Making a Sound

Need to have a sound played if a certain condition is met? It is rather easy to do if you use a user-defined function to ...

Discover More

Controlling Data Entry in a Cell

Sometimes you want whatever is displayed in one cell to control what is displayed in a different cell. This tip looks at ...

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}] (all 7 characters, in the sequence shown) 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 eight less than 8?

2023-04-18 10:55:10

J. Woolley

Here is a simpler version of the Tip's macro. It corrects a potential problem with MaxRow and does not require temporary use of column B.

Sub DryPeriod2()
    Dim RowNum As Long, MaxRow As Long, AvDuration As Long, DryDur() As Long
    MaxRow = Cells(Rows.Count, 1).End(xlUp).Row
    With Range("A2:A" & MaxRow).Font
        .ColorIndex = xlAutomatic
        .Bold = False
    End With
    ReDim DryDur(1 To MaxRow)
    For RowNum = 3 To MaxRow
        If Cells(RowNum, 1) > "" Then
            DryDur(RowNum) = Cells(RowNum, 1) - Cells(RowNum - 1, 1)
        End If
    Next RowNum
    AvDuration = Application.WorksheetFunction.Average(DryDur)
    For RowNum = 3 To MaxRow
        If DryDur(RowNum) > AvDuration Then
            Cells(RowNum, 1).Font.Color = vbRed
            Cells(RowNum, 1).Font.Bold = True
        End If
    Next RowNum
End Sub


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.