Tab Color Change to Cell Color

justjaxi

New Member
Joined
Apr 30, 2020
Messages
9
Office Version
  1. 2016
Platform
  1. Windows
Is there a way to make the tab color change with the color of a cell on that worksheet?

Example: Workbook “CUSTOMER CONTACT” has several worksheets. One worksheet is titled “Cold Calls”, another is titled “Mailings”. In cell C1 on the “Cold Calls” worksheet, the cell changes color based on a percentile set from conditional formatting. In cell D5 on the “Mailings” worksheet, the cell changes color based on a specific text set from conditional formatting.

I want the “Cold Calls” tab in my workbook to change colors along with the color on that same worksheet (“Cold Calls”) of cell C1.

I want the “Mailings” tab in my workbook to change colors along with the color on that same worksheet (“Mailings”) of cell D5

If it can be done, do the colors have to be ‘prime’ colors (in other words, no variations of colors, just the set colors allowed)?

etc., etc. etc.

TIA
 

Some videos you may like

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
47,926
Office Version
  1. 365
Platform
  1. Windows
What are the Conditional Formatting trigger conditions for each of those two cells?
 

justjaxi

New Member
Joined
Apr 30, 2020
Messages
9
Office Version
  1. 2016
Platform
  1. Windows
What are the Conditional Formatting trigger conditions for each of those two cells?
Apologies, I thought it was based on percentile, it is based on number. Both are graded color scales. 2-Color Scale, Minimum set to number 0 (green), Maximum set to number 10 (orange).
 

EXCEL MAX

Active Member
Joined
Nov 11, 2020
Messages
310
Office Version
  1. 2007
Platform
  1. Windows
Hello Justjaxi,
Here is some example.
Contitional formating rule must to be same as in the code.
"Sheets("Cold Calls").Range("C1").Value > 0"

Capture.PNG

VBA Code:
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
    
    Dim varColor As String
    
    varColor = Sheets("Cold Calls").Range("C1").Interior.Color
    If Sheets("Cold Calls").Range("C1").Value > 0 Then
        ActiveWorkbook.Sheets("Cold Calls").Tab _
         .Color = Sheets("Cold Calls").Range("C1"). _
            FormatConditions(1).Interior.Color
    Else
        ActiveWorkbook.Sheets("Cold Calls").Tab _
         .Color = varColor
    End If

End Sub
 

MARK858

MrExcel MVP
Joined
Nov 12, 2010
Messages
13,886
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
  2. Mobile

ADVERTISEMENT

I think Peter was after what makes the change in the Conditional formatting so he could use it to trigger the macro.
As a basic you can make the tab color match the conditional formatting color of a cell like...

VBA Code:
 Sheets("Cold Calls").Tab.Color = Sheets("Cold Calls").Range("C1").DisplayFormat.Interior.Color

but to go any further then we need to know how you are triggering the change to the conditional formatting
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
53,344
Office Version
  1. 365
Platform
  1. Windows
Another option which will trigger when any cell is changed
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
   Me.Tab.Color = Range("C1").DisplayFormat.Interior.Color
End Sub
This needs to go in the Cold Calls sheet module.
We can restrict which cells trigger the code if needed.
 

EXCEL MAX

Active Member
Joined
Nov 11, 2020
Messages
310
Office Version
  1. 2007
Platform
  1. Windows

ADVERTISEMENT

I love simplicity. New technologies. This not work in my Excel 2007.
 

MARK858

MrExcel MVP
Joined
Nov 12, 2010
Messages
13,886
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
  2. Mobile
Oops didn't spot that you were on 2007, no DisplayFormat didn't come in until 2010. Sorry.

Edit: my response above is because I thought it was the OP replying. DisplayFormat is still the way to go for the OP.
 
Last edited:

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
53,344
Office Version
  1. 365
Platform
  1. Windows
I have a feeling that DisplayFormat arrived with 2010, but could well be wrong.

Also using FormatConditions like you did, won't work with colour scales.
 

Taul

Well-known Member
Joined
Oct 24, 2004
Messages
748
Office Version
  1. 2019
  2. 2013
Platform
  1. Windows
Hi,
One way is to list the colours for each value between 0 and 10 (Green to Orange)
In the sheet module for "Cold Calls", paste this code.
You will need to repeat it for cell D5 on the "mailings" page

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    
    If Target.Address = "$C$1" Then
        Select Case Target.Value
        
        Case "0"
            Me.Tab.Color = RGB(169, 208, 142)
        Case "1"
            Me.Tab.Color = RGB(176, 205, 141)
        Case "2"
            Me.Tab.Color = RGB(184, 202, 140)
        Case "3"
            Me.Tab.Color = RGB(191, 199, 139)
        Case "4"
            Me.Tab.Color = RGB(199, 196, 138)
        Case "5"
            Me.Tab.Color = RGB(206, 192, 137)
        Case "6"
            Me.Tab.Color = RGB(214, 189, 136)
        Case "7"
            Me.Tab.Color = RGB(221, 186, 135)
        Case "8"
            Me.Tab.Color = RGB(229, 183, 134)
        Case "9"
            Me.Tab.Color = RGB(236, 180, 133)
        Case "10"
            Me.Tab.Color = RGB(244, 176, 132)
        
        Case Else
            Me.Tab.ColorIndex = xlColorIndexNone

        End Select
    End If
End Sub
 

Watch MrExcel Video

Forum statistics

Threads
1,123,448
Messages
5,601,713
Members
414,470
Latest member
glukemey

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top