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 Office 365. You can find a version of this tip for the older menu interface of Excel here: Changing Font Face and Size Conditionally.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
After you've applied a conditional format to a cell, you may have a need to later delete that format so that the cell is ...
Discover MoreNeed to have your worksheet printout start on a new page every time a value in a column changes? There are a couple of ...
Discover MoreIf you just updated your copy of Excel, you may have noticed some differences in how the program handles applying ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-01-23 20:55:55
Roy
Interesting point in this Tip:
One often has a problem with users changing formatting to suit themselves, even on files they know are used by others and even when the changes are made to change printouts and they save the changes.
Not that one could protect everything this way, obviously, but if one applied a CF to ALL the cells of a spreadsheet with a simple "=A1=A1" kind of test, and set all the formatting that can be set in CF, then those formatting setting would be protected from anything the user did in the worksheet.
Since CF cannot itself be protected, sooner or later they'd suss it out, one supposes. But until then... and since thinking of checking CF is likely low on their list of "Why didn't that work?" reasons, it might be a while. Nothing lasts forever. Gotta use your time after a tactic, before it is overcome, to think of the next one. But for a while...
2018-04-26 15:03:30
Richard Matt
First: Thank you for a very nicely written , relevant post.
Second: I tried to subscribe to your newsletter, but my e-mail address was not accepted.
Third: I am an experienced programmer, but have never used an Excel macro, so the root of my problem is probably something trivial.
By looking up other webpages on how to save a macro into an Excel file, I was able to get the first macro on this webpage to work properly when I clicked on the 'Run' button.
When I repeated the same steps with the second macro on this webpage, it would run successfully when I clicked on the 'Run' button; however, I understood that the object of this macro was that it would run automatically. (Well . . . it would run when the Excel spreadsheet recalculates, and I verified that the spreadsheet was set-up so it recalculated automatically.)
Can you tell me a few likely reasons (or things to check) for the second macro to update the format as soon as the cell content changes?
2014-10-06 12:37:37
Alex
This was very helpful. One further question though: is there code that will format the size of text in a range based on the values a different or neighboring range? Thanks.
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 © 2021 Sharon Parq Associates, Inc.
Comments