Conditionally Setting the Color of Worksheet Tabs

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


1

Ray understands that he can set a color for the worksheet tabs that display at the bottom of the Excel screen. He wonders if he can make that color conditional on the contents or status of the worksheet. For example, he would like the tab to be yellow if user input is needed in the worksheet and green if the input has actually been entered.

Changing the color of a worksheet tab can only be done manually or via a macro. Here's a simple macro that will check two cell in the worksheet, see if there is anything in those cells, and then modify the tab color based on the findings:

Sub ChangeColor()
    If Range("A1") = "" Or Range("A5") = "" Then
        ActiveSheet.Tab.Color = vbYellow
    Else
        ActiveSheet.Tab.Color = vbGreen
  End If
End Sub

The problem with such a macro, of course, is that you must run it manually. If you want the color changes to be more automatic, then you could incorporate the logic into an event handler. This macro should be added to the code for the worksheet itself. (Right-click on the worksheet tab and choose View Code from the resulting Context menu. That's where this macro goes.)

Private Sub Worksheet_SelectionChange(ByVal Target As Range)
    If Range("A1") = "" Or Range("A5") = "" Then
        ActiveSheet.Tab.Color = vbYellow
    Else
        ActiveSheet.Tab.Color = vbGreen
    End If
End Sub

The macro will affect only the single worksheet, and it will be triggered each time you change the cell selected within that worksheet. If you want something that runs less often and that is easier to add to multiple worksheets, then a good approach is to use three macros—two in the code window for the worksheet, and one in a regular module. Here's the one you should place in the regular macro module:

Private Sub SetTabColor(sRangeName)
    Dim c As Range

    Me.Tab.Color = vbGreen
    For Each c In Range(sRangeName).Cells
        If IsEmpty(c) Then
            Me.Tab.Color = vbYellow
            Exit For
        End If
    Next c
End Sub

This macro tests to see whether any of the cells in a named range is empty. If that occurs, then the tab color is set to yellow. (You could easily change the testing conditions before setting the tab color.) To make the macro work, however, you need to add the following two macros to the code window for the worksheet you want tested:

Private Sub Worksheet_Activate()
    SetTabColor("CheckRange")
End Sub
Private Sub Worksheet_Deactivate()
    SetTabColor("CheckRange")
End Sub

Note that the event handlers are executed whenever the worksheet is activated or deactivated. Note, as well, that the name of the named range containing the cells to check is passed to the SetTabColor macro. In this way, if you add these two macros to multiple worksheets, all you need to do is to change the name of the range for each of those worksheets.

If you have even more complex needs on modifying the tab colors, you will benefit by examining this tip and applying the various techniques discussed there:

https://tips.net/T013710

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (326) 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

Putting Cell Contents in Footers

Referencing information between cells in a worksheet is a piece of cake using some elemental formulas. You cannot, ...

Discover More

Quickly Displaying the Tabs Dialog Box

Setting tabs in a paragraph is a common task. This is most easily done by using the Tabs dialog box. Displaying the ...

Discover More

Criteria-Based Counting in a Filtered Column

The filtering capabilities of Excel are excellent, providing you with great control over which records in a worksheet are ...

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)

Unhiding Multiple Worksheets

You can hide a bunch of worksheets at the same time, but Excel makes it impossible to unhide a bunch at once. You can, ...

Discover More

Using Very Long Worksheet Tab Names

Excel places a limit on how many characters you can use in a worksheet name. This tip discusses that limit and provides ...

Discover More

Freezing Top Rows and Bottom Rows

Freezing the top rows in a worksheet so that they are always visible is easy to do. Freezing the bottom rows is not so ...

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 four less than 7?

2023-03-11 13:53:33

Ron S

The following links demonstrate some more techniques for handling color in Excel and coloring tabs

Here are a couple more variations

https://www.extendoffice.com/documents/excel/4090-excel-color-tab-based-on-cell-value.html

https://www.youtube.com/watch?v=052ifNgG5mg



This article talks about tab colors/formatting in general, but does not address the specific question
https://www.indeed.com/career-advice/career-development/change-tabs-color-in-excel

Using color in VBA- How it works- assign color using “IndexNumber”
Change sheet tab color with Excel VBA
https://www.youtube.com/watch?v=ssdJcLBFmy4
Change sheet tab color based on cell value in Excel using VBA
https://www.youtube.com/watch?v=052ifNgG5mg
Change Sheet Tab Color
https://www.youtube.com/watch?v=-MdCfJOg8Vs
Color All Excel Sheet Tabs Differently in One Step
https://www.youtube.com/watch?v=EbScVJNGmXE

Color All Excel Sheet Tabs Differently in One Step (using IndexColor)
https://www.youtube.com/watch?v=EbScVJNGmXE
Oct 9, 2019 VBA Projects
You can organize your workbook by assigning colors to the sheet Tabs that will help you identify the content visually.


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.