Written by Allen Wyatt (last updated January 29, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
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:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13879) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021.
Program Successfully in Excel! This guide will provide you with all the information you need to automate any task in Excel and save time and effort. Learn how to extend Excel's functionality with VBA to create solutions not possible with the standard features. Includes latest information for Excel 2024 and Microsoft 365. Check out Mastering Excel VBA Programming today!
Want to change the size of the font within a worksheet? Excel allows you to choose from a list of sizes, as well as ...
Discover MoreA handy way to store latitude and longitude values in Excel is to treat them as regular time values. When it comes around ...
Discover MoreWhen you display a time in a cell, Excel normally displays just the hours, minutes, and seconds. If you want to display ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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 © 2025 Sharon Parq Associates, Inc.
Comments