Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Changing Font Face and Size Conditionally.
Written by Allen Wyatt (last updated November 20, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Robin asks if there is a way to use Excel's conditional formatting capabilities to change the font used in a cell or to change the font size in a cell. The short answer is no, that can't be done—at least not with conditional formatting. (The controls that allow you to specify font name and size are grayed-out in the formatting dialog box used with conditional formatting.)
You can, however, use a macro to examine cell contents and make changes in the appearance of a cell. Consider the following macro which examines any cells you have selected when you run the macro. If any of the cells have a length of more than two characters or a value of more than 10, then the cell's font is changed.
Sub DoReformat() Dim rCell As Range For Each rCell In Selection.Cells If Len(rCell.Text) > 2 Or _ Val(rCell.Value) > 10 Then rCell.Font.Name = "Arial" rCell.Font.Size = 16 Else rCell.Font.Name = "Times New Roman" rCell.Font.Size = 12 End If Next End Sub
To use the macro, just select the cells you want changed and then run the macro. If you want the formatting to change more automatically, then you can have the macro check to see if a change was made within a certain range of cells:
Private Sub Worksheet_Calculate() Dim rng As Range Dim rCell As Range Set rng = Range("A1:A10") For Each rCell In rng If Len(rCell.Text) > 2 Or _ Val(rCell.Value) > 10 Then rCell.Font.Name = "Arial" rCell.Font.Size = 16 Else rCell.Font.Name = "Times New Roman" rCell.Font.Size = 12 End If Next End Sub
This macro, when added to the worksheet object, will run every time the worksheet is recalculated. It checks the range A1:A10, applying the same tests as in the previous macro. The result is that the formatting of the cells is checked and changed continuously. To have the macro check a different range, just change the addresses assigned to the rng variable near the beginning of the macro.
One drawback of this macro is that it can get sluggish if you have a very large range for it to check. It will go very quickly if you are checking A1:A10 (ten cells), but may go much slower if you are continually checking B2:N465 (over 6,000 cells). In that case, you may want to design the macro so it runs whenever the worksheet is changed, but only takes action if the change was done to a cell in your target range. The following version is also added to the worksheet object:
Private Sub Worksheet_Change(ByVal Target As Range) Dim rCell As Range If Union(Target, Range("A1:A10")).Address = _ Range("A1:A10").Address Then Application.EnableEvents = False For Each rCell In Target If Len(rCell.Text) > 2 Or _ Val(rCell.Value) > 10 Then rCell.Font.Name = "Arial" rCell.Font.Size = 16 Else rCell.Font.Name = "Times New Roman" rCell.Font.Size = 12 End If Next Application.EnableEvents = True End If End Sub
The macro uses the Union function to check whether the cells changed (passed to the event handler in the Target variable) have any overlap with the range you want checked. If they do, then the checking is done on the cells in the Target range.
One thing to keep in mind with macros that affect formatting is that if you have conditional formatting applied to a cell that is also checked by a macro, the formatting in the conditional formatting takes precedence over the formatting in the macro. If your macro is changing font name and font size, this isn't a big concern because conditional formatting won't affect these attributes. However, if you change your macro to also change a different format attribute—such as cell color—and that attribute is also changed by the conditional format, then it won't look like the macro did anything because Excel uses the conditional formatting in preference to what the macro does.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13236) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Changing Font Face and Size Conditionally.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
There are many times when you are creating a worksheet that you need to analyze dates within that worksheet. Once such ...
Discover MoreSetting up conditional formatting can be challenging under some circumstances, but once set it can work great. Unless, of ...
Discover MoreIf you want to highlight cells that contain certain characters, you can use the conditional formatting features of Excel ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-11-22 11:23:21
J. Woolley
The following three functions are included in My Excel Toolbox:
=SetFont(Name, Size, Style, Color, Underline, Strikethrough, Target)
=SetChars(Target, Start, Count,
Name, Size, Style, Color, Underline, Strikethrough, Superscript, Subscript)
=SetFill(Color, PatternStyle, PatternColor, Target)
When these functions appear in a cell formula, they will set the Target range's font and/or fill properties. For each function, all property parameters are optional and unchanged if missing; if Target is missing, the formula's cell is assumed. SetChars is similar to SetFont except it applies to a limited number of characters (Start, Count) in each cell of Target's range.
Using these functions might be more convient than the Tip's macros. They can be used with an IF(...) function to set or reset properties. Each function returns an empty string ("") in a text formula, zero (0) in a numeric formula, or FALSE in a boolean formula. For example:
=A1+IF(A1>10,SetFont("Arial",16),SetFont("Times",12))
See https://sites.google.com/view/MyExcelToolbox/
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