Retrieve First and Last Name from Email - Formula help

nt_beans

New Member
Joined
Nov 10, 2015
Messages
26
Hi,
I have a column A which contains email ids of all our users. Basically I want to add two additional columns ( First and Last name) which can be retrieved from those email:

Current
EmailTelExchange
kate.nash@theice.com+13230323032CBOT
amar.prem@theice.com+12324434344CBOT
henry.graves@theice.com+14323434434CBOT

<tbody>
</tbody>

Desired Output
EmailFirst NameLast NameTelExchange
kate.nash@theice.comKateNash+13230323032CBOT
amar.prem@theice.comAmarPrem+12324434344CBOT
henry.graves@theice.comHenryGraves+14323434434CBOT

<tbody>
</tbody>

Thanks in advance for your help
 

Excel Facts

Return population for a City
If you have a list of cities in A2:A100, use Data, Geography. Then =A2.Population and copy down.
Hi,

One way :-

First Name =LEFT(A1,FIND(".",A1)-1)
Las Name =MID(A1,FIND(".",A1)+1,FIND("@",A1)-FIND(".",A1)-1)
 
Upvote 0
nt_beans,

Here is a macro solution for you to consider that uses two arrays in memory.

The original raw data in range A1:C4, will be replaced with the results in range A1:E4.

Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).

1. Copy the below code
2. Open your NEW workbook
3. Press the keys ALT + F11 to open the Visual Basic Editor
4. Press the keys ALT + I to activate the Insert menu
5. Press M to insert a Standard Module
6. Where the cursor is flashing, paste the code
7. Press the keys ALT + Q to exit the Editor, and return to Excel
8. To run the macro from Excel press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.

Code:
Sub ReorganizeData()
' hiker95, 12/11/2017, ME1034899
Dim a As Variant, r As Long, c As Long
Dim o As Variant, j As Long
Dim s1, i As Long, s2, ii As Long
Application.ScreenUpdating = False
a = Cells(1, 1).CurrentRegion
ReDim o(1 To UBound(a, 1), 1 To 5)
j = j + 1: o(j, 1) = a(1, 1): o(j, 2) = "First Name": o(j, 3) = "Last Name"
o(j, 4) = a(1, 2): o(j, 5) = a(1, 3)
For r = 2 To UBound(a, 1)
  For c = 1 To UBound(a, 2)
    If c = 1 Then
      j = j + 1: o(j, 1) = a(r, c)
      s1 = Split(a(r, c), "@")
      s2 = Split(s1(0), ".")
      o(j, 2) = WorksheetFunction.Proper(s2(0))
      o(j, 3) = WorksheetFunction.Proper(s2(1))
    ElseIf c = 2 Then
      o(j, 4) = a(r, c)
    ElseIf c = 3 Then
      o(j, 5) = a(r, c)
    End If
  Next c
Next r
Cells(1, 1).CurrentRegion.ClearContents
Cells(1, 1).Resize(UBound(o, 1), UBound(o, 2)) = o
Columns.AutoFit
Application.ScreenUpdating = True
End Sub

Before you use the macro with Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension .xlsm, and, answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.

Then run the ReorganizeData macro.
 
Upvote 0
nt_beans,

Here is a macro solution for you to consider that uses two arrays in memory.

The original raw data in range A1:C4, will be replaced with the results in range A1:E4.

Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).

1. Copy the below code
2. Open your NEW workbook
3. Press the keys ALT + F11 to open the Visual Basic Editor
4. Press the keys ALT + I to activate the Insert menu
5. Press M to insert a Standard Module
6. Where the cursor is flashing, paste the code
7. Press the keys ALT + Q to exit the Editor, and return to Excel
8. To run the macro from Excel press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.

Code:
Sub ReorganizeData()
' hiker95, 12/11/2017, ME1034899
Dim a As Variant, r As Long, c As Long
Dim o As Variant, j As Long
Dim s1, i As Long, s2, ii As Long
Application.ScreenUpdating = False
a = Cells(1, 1).CurrentRegion
ReDim o(1 To UBound(a, 1), 1 To 5)
j = j + 1: o(j, 1) = a(1, 1): o(j, 2) = "First Name": o(j, 3) = "Last Name"
o(j, 4) = a(1, 2): o(j, 5) = a(1, 3)
For r = 2 To UBound(a, 1)
  For c = 1 To UBound(a, 2)
    If c = 1 Then
      j = j + 1: o(j, 1) = a(r, c)
      s1 = Split(a(r, c), "@")
      s2 = Split(s1(0), ".")
      o(j, 2) = WorksheetFunction.Proper(s2(0))
      o(j, 3) = WorksheetFunction.Proper(s2(1))
    ElseIf c = 2 Then
      o(j, 4) = a(r, c)
    ElseIf c = 3 Then
      o(j, 5) = a(r, c)
    End If
  Next c
Next r
Cells(1, 1).CurrentRegion.ClearContents
Cells(1, 1).Resize(UBound(o, 1), UBound(o, 2)) = o
Columns.AutoFit
Application.ScreenUpdating = True
End Sub

Before you use the macro with Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension .xlsm, and, answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.

Then run the ReorganizeData macro.
This works like a charm..thanks very much
 
Upvote 0
Formula method seems so much simpler than a macro...

Original email address in A2
B2: =LEFT(A2,FIND(".",A2)-1)
C2: =REPLACE(LEFT(A2,FIND("@",A2)-1),1,LEN(B2)+1,"")
 
Upvote 0

Forum statistics

Threads
1,213,550
Messages
6,114,265
Members
448,558
Latest member
aivin

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