Limit text to column to using only 2 columns

debbi

New Member
Joined
Apr 28, 2011
Messages
8
I have a list of names that contain one to as many as three or four ",". I need these to be in two columns and include this in a macro. I would like to find the last ","and then text to column. Below are some examples of what my information can look like:

<TABLE style="WIDTH: 132pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=176><COLGROUP><COL style="WIDTH: 132pt; mso-width-source: userset; mso-width-alt: 6436" width=176><TBODY><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; WIDTH: 132pt; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" class=xl66 height=20 width=176>Smith, Jones, , Jane</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" class=xl66 height=20>Doe, Jane I</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" class=xl66 height=20>Johns, Judy</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" class=xl66 height=20>Davis, Jr., Richard</TD></TR></TBODY></TABLE>
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
debbi,

Welcome to the MrExcel forum.


What version of Excel are you using?

You will generally get much more help (and faster) in this forum if you can post your small samples (what you have and what you expect to achieve) directly in the forum.

To attach screenshots, see below in my Signature block: Post a screen shot with one of these:

If you are not able to give us screenshots, see below in my Signature block: You can upload your workbook to Box Net
 
Upvote 0
I hope this will work, I'm using Excel 2007 and this is an example of my data...



Excel Workbook
GHIJKLMNOPQ
4LASTFIRSTADDRESSCITYSTATEZIPPHONEPHONE2EMAILCATEGORYLEADDATE
5Smith, Jones, , JaneANY STREETANYWA99999
6Doe, Jane LANY STREETANYWA100000
7Johns, JudyANY STREETANYWA100001
8Davis, Jr., RichardANY STREETANYWA100002
Sheet1

Excel 2007
 
Upvote 0
debbi,

Can we have another screenshot, of what columns G and H should look like (before and after) per your request (please make the columns wide enough to see all the information).

We also would need examples of the raw data in column G, per as many as three or four ","
 
Last edited:
Upvote 0
<table border="0" cellpadding="0" cellspacing="0" width="574"><col style="width: 83pt;" width="110"> <col style="width: 97pt;" width="129"> <col style="width: 48pt;" width="64"> <col style="width: 59pt;" width="79"> <col style="width: 48pt;" width="64" span="3"> <tbody><tr style="height: 15pt;" height="20"> <td class="xl68" style="height: 15pt; width: 83pt;" width="110" height="20"> Column"F"
</td> <td class="xl69" style="border-left: medium none; width: 97pt;" width="129">Column"G"
</td> <td class="xl69" style="border-left: medium none; width: 48pt;" width="64">Column"H"
</td> <td valign="top">
</td><td class="xl69" style="border-left: medium none; width: 59pt;" width="79">ADDRESS</td> <td class="xl69" style="border-left: medium none; width: 48pt;" width="64">CITY</td> <td class="xl69" style="border-left: medium none; width: 48pt;" width="64">STATE</td> <td class="xl69" style="border-left: medium none; width: 48pt;" width="64">ZIP</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl68" style="height: 15pt; border-top: medium none;" height="20">before with 3 ","</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">Smith, Jones, , Jane</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">
</td> <td valign="top">
</td><td class="xl68" style="border-top: medium none; border-left: medium none;">ANY STREET</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">ANY</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">WA</td> <td class="xl68" style="border-top: medium none; border-left: medium none;" align="right">99999</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl68" style="height: 15pt; border-top: medium none;" height="20">before </td> <td class="xl68" style="border-top: medium none; border-left: medium none;">Doe, Jane L</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">
</td> <td valign="top">
</td><td class="xl68" style="border-top: medium none; border-left: medium none;">ANY STREET</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">ANY</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">WA</td> <td class="xl68" style="border-top: medium none; border-left: medium none;" align="right">100000</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl68" style="height: 15pt; border-top: medium none;" height="20">before </td> <td class="xl68" style="border-top: medium none; border-left: medium none;">Johns, Judy</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">
</td> <td valign="top">
</td><td class="xl68" style="border-top: medium none; border-left: medium none;">ANY STREET</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">ANY</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">WA</td> <td class="xl68" style="border-top: medium none; border-left: medium none;" align="right">100001</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl68" style="height: 15pt; border-top: medium none;" height="20">before with 2 ","</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">Davis, Jr., Richard</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">
</td> <td valign="top">
</td><td class="xl68" style="border-top: medium none; border-left: medium none;">ANY STREET</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">ANY</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">WA</td> <td class="xl68" style="border-top: medium none; border-left: medium none;" align="right">100002</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl68" style="height: 15pt; border-top: medium none;" height="20">
</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">
</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">
</td> <td valign="top">
</td><td class="xl68" style="border-top: medium none; border-left: medium none;">
</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">
</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">
</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">
</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl68" style="height: 15pt; border-top: medium none;" height="20">after</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">Smith, Jones, </td> <td class="xl68" style="border-top: medium none; border-left: medium none;"> Jane</td> <td valign="top">
</td><td class="xl68" style="border-top: medium none; border-left: medium none;">ANY STREET</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">ANY</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">WA</td> <td class="xl68" style="border-top: medium none; border-left: medium none;" align="right">99999</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl68" style="height: 15pt; border-top: medium none;" height="20">after</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">Doe</td> <td class="xl68" style="border-top: medium none; border-left: medium none;"> Jane L</td> <td valign="top">
</td><td class="xl68" style="border-top: medium none; border-left: medium none;">ANY STREET</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">ANY</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">WA</td> <td class="xl68" style="border-top: medium none; border-left: medium none;" align="right">100000</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl68" style="height: 15pt; border-top: medium none;" height="20">after</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">Johns</td> <td class="xl68" style="border-top: medium none; border-left: medium none;"> Judy</td> <td valign="top">
</td><td class="xl68" style="border-top: medium none; border-left: medium none;">ANY STREET</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">ANY</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">WA</td> <td class="xl68" style="border-top: medium none; border-left: medium none;" align="right">100001</td> </tr> <tr style="height: 15pt;" height="20"> <td class="xl68" style="height: 15pt; border-top: medium none;" height="20">after</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">Davis, Jr.</td> <td class="xl68" style="border-top: medium none; border-left: medium none;"> Richard</td> <td valign="top">
</td><td class="xl68" style="border-top: medium none; border-left: medium none;">ANY STREET</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">ANY</td> <td class="xl68" style="border-top: medium none; border-left: medium none;">WA</td> <td class="xl68" style="border-top: medium none; border-left: medium none;" align="right">100002</td> </tr> </tbody></table><table style="width: 574px; height: 276px;" border="0" cellpadding="0" cellspacing="0"><col style="width: 83pt;" width="110"> <col style="width: 97pt;" width="129"> <col style="width: 48pt;" width="64"> <col style="width: 59pt;" width="79"> <col style="width: 48pt;" width="64" span="3"> <tbody> <tr style="height: 15pt;" height="20"> <td style="height: 15pt;" height="20">
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td align="right">
</td> </tr> <tr style="height: 15pt;" height="20"> <td style="height: 15pt;" height="20">
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td align="right">
</td> </tr> <tr style="height: 15pt;" height="20"> <td style="height: 15pt;" height="20">
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td align="right">
</td> </tr> <tr style="height: 15pt;" height="20"> <td style="height: 15pt;" height="20">
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td align="right">
</td> </tr> <tr style="height: 15pt;" height="20"> <td style="height: 15pt;" height="20">
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> </tr> <tr style="height: 15pt;" height="20"> <td style="height: 15pt;" height="20">
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td align="right">
</td> </tr> <tr style="height: 15pt;" height="20"> <td style="height: 15pt;" height="20">
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td align="right">
</td> </tr> <tr style="height: 15pt;" height="20"> <td style="height: 15pt;" height="20">
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td align="right">
</td> </tr> <tr style="height: 15pt;" height="20"> <td style="height: 15pt;" height="20">
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td align="right">
</td> </tr> </tbody></table>
 
Upvote 0
Sorry, I'm having problems posting from a different computer and didn't want to leave this with no reply:( I can send a better reply tomorrow if this one it's helping
 
Upvote 0
I don't think Text to Columns lends itself to this task. Try this in a copy of your workbook. It assumes that each cell in the 'G' range has a value and that value contains at least one comma.

<font face=Courier New><br><br><SPAN style="color:#00007F">Sub</SPAN> Split_Names()<br>    <SPAN style="color:#00007F">Dim</SPAN> a<br>    <SPAN style="color:#00007F">Dim</SPAN> r <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN>, pos <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN><br>    <SPAN style="color:#00007F">Dim</SPAN> s <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">String</SPAN><br>    <br>    a = Range("G5:H" & Range("G" & Rows.Count).End(xlUp).Row).Value<br>    <SPAN style="color:#00007F">For</SPAN> r = 1 <SPAN style="color:#00007F">To</SPAN> <SPAN style="color:#00007F">UBound</SPAN>(a, 1)<br>        s = a(r, 1)<br>        pos = InStrRev(s, ",")<br>        a(r, 1) = Trim(Left(s, pos - 1))<br>        a(r, 2) = Trim(Right(s, Len(s) - pos))<br>    <SPAN style="color:#00007F">Next</SPAN> r<br>    Range("G5").Resize(UBound(a, 1), 2).Value = a<br><SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN><br></FONT>
 
Upvote 0

Forum statistics

Threads
1,217,123
Messages
6,134,761
Members
449,888
Latest member
webarnes99

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