Written by Allen Wyatt (last updated January 28, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Tom wonders if there is a way to change the automatic format settings on some of the Ribbon tools. For example, the Borders button always defaults to a single underline, but Tom would like it to be bold borders on all four sides. Or, the default colors in the Fill Color and Font Color tools always start at yellow and red, but Tom would like other combinations as his default.
While you can add or remove tools on the ribbon, there are no settings in Excel that allow you to permanently change the defaults used by the tools themselves. Once you use a tool, the option you selected (such as bold borders on all four sides) should remain as the default for that tool for the rest of the Excel session, but the next time you start the program the real default settings come back into play. It seems that these default settings are hard-coded into the program.
To get around this type of issue, most people record or create macros that apply the desired formatting. The macros can then be assigned to a button on the Quick Access Toolbar or to a shortcut key. In this way, you could simply apply your preferred formatting with the click of a button (or the typing of a shortcut key), bypassing the built-in Ribbon tools entirely.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13425) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
Excel lets you change lots of settings that affect the configuration of your system. At some point you may want to save ...
Discover MoreEnter a value into a cell and "poof!" it is automatically divided by 100. What's going on, and how can you fix it so that ...
Discover MoreExcel can helpfully display some statistical information in the program's Status Bar. If you cannot see all the ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-02-06 10:10:32
J. Woolley
The SetToolColor function in my first comment below assumes the Fill Color tool (Alt+H+H) looks like (see Figure 1 below) and the Font Color tool (Alt+H+F+C) looks like (see Figure 2 below) . In the first case, Standard Colors are 6 keystrokes down; in the second, they are down 7 keystrokes. If your version of Excel looks different, the SetToolColor function would require adjustment.
Figure 1.
Figure 2.
2023-02-05 21:56:41
Tomek
I like your approach.
Will try it soon.
2023-02-03 16:44:51
J. Woolley
If the VBA code in my previous comment is added to a standard module in Personal.xlsb, the following code will set default colors for the Home Ribbon's Fill Color and Font Color tools each time Excel is started. This code must be added to the ThisWorkbook module in Personal.xlsb.
Private WithEvents MyApp As Application 'process Application events
Private ToolDefaultsSet As Boolean
Private Sub Workbook_Open()
' Prepare to process Application events
' see http://www.cpearson.com/Excel/AppEvent.aspx
Set MyApp = Application
End Sub
Private Sub MyApp_WorkbookOpen(ByVal WB As Workbook)
If WB Is ThisWorkbook Then Exit Sub
If Not ToolDefaultsSet Then
SetToolDefaults
ToolDefaultsSet = True
End If
End Sub
Private Sub MyApp_NewWorkbook(ByVal WB As Workbook)
If Not ToolDefaultsSet Then
SetToolDefaults
ToolDefaultsSet = True
End If
End Sub
This code could be used with an Excel Add-in instead. For references to information about Personal.xlsb and Excel Add-in files, see https://sites.google.com/view/MyExcelToolbox/
2023-02-03 16:41:49
J. Woolley
The following SetToolDefaults macro will set default colors for the Fill Color and Font Color tools on the Home Ribbon. Once set, the new colors persist until changed by the user. (The Border tool default could also be set, but it will not persist; the keyboard shortcut for thick outside borders is Alt+H+B+T.)
This VBA code sets Fill Color to Green and Font Color to Blue. You can change those colors in the code to any of the Standard Colors DarkRed, Red, Orange, Yellow, LightGreen, Green, LightBlue, Blue, DarkBlue, or Purple.
Sub SetToolDefaults()
' Set persistent default Fill Color and Font Color tools on Home Ribbon
'start in separate thread
Application.OnTime Now, "SetToolDefaults_Do"
End Sub
Sub SetToolDefaults_Do(Optional Unlisted As Byte) 'removed from Macros list
' Set persistent default Fill Color and Font Color tools on Home Ribbon
' The Border tool can also be set, but it will not persist
' For example, thick outside border shortcut is Alt+H+B+T
' Standard Colors are DarkRed, Red, Orange, Yellow, LightGreen, Green,
' LightBlue, Blue, DarkBlue, and Purple
Const FillColor As String = "Green"
Const FontColor As String = "Blue"
Dim sKeysFill As String, sKeysFont As String
sKeysFill = SetToolColor("Fill", FillColor)
sKeysFont = SetToolColor("Font", FontColor)
'Ribbon must be visible but not pinned
Dim Hidden As Boolean, Pinned As Boolean
With Application
.ScreenUpdating = False
Hidden = (Not .CommandBars("Ribbon").Visible)
If Hidden Then .ExecuteExcel4Macro "Show.ToolBar(""Ribbon"", True)"
Pinned = (.CommandBars("Ribbon").Height > 100)
If Pinned Then .CommandBars.ExecuteMso "MinimizeRibbon"
End With
'add temporary workbook
Workbooks.Add
'because Application.SendKeys is unreliable
CreateObject("WScript.Shell").SendKeys sKeysFill & sKeysFont
'finish in separate thread with adequate delay
Const Delay As Double = 1 / 3600 / 24 'one second (adjust if necessary)
With Application
.OnTime (Now + Delay), _
"'SetToolDefaults_Done " & Pinned & "," & Hidden & "'"
.ScreenUpdating = True
End With
End Sub
Sub SetToolDefaults_Done(Pinned As Boolean, Hidden As Boolean)
'delete temporary workbook
ActiveWorkbook.Close SaveChanges:=False
'restore Ribbon
With Application
If Pinned Then .CommandBars.ExecuteMso "MinimizeRibbon"
If Hidden Then .ExecuteExcel4Macro "Show.ToolBar(""Ribbon"", False)"
End With
End Sub
Function SetToolColor(Tool As String, Color As String) As String
Dim StandardColors As Variant, v As Variant, sHead As String
Dim nDown As Integer, sDown As String
Dim nRight As Integer, sRight As String
Const myName As String = "SetToolColor"
StandardColors = Array("DarkRed", "Red", "Orange", "Yellow", _
"LightGreen", "Green", "LightBlue", "Blue", "DarkBlue", "Purple")
For Each v In StandardColors
v = LCase(v)
Next v
Select Case LCase(Tool)
Case "fill": nDown = 6: sHead = "%hh"
Case "font": nDown = 7: sHead = "%hfc"
Case Else
v = "Unrecognized tool " & Tool
MsgBox v, vbCritical, myName
Exit Function
End Select
With Application.WorksheetFunction
sDown = .Rept("{DOWN}", nDown)
On Error Resume Next
nRight = .Match(LCase(Color), StandardColors, 0) - 1
If Err Then
v = "Standard Colors does not include " & Color
MsgBox v, vbCritical, myName
Exit Function
End If
On Error GoTo 0
sRight = .Rept("{RIGHT}", nRight)
End With
SetToolColor = sHead & sDown & sRight & "~"
End Function
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 © 2024 Sharon Parq Associates, Inc.
Comments