Creating a dictionary of all the values from a column

sinz0000

New Member
Joined
Jul 6, 2018
Messages
12
there is going to be a data in A column of current sheet containing unique values. I want to add all these already existing unique values to a dictionary and use each of the unique value as a criteria for filtering in next sheet.

How to add all the values of A column to the dictionary? and how to refer to each of the value in it?
 
Upvote 0

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
Do you think there might be more changes? If so, it would be best to wait till the final format & requirements are determined before proceeding. :)


On what sheet?


On what sheet?

Hi,
No I am hoping that i wont receive any further changes after this from the upper management. So all in all the case is like this.
In criteria sheet, suppose we have:
ModuleProcesses
AP1
AP2
AP3
AP4
AP5
AP6
AP7
AP8
BP9
BP10
BP11
BP12
BP13
BP14
CP15
CP16
CP17
CP18
CP19
CP20
CP21

<tbody>
</tbody>

And in the next sheet the outcome should be like(Division of processes in 4 columns):

AP1P2P3P4
P5P6P7P8
BP9P10P11P12
P13P14
CP15P16P17P18
P19P20P21

<tbody>
</tbody>
 
Upvote 0
In the dictionary, it is joining all the Processes for a Module together with a semicolon between - as described in post 6:
Yes i understood what that code is doing but i am not able to understand the syntax.

I am trying to understand syntax of:
Code:
Dict(Data(i, 1)) = Dict(Data(i, 1)) & Data(i, 2) & ";"
how to read the meaning here, for example what does "Dict(Data(i, 1))" and other syntax stand for?
 
Upvote 0
Thanks for clarifying the layouts. I have just commented the changed sections in this code.
Rich (BB code):
Sub CollateData_v2()
  Dim Dict As Object
  Dim Data As Variant, Results As Variant, Ky As Variant, Itm As Variant
  Dim i As Long, r As Long, c As Long
  
  Set Dict = CreateObject("Scripting.Dictionary")
  
  With Sheets("Criteria")
    Data = .Range("A1", .Range("B" & .Rows.Count).End(xlUp)).Value
  End With
 
  For i = 1 To UBound(Data)
    Dict(Data(i, 1)) = Dict(Data(i, 1)) & ";" & Data(i, 2)
  Next i
  
  'Set up an array at least big enough to hold the results
  ReDim Results(1 To UBound(Data), 1 To 5)
  
  'Work through the Keys (ie Modules) in the dictionary &
  'Split the Items (ie Processes) into rows of 4 columns
  'Putting them in the Results array
  For Each Ky In Dict.Keys()
    r = r + 1
    c = 1
    Results(r, 1) = Ky
    For Each Itm In Split(Mid(Dict(Ky), 2), ";")
      c = c + 1
      If c = 6 Then
        c = 2
        r = r + 1
      End If
      Results(r, c) = Itm
    Next Itm
  Next Ky
  
  'Add the new sheet and write the Results array into it
  Sheets.Add After:=Sheets(Sheets.Count)
  Sheets(Sheets.Count).Range("A1").Resize(r, 5).Value = Results
End Sub
 
Upvote 0
I am trying to understand syntax of:
Code:
Dict(Data(i, 1)) = Dict(Data(i, 1)) & Data(i, 2) & ";"
how to read the meaning here, for example what does "Dict(Data(i, 1))" and other syntax stand for?
Not sure how clearly I can explain, but I'll try using this sheet as a small example


Book1
AB
1ModuleProcesses
2AP1
3AP2
4AP3
5BP9
6CP15
7CP16
8
Criteria


I'll also use the new version of that line of code as it changed slightly (putting the semicolon in a different place)
Code:
Dict(Data(i, 1)) = Dict(Data(i, 1)) & ";" & Data(i, 2)

Data is a 2-dimensional array holding the data you see above so still think of rows and columns.
The code line above is in a loop where the variable i runs from 1 to 7 as there are 7 rows of data.
When i = 1
Data(i,1) = Data(1,1) = "Module"
Data(i,2) = Data(1,2) = "Processes"
so the code line says
Dict("Module") = Dict("Module") & ";" & "Processes"

Dict("Module") means what is stored in the dictionary for "Module". When this line is about to run for the first time nothing is in the dictionary at all so what is stored for "Module" is nothing & so this line is saying
In the dictionary for "Module" store whatever is already in there (nothing) and append a semicolon and append "Processes"
So, after processing row 1 above what is stored in the dictionary is what is shown in F2:G2 below

Row 2 above is similar in that "A" is not already in the dictionary so after processing row 2 what is in the dictionary is what is shown in F2:G3 below.

When we get to row 3 above "A" is repeated so our code line says, for the Key "A", store whatever is already in the dictionary for "A" (ie ";P1") and append a semicolon and whatever is in the 2nd column of that row. So for "A" now is stored ";P1;P2" as shown in row 4 below. Row 3 below is no longer relevant. In the end, there are just 4 Keys & 4 Items in the dictionary - the last row of each Key (coloured).
etc

Hope that helped. If you need more about dictionaries in vba, here is one resource but Googling I'm sure would find you plenty more.


Book1
ABCDEFG
1ModuleProcessesAfter RowDict KeysDict Items
2AP11Module;Processes
3AP22A;P1
4AP33A;P1;P2
5BP94A;P1;P2;P3
6CP155B;P9
7CP166C;P15
87C;P15;P16
Criteria
 
Last edited:
Upvote 0
When i = 1
Data(i,1) = Data(1,1) = "Module"
Data(i,2) = Data(1,2) = "Processes"
so the code line says
Dict("Module") = Dict("Module") & ";" & "Processes"

Dict("Module") means what is stored in the dictionary for "Module". When this line is about to run for the first time nothing is in the dictionary at all so what is stored for "Module" is nothing & so this line is saying
In the dictionary for "Module" store whatever is already in there (nothing) and append a semicolon and append "Processes"
So, after processing row 1 above what is stored in the dictionary is what is shown in F2:G2 below

Row 2 above is similar in that "A" is not already in the dictionary so after processing row 2 what is in the dictionary is what is shown in F2:G3 below.

Awesomely explained. I got this now. Thank you very very much.
 
Upvote 0
Hi,

I wasnt able to put in some time to study this. Today, I tried to understand it. I again need your expertise to understand it; hope you can help. In the code
Code:
 For Each Ky In Dict.Keys()
    r = r + 1
    c = 1
    Results(r, 1) = Ky
    For Each Itm In Split(Mid(Dict(Ky), 2), ";")
      c = c + 1
      If c = 6 Then
        c = 2
        r = r + 1
      End If
      Results(r, c) = Itm
    Next Itm
  Next Ky

We are inserting dictionary values in results. However for
r = r + 1, where is the base value set for r? Like on the third line we are setting the base value of C as 1 but for r how is the code picking the base value?

Also could you help me with the below line, I know it is for splitting the values on the basis of ";" but i am not able to understand how the highlighted syntax is working.
For Each Itm In Split(Mid(Dict(Ky), 2), ";")

Thanks
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,945
Messages
6,122,393
Members
449,081
Latest member
JAMES KECULAH

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