Select One Cell and Make Another Cell Bold

Written by Allen Wyatt (last updated April 11, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


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 Excel in Microsoft 365.

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

Understanding Relative and Absolute Addressing

In Excel you can reference a cell in a formula by entering the coordinates for the cell you want to reference. This can ...

Discover More

Item Not Available in Library

When sharing workbooks with others, you may find that the macros in those workbooks may not work as you expect. This tip ...

Discover More

Dynamically Changing Worksheet Tab Color

Excel makes it easy to change the color of a worksheet's tab. If you want that color change to be dynamic, one way to do ...

Discover More

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!

More ExcelTips (ribbon)

Extra Blank Lines in Some Cells

When adjusting column width, Excel can add an extra line to some cells. This behavior seems to be related to the text ...

Discover More

Setting Cell Color Based on Numeric Values

Excel allows you to specify colors for the interior of cells in your worksheet. If you want those colors to be set ...

Discover More

Changing the Default Vertical Alignment

By default, Excel vertically aligns cell contents to the bottom of cells. If you prefer a different default alignment, ...

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 one less than 9?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.