Adding Differently Formatted Text to a Cell

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


Larry has been tasked with replacing or adding text to each cell in a column in several Excel workbooks. The problem is that this new text has to be underlined and a different color. Find and Replace underlines and colors all of the text in the cells, but Larry needs the formatting to apply to just the added text.

If you only have to do this sort of task a few times, the simplest solution might be to enlist the help of Microsoft Word. You can copy the range of cells to a Word document, use Word's Find and Replace capabilities to make the formatting changes, and then copy the text back to your Excel worksheet.

If you have to do this task more often, then the best approach is to use a macro. The following macro can be used to either change text in the cells of a column or to add text to the cells.

Sub AddFormatedText()
    Dim K As Long
    Dim lCol As Long
    Dim LastRow As Long
    Dim sFind As String
    Dim sReplace As String
    Dim FullCells As Range
    Dim c As Range

    ' Column to work on
    lCol = 1

    ' Text to be replaced in the cell
    ' If this variable is empty, then
    ' the contents of sReplace are added
    ' to the end of the cell
    sFind = ""

    ' Text to replace sFind or to add to the cell
    sReplace = "More Text"

    ' Find last row in column A
    LastRow = Cells(Rows.Count, "A").End(xlUp).Row

    ' Set range to check
    Set FullCells = Range(Cells(1, lCol), Cells(LastRow, lCol))
    ' Start looking through each cell
    For Each c In FullCells
        K = 0
        ' Only check if there is not a formula in the cell
        ' and if the cell has some text in it
        If Not c.HasFormula And Len(c.Text) > 0 Then
            If sFind > "" Then
                ' Replace first found instance of text in sFind
                K = InStr(c.Text, sFind)
                If K > 0 Then
                    c = Left(c.Text, K - 1) & sReplace & _
                      Mid(c.Text, K + Len(sFind))
                End If
            Else
                K = Len(c.Text)
                ' Add the text to the cell (plus a space)
                c = c & " " & sReplace
                ' Adjust starting position for formatting
                K = K + 2
            End If
        End If

        ' Format the added text, if any
        If K > 0 Then
            With c.Characters(Start:=K, Length:=Len(sReplace)).Font
                .Underline = xlUnderlineStyleSingle
                .Color = vbRed
            End With
        End If
    Next c
End Sub

There are three changes you need to make in order to use the macro. The first is to make sure the lCol variable is set to the column number you want to affect. Second, you should set sFind equal to the text you want to find and replace in the cells. You can, if you wish, leave sFind empty (as it is above) if you just want to add text to the cell. Finally, you need to set sReplace equal to what you want to either replace sFind with or to what you want added to the cells.

The macro looks through each cell in the specified column and, if the cell doesn't contain a formula and it already has some text in it, it replaces or appends your text. Finally, if a change was made to the cell, then whatever was in sReplace is underlined and made red. You should note that if a change is made to the cell, then any existing formatting in the cell is overridden by the change being made.

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 (9302) 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

Limits to Filtering

Excel limits the number of items that can be shown in an AutoFilter drop-down list. Granted, it is a high limit, but it ...

Discover More

Spelling Errors on Internet Addresses

Tired of Word marking Internet addresses as spelling errors? You can turn off this check by applying the steps in this tip.

Discover More

Condensing Figure Caption References

Word can automatically add captions to your figures. You can then reference those captions from within your document. If ...

Discover More

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

More ExcelTips (ribbon)

Displaying the Selected Cell's Address

Need to know the address of the cell that is currently selected? The function and macro highlighted in this tip will come ...

Discover More

Controlling Window Size when Opening Additional Workbooks

When you open multiple workbooks, the way in which Excel sizes them is not the best for your needs. This tip looks at a ...

Discover More

Creating Worksheets with a Macro

Using a macro to add worksheets to your workbook is easy. This tip provides two different methods you can use.

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 8 - 5?

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.