Extract text of the form xxxxxxxxxx@txt.att.net from a column where spacing is all over the place

Willowdale

New Member
Joined
May 28, 2017
Messages
14
i have a column of data where in many cases, there is an sms shortcut of the form xxxxxxxxxx@txt.att.net.
in this column, it might be the only thing , or it might be appended to other text.

I need a formula to : locate all contiguous characters on either side of the @, and extract that value to another column.
the column may look like:

Fred eats apples for breakfast, rev/col 9999999999@tmomail.net Do not reopen.

or

xmannn see 876543 9999999999@txt.att.net

and I would want the blue text copied and posted in, say some adjacent column.

I looked at extraction forumulae, but I couldn't seem to locate this specific case, esp considering the irregularity of the character spacing.

Thanks listers. Greatly appreciate it. My job requires a lot more excel than it used to.
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.

mrshl9898

Well-known Member
Joined
Feb 6, 2012
Messages
1,778
are there always 9 digits in front of the @ and a .net address?

=LEFT(MID(A1,FIND("@",A1)-10,100),FIND(".net",MID(A1,FIND("@",A1)-10,100))+3)
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
36,978
Office Version
  1. 2016
Platform
  1. Windows
If there are not always 9 digits (that is it could be any length of text) and if the email address is always surrounded by spaces, then this should work...
Excel Formula:
=TRIM(RIGHT(SUBSTITUTE(LEFT(A1,FIND("@",A1)-1)," ",REPT(" ",99)),99))&MID(A1,FIND("@",A1),FIND(" ",A1&" ",FIND("@",A1))-FIND("@",A1))
 

Saurabhj

Active Member
Joined
Jun 6, 2020
Messages
414
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
Hi,

The code is big, and there may be some other formula to extract. But check below:

Excel Formula:
=MID(B2,FIND("*",SUBSTITUTE(MID(B2,1,FIND("@",B2))," ","*",LEN(MID(B2,1,FIND("@",B2)))-LEN(SUBSTITUTE(MID(B2,1,FIND("@",B2))," ",""))),1)+1,FIND("@",B2)-1-FIND("*",SUBSTITUTE(MID(B2,1,FIND("@",B2))," ","*",LEN(MID(B2,1,FIND("@",B2)))-LEN(SUBSTITUTE(MID(B2,1,FIND("@",B2))," ",""))),1))&MID(B2,FIND("@",B2),IFERROR(FIND(" ",B2,FIND("@",B2)),LEN(B2)+1)-FIND("@",B2))
 

Willowdale

New Member
Joined
May 28, 2017
Messages
14

ADVERTISEMENT

Wow. I never would have got that. Not w my skill level. Thanks fellas, I'll post the solution flag as soon as I can test it.
Seriously, thank you.
 

Willowdale

New Member
Joined
May 28, 2017
Messages
14
The data I want to extract is in column c, and i have created column d as the target column. Will that affect the above?
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
36,978
Office Version
  1. 2016
Platform
  1. Windows
For the formula I posted in Message #3...
Excel Formula:
=TRIM(RIGHT(SUBSTITUTE(LEFT(C1,FIND("@",C1)-1)," ",REPT(" ",99)),99))&MID(C1,FIND("@",C1),FIND(" ",C1&" ",FIND("@",C1))-FIND("@",C1))
 
Solution

Willowdale

New Member
Joined
May 28, 2017
Messages
14
Rick, thanks very much sir. Worked like a charm. I don't know how you guys keep all that formula syntax straight in your head.
And sorry, I should have been able to hash that much out.
 

Watch MrExcel Video

Forum statistics

Threads
1,129,838
Messages
5,638,649
Members
417,040
Latest member
EC1728

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
Top