Automatically Changing a Cell's Background Color

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


Jim wrote in, asking how to automatically change the background color of cell A1 on Sheet2 to match the background color of cell A1 on Sheet1 if the background color of cell A1 on Sheet1 changes.

The answer to this question depends on whether the Sheet1!A1 cell is changing color because of conditional formatting or if the color is changing because the user is explicitly changing the color.

Believe it or not, if the color change is the result of conditional formatting, then the answer is easy—all you need to do is add a conditional formatting rule to the Sheet2!A1 cell that is essentially the same as the rule used for the Sheet1!A1 cell. The only potential difference is that your rule for Sheet2!A1 may need to include worksheet references, such as those being used in this paragraph.

If the color of Sheet1!A1 is changing because the user if making the change, then you need to resort to using a macro. Unfortunately, there is no workbook or worksheet event that can handle color changes in a cell. You can, however, create an event handler that will execute whenever the user makes Sheet2 active. (This makes sense; the user can only see what is in cell A1 in that sheet when the sheet is made active.) Here's an example event handler that can be added to the code sheet for Sheet2:

Private Sub Worksheet_Activate()
    Dim rSource As Range

    Set rSource = Worksheets("Sheet1").Range("A1")
    Range("A1").Interior.Color = rSource.DisplayFormat.Interior.Color
End Sub

Interestingly enough, this macro will work even if the color of Sheet1!A1 is being affected by a conditional formatting rule. The secret is the use of the DisplayFormat object, which represents the format as it is displayed, rather than as it is explicitly formatted.

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 (13879) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.

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

Determining the Number of Visible Columns

When using a macro to process information in a worksheet, you may want that macro to figure out how many columns are ...

Discover More

Formatting Endnote Reference Marks

The reference marks used for endnotes are, by default, formatted "good enough" for most people. If you are one of those ...

Discover More

Moving Building Block Templates

Not all templates are created equal. Word uses two special templates for storing building blocks. If you want to move ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (ribbon)

Checking All Cell Formatting in VBA

When your macro checks the formatting used for a cell, it needs to be careful that the type of formatting being checked ...

Discover More

Displaying Negative Times

Excel allows you to perform math using times as operands. If you subtract a later time from an earlier time, you should ...

Discover More

Creating 3-D Formatting for a Cell

The formatting capabilities provided by Excel are quite diverse. This tip examines how you can use those capabilities to ...

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 two more than 7?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.