Select One Cell and Make Another Cell Bold

Written by Allen Wyatt (last updated January 10, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021


2

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:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13178) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Full Path Names in Word

An easy way to display the document's full path name in the title bar.

Discover More

Setting the Distance between Text and Borders

Add a border around a piece of text (such as a paragraph), and Word makes some assumptions about the placement of that ...

Discover More

Importing a Subset of Records

If you only want to import a portion of whatever records are in a text file, Excel provides a number of ways you can ...

Discover More

Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!

More ExcelTips (ribbon)

Locking the Background Color

You can spend a lot of time getting the formatting in your worksheets just right. If you want to protect an element of ...

Discover More

Exporting Latitude and Longitude

A handy way to store latitude and longitude values in Excel is to treat them as regular time values. When it comes around ...

Discover More

Changing Cell Colors

If you need to change the color with which a particular cell is filled, the easier method is to use the Fill Color tool, ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is two minus 0?

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 ?


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.