Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Finding the Nth Occurrence of a Character.
Written by Allen Wyatt (last updated October 9, 2020)
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.
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!
When you've got a column full of names, you may want to get a count of how many of those names are unique. You can make ...
Discover MoreIf you have a string of text that is composed of digits and non-digits, you may want to know where the digits stop and ...
Discover MoreAt the heart of working with Excel is the process of creating formulas that calculate results based on information within ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2017-08-15 03:16:33
Rick Rothstein
@Michael (Micky) Avidan,
That is the same formula that Allen Wyatt posted in his article except that he used CHAR(1) instead of "|" in order to guarantee he wouldn't accidentally trip over the replacement character within the text.
2017-08-14 21:32:18
sdfhuiu
You were the only person to actually answer this question on the internet
2016-08-22 19:42:23
Hello,
I'm working with two large spread sheets that consist of account numbers that can have multiple duplicates. I want to retrieve the Codes that I'm doing a V-lookup on to show the many different type of services that were done. When I Google my request normally the formulas consist of one single tab with an array of no more than 10 to keep it simple. Can anybody give me an example of two different spread sheets and how to select the data in a vlookup format and or index to retrieve the value desired??
2016-04-17 19:38:19
Galan
As a note, =FIND(CHAR(1),SUBSTITUTE(A1,"B",CHAR(1),3))
in Google Sheets, this does not work for char's that are non-printable characters like char(1). I went with char(239) and that seems to work.
2016-04-02 06:17:53
Rick Rothstein
This much shorter UDF for your FindN function works in XL2003 (the earliest version I own) but I think should work in the earlier versions of Excel covered by this article as well...
Function FindN(sFindWhat As String, sInputString As String, N As Long) As Long
Application.Volatile
FindN = InStr(Replace(sInputString, sFindWhat, " ", 1, N - 1), sFindWhat)
End Function
2016-04-02 05:51:44
Michael (Micky) Avidan
...Sorry,
Didn't noticed the: =FIND(CHAR(1),SUBSTITUTE(A1,"B",CHAR(1),3))
formula.
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL
2016-04-02 05:49:36
Michael (Micky) Avidan
@To whom it may concern,
There is a much shorter and simpler formula to identify the place of the 3rd occurrence of the letter "B":
=FIND("|",SUBSTITUTE(A1,"B","|",3))
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL
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 © 2024 Sharon Parq Associates, Inc.
Comments