Combining Data w/ VBA

jetstrike

New Member
Joined
Jan 17, 2019
Messages
4
Hello everyone,

I am a long time lurker and excel novice. I have a data set that has multiple entries per date and per group and I would like to combine those entries into a single line. I have given an before and after example below. I am hoping for a VBA solution so that I can save it as a macro but the method to do so escapes me. The actual data set is approximately 250,000 records. I have had mixed success's with various methods and any assistance would be greatly appreciated.

[TABLE="width: 500"]
<tbody>[TR]
[TD]Name[/TD]
[TD]Date[/TD]
[TD]Group[/TD]
[TD]Time[/TD]
[/TR]
[TR]
[TD]Jeff[/TD]
[TD]1/1/19[/TD]
[TD]G1[/TD]
[TD]284[/TD]
[/TR]
[TR]
[TD]Jeff[/TD]
[TD]1/1/19[/TD]
[TD]G2[/TD]
[TD]767[/TD]
[/TR]
[TR]
[TD]Jeff[/TD]
[TD]1/1/19[/TD]
[TD]G3[/TD]
[TD]451[/TD]
[/TR]
[TR]
[TD]Jeff[/TD]
[TD]1/2/19[/TD]
[TD]G2[/TD]
[TD]568[/TD]
[/TR]
[TR]
[TD]Jeff[/TD]
[TD]1/2/19[/TD]
[TD]G7[/TD]
[TD]489[/TD]
[/TR]
[TR]
[TD]Steve[/TD]
[TD]1/1/19[/TD]
[TD]G13[/TD]
[TD]654[/TD]
[/TR]
[TR]
[TD]Steve[/TD]
[TD]1/1/19[/TD]
[TD]G77[/TD]
[TD]789[/TD]
[/TR]
[TR]
[TD]Steve[/TD]
[TD]1/2/19[/TD]
[TD]G31[/TD]
[TD]413[/TD]
[/TR]
[TR]
[TD]Steve[/TD]
[TD]1/2/19[/TD]
[TD]G23[/TD]
[TD]877[/TD]
[/TR]
</tbody>[/TABLE]


[TABLE="width: 500"]
<tbody>[TR]
[TD]Name[/TD]
[TD]Date[/TD]
[TD]Group[/TD]
[TD]Time[/TD]
[/TR]
[TR]
[TD]Jeff[/TD]
[TD]1/1/19[/TD]
[TD]G1;G2;G3[/TD]
[TD]1502[/TD]
[/TR]
[TR]
[TD]Jeff[/TD]
[TD]1/2/19[/TD]
[TD]G2;G7[/TD]
[TD]1057[/TD]
[/TR]
[TR]
[TD]Steve[/TD]
[TD]1/1/19[/TD]
[TD]G13;G77[/TD]
[TD]1443[/TD]
[/TR]
[TR]
[TD]Steve[/TD]
[TD]1/2/19[/TD]
[TD]G31;G23[/TD]
[TD]1290[/TD]
[/TR]
</tbody>[/TABLE]


Thank you for your time and have a wonderful day!
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
just for fun without VBA but with PowerQuery aka Get&Transform

[Table="width:, class:head"]
[tr=bgcolor:#FFFFFF][td=bgcolor:#5B9BD5]Name[/td][td=bgcolor:#5B9BD5]Date[/td][td=bgcolor:#5B9BD5]Group[/td][td=bgcolor:#5B9BD5]Time[/td][td][/td][td=bgcolor:#70AD47]Name[/td][td=bgcolor:#70AD47]Date[/td][td=bgcolor:#70AD47]Group[/td][td=bgcolor:#70AD47]Sum of Time[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]Jeff[/td][td=bgcolor:#DDEBF7]
01/01/2019​
[/td][td=bgcolor:#DDEBF7]G1[/td][td=bgcolor:#DDEBF7]
284​
[/td][td][/td][td=bgcolor:#E2EFDA]Jeff[/td][td=bgcolor:#E2EFDA]
01/01/2019​
[/td][td=bgcolor:#E2EFDA]G1;G2;G3[/td][td=bgcolor:#E2EFDA]
1502​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td]Jeff[/td][td]
01/01/2019​
[/td][td]G2[/td][td]
767​
[/td][td][/td][td]Jeff[/td][td]
01/02/2019​
[/td][td]G2;G7[/td][td]
1057​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]Jeff[/td][td=bgcolor:#DDEBF7]
01/01/2019​
[/td][td=bgcolor:#DDEBF7]G3[/td][td=bgcolor:#DDEBF7]
451​
[/td][td][/td][td=bgcolor:#E2EFDA]Steve[/td][td=bgcolor:#E2EFDA]
01/01/2019​
[/td][td=bgcolor:#E2EFDA]G13;G77[/td][td=bgcolor:#E2EFDA]
1443​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td]Jeff[/td][td]
01/02/2019​
[/td][td]G2[/td][td]
568​
[/td][td][/td][td]Steve[/td][td]
01/02/2019​
[/td][td]G31;G23[/td][td]
1290​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]Jeff[/td][td=bgcolor:#DDEBF7]
01/02/2019​
[/td][td=bgcolor:#DDEBF7]G7[/td][td=bgcolor:#DDEBF7]
489​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]Steve[/td][td]
01/01/2019​
[/td][td]G13[/td][td]
654​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]Steve[/td][td=bgcolor:#DDEBF7]
01/01/2019​
[/td][td=bgcolor:#DDEBF7]G77[/td][td=bgcolor:#DDEBF7]
789​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td]Steve[/td][td]
01/02/2019​
[/td][td]G31[/td][td]
413​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]Steve[/td][td=bgcolor:#DDEBF7]
01/02/2019​
[/td][td=bgcolor:#DDEBF7]G23[/td][td=bgcolor:#DDEBF7]
877​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]
[/table]


Code:
[SIZE=1]let
    Source = Excel.CurrentWorkbook(){[Name="Table8"]}[Content],
    #"Grouped Rows" = Table.Group(Source, {"Name", "Date"}, {{"Count", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Group", each Table.Column([Count],"Group")),
    #"Aggregated Count" = Table.AggregateTableColumn(#"Added Custom", "Count", {{"Time", List.Sum, "Sum of Time"}}),
    #"Extracted Values" = Table.TransformColumns(#"Aggregated Count", {"Group", each Text.Combine(List.Transform(_, Text.From), ";"), type text}),
    #"Reordered Columns" = Table.ReorderColumns(#"Extracted Values",{"Name", "Date", "Group", "Sum of Time"}),
    #"Changed Type" = Table.TransformColumnTypes(#"Reordered Columns",{{"Date", type date}})
in
    #"Changed Type"[/SIZE]
 
Upvote 0
Howdy,

I think I understand what you'd like to do. Just a few questions:

1) Is the data always in date order?

2) Will all the Jeffs and Steves be clumped together like in your example, or will they be spread out with different names in between?

3) Should the macro put the combined data in a new sheet or overwrite the data on the current sheet?

-Matt
 
Upvote 0
Howdy,

I think I understand what you'd like to do. Just a few questions:

1) Is the data always in date order?

2) Will all the Jeffs and Steves be clumped together like in your example, or will they be spread out with different names in between?

3) Should the macro put the combined data in a new sheet or overwrite the data on the current sheet?

-Matt

1. I can definitly sort the data to be date order quickly with a macro but the source data is not always in order.
2. There are about 900 users and they will be spread out with others in between.
3. Either is fine I am just struggling with the steps to combine the data. New sheet would be best so I can test without destroying data.

For the first two questions it seems to me I could just sort by name and then date or vice versa if that helps.
 
Upvote 0
I really appreciate this. Unfortunately my workplace is extremely strict in terms of security and I cannot use power query.


just for fun without VBA but with PowerQuery aka Get&Transform

[TABLE="class: head"]
<tbody>[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD="bgcolor: #5B9BD5"][COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]Name[/COLOR][/TD]
[TD="bgcolor: #5B9BD5"][COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]Date[/COLOR][/TD]
[TD="bgcolor: #5B9BD5"][COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]Group[/COLOR][/TD]
[TD="bgcolor: #5B9BD5"][COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]Time[/COLOR][/TD]
[TD][/TD]
[TD="bgcolor: #70AD47"][COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]Name[/COLOR][/TD]
[TD="bgcolor: #70AD47"][COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]Date[/COLOR][/TD]
[TD="bgcolor: #70AD47"][COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]Group[/COLOR][/TD]
[TD="bgcolor: #70AD47"][COLOR=[URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] ]Sum of Time[/COLOR][/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD="bgcolor: #DDEBF7"]Jeff[/TD]
[TD="bgcolor: #DDEBF7"]
01/01/2019​
[/TD]
[TD="bgcolor: #DDEBF7"]G1[/TD]
[TD="bgcolor: #DDEBF7"]
284​
[/TD]
[TD][/TD]
[TD="bgcolor: #E2EFDA"]Jeff[/TD]
[TD="bgcolor: #E2EFDA"]
01/01/2019​
[/TD]
[TD="bgcolor: #E2EFDA"]G1;G2;G3[/TD]
[TD="bgcolor: #E2EFDA"]
1502​
[/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD]Jeff[/TD]
[TD]
01/01/2019​
[/TD]
[TD]G2[/TD]
[TD]
767​
[/TD]
[TD][/TD]
[TD]Jeff[/TD]
[TD]
01/02/2019​
[/TD]
[TD]G2;G7[/TD]
[TD]
1057​
[/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD="bgcolor: #DDEBF7"]Jeff[/TD]
[TD="bgcolor: #DDEBF7"]
01/01/2019​
[/TD]
[TD="bgcolor: #DDEBF7"]G3[/TD]
[TD="bgcolor: #DDEBF7"]
451​
[/TD]
[TD][/TD]
[TD="bgcolor: #E2EFDA"]Steve[/TD]
[TD="bgcolor: #E2EFDA"]
01/01/2019​
[/TD]
[TD="bgcolor: #E2EFDA"]G13;G77[/TD]
[TD="bgcolor: #E2EFDA"]
1443​
[/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD]Jeff[/TD]
[TD]
01/02/2019​
[/TD]
[TD]G2[/TD]
[TD]
568​
[/TD]
[TD][/TD]
[TD]Steve[/TD]
[TD]
01/02/2019​
[/TD]
[TD]G31;G23[/TD]
[TD]
1290​
[/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD="bgcolor: #DDEBF7"]Jeff[/TD]
[TD="bgcolor: #DDEBF7"]
01/02/2019​
[/TD]
[TD="bgcolor: #DDEBF7"]G7[/TD]
[TD="bgcolor: #DDEBF7"]
489​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD]Steve[/TD]
[TD]
01/01/2019​
[/TD]
[TD]G13[/TD]
[TD]
654​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD="bgcolor: #DDEBF7"]Steve[/TD]
[TD="bgcolor: #DDEBF7"]
01/01/2019​
[/TD]
[TD="bgcolor: #DDEBF7"]G77[/TD]
[TD="bgcolor: #DDEBF7"]
789​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD]Steve[/TD]
[TD]
01/02/2019​
[/TD]
[TD]G31[/TD]
[TD]
413​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FFFFFF]#FFFFFF[/URL] "]
[TD="bgcolor: #DDEBF7"]Steve[/TD]
[TD="bgcolor: #DDEBF7"]
01/02/2019​
[/TD]
[TD="bgcolor: #DDEBF7"]G23[/TD]
[TD="bgcolor: #DDEBF7"]
877​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Code:
[SIZE=1]let
    Source = Excel.CurrentWorkbook(){[Name="Table8"]}[Content],
    #"Grouped Rows" = Table.Group(Source, {"Name", "Date"}, {{"Count", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Group", each Table.Column([Count],"Group")),
    #"Aggregated Count" = Table.AggregateTableColumn(#"Added Custom", "Count", {{"Time", List.Sum, "Sum of Time"}}),
    #"Extracted Values" = Table.TransformColumns(#"Aggregated Count", {"Group", each Text.Combine(List.Transform(_, Text.From), ";"), type text}),
    #"Reordered Columns" = Table.ReorderColumns(#"Extracted Values",{"Name", "Date", "Group", "Sum of Time"}),
    #"Changed Type" = Table.TransformColumnTypes(#"Reordered Columns",{{"Date", type date}})
in
    #"Changed Type"[/SIZE]
 
Upvote 0
Sorry, I had a go at it, but this seems to be above my knowledge level. I'm pretty sure this should be doable using VBA though; maybe someone else will weigh it. I don't know anything about PowerQuery, but Sandy666's solution looks exactly like what you need if you could convince the powers that be to allow it. Good luck!

-Matt
 
Upvote 0
How about
Code:
Sub Jetstrike()
   Dim Ary As Variant, Ky As Variant, K As Variant
   Dim i As Long
   Dim Dic As Object
   Dim Tmp1 As String, Tmp2 As Long
   
   Ary = Sheets("Sheet1").Range("A1").CurrentRegion.Value2
   Set Dic = CreateObject("Scripting.dictionary")
   For i = 1 To UBound(Ary)
      If Not Dic.Exists(Ary(i, 1)) Then Dic.Add Ary(i, 1), CreateObject("scripting.dictionary")
      If Not Dic(Ary(i, 1)).Exists(Ary(i, 2)) Then
         Dic(Ary(i, 1)).Add (Ary(i, 2)), Array(Ary(i, 3), Ary(i, 4))
      Else
         Tmp1 = Dic(Ary(i, 1))(Ary(i, 2))(0) & ", " & Ary(i, 3)
'         Debug.Print Dic(Ary(i, 1))(Ary(i, 2))(2)
         Tmp2 = Dic(Ary(i, 1))(Ary(i, 2))(1) + Ary(i, 4)
         Dic(Ary(i, 1))(Ary(i, 2)) = Array(Tmp1, Tmp2)
      End If
   Next i
   With Sheets("Sheet2")
      For Each Ky In Dic.Keys
         For Each K In Dic(Ky)
            .Range("A" & Rows.Count).End(xlUp).Offset(1).Value = Ky
            .Range("B" & Rows.Count).End(xlUp).Offset(1).Value = K
            .Range("C" & Rows.Count).End(xlUp).Offset(1).Resize(, 2).Value = Application.Index(Dic(Ky)(K), 1, 0)
         Next K
      Next Ky
   End With
End Sub
 
Upvote 0
This works, thank you.

How about
Code:
Sub Jetstrike()
   Dim Ary As Variant, Ky As Variant, K As Variant
   Dim i As Long
   Dim Dic As Object
   Dim Tmp1 As String, Tmp2 As Long
   
   Ary = Sheets("Sheet1").Range("A1").CurrentRegion.Value2
   Set Dic = CreateObject("Scripting.dictionary")
   For i = 1 To UBound(Ary)
      If Not Dic.Exists(Ary(i, 1)) Then Dic.Add Ary(i, 1), CreateObject("scripting.dictionary")
      If Not Dic(Ary(i, 1)).Exists(Ary(i, 2)) Then
         Dic(Ary(i, 1)).Add (Ary(i, 2)), Array(Ary(i, 3), Ary(i, 4))
      Else
         Tmp1 = Dic(Ary(i, 1))(Ary(i, 2))(0) & ", " & Ary(i, 3)
'         Debug.Print Dic(Ary(i, 1))(Ary(i, 2))(2)
         Tmp2 = Dic(Ary(i, 1))(Ary(i, 2))(1) + Ary(i, 4)
         Dic(Ary(i, 1))(Ary(i, 2)) = Array(Tmp1, Tmp2)
      End If
   Next i
   With Sheets("Sheet2")
      For Each Ky In Dic.Keys
         For Each K In Dic(Ky)
            .Range("A" & Rows.Count).End(xlUp).Offset(1).Value = Ky
            .Range("B" & Rows.Count).End(xlUp).Offset(1).Value = K
            .Range("C" & Rows.Count).End(xlUp).Offset(1).Resize(, 2).Value = Application.Index(Dic(Ky)(K), 1, 0)
         Next K
      Next Ky
   End With
End Sub
 
Upvote 0
You're welcome & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,249
Members
452,623
Latest member
Techenthusiast

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