Written by Allen Wyatt (last updated January 10, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
Clay wants to know if there is a way that when he selects a specific cell Excel will automatically make the contents of a different cell bold. For instance, if he selects cell K5 he would like whatever is in cell C5 to show as bold; when he leaves cell K5 (to go to a different cell), then cell C5 should revert to however it was before selecting K5 made it bold.
In coming up with solutions, you might think you could use conditional formatting to apply the formatting to cell C5. Theoretically, this should be easy to do; all you need to do is create a conditional formatting rule based on the following formula:
=CELL("address")="$K$5"
Since the CELL function, as used here, returns the address of whatever cell is selected, then whenever cell K5 is selected, the formatting in the rule (in this case, setting the cell to bold) is applied. The problem with this approach, however, is that it doesn't work well in practice.
The reason is because the CELL function is only evaluated when the worksheet is recalculated. If you just select cell K5, then the worksheet isn't recalculated, so the formula doesn't resolve to True, and the conditional format is not applied. The only way for it to work is to select cell K5, then press F9 to recalculate the worksheet, and then cell C5 will show up as bold.
The best way to go about the formatting is to use a macro, specifically one tied to the SelectionChange event for the worksheet. This event triggers every time the selected cell is changed. The following macro checks to see if cell K5 is selected. If it is, then cell C5 is bolded; if it is not, then cell C5 is "unbolded."
Private Sub Worksheet_SelectionChange(ByVal Target As Range) If ActiveCell.Address(False, False) = "K5" Then Range("C5").Font.Bold = True Else Range("C5").Font.Bold = False End If End Sub
Remember that this macro is added to the code for the sheet to which is applies—right click the worksheet tab and choose View Code. That is where the macro should be placed. Since the macro is executed every time you change what is selected in the worksheet, the "bold status" of cell C5 is continually updated.
Note that the macro effectively toggles the Bold property of the cell. Thus, if you select a cell other than K5, whatever is in cell C5 will not be bold. This doesn't apply, of course, if you do have some other conditional formatting rule defined for cell C5 that would cause it to appear as bold. In that case, the conditional format takes precedence of anything that this particular macro might do.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13178) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021.
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!
Need a line through the middle of your text? Use strikethrough formatting, which is easy to apply using the Format Cells ...
Discover MoreIf you want to format currency values so that Excel uses periods between groups of thousands and commas as a decimal ...
Discover MoreExcel often changes the formatting of a cell based on how it parses what you are entering into that cell. This is ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2025-01-12 17:12:25
J. Woolley
@jamies
The use of any macro does not clear the Undo list; it depends on the macro. The Undo list is cleared only if the macro changes Excel's "environment" (such as a cell's Bold status). See my comment dated 2024-12-16 here: https://excelribbon.tips.net/T012513_Preserving_the_Undo_List.html
However, this Tip's Worksheet_SelectionChange event procedure always clears the Undo list because it updates the Bold status of cell C5 every time the selection is changed from one cell to another on the worksheet. The macro would be more efficient if this statement
Else
was replaced by this statement
ElseIf Range("C5").Font.Bold Then
With this revision the macro changes Excel's "environment" and clears the Undo list only when the selection is moved to or from cell K5; Undo is preserved when the selection is moved between other cells.
This statement
If ActiveCell.Address(False, False) = "K5" Then
can also be replaced by this statement
If ActiveCell = Range("K5") Then
but the difference is minor.
2025-01-10 09:47:22
jamies
Doesn't the use of any Macro
clear out the undo list of actions ?
So making the use of the macro have what may be a very annoying effect on the user's workings ?
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 © 2025 Sharon Parq Associates, Inc.
Comments