selectively combining rows of data in excel

winpod

New Member
Joined
Sep 11, 2011
Messages
2
We have a need to selectively combine rows of data, merging groups of rows into a single row in order to facilitate a big mail merge into some special labels. I've searched around here but can't find a solution that matches.

These are examples of data input and output that we need to accomplish.

<table border="0" cellpadding="0" cellspacing="0" width="320"><colgroup><col style="width:48pt" span="5" width="64"> </colgroup><tbody><tr style="height:15.0pt" height="20"> <td style="height:15.0pt;width:48pt" height="20" width="64">Name1</td> <td style="width:48pt" width="64">Data-a-1</td> <td style="width:48pt" width="64">Data-b-1</td> <td style="width:48pt" width="64">Data-c-1</td> <td style="width:48pt" width="64">Data-d-1</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name1</td> <td>Data-a-2</td> <td>Data-b-2</td> <td>Data-c-2</td> <td>Data-d-2</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name2</td> <td>Data-a-3</td> <td>Data-b-3</td> <td>Data-c-3</td> <td>Data-d-3</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name2</td> <td>Data-a-4</td> <td>Data-b-4</td> <td>Data-c-4</td> <td>Data-d-4</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name3</td> <td>Data-a-5</td> <td>Data-b-5</td> <td>Data-c-5</td> <td>Data-d-5</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name4</td> <td>Data-a-6</td> <td>Data-b-6</td> <td>Data-c-6</td> <td>Data-d-6</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name4</td> <td>Data-a-7</td> <td>Data-b-7</td> <td>Data-c-7</td> <td>Data-d-7</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name4</td> <td>Data-a-8</td> <td>Data-b-8</td> <td>Data-c-8</td> <td>Data-d-8</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name5</td> <td>Data-a-9</td> <td>Data-b-9</td> <td>Data-c-9</td> <td>Data-d-9</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name5</td> <td>Data-a-10</td> <td>Data-b-10</td> <td>Data-c-10</td> <td>Data-d-10</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name6</td> <td>Data-a-11</td> <td>Data-b-11</td> <td>Data-c-11</td> <td>Data-d-11</td> </tr> </tbody></table>
<table border="0" cellpadding="0" cellspacing="0" width="960"><colgroup><col style="width:48pt" span="15" width="64"> </colgroup><tbody><tr style="height:15.0pt" height="20"> <td style="height:15.0pt;width:48pt" height="20" width="64">Name1</td> <td style="width:48pt" width="64">Data-a-1</td> <td style="width:48pt" width="64">Data-b-1</td> <td style="width:48pt" width="64">Data-c-1</td> <td style="width:48pt" width="64">Data-d-1</td> <td style="width:48pt" width="64">Name1</td> <td style="width:48pt" width="64">Data-a-2</td> <td style="width:48pt" width="64">Data-b-2</td> <td style="width:48pt" width="64">Data-c-2</td> <td style="width:48pt" width="64">Data-d-2</td> <td style="width:48pt" width="64">
</td> <td style="width:48pt" width="64">
</td> <td style="width:48pt" width="64">
</td> <td style="width:48pt" width="64">
</td> <td style="width:48pt" width="64">
</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name2</td> <td>Data-a-3</td> <td>Data-b-3</td> <td>Data-c-3</td> <td>Data-d-3</td> <td>Name2</td> <td>Data-a-4</td> <td>Data-b-4</td> <td>Data-c-4</td> <td>Data-d-4</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name3</td> <td>Data-a-5</td> <td>Data-b-5</td> <td>Data-c-5</td> <td>Data-d-5</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name4</td> <td>Data-a-6</td> <td>Data-b-6</td> <td>Data-c-6</td> <td>Data-d-6</td> <td>Name4</td> <td>Data-a-7</td> <td>Data-b-7</td> <td>Data-c-7</td> <td>Data-d-7</td> <td>Name4</td> <td>Data-a-8</td> <td>Data-b-8</td> <td>Data-c-8</td> <td>Data-d-8</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name5</td> <td>Data-a-9</td> <td>Data-b-9</td> <td>Data-c-9</td> <td>Data-d-9</td> <td>Name5</td> <td>Data-a-10</td> <td>Data-b-10</td> <td>Data-c-10</td> <td colspan="2" style="mso-ignore:colspan">Data-d-10</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> </tr> <tr style="height:15.0pt" height="20"> <td style="height:15.0pt" height="20">Name6</td> <td>Data-a-11</td> <td>Data-b-11</td> <td>Data-c-11</td> <td colspan="2" style="mso-ignore:colspan">Data-d-11</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> </tr> </tbody></table>
There are also cases where we can skip the re-statement of "Name" in the rows, but this can be done separately as well.

Can anyone point me in the right direction? Spent many years programming ... many years ago. No experience with VB, so this will be my starting point. I appreciate any suggestions.
 

Excel Facts

Format cells as date
Select range and press Ctrl+Shift+3 to format cells as date. (Shift 3 is the # sign which sort of looks like a small calendar).
Try this:-
Results start:- Sheet2. "A1"
Code:
[COLOR=navy]Sub[/COLOR] MG11Sep17
[COLOR=navy]Dim[/COLOR] Rng         [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Dim[/COLOR] Dn          [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Dim[/COLOR] n           [COLOR=navy]As[/COLOR] [COLOR=navy]Long[/COLOR]
[COLOR=navy]Dim[/COLOR] Temp        [COLOR=navy]As[/COLOR] [COLOR=navy]Long[/COLOR]
[COLOR=navy]Dim[/COLOR] Q           [COLOR=navy]As[/COLOR] Variant
[COLOR=navy]Dim[/COLOR] K           [COLOR=navy]As[/COLOR] Variant
[COLOR=navy]Dim[/COLOR] c           [COLOR=navy]As[/COLOR] [COLOR=navy]Long[/COLOR]
[COLOR=navy]Set[/COLOR] Rng = Range(Range("A1"), Range("A" & Rows.Count).End(xlUp))
    [COLOR=navy]With[/COLOR] CreateObject("scripting.dictionary")
        .CompareMode = vbTextCompare
[COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] Dn [COLOR=navy]In[/COLOR] Rng
    [COLOR=navy]If[/COLOR] Not .Exists(Dn.Value) [COLOR=navy]Then[/COLOR]
        ReDim Ray(1 To 5)
            [COLOR=navy]For[/COLOR] n = 1 To 5
                Ray(n) = Dn(, n)
            [COLOR=navy]Next[/COLOR] n
        .Add Dn.Value, Array(Ray, 5)
    [COLOR=navy]Else[/COLOR]
        Q = .Item(Dn.Value)
        Temp = Q(1)
        Q(1) = Q(1) + 5
            ReDim Preserve Ray(1 To Q(1))
                [COLOR=navy]For[/COLOR] n = 1 To 5
                    Ray(n + Temp) = Dn(, n)
                [COLOR=navy]Next[/COLOR] n
        Q(0) = Ray
        .Item(Dn.Value) = Q
    [COLOR=navy]End[/COLOR] If
[COLOR=navy]Next[/COLOR]
[COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] K [COLOR=navy]In[/COLOR] .Keys
    c = c + 1
    [COLOR=navy]For[/COLOR] n = 1 To .Item(K)(1)
        Sheets("Sheet2").Cells(c, n) = .Item(K)(0)(n)
    [COLOR=navy]Next[/COLOR] n
[COLOR=navy]Next[/COLOR] K
[COLOR=navy]End[/COLOR] With
[COLOR=navy]End[/COLOR] [COLOR=navy]Sub[/COLOR]
Regards Mick
 
Upvote 0
Out of interest, if you want the name column to appear only once, try
this.
Code:
[COLOR="Navy"]Sub[/COLOR] MG12Sep30
[COLOR="Navy"]Dim[/COLOR] Rng         [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] Dn          [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] n           [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Dim[/COLOR] Temp        [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Dim[/COLOR] Q           [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]Dim[/COLOR] K           [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]Dim[/COLOR] c           [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Set[/COLOR] Rng = Range(Range("A1"), Range("A" & Rows.Count).End(xlUp))
    [COLOR="Navy"]With[/COLOR] CreateObject("scripting.dictionary")
        .CompareMode = vbTextCompare
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
    [COLOR="Navy"]If[/COLOR] Not .Exists(Dn.Value) [COLOR="Navy"]Then[/COLOR]
        ReDim Ray(1 To 5)
            [COLOR="Navy"]For[/COLOR] n = 1 To 5
                Ray(n) = Dn(, n)
            [COLOR="Navy"]Next[/COLOR] n
        .Add Dn.Value, Array(Ray, 5)
    [COLOR="Navy"]Else[/COLOR]
        Q = .Item(Dn.Value)
        Temp = Q(1)
        Q(1) = Q(1) + 5
            ReDim Preserve Ray(1 To Q(1))
                [COLOR="Navy"]For[/COLOR] n = 1 To 5
                    Ray(n + Temp) = Dn(, n)
                [COLOR="Navy"]Next[/COLOR] n
        Q(0) = Ray
        .Item(Dn.Value) = Q
    [COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]Next[/COLOR]
[COLOR="Navy"]Dim[/COLOR] Ac, p
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] K [COLOR="Navy"]In[/COLOR] .Keys
   p = 0
    c = c + 1
     Ac = 0
    [COLOR="Navy"]For[/COLOR] n = 1 To .Item(K)(1)
        p = p + IIf(n > 1, 1, 0)
        [COLOR="Navy"]If[/COLOR] p = 0 Or Not p Mod 5 = 0 [COLOR="Navy"]Then[/COLOR]
        Ac = Ac + 1
        Sheets("Sheet2").Cells(c, Ac) = .Item(K)(0)(n)
        [COLOR="Navy"]End[/COLOR] If
    
    [COLOR="Navy"]Next[/COLOR] n
[COLOR="Navy"]Next[/COLOR] K
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0

Forum statistics

Threads
1,224,521
Messages
6,179,280
Members
452,902
Latest member
Knuddeluff

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