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
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:
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:
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.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
If you need to shade alternating rows in a data table, you'll want to examine how you can accomplish the task with ...
Discover MoreYou can use conditional formatting to add shading to various cells in your worksheet. This tip shows how you can shade ...
Discover MoreConditional formatting is a great tool for changing the format of cells based on whether certain conditions (rules) are ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
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
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