Written by Allen Wyatt (last updated February 19, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
Gary has a worksheet that contains unstructured text strings that he needs to parse into component elements. Sometimes he needs to search for types of text rather than a specific character. For example, he might want to find the first, the Nth, or the last occurrence of any bold character (or any italics character) in the cell.
There is no intrinsic function or tool in Excel to accomplish this task. The regular Find and Replace feature returns matches for formatting, but not the position at which those matches occur. To get that specific about what you want to find, you'll need to use a macro. You can get the positioning information back into your worksheet if you implement the macro as a user-defined function.
The following macro accepts a range (intended to be a specific cell), an indicator of whether you want bold or italic (or both), and the occurrence of that formatting.
Function FindNth(r As Range, sType As String, N As Integer) As Integer
Dim J As Integer
Dim iCount As Integer
Dim sStyle As String
If r.Count = 1 Then
FindNth = 0
iCount = 0
For J = 1 To Len(r.Text)
sStyle = r.Characters(J, 1).Font.FontStyle
If LCase(sStyle) = LCase(sType) Then
iCount = iCount + 1
If N = 0 Then
FindNth = J
Else
If N = iCount Then
FindNth = J
Exit For
End If
End If
End If
Next J
Else
FindNth = -1
End If
End Function
In order to use the macro, use one of the following formulas in your worksheet:
=FindNth(A1, "bold", 2) =FindNth(A1, "italic", 3) =FindNth(A1, "bold italic", 1)
In each case the third parameter specifies which occurrence of the given formatting you want to find. The function returns the character position of that occurrence within the cell. If there is no such occurrence, then 0 is returned. If you specify multiple cells in the first parameter of the function, it returns a -1. If you specify an occurrence of 0, then the character position of the last occurrence of the specified format is returned.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13402) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2019 For Dummies today!
You can easily use formulas to pull apart text stored in a cell. For instance, if you need to pull individual characters ...
Discover MoreWant to run a macro when you first select a worksheet? You can do so by using one of the event handlers built into Excel, ...
Discover MoreWhen you use macros to create functions, you might want to share those functions with others�"particularly if they ...
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 © 2025 Sharon Parq Associates, Inc.
Comments