Separating text when someone inputted the middle initial with the last name.

MrBurn5

New Member
Joined
Jul 4, 2016
Messages
48
Help... I've done something like this before where I had a names entered in to the same cell, but they always had spaces between the first and last or first, middle, last.

This time around I'm looking at 15,000 entries where it's a capitalized middle initial immediately followed by the capitalized last name... The only caveat is that not all cells have the middle initial. See table below for an example.

The best way to do this would be to ask it IF second character is UPPERCASE, then put the First letter in Cell C, and all the rest of the text in Cell D.

I've been struggling with this for a few hours and finally gave up. I know it should be possible but I'm getting increasingly frustrated.

Unknown 64 bit


[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]A[/COLOR]​
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]B[/COLOR]​
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]C[/COLOR]​
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]D[/COLOR]​
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]3[/COLOR]​
CombinedMiddle initiallast name
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]4[/COLOR]​
AJenkinsAJenkins
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]5[/COLOR]​
JonesJones
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]6[/COLOR]​
SJonesSJones
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]7[/COLOR]​
MWeaverMWeaver
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]8[/COLOR]​
DWatkinsDWatkins
[COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]9[/COLOR]​
WilliamsWilliams

<tbody>
</tbody>
Sheet: Sheet2

<tbody>
</tbody>
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
Hi,

This should help:


Book1
ABCD
1CombinedMiddle initiallast name
2AJenkinsAJenkins
3JonesJones
4SJonesSJones
5MWeaverMWeaver
6DWatkinsDWatkins
7WilliamsWilliams
Sheet42
Cell Formulas
RangeFormula
C2=IF(AND(CODE(MID(A2,2,1))>63,CODE(MID(A2,2,1))<91),LEFT(A2,1),"")
D2=IF(AND(CODE(MID(A2,2,1))>63,CODE(MID(A2,2,1))<91),MID(A2,2,255),A2)


Formulas copied down.
 
Upvote 0
Hi,

This should help:

Formulas copied down.

Thank you! When it comes to text problems my skills are sorely lacking. I need to be better about learning CODE and MID since I've been it used a lot for my other problems.
 
Upvote 0
Oops, made a mistake in the formula, 63 should be 64:


Book1
ABCD
1CombinedMiddle initiallast name
2AJenkinsAJenkins
3JonesJones
4SJonesSJones
5MWeaverMWeaver
6DWatkinsDWatkins
7WilliamsWilliams
Sheet42
Cell Formulas
RangeFormula
C2=IF(AND(CODE(MID(A2,2,1))>64,CODE(MID(A2,2,1))<91),LEFT(A2,1),"")
D2=IF(AND(CODE(MID(A2,2,1))>64,CODE(MID(A2,2,1))<91),MID(A2,2,255),A2)
 
Upvote 0
Thank you! When it comes to text problems my skills are sorely lacking. I need to be better about learning CODE and MID since I've been it used a lot for my other problems.

You're welcome, don't forget to change the 63 to 64. (although the formulas will still work without the change unless you have "@" as the second character:LOL:)
 
Upvote 0
Here are another (shorter) set of formulas that you can consider...

C2: =LEFT(A2,EXACT(MID(A2,2,1),UPPER(MID(A2,2,1))))

D2: =MID(A2,1+LEN(C2),LEN(A2))
 
Upvote 0

Forum statistics

Threads
1,215,357
Messages
6,124,482
Members
449,165
Latest member
ChipDude83

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