VBA to change tab colour using the palette

sparky2205

Well-known Member
Joined
Feb 6, 2013
Messages
507
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Hi folks,
I'm trying to write a macro to allow users to change the colour of a selected tab on a protected worksheet.
My plan:
• Use an input box to get the tab name from the user and assign it to a variable
• Present the user with the colour palette to select the colour (standard or custom) and assign it to a variable
• Set the tab to the selected colour
I've been using...
Code:
ColorCode = Application.Dialogs(xlDialogEditColor).Show(1, 26, 82, 48)
...to present the palette and assign the selected value to ColorCode but it refuses to be equal to anything other than -1.
I haven't worked with the palette in Vba previously so what I'm trying is probably not correct.
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Show just returns either False, if the user cancelled, or True. It will not return the selected colour. I think you'd need to create a userform with buttons for each colour.
 
Upvote 0
If you were happy with 56 colours, then you could use a separate worksheet as your "Pallette" and, in the sheet's _selectionChange event temporarily use:
Code:
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
Target.Interior.ColorIndex = .Row
End Sub
select any cell in row 1, then use the down arrow to scroll to 56. This will give you your "Pallette."

Then build a simple userform with a listbox (or combo) populated with all the sheet names, and the _click event coded to bring up your "Pallette" worksheet (might need to make the userform Modeless for this).
User selects colour, and row number can be passed back to the userform code, to finish with:
Code:
activesheet.tab.colorindex= colourfromsheetselectionvariable
etc.
 
Upvote 0
You need to retrieve the color from the first colorindex in your workbook

This worked for me:
Code:
If Application.Dialogs(xlDialogEditColor).Show(1, 26, 82, 48) Then
  ActiveSheet.Tab.Color = ActiveWorkbook.Colors(1)
End If
 
Upvote 0
Hi folks,
thank you all for your efforts on this.
Jaafar's solution looks to be the simpler one and it does work.
I do have one question. As I'm not familiar with using the palette in this way does this have a lasting impact on my palette or does it remain unaffected? Probably a silly question but I want to be sure I'm not pemanently changing a red RGB to green or something like that.
 
Upvote 0
The code as is, would affect the color palette of the workbook if the latter is saved... It shoudn't affect the excel default palette for new workbooks.

You could adapt the code as follows to make sure the workbook palette remains unchanged:
Code:
Sub Test()

    Dim lColor As Long
    
    On Error GoTo errHandler
    
    [COLOR=#008000]'store existing first colorindex color.[/COLOR]
    lColor = ActiveWorkbook.Colors(1)
    
    If Application.Dialogs(xlDialogEditColor).Show(1, 26, 82, 48) Then
      ActiveSheet.Tab.Color = ActiveWorkbook.Colors(1)
    End If
    
    
errHandler:
    [COLOR=#008000]'restore initial color[/COLOR]
    ActiveWorkbook.Colors(1) = lColor

End Sub
 
Last edited:
Upvote 0
Solution
Excellent,
thanks again for your help Jaafar.
Much appreciated.
 
Upvote 0

Forum statistics

Threads
1,223,244
Messages
6,170,976
Members
452,372
Latest member
Natalie18

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
Back
Top