"Nth" occurrence...

Mark Kingsley

New Member
Joined
Nov 4, 2002
Messages
2
This is a 2 part question.

1) Is there a formula that can be used to find the "nth" occurrence of a character in a string?

For example, how could you determine that the 3rd occurrence of "s" in the word "suggestions" is the 11th character?

2) Is there a function/formula that would return "3" for the number of times "s" appears in "suggestions"?
 

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.
On 2002-11-05 13:35, Mark Kingsley wrote:
This is a 2 part question.

1) Is there a formula that can be used to find the "nth" occurrence of a character in a string?

For example, how could you determine that the 3rd occurrence of "s" in the word "suggestions" is the 11th character?

2) Is there a function/formula that would return "3" for the number of times "s" appears in "suggestions"?

Q1:

=IF(LEN(A1)-LEN(SUBSTITUTE(A1,E1,""))=F1,SEARCH("@",SUBSTITUTE(A1,E1,"@",F1)),"Not Found")

where A1 houses a target string, E1 a character the Nth occurrence of which you want the position in A1, and F1 the Nth occurrence.


Q2:

=LEN(A1)-LEN(SUBSTITUTE(A1,E1,""))

where A1 houses a target string and E1 a character whose occurrence you want to count.
This message was edited by Aladin Akyurek on 2002-11-05 14:02
 
Upvote 0
Re: "Nth" occurrence...

Q1:

=IF(LEN(A1)-LEN(SUBSTITUTE(A1,E1,""))=F1,SEARCH("@",SUBSTITUTE(A1,E1,"@",F1)),"Not Found")

where A1 houses a target string, E1 a character the Nth occurrence of which you want the position in A1, and F1 the Nth occurrence.

I'm trying to use this but if I input a 2 in F1 and there are more than 2 occurences of E1 in A1, then it returns "Not Found". It works perfectly if there are 2 occurences.
 
Upvote 0
Re: "Nth" occurrence...

I'm trying to use this but if I input a 2 in F1 and there are more than 2 occurences of E1 in A1, then it returns "Not Found". It works perfectly if there are 2 occurences.

Right... Should have been:
Rich (BB code):
=IF(LEN(A1)-LEN(SUBSTITUTE(A1,E1,""))>=F1,
  SEARCH("@",SUBSTITUTE(A1,E1,"@",F1)),"Not Found")

Thanks for creating this corrective occasion.
 
Upvote 0

Forum statistics

Threads
1,213,544
Messages
6,114,249
Members
448,556
Latest member
peterhess2002

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top