ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   help needed (https://www.excelbanter.com/excel-worksheet-functions/62968-help-needed.html)

zomex

help needed
 
eg. "mick jagger bush" "muhammad ali clay" "ayesha bin batool"
suppose that these r the names and i want formula that would be generic to
all, such that it gets "jagger" "ali" and "bin"

JE McGimpsey

help needed
 
One way:

=TRIM(MID(LEFT(A1, FIND("$", SUBSTITUTE(A1, "_", "$", 2))),
FIND("_", A1), 32767))

where _ represents a space character to prevent unfortunate linewrap.

In article ,
"zomex" wrote:

eg. "mick jagger bush" "muhammad ali clay" "ayesha bin batool"
suppose that these r the names and i want formula that would be generic to
all, such that it gets "jagger" "ali" and "bin"


JulieD

help needed
 
Hi Zomex

your teacher is obviously in a mean mood today :)

for this one - one answer involves a combination of MID and SEARCH functions

the way to approach it is
- locate the first space using the SEARCH function
- locate the second space using the SEARCH function (you'll have to nest the
first formula in here again to get your starting point), then subtract the
first formula again to calculate the number of chatacters between the two
spaces.

then nest these two formulas in the MID function.

Using the above method will give you leading and trailing spaces, these can
easily be edited out by modifying the formula (once you get that far).

Give it a go and if you'ld like more help, just post back.

Cheers
JulieD

julied at hctsReMoVeThIs dot net dot au


"zomex" wrote:

eg. "mick jagger bush" "muhammad ali clay" "ayesha bin batool"
suppose that these r the names and i want formula that would be generic to
all, such that it gets "jagger" "ali" and "bin"


zomex

help needed
 
thanks for the wonderful reply.... i couldnt get the middle name though the
formula that i was using sure did get me the last name and the3 formula is
=MID(E4,FIND(" ",E4,FIND(" ",E4)+1),LEN(E4)) ...the other formula did
work, but it shows the result like "0UsMan" and for even it shows
"1UmEr"...how can i remove this "0" abd "1"... :)

"JulieD" wrote:

Hi Zomex

your teacher is obviously in a mean mood today :)

for this one - one answer involves a combination of MID and SEARCH functions

the way to approach it is
- locate the first space using the SEARCH function
- locate the second space using the SEARCH function (you'll have to nest the
first formula in here again to get your starting point), then subtract the
first formula again to calculate the number of chatacters between the two
spaces.

then nest these two formulas in the MID function.

Using the above method will give you leading and trailing spaces, these can
easily be edited out by modifying the formula (once you get that far).

Give it a go and if you'ld like more help, just post back.

Cheers
JulieD

julied at hctsReMoVeThIs dot net dot au


"zomex" wrote:

eg. "mick jagger bush" "muhammad ali clay" "ayesha bin batool"
suppose that these r the names and i want formula that would be generic to
all, such that it gets "jagger" "ali" and "bin"


Bob Phillips

help needed
 
Maybe

=MID(E4,FIND(" ",E4,FIND(" ",E4)+1)+1,LEN(E4))

--
HTH

Bob Phillips

(remove nothere from email address if mailing direct)

"zomex" wrote in message
...
thanks for the wonderful reply.... i couldnt get the middle name though

the
formula that i was using sure did get me the last name and the3 formula is
=MID(E4,FIND(" ",E4,FIND(" ",E4)+1),LEN(E4)) ...the other formula

did
work, but it shows the result like "0UsMan" and for even it shows
"1UmEr"...how can i remove this "0" abd "1"... :)

"JulieD" wrote:

Hi Zomex

your teacher is obviously in a mean mood today :)

for this one - one answer involves a combination of MID and SEARCH

functions

the way to approach it is
- locate the first space using the SEARCH function
- locate the second space using the SEARCH function (you'll have to nest

the
first formula in here again to get your starting point), then subtract

the
first formula again to calculate the number of chatacters between the

two
spaces.

then nest these two formulas in the MID function.

Using the above method will give you leading and trailing spaces, these

can
easily be edited out by modifying the formula (once you get that far).

Give it a go and if you'ld like more help, just post back.

Cheers
JulieD

julied at hctsReMoVeThIs dot net dot au


"zomex" wrote:

eg. "mick jagger bush" "muhammad ali clay" "ayesha bin batool"
suppose that these r the names and i want formula that would be

generic to
all, such that it gets "jagger" "ali" and "bin"




Ron Rosenfeld

help needed
 
On Tue, 3 Jan 2006 21:19:02 -0800, "zomex"
wrote:

eg. "mick jagger bush" "muhammad ali clay" "ayesha bin batool"
suppose that these r the names and i want formula that would be generic to
all, such that it gets "jagger" "ali" and "bin"



=LEFT(REPLACE(A1,1,FIND(" ",A1),""),FIND(" ",REPLACE(A1,1,FIND(" ",A1),""))-1)

Will find the first word after the first space.

If there may be multiple spaces within the string, then replace all A1 with
TRIM(A1)

On the other hand, a little more complex, imagine that you may have name
strings with 2, 3, or more names.

You might want to extract the first name, last name, and all of the middle
names separately. You also might want to be able to strip off Titles and such
(e.g. Mr., Ms., Jr, III, Sr.)

If this is a possibility, then regular expressions would be a more powerful
tool to use. You can look at that by installing Longre's free morefunc.xll
add-in from http://xcell05.free.fr

First Name: =REGEX.MID(TRIM(A1),"\w+")
Last Name: =REGEX.MID(TRIM(A1),"\w+$")
Middle Names: =REGEX.MID(TRIM(A1),"(?<=\s)(\w+\s)+")

Note that the formula for Middle Names will return a blank if there are only
two names (i.e. no middle name).


--ron


All times are GMT +1. The time now is 06:33 PM.

Powered by vBulletin® Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
ExcelBanter.com