Splitting out name, title and known as name

Declamatory

Active Member
Joined
Nov 6, 2014
Messages
319
God morning folks,

I have the following table:

Job holderTitleForenameSurnameKnown As
Pickford, Mr LeightonMr LeightonPickford
Baines-Gueye, Mr RichardMr RichardBaines-Gueye
Digne, Mrs NgoloMrs NgoloDigne
Southgate, Miss Nicola (Nikki)Miss Nicola (Nikki)Southgate(Nikki)
Schneiderlin, Doctor MorganDoctor MorganSchneiderlin
Keane, Mrs Gemma Louise (Gemma)Mrs Gemma Louise (Gemma)KeaneLouise (Gemma)
***Vacant***
Claus, Mrs JoanneMrs JoanneClaus
Claus, Mrs JoanneMrs JoanneClaus
Datix-Pickford, Mr JordanMr JordanDatix-Pickford
Datix-Mina, Mr BernardMr BernardDatix-Mina
Richarlison, Mr RichardMr RichardRicharlison
Coleman, Dr James SeamusDr James SeamusColeman


<colgroup><col><col><col><col><col></colgroup><tbody>
</tbody>

<colgroup><col><col><col><col><col></colgroup><tbody>
</tbody>

The columns split out the data from column A.

Formula in B2= =IFERROR(MID(A2,SEARCH(" ",A2,1)+1,SEARCH(" ",A2,SEARCH(" ",A2,1)+1)-SEARCH(" ",A2,1)),"")

Formula in C2= =IFERROR(RIGHT(A2,LEN(A2)-SEARCH(" ",A2,SEARCH(" ",A2,1)+1)),"")

Formula in D2= =IFERROR(LEFT(A2,SEARCH(" ",A2,1)-2),"")

Formula in E2 = =IFERROR(RIGHT(A2,LEN(A2)-SEARCH(" ",A2,SEARCH(" ",A2,SEARCH(" ",A2,1)+1)+1)),"")

Is there a way I can:


  1. remove the ‘known as’ name and parentheses from the forename column, without using MID in the formula
  2. remove the parentheses in the ‘known as’ column leaving just the known as name?

Thanks and kind regards,
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
The answer to question 1:
=IFERROR(LEFT(A2,FIND("(",A2,1)-2),"")
Note that with this formula I assume that there is no text after the 'known as' name.

The answer to question 2:
=IFERROR(SUBSTITUTE(SUBSTITUTE(E5,"(",""),")",""))

You'd want to replace the cell references with the formulas you already have.
 
Last edited:
Upvote 0
Thanks for the reply Tim.

=IFERROR(SUBSTITUTE(SUBSTITUTE(E5,"(",""),")","")) works for Row 5 but for row 7 I get a result of Louise Gemma when her known name is just "Gemma".

Thanks
 
Upvote 0
=IFERROR(SUBSTITUTE(RIGHT(E5,LEN(E5)-FIND("(",E5)),")",""),"")

Tested and works, good luck!
 
Upvote 0

Forum statistics

Threads
1,213,513
Messages
6,114,072
Members
448,546
Latest member
KH Consulting

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