Written by Allen Wyatt (last updated May 17, 2025)
This tip applies to Excel 97, 2000, 2002, and 2003
Barry often finds himself wanting to identify the Nth occurrence of a character within a text string. He knows he can use the SEARCH and FIND worksheet functions for finding an initial occurrence, but is unsure how to find, say, the 3rd occurrence of the letter "B" within a text string.
Actually, the SEARCH function could be used to find the desired occurrence, in the following manner:
=SEARCHB("b",G20,(SEARCHB("b",G20,(SEARCHB("b",G20,1)+1))+1))
Notice how the SEARCHB function is used in a nested manner. The formula specifies what is being searched for (the letter "b") and the number of nesting levels indicates which occurrence within the cell you want to find. The formula returns the position of the desired character within the cell.
The problem with such a formula, of course, is that it is difficult to maintain and can quickly get unusable if you want to find, say, the seventh occurrence.
A more flexible formula would be the following:
=FIND(CHAR(1),SUBSTITUTE(A1,"B",CHAR(1),3))
This formula examines the value in A1. It substitutes the CHAR(1) code for the third occurrence of "B" within the cell. The FIND function then looks within the resulting string for the position where CHAR(1) occurs. If the desired occurrence does not exist, then the formula returns a #VALUE error.
If you prefer, you could create a user-defined function that will look for the Nth position of a character. The following is a very simple macro that takes three arguments: the string to be searched, the text to match, and the position desired.
Function FindN(sFindWhat As String, _ sInputString As String, N As Integer) As Integer Dim J As Integer Application.Volatile FindN = 0 For J = 1 To N FindN = InStr(FindN + 1, sInputString, sFindWhat) If FindN = 0 Then Exit For Next End Function
The function is case sensitive in what it searches for, and it returns the position within the specified string at which the sFindWhat value occurs. If there is no occurrence at the specified instance, then the function returns a 0. The following shows how the function can be used in a worksheet:
=FindN("b",C15,3)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3324) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Finding the Nth Occurrence of a Character.
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!
An easy way to create a name for a formula or constant value. The name can then be used in other formulas or for ...
Discover MoreWith a long list of items in a worksheet, you may want to determine the last time a particular item appeared in the list. ...
Discover MoreAdding row numbers to a column of your worksheet is easy; you just need to use a formula to do it. Here's a quick look at ...
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 menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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