Table consolidation help

patchkek

New Member
Joined
Sep 4, 2018
Messages
9
Hello,

I have a table that looks like this

[TABLE="width: 356"]
<colgroup><col><col><col></colgroup><tbody>[TR]
[TD]Customer Number[/TD]
[TD]Date Visited[/TD]
[TD]Rating[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]5/21/2018[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]2/7/2017[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]4/2/2018[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]5/6/2017[/TD]
[TD]5[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]9/8/2017[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]11/25/2017[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]3/2/2017[/TD]
[TD]5[/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]6/8/2018[/TD]
[TD]3[/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]7/22/2018[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]2/16/2018[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]2/1/2018[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]12/14/2017[/TD]
[TD]5[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]12/1/2017[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]8/8/2017[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]9/6/2017[/TD]
[TD]3[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]5/6/2017[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]2/16/2018[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]2/7/2017[/TD]
[TD]5[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]7/22/2018[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]8/19/2018[/TD]
[TD]3[/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]1/16/2018[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]10/17/2017[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]7/5/2017[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]6/6/2017[/TD]
[TD]2[/TD]
[/TR]
</tbody>[/TABLE]



And I would like to transpose / consolidate / combine to look like this:

[TABLE="width: 980"]
<colgroup><col><col><col><col><col><col><col><col><col><col><col></colgroup><tbody>[TR]
[TD]Customer Number[/TD]
[TD]Date Visited[/TD]
[TD]Rating[/TD]
[TD]Date Visited2[/TD]
[TD]Rating3[/TD]
[TD]Date Visited4[/TD]
[TD]Rating5[/TD]
[TD]Date Visited6[/TD]
[TD]Rating7[/TD]
[TD]Date Visited8[/TD]
[TD]Rating9[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]2/7/2017[/TD]
[TD]4[/TD]
[TD]12/1/2017[/TD]
[TD]1[/TD]
[TD]9/6/2017[/TD]
[TD]3[/TD]
[TD]7/22/2018[/TD]
[TD]2[/TD]
[TD]7/5/2017[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]4/2/2018[/TD]
[TD]2[/TD]
[TD]12/14/2017[/TD]
[TD]5[/TD]
[TD]5/6/2017[/TD]
[TD]2[/TD]
[TD]6/6/2017[/TD]
[TD]2[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]9/8/2017[/TD]
[TD]4[/TD]
[TD]3/2/2017[/TD]
[TD]5[/TD]
[TD]2/1/2018[/TD]
[TD]4[/TD]
[TD]2/7/2017[/TD]
[TD]5[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Any help/advise you can offer?

Thanks so much!
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
at first glance you can try with PowerQuery

[Table="width:, class:head"]
[tr=bgcolor:#FFFFFF][td=bgcolor:#70AD47]Customer Number[/td][td=bgcolor:#70AD47]Date Visited.1[/td][td=bgcolor:#70AD47]Rating.1[/td][td=bgcolor:#70AD47]Date Visited.2[/td][td=bgcolor:#70AD47]Rating.2[/td][td=bgcolor:#70AD47]Date Visited.3[/td][td=bgcolor:#70AD47]Rating.3[/td][td=bgcolor:#70AD47]Date Visited.4[/td][td=bgcolor:#70AD47]Rating.4[/td][td=bgcolor:#70AD47]Date Visited.5[/td][td=bgcolor:#70AD47]Rating.5[/td][td=bgcolor:#70AD47]Date Visited.6[/td][td=bgcolor:#70AD47]Rating.6[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#E2EFDA]
1​
[/td][td=bgcolor:#E2EFDA]
08/08/2017​
[/td][td=bgcolor:#E2EFDA]
2​
[/td][td=bgcolor:#E2EFDA]
17/10/2017​
[/td][td=bgcolor:#E2EFDA]
4​
[/td][td=bgcolor:#E2EFDA]
21/05/2018​
[/td][td=bgcolor:#E2EFDA]
1​
[/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][/tr]

[tr=bgcolor:#FFFFFF][td]
2​
[/td][td]
07/02/2017​
[/td][td]
4​
[/td][td]
06/05/2017​
[/td][td]
5​
[/td][td]
05/07/2017​
[/td][td]
4​
[/td][td]
06/09/2017​
[/td][td]
3​
[/td][td]
01/12/2017​
[/td][td]
1​
[/td][td]
22/07/2018​
[/td][td]
2​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#E2EFDA]
3​
[/td][td=bgcolor:#E2EFDA]
06/05/2017​
[/td][td=bgcolor:#E2EFDA]
2​
[/td][td=bgcolor:#E2EFDA]
06/06/2017​
[/td][td=bgcolor:#E2EFDA]
2​
[/td][td=bgcolor:#E2EFDA]
14/12/2017​
[/td][td=bgcolor:#E2EFDA]
5​
[/td][td=bgcolor:#E2EFDA]
02/04/2018​
[/td][td=bgcolor:#E2EFDA]
2​
[/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][/tr]

[tr=bgcolor:#FFFFFF][td]
4​
[/td][td]
07/02/2017​
[/td][td]
5​
[/td][td]
02/03/2017​
[/td][td]
5​
[/td][td]
08/09/2017​
[/td][td]
4​
[/td][td]
01/02/2018​
[/td][td]
4​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#E2EFDA]
5​
[/td][td=bgcolor:#E2EFDA]
25/11/2017​
[/td][td=bgcolor:#E2EFDA]
2​
[/td][td=bgcolor:#E2EFDA]
16/02/2018​
[/td][td=bgcolor:#E2EFDA]
4​
[/td][td=bgcolor:#E2EFDA]
19/08/2018​
[/td][td=bgcolor:#E2EFDA]
3​
[/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][/tr]

[tr=bgcolor:#FFFFFF][td]
6​
[/td][td]
16/01/2018​
[/td][td]
4​
[/td][td]
08/06/2018​
[/td][td]
3​
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#E2EFDA]
7​
[/td][td=bgcolor:#E2EFDA]
16/02/2018​
[/td][td=bgcolor:#E2EFDA]
1​
[/td][td=bgcolor:#E2EFDA]
22/07/2018​
[/td][td=bgcolor:#E2EFDA]
2​
[/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][/tr]
[/table]


Code:
[SIZE=1]let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Customer Number", Int64.Type}, {"Date Visited", type date}, {"Rating", Int64.Type}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type",{{"Customer Number", Order.Ascending}, {"Date Visited", Order.Ascending}}),
    #"Grouped Rows" = Table.Group(#"Sorted Rows", {"Customer Number"}, {{"Count", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Date Visited", each Table.Column([Count],"Date Visited")),
    #"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Date Visited", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    #"Added Custom1" = Table.AddColumn(#"Extracted Values", "Rating", each Table.Column([Count],"Rating")),
    #"Extracted Values1" = Table.TransformColumns(#"Added Custom1", {"Rating", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values1", "Date Visited", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Date Visited.1", "Date Visited.2", "Date Visited.3", "Date Visited.4", "Date Visited.5", "Date Visited.6"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Date Visited.1", type date}, {"Date Visited.2", type date}, {"Date Visited.3", type date}, {"Date Visited.4", type date}, {"Date Visited.5", type date}, {"Date Visited.6", type date}}),
    #"Split Column by Delimiter1" = Table.SplitColumn(#"Changed Type1", "Rating", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Rating.1", "Rating.2", "Rating.3", "Rating.4", "Rating.5", "Rating.6"}),
    #"Changed Type2" = Table.TransformColumnTypes(#"Split Column by Delimiter1",{{"Rating.1", Int64.Type}, {"Rating.2", Int64.Type}, {"Rating.3", Int64.Type}, {"Rating.4", Int64.Type}, {"Rating.5", Int64.Type}, {"Rating.6", Int64.Type}}),
    #"Reordered Columns" = Table.ReorderColumns(#"Changed Type2",{"Customer Number", "Count", "Date Visited.1", "Rating.1", "Date Visited.2", "Rating.2", "Date Visited.3", "Rating.3", "Date Visited.4", "Rating.4", "Date Visited.5", "Rating.5", "Date Visited.6", "Rating.6"}),
    #"Removed Columns" = Table.RemoveColumns(#"Reordered Columns",{"Count"})
in
    #"Removed Columns"[/SIZE]
 
Upvote 0

Forum statistics

Threads
1,224,824
Messages
6,181,186
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

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