Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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: Detecting Errors in Conditional Formatting Formulas.

Detecting Errors in Conditional Formatting Formulas

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


1

Allan uses a lot of conditional formatting, nearly always using formulas to specify the conditions for the formatting. Recently he discovered, by chance, that he had a #REF! error in one of his conditional format formulas. As far as Allan could figure, this was the result of deleting the row of a cell referred to in the formula. The impact is that the conditional formatting won't work for that condition. This has made Allan concerned that there are other instances of conditional formats that have become corrupted since originally being set up. He wonders if there is any simple way of checking all conditional formatting so that these errors can easily be found.

The best way is to use a macro to step through all the conditional formats defined for a worksheet. The following macro does just that, looking for any #REF! errors in the formulas.

Sub FindCorruptConditionalFormat()
    Dim c As Range
    Dim fc As Variant

    Selection.SpecialCells(xlCellTypeAllFormatConditions).Select
    For Each c In Selection.Cells
        For Each fc In c.FormatConditions
            If InStr(1, fc.Formula1, "#REF!", _
              vbBinaryCompare) > 0 Then
                MsgBox Prompt:=c.Address & ": " _
                  & fc.Formula1, Buttons:=vbOKOnly
            End If
        Next fc
    Next c
End Sub

If an error is found, then a message box displays both the address of the cell and the formula used in the conditional formatting rule.

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 (11361) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Detecting Errors in Conditional Formatting Formulas.

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

Selecting a Field

Do you need to select a field? It is as simple as selecting a single character, as this tip explains.

Discover More

Using Drag-and-Drop to Create a Hyperlink

If you open workbooks in two instances of Excel, you can use drag-and-drop techniques to create hyperlinks from one ...

Discover More

Ignoring N/A Values in a Sum

You can use some of Excel's worksheet functions across a range or worksheets, but not all of them. One that has problems ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!

More ExcelTips (ribbon)

Comparing Dollar Values in a Conditional Formatting Rule

Comparing values (like is done in conditional formatting rules) can yield some crazy results at times. This tip looks at ...

Discover More

Conditionally Highlighting Cells Containing Formulas

Excel's conditional formatting feature allows you to create formats that are based on a wide variety of criteria. If you ...

Discover More

Conditional Format that Checks for Data Type

Conditional formatting can be used to highlight cells that contain the improper type of data for your needs. This tip ...

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 2 + 2?

2024-06-17 12:08:11

J. Woolley

The Tip's FindCorruptConditionalFormat macro might be more reliable if the following statement
    Selection.SpecialCells(xlCellTypeAllFormatConditions).Select
was replaced by this statement
    ActiveSheet.UsedRange.SpecialCells(xlCellTypeAllFormatConditions).Select
But here is a more efficient version of the macro:

Sub FindCorruptConditionalFormat2()
    Dim fc As FormatCondition
    ActiveSheet.UsedRange.SpecialCells(xlCellTypeAllFormatConditions).Select
    For Each fc In Selection.FormatConditions
        If InStr(1, fc.Formula1, "#REF!", vbBinaryCompare) > 0 Then
            MsgBox fc.AppliesTo.Address & ": " & fc.Formula1
        End If
    Next fc
End Sub

Notice Microsoft's documentation defines xlCellTypeAllFormatConditions as "Cells of any format," but testing demonstrates it actually selects "Cells of any conditional format."
Similarly, Microsoft's documentation defines xlCellTypeSameFormatConditions as "Cells having the same format," but it actually selects "Cells having the same conditional format." For this case the macro's first statement after Dim... should be replaced by
    If ActiveCell.FormatConditions.Count = 0 Then Exit Sub
    ActiveCell.SpecialCells(xlCellTypeSameFormatConditions).Select
Like many, I’ve been frustrated when my carefully crafted conditional formatting becomes corrupted after innocently performing a copy/paste or some other such sin. And Excel’s miserable Conditional Formatting Rules Manager makes it a chore to fix the mangled rules. So My Excel Toolbox includes macros to backup and restore the active sheet’s conditional formatting using named ranges that auto-adjust to row/column changes. Run the CFBackup macro before your conditional formatting rules are broken. If they later become broken, run CFRestore.
My Excel Toolbox also includes the following dynamic array function:
    =ListFormatConditions([AllSheets], [SkipHeader])
This function returns Applies To Range, Type, and Stop If True for each conditional format. When using pre-2021 versions of Excel without support for dynamic arrays, review the PDF file UseSpillArray.pdf.
See https://sites.google.com/view/MyExcelToolbox/


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.