PowerQuery: Row with same ID, CONCATENATE image column into one row.

santnok

Board Regular
Joined
Jan 10, 2014
Messages
97
Hi

In PowerQuery I have a tabel that looks like the tabel under (TBL1). if you see under the ItemNo I have 1 or several same ID. So I need help to
make a colum that takes e.g. ItemNo: SHD3061 that have 2 rows of images and concatenate. So my result I hope to achieve is this (TBL2)

TBL2
[TABLE="width: 557"]
<tbody>[TR]
[TD]ItemNo[/TD]
[TD]Images[/TD]
[/TR]
[TR]
[TD]SHD3061[/TD]
[TD]/photos/SHD3061/SHD3061.jpg, /photos/SHD3061/SHD3061_4.png[/TD]
[/TR]
</tbody>[/TABLE]

From the tabel under you can see that the Image can be more than 1 for a ItemNo.

TBL1: Here is my result today I hope to fix
[TABLE="width: 557"]
<tbody>[TR]
[TD]ItemNo[/TD]
[TD]Images[/TD]
[/TR]
[TR]
[TD]SHD3061[/TD]
[TD]/photos/SHD3061/SHD3061.jpg[/TD]
[/TR]
[TR]
[TD]SHD3061[/TD]
[TD]/photos/SHD3061/SHD3061_4.png[/TD]
[/TR]
[TR]
[TD]SHD3062[/TD]
[TD]/photos/SHD3062/SHD3062.jpg[/TD]
[/TR]
[TR]
[TD]SHD3062[/TD]
[TD]/photos/SHD3062/SHD3062_pack.png[/TD]
[/TR]
[TR]
[TD]SHD3063[/TD]
[TD]/photos/SHD3063/SHD3063.jpg[/TD]
[/TR]
[TR]
[TD]SHD3063[/TD]
[TD]/photos/SHD3063/SHD3063_4.png[/TD]
[/TR]
[TR]
[TD]SHD3071[/TD]
[TD]/photos/SHD3071/SHD3071.jpg[/TD]
[/TR]
[TR]
[TD]SHD3071[/TD]
[TD]/photos/SHD3071/SHD3071_1.png[/TD]
[/TR]
[TR]
[TD]SHD3072[/TD]
[TD]/photos/SHD3072/SHD3072.jpg[/TD]
[/TR]
[TR]
[TD]SHD3072[/TD]
[TD]/photos/SHD3072/SHD3072_1.png[/TD]
[/TR]
[TR]
[TD]SHD3361[/TD]
[TD]/photos/SHD3361/SHD3361.jpg[/TD]
[/TR]
[TR]
[TD]SHD3361[/TD]
[TD]/photos/SHD3361/SHD3361_4.png[/TD]
[/TR]
[TR]
[TD]SHD3362[/TD]
[TD]/photos/SHD3362/SHD3362.jpg[/TD]
[/TR]
[TR]
[TD]SHD3362[/TD]
[TD]/photos/SHD3362/SHD3362_pack.png[/TD]
[/TR]
[TR]
[TD]SHD3461[/TD]
[TD]/photos/SHD3461/SHD3461.jpg[/TD]
[/TR]
[TR]
[TD]SHD3461[/TD]
[TD]/photos/SHD3461/SHD3461_4.png[/TD]
[/TR]
[TR]
[TD]SHD3462[/TD]
[TD]/photos/SHD3462/SHD3462.jpg[/TD]
[/TR]
[TR]
[TD]SHD3462[/TD]
[TD]/photos/SHD3462/SHD3462_pack.png[/TD]
[/TR]
[TR]
[TD]SHD3561[/TD]
[TD]/photos/SHD3561/SHD3561.jpg[/TD]
[/TR]
[TR]
[TD]SHD3561[/TD]
[TD]/photos/SHD3561/SHD3561_4.png[/TD]
[/TR]
[TR]
[TD]SHD3562[/TD]
[TD]/photos/SHD3562/SHD3562.jpg[/TD]
[/TR]
[TR]
[TD]SHD3562[/TD]
[TD]/photos/SHD3562/SHD3562_4.png[/TD]
[/TR]
[TR]
[TD]SHD3661[/TD]
[TD]/photos/SHD3661/SHD3661.jpg[/TD]
[/TR]
[TR]
[TD]SHD3661[/TD]
[TD]/photos/SHD3661/SHD3661_4.png[/TD]
[/TR]
[TR]
[TD]SHD3662[/TD]
[TD]/photos/SHD3662/SHD3662.jpg[/TD]
[/TR]
[TR]
[TD]SHD3662[/TD]
[TD]/photos/SHD3662/SHD3662_pack.png[/TD]
[/TR]
[TR]
[TD]SHD3862[/TD]
[TD]/photos/SHD3862/SHD3862.jpg[/TD]
[/TR]
[TR]
[TD]SHD3862[/TD]
[TD]/photos/SHD3862/SHD3862_Box.png[/TD]
[/TR]
[TR]
[TD]SHD3863[/TD]
[TD]/photos/SHD3863/SHD3863.jpg[/TD]
[/TR]
[TR]
[TD]SHD3863[/TD]
[TD]/photos/SHD3863/SHD3863_Box.png[/TD]
[/TR]
[TR]
[TD]SWB7140[/TD]
[TD]/photos/SWB7140/SWB7140.jpg[/TD]
[/TR]
[TR]
[TD]SWB7140[/TD]
[TD]/photos/SWB7140/SWB7140_0.jpg[/TD]
[/TR]
[TR]
[TD]SWB7140[/TD]
[TD]/photos/SWB7140/SWB7140_1.jpg[/TD]
[/TR]
[TR]
[TD]SWB7140[/TD]
[TD]/photos/SWB7140/SWB7140_10.jpg[/TD]
[/TR]
[TR]
[TD]SWB7140[/TD]
[TD]/photos/SWB7140/SWB7140_11.jpg[/TD]
[/TR]
[TR]
[TD]SWB7140[/TD]
[TD]/photos/SWB7140/SWB7140_12.jpg[/TD]
[/TR]
[TR]
[TD]SWB7140[/TD]
[TD]/photos/SWB7140/SWB7140_13.jpg[/TD]
[/TR]
[TR]
[TD]SWB7140[/TD]
[TD]/photos/SWB7140/SWB7140_14.jpg[/TD]
[/TR]
[TR]
[TD]SWB7140[/TD]
[TD]/photos/SWB7140/SWB7140_15.jpg[/TD]
[/TR]
</tbody>[/TABLE]

Hope it is possible to do without coding directly in the Advanced Editor

Hope somone can help me out here

Thanks for all help :-)
 

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
try

Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Grouped Rows" = Table.Group(Source, {"ItemNo"}, {{"Count", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Images", each Table.Column([Count],"Images")),
    #"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Images", each Text.Combine(List.Transform(_, Text.From), ", "), type text})
in
    #"Extracted Values"[/SIZE]

without Advanced Editor ;)
 
Upvote 0
Thanks for the reply, can you please help me out when I have this code before in Advanced Editor
How to place your code in my code :-)

Code:
let
    Kilde = Xml.Tables(Web.Contents("https://xxxxxxxxxxxxxxxxxxx.xml")),
    Table1 = Kilde{1}[Table],
    Table0 = Table1{0}[Table],
    #"Utvidet Picture" = Table.ExpandTableColumn(Table0, "Picture", {"Property"}, {"Property"}),
    #"Utvidet Property" = Table.ExpandTableColumn(#"Utvidet Picture", "Property", {"Attribute:Value"}, {"Attribute:Value"}),
    #"Renamed Columns" = Table.RenameColumns(#"Utvidet Property",{{"Attribute:Value", "Image"}}),
    #"Removed Other Columns" = Table.SelectColumns(#"Renamed Columns",{"ItemNo", "Image"})
in
    #"Removed Other Columns"

I see that in the code it shows some norwegian words.

Kilde = Source
Utvidet = Extended

Thanks :-)
 
Upvote 0
if the result of your M-code is your table from post#1 add last 3 lines from my post to your M-code, eg.

Code:
[SIZE=1]let
    Kilde = Xml.Tables(Web.Contents("https://xxxxxxxxxxxxxxxxxxx.xml")),
    Table1 = Kilde{1}[Table],
    Table0 = Table1{0}[Table],
    #"Utvidet Picture" = Table.ExpandTableColumn(Table0, "Picture", {"Property"}, {"Property"}),
    #"Utvidet Property" = Table.ExpandTableColumn(#"Utvidet Picture", "Property", {"Attribute:Value"}, {"Attribute:Value"}),
    #"Renamed Columns" = Table.RenameColumns(#"Utvidet Property",{{"Attribute:Value", "Image"}}),
    #"Removed Other Columns" = Table.SelectColumns(#"Renamed Columns",{"ItemNo", "Image"}),
[COLOR="#0000FF"]    #"Grouped Rows" = Table.Group(#"Removed Other Columns", {"ItemNo"}, {{"Count", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Images", each Table.Column([Count],"Images")),
    #"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Images", each Text.Combine(List.Transform(_, Text.From), ", "), type text})
in
    #"Extracted Values"[/COLOR][/SIZE]

but you should check proper syntax (you need to use Advanced Editor :) :) :) )

or
with your M-code
- group by ItemNo
- add custom column with Table.Column(....
- expand List column with delimiter: ", " (second option)

btw. your code has Image but your table from post#1 has Images
 
Last edited:
Upvote 0
Hi

Thanks, now I get an Error

See the picture here http://servyou.net/Capture.PNG

My code is now

Code:
let
    Kilde = Xml.Tables(Web.Contents("https://xxxxxxxxxxxx.xml")),
    Table1 = Kilde{1}[Table],
    Table0 = Table1{0}[Table],
    #"Utvidet Picture" = Table.ExpandTableColumn(Table0, "Picture", {"Property"}, {"Property"}),
    #"Utvidet Property" = Table.ExpandTableColumn(#"Utvidet Picture", "Property", {"Attribute:Value"}, {"Attribute:Value"}),
    #"Renamed Columns" = Table.RenameColumns(#"Utvidet Property",{{"Attribute:Value", "Image"}}),
    #"Removed Other Columns" = Table.SelectColumns(#"Renamed Columns",{"ItemNo", "Image"}),
    #"Grouped Rows" = Table.Group(#"Removed Other Columns", {"ItemNo"}, {{"Count", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Images", each Table.Column([Count],"Images")),
    #"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Images", each Text.Combine(List.Transform(_, Text.From), ", "), type text})
in
    #"Extracted Values"

Thanks for help :-)
 
Upvote 0
Hi again,

I found what is wrong, see in your code that you have writen Images, I changed to Image and it work :-)
So thank you verry much for the help :-) Have a nice day :-)

Sorry, dident see btw in your last post :-)
 
Last edited:
Upvote 0
Hi again

Have a follwup question. If I want to seperate the images into new column for each image insted of have them comma seperated in one column, is that possible?

Best Regard
Roy
 
Upvote 0
I want to seperate the images into new column for each image insted of have them comma seperated in one column

from the ribbon use Split Column with delimiter ", " without quotation marks
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,246
Members
452,623
Latest member
cliftonhandyman

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