Creating a new table based on the number of groupings in a row

RRaven

New Member
Joined
Nov 23, 2015
Messages
2
Hi everyone,

I have an Excel 2007 Spreadsheet which takes a data-set and groups the results into column ranges:

[TABLE="class: grid, width: 500, align: center"]
<tbody>[TR]
[TD="align: center"]ID[/TD]
[TD="align: center"]1-9[/TD]
[TD="align: center"]10-19[/TD]
[TD="align: center"]20-29[/TD]
[TD="align: center"]30-39[/TD]
[TD="align: center"]40-49[/TD]
[TD="align: center"]50-59[/TD]
[/TR]
[TR]
[TD="align: center"]001[/TD]
[TD="align: center"]2, 8[/TD]
[TD="align: center"]13, 16[/TD]
[TD="align: center"]22, 29[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[/TR]
[TR]
[TD="align: center"]002[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]41, 44, 48[/TD]
[TD="align: center"]52, 56, 58[/TD]
[/TR]
[TR]
[TD="align: center"]003[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]11, 12[/TD]
[TD="align: center"]23, 26[/TD]
[TD="align: center"]33, 38[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[/TR]
[TR]
[TD="align: center"]004[/TD]
[TD="align: center"]1[/TD]
[TD="align: center"]11[/TD]
[TD="align: center"]24[/TD]
[TD="align: center"]34[/TD]
[TD="align: center"]45[/TD]
[TD="align: center"]58[/TD]
[/TR]
[TR]
[TD="align: center"]005[/TD]
[TD="align: center"]2[/TD]
[TD="align: center"]13[/TD]
[TD="align: center"]22[/TD]
[TD="align: center"]34[/TD]
[TD="align: center"]42, 38[/TD]
[TD="align: center"]N/A[/TD]
[/TR]
[TR]
[TD="align: center"]006[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]33, 36[/TD]
[TD="align: center"]42, 47[/TD]
[TD="align: center"]52, 57[/TD]
[/TR]
[TR]
[TD="align: center"]007[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]12, 15[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]51, 53, 56, 58[/TD]
[/TR]
[TR]
[TD="align: center"]008[/TD]
[TD="align: center"]1, 7[/TD]
[TD="align: center"]11, 13[/TD]
[TD="align: center"]23, 29[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[/TR]
[TR]
[TD="align: center"]009[/TD]
[TD="align: center"]4[/TD]
[TD="align: center"]14[/TD]
[TD="align: center"]27[/TD]
[TD="align: center"]33[/TD]
[TD="align: center"]47[/TD]
[TD="align: center"]59[/TD]
[/TR]
[TR]
[TD="align: center"]010[/TD]
[TD="align: center"]1, 3, 9[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]52, 53, 59[/TD]
[/TR]
</tbody>[/TABLE]

My question is - How do I take the row data and populate new tables based on how many groups of numbers appear in the row (excluding the ID column.) For example, the 2 group table would become:

[TABLE="class: grid, width: 500, align: center"]
<tbody>[TR]
[TD="align: center"]ID[/TD]
[TD="align: center"]1-9[/TD]
[TD="align: center"]10-19[/TD]
[TD="align: center"]20-29[/TD]
[TD="align: center"]30-39[/TD]
[TD="align: center"]40-49[/TD]
[TD="align: center"]50-59[/TD]
[/TR]
[TR]
[TD="align: center"]002[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]41, 44, 48[/TD]
[TD="align: center"]52, 56, 58[/TD]
[/TR]
[TR]
[TD="align: center"]007[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]12, 15[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]51, 53, 56, 58[/TD]
[/TR]
[TR]
[TD="align: center"]010[/TD]
[TD="align: center"]1, 3, 9[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]52, 53, 59[/TD]
[/TR]
</tbody>[/TABLE]

The 3 group table would become:

[TABLE="class: grid, width: 500, align: center"]
<tbody>[TR]
[TD="align: center"]ID[/TD]
[TD="align: center"]1-9[/TD]
[TD="align: center"]10-19[/TD]
[TD="align: center"]20-29[/TD]
[TD="align: center"]30-39[/TD]
[TD="align: center"]40-49[/TD]
[TD="align: center"]50-59[/TD]
[/TR]
[TR]
[TD="align: center"]001[/TD]
[TD="align: center"]2, 8[/TD]
[TD="align: center"]13, 16[/TD]
[TD="align: center"]22, 29[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[/TR]
[TR]
[TD="align: center"]003[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]11, 12[/TD]
[TD="align: center"]23, 26[/TD]
[TD="align: center"]33, 38[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[/TR]
[TR]
[TD="align: center"]006[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]N/A[/TD]
[TD="align: center"]33, 36[/TD]
[TD="align: center"]42, 47[/TD]
[TD="align: center"]52, 57[/TD]
[/TR]
</tbody>[/TABLE]

I wouldn't need the remainder of numbered groupings, so a solution for a 2 and 3 group would be perfect. My table which contains this data is not in the A column and is dynamically updated using a VBA macro.

Any help or pointers would be very much appreciated.

Thank you all in advance. :)
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Try this :-
NB:- The string "N/A" is taken as "N/A" and not "#N/A".
Results start "K1"
Code:
[COLOR="Navy"]Sub[/COLOR] MG23Nov04
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, c [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] cc [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] Ac [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer[/COLOR]
'[COLOR="Green"][B]Change the starting column inline below, from "A" to Whatever !!!![/B][/COLOR]
[COLOR="Navy"]Set[/COLOR] Rng = Range(Range("A1"), Range("A" & Rows.Count).End(xlUp))
ReDim Ray2(1 To Rng.Count, 1 To 7)
ReDim Ray3(1 To Rng.Count, 1 To 7)


[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
    [COLOR="Navy"]If[/COLOR] 6 - Application.CountIf(Dn.Offset(, 1).Resize(, 6), "N/A") = 2 [COLOR="Navy"]Then[/COLOR]
        c = c + 1
        [COLOR="Navy"]For[/COLOR] Ac = 1 To 7
            Ray2(1, Ac) = Rng(1, Ac)
            Ray2(c + 1, Ac) = Dn(, Ac)
        [COLOR="Navy"]Next[/COLOR] Ac
    [COLOR="Navy"]ElseIf[/COLOR] 6 - Application.CountIf(Dn.Offset(, 1).Resize(, 6), "N/A") = 3 [COLOR="Navy"]Then[/COLOR]
           cc = cc + 1
        [COLOR="Navy"]For[/COLOR] Ac = 1 To 7
            Ray3(1, Ac) = Rng(1, Ac)
            Ray3(cc + 1, Ac) = Dn(, Ac)
        [COLOR="Navy"]Next[/COLOR] Ac
    [COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]Next[/COLOR] Dn
[COLOR="Navy"]With[/COLOR] Range("K1").Resize(c + 1, 7)
    .Value = Ray2
    .Borders.Weight = 2
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]With[/COLOR] Range("K1").Offset(c + 2).Resize(c + 1, 7)
    .Value = Ray3
    .Borders.Weight = 2
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]With[/COLOR]
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0
Thank you for your quick reply and solution. :) With a couple of slight tweaks I got everything working as I needed it to.
Thanks again.
 
Upvote 0

Forum statistics

Threads
1,223,247
Messages
6,171,004
Members
452,374
Latest member
keccles

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