LEFT() for each rows in a single cell?

jeffcoleky

Active Member
Joined
May 24, 2011
Messages
274
The following data is in a SINGLE cell. I'm trying to get the phone number from each line and output it as just a list of phone numbers in a single cell.

FROM THIS:
Code:
[TABLE="width: 357"]
<tbody>[TR]
[TD](734) 435-8519 < Sent TXT 14/25/09 @ 08:54
(734) 917-1416 < Sent TXT 14/25/09 @ 08:54
(734) 742-6437 < Sent TXT 14/25/09 @ 08:54
(734) 435-8511 < Sent TXT 14/25/09 @ 08:54-Bob's number
(734) 360-5106 < Sent TXT 14/25/09 @ 08:54
(734) 880-3306 < Sent TXT 14/25/09 @ 08:54
(734) 384-0869 < Sent TXT 14/25/09 @ 08:54-Not working
(734) 494-5151 < Sent TXT 14/25/09 @ 08:54
(435) 851-8519 < Sent TXT 14/25/09 @ 08:54-Yelled at me
(734) 408-2349 < Sent TXT 14/25/09 @ 08:54
(734) 224-7269 < Sent TXT 14/25/09 @ 08:54
(734) 299-4730 < Sent TXT 14/25/09 @ 09:02
(734) 299-4703 < Sent TXT 14/25/09 @ 09:02-Not working#
(734) 291-9930 < Sent TXT 14/25/09 @ 09:02
(734) 345-8002 < Sent TXT 14/25/09 @ 09:02[/TD]
[/TR]
</tbody>[/TABLE]

TO THIS:
Code:
[TABLE="width: 357"]
<tbody>[TR]
[TD="class: xl65, width: 357"](734)  435-8519
(734) 917-1416
(734) 742-6437
(734) 435-8511
(734) 360-5106
(734) 880-3306
(734) 384-0869
(734) 494-5151
(435) 851-8519
(734) 408-2349
(734) 224-7269
(734) 299-4730
(734) 299-4703
(734) 291-9930
(734) 345-8002[/TD]
[/TR]
[TR]
[TD="class: xl65, width: 357"][/TD]
[/TR]
</tbody>[/TABLE]

I'm not sure how to use LEFT() for this type of situation. The text located to the right of the numbers could be ANYTHING. But the phone number format is always the same.

Any ideas?
 
Last edited:
So no easy formula method in excel either? If not, thanks everyone for making it work this way! it saves me hours.

This may be an option to extract a phone in a cell with a formula.
Copy the formula to the right to extract one phone at a time.

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:608.32px;" /><col style="width:146.38px;" /><col style="width:154.93px;" /><col style="width:160.63px;" /><col style="width:166.34px;" /><col style="width:151.13px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td></tr><tr style="height:93px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >(734) 435-8519 < Sent TXT 14/25/09 @ 08:54<br />(734) 917-1416 < Sent TXT 14/25/09 @ 08:55<br />(734) 742-6437 < Sent TXT 14/25/09 @ 08:56<br />(734) 435-8511 < Sent TXT 14/25/09 @ 08:57-Bob's number<br />(734) 360-5106 < Sent TXT 14/25/09 @ 08:58</td><td >(734) 435-8519</td><td >(734) 917-1416</td><td >(734) 742-6437</td><td >(734) 435-8511</td><td >(734) 360-5106</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >B2</td><td >=TRIM(MID(SUBSTITUTE(SUBSTITUTE(" " & $A2," < ",REPT(" ",250)),"(",REPT(" ",250)&"("),(250*((COLUMNS($B$1:B1)*2)-1)),250))</td></tr></table></td></tr></table>
 
Last edited:
Upvote 0

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
Hi
What about
Code:
B1=LEFT(A1,LEN(A1)-LEN(RIGHT(A1,LEN(MID(A1,FIND("<",A1),255))))-1)

Although, we could use a 2-step process. If there was a way to turn the original data into individual rows first, then use the formula and back into a single cell? (two formulas using two Columns of cells, not using text to columns)
 
Last edited:
Upvote 0
In Google sheets this works.

=REGEXREPLACE(A1&CHAR(10),"<.*\n",CHAR(10))
 
Upvote 0
If you did want to stick with Excel, there is a manual process you could follow. It takes a bit for me to write out but is a fairly quick process to do.

1. Copy the date to a new column
2. Select the column by clicking its heading label
3. Invoke Find/Replace (Ctrl+H is one way)
4. In the Find what: box type a space followed by a < sign followed by an * then press Ctrl+J (you won't see the Ctrl+J but that is for the line-feed character)
5. Put your cursor in the Replace with: box and do another Ctrl+J
6. In Options>> make sure 'Match entire cell contents' is not checked
7. Replace All then OK
8. With the column still selected and the Find/Replace still open put your cursor immediately after the * and press Delete (to remove the invisible line-feed character)
9. Put your cursor in the Replace with: box and press delete again to remove that line-feed character
10. Replace All, OK
 
Last edited:
Upvote 0
Also possible with worksheet functions in Excel if you have the TEXTJOIN function in your version.
Here I have assumed that all your phone numbers are in identical format (since that is what your sample was) but if not and you wanted to pursue the Excel option, it could be adapted for varying formats.
This is an array formula so should be entered without the {} but confirmed with Ctrl+Shift+Enter, not just Enter. If confirmed correctly, Excel will insert the {}. The formula can then be copied down.

 
Upvote 0
Thank you as well!

If you did want to stick with Excel, there is a manual process you could follow. It takes a bit for me to write out but is a fairly quick process to do.

1. Copy the date to a new column
2. Select the column by clicking its heading label
3. Invoke Find/Replace (Ctrl+H is one way)
4. In the Find what: box type a space followed by a < sign followed by an * then press Ctrl+J (you won't see the Ctrl+J but that is for the line-feed character)
5. Put your cursor in the Replace with: box and do another Ctrl+J
6. In Options>> make sure 'Match entire cell contents' is not checked
7. Replace All then OK
8. With the column still selected and the Find/Replace still open put your cursor immediately after the * and press Delete (to remove the invisible line-feed character)
9. Put your cursor in the Replace with: box and press delete again to remove that line-feed character
10. Replace All, OK
 
Upvote 0
I don't know if this helps you, but if you have the "CONCAT" function (Office 365 of Excel 2019), you could put the initial data in alternate rows starting at A1 and then use a helper column in B1 "=IF(ISBLANK(A1),"=char(10)",LEFT(A1,14))", copied down. Then use the formula "=CONCAT(B1:B31)" and format the cell to wrap.
 
Upvote 0
... if you have the "CONCAT" function ... you could put the initial data in alternate rows starting at A1 and then use a helper column
If the CONCAT function is available, then so is TEXTJOIN and the result can be obtained without any rearrangement of the original data or helper cells as per post 16. :)
 
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,871
Members
452,363
Latest member
merico17

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