Formula or Macro to Organize a List of Data into a Table for a Dependent Dropdown List?

MorgWalker

New Member
Joined
Aug 20, 2017
Messages
2
Hi Everyone,

I'm trying to organize my data so that it can be used in a dependent dropdown list.

I can't figure out how to do this. I can't do it manually because there are 100+ rows that need to be converted. I've tried transposing it, as well as creating a pivot table, but neither option seems to work. I've googled other peoples macros in excel for similar situations, but everyone seems to have slightly different data or requirements than I do, so their code doesn't work for me.

My data is organized like this into two columns:

A1
B2
A3
F4
C5
D
A9
E7
G8
H
F9
A6
G2

<tbody>
</tbody>






















Each row has to be "flipped" so that each unique row in the first column becomes a header in a column, and all the data associated with it is listed under the header. Notice that some items such as "D" and "H" have no data associated with them, but I need them incorporated as well. Also notice that the data is not 1:1 (e.g. B,2 and G,2)

I need the data to be arranged like this:

ABCDEFGH
125748
392
6
9

<tbody>
</tbody>









Is there a formula or a macro that can help arrange the data to be this way?

If anything is unclear, please let me know.

Thank you.
 

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.
Try this or results on sheet2.
Code:
[COLOR=navy]Sub[/COLOR] MG20Aug01
[COLOR=navy]Dim[/COLOR] myArraylist [COLOR=navy]As[/COLOR] Object, Dic [COLOR=navy]As[/COLOR] Object, Q [COLOR=navy]As[/COLOR] Variant, oMax [COLOR=navy]As[/COLOR] [COLOR=navy]Long[/COLOR]
[COLOR=navy]Dim[/COLOR] Rng [COLOR=navy]As[/COLOR] Range, Dn [COLOR=navy]As[/COLOR] Range, n [COLOR=navy]As[/COLOR] [COLOR=navy]Long,[/COLOR] Rw [COLOR=navy]As[/COLOR] [COLOR=navy]Long,[/COLOR] Sp [COLOR=navy]As[/COLOR] Variant
[COLOR=navy]Set[/COLOR] Rng = Range(Range("A1"), Range("A" & Rows.Count).End(xlUp))
[COLOR=navy]Set[/COLOR] Dic = CreateObject("scripting.dictionary")
Dic.CompareMode = vbTextCompare
[COLOR=navy]Set[/COLOR] myArraylist = CreateObject("System.Collections.ArrayList")
[COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] Dn [COLOR=navy]In[/COLOR] Rng
    [COLOR=navy]If[/COLOR] Not Dic.exists(Dn.Value) [COLOR=navy]Then[/COLOR]
        Dic.Add Dn.Value, Array(Dn.Offset(, 1), 1)
    [COLOR=navy]Else[/COLOR]
      Q = Dic(Dn.Value)
        Q(0) = Q(0) & "," & Dn.Offset(, 1)
        Q(1) = Q(1) + 1
        oMax = Application.Max(oMax, Q(1))
      Dic(Dn.Value) = Q
    [COLOR=navy]End[/COLOR] If
    [COLOR=navy]If[/COLOR] Not myArraylist.CONTAINS(Dn.Value) [COLOR=navy]Then[/COLOR]
        myArraylist.Add Dn.Value 
    [COLOR=navy]End[/COLOR] If
[COLOR=navy]Next[/COLOR] Dn
myArraylist.Sort
ReDim nray(1 To oMax + 1, 1 To myArraylist.Count)
[COLOR=navy]For[/COLOR] n = 0 To myArraylist.Count - 1
    Sp = Split(Dic(myArraylist(n))(0), ",")
        nray(1, n + 1) = myArraylist(n)
        [COLOR=navy]For[/COLOR] Rw = 0 To UBound(Sp)
            nray(Rw + 2, n + 1) = Sp(Rw)
        [COLOR=navy]Next[/COLOR] Rw
[COLOR=navy]Next[/COLOR] n
[COLOR=navy]With[/COLOR] Sheets("Sheet2").Range("A1").Resize(oMax + 1, myArraylist.Count)
    .Value = nray
    .Borders.Weight = 2
    .Columns.AutoFit
[COLOR=navy]End[/COLOR] [COLOR=navy]With[/COLOR]
[COLOR=navy]End[/COLOR] [COLOR=navy]Sub[/COLOR]
Regards Mick
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,200
Messages
6,123,612
Members
449,109
Latest member
Sebas8956

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