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:
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.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
When developing macros, you can create subroutines. This is a great way to reuse common code and make your programming ...
Discover MoreNamed ranges are a great capability provided by Excel. You can define all sorts of named ranges in a workbook, but how do ...
Discover MoreWant a quick way to speed up your macros? All you need to do is to stop Excel from updating the screen while the macro is ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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 © 2024 Sharon Parq Associates, Inc.
Comments