Comma-separated values separated into their own (new) rows?

squidmark

Board Regular
Joined
Aug 1, 2007
Messages
105
Hi Everyone, and thanks for anyone who is able to help with this.

I have a 300-line worksheet. Column A contains a text string. Column D contains Zip Codes. It could be just one zip code, or it could be 15 zip codes. Column E is similar to D, but has textstring_zipcode.

Example:

CA_DEL NORTE.............<col b>.....<col c>.....95531,95532.....................................Crescent City_95531,Northcrest_95531,Crescent City_95532
CA_CONTRA_COSTA........<col b>.....<col c>....94801,94802,94803,94804,94805........Richmond_94801,Richmond_94802,Richmond_94803,Richmond_94804,Richmond_94805

Note that, as in the 1st row, there could be more values in column E than D.

I need to format this so, for example, CA_DEL Norte is in cell A6, Crescent City_95531 is in E6, Northcrest_95531 is in E7 and Crescent City_95532 is in E8. So rows 7 and 8 would have to get inserted, pushing down the other column A values to accommodate for the new rows. The number of rows I'd need to insert is 'n minus 1' of the unique values in that row's column E.

Should look something like this:
CA_DEL NORTE.............<col b>.......<col c>....95531..............................................Crescent City_95531
...................................<col b>.......<col c>....95531..............................................Northcrest_95531
...................................<col b>.......<col c>....95532..............................................Crescent City_95532
CA_CONTRA_COSTA.......<col b>.......<col c>....94801..............................................Richmond_94801
....................................<col b>.......<col c>....94802..............................................Richmond_94802
. . . etc.

(sorry about using the dots to facilitate formatting. I'll figure out the right way to format one of these days)

So, while the original file has some 300 rows, the completed one would likely have a couple thousand.

I need to do this same thing for the zip codes, but I'm content with doing this for column E, and then just taking the last five characters from column E and populating that into column D.

How can I do this?

Thank You.
 
Last edited:

Some videos you may like

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.

veyselemre

Board Regular
Joined
Mar 16, 2006
Messages
55
Lists to the other page.
Code:
Sub test()    With CreateObject("Scripting.Dictionary")
        Set s1 = Sheets("Sayfa1")
        Set s2 = Sheets("Sayfa2")
        s2.Cells.ClearContents
        sat = 6
        For i = 1 To s1.Cells(Rows.Count, 1).End(3).Row
            first = True
            For Each bl In Split(s1.Cells(i, 5).Value, ",")
                If Not .exists(bl) Then
                    .Item(bl) = Null
                    zip = Right(bl, 5)
                    If first Then
                        s2.Cells(sat, 1).Value = s1.Cells(i, 1).Value
                        first = False
                    End If
                    s2.Cells(sat, 4).Value = zip
                    s2.Cells(sat, 5).Value = bl
                    sat = sat + 1
                End If
            Next bl
            .RemoveAll
        Next i
    End With
    s2.Select
End Sub
https://yadi.sk/i/NTIME0zANwP0Xg
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
11,166
Office Version
2007
Platform
Windows
Try this

Code:
Sub separated_values()
    Dim i As Long, j As Long, zips As Variant
    Application.ScreenUpdating = False
    For i = Cells(Rows.Count, "A").End(xlUp).Row To 6 Step -1
        zips = Split(Cells(i, "E").Value, ",")
        For j = 0 To UBound(zips)
            If j > 0 Then Rows(i + j).Insert Shift:=xlDown
            Range("D" & i + j & ":E" & i + j).Value = Array(Right(zips(j), 5), zips(j))
        Next
    Next
End Sub
 

Watch MrExcel Video

Forum statistics

Threads
1,095,671
Messages
5,445,888
Members
405,367
Latest member
Tony_Y

This Week's Hot Topics

Top