Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
dsbuilder
New Member

Need to fetch multiple values from the same table

Hello, I have a problem that I believe it's simple but I haven't been able to do this. 

Imagine a table like this

L1columnL2columnNumber_ext
1.1 Rice  
1.1 Rice1.1.1 Blue RiceFIVE
1.1 Rice1.1.2 Green Rice 
1.2 Potatoes  
1.2 Potatoes1.2.1 Old PotatoesTWELVE
1.1 Rice1.1.1 Blue RiceTEN, ELEVEN
1.1 Rice1.1.1 Blue Rice 

 

I want to be able to create a new column that concatenates all the Number_ext column on the rows that have only the L1values and not L2values. Something like this:

L1columnL2columnNumber_extNew column
1.1 Rice  FIVE, TEN, ELEVEN 
1.1 Rice1.1.1 Blue RiceFIVE 
1.1 Rice1.1.2 Green Rice  
1.2 Potatoes  TWELVE
1.2 Potatoes1.2.1 Old PotatoesTWELVE 
1.1 Rice1.1.1 Blue RiceTEN, ELEVEN 
1.1 Rice1.1.1 Blue Rice  

 

I've been trying Lookups and filters and new tables but I haven't been able to do this. 

Can someone please help me with this? 

Thank you!

(this is a dummy table - I don't work with vegetables)

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @dsbuilder 

 

check out this solution. It uses Table.Group and AddColumn. This will write your requested data in every column, no only in the first 🙂

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtQzVAjKTE5V0lFSAONYHRRBIBPIccopTYWJuHmGuWJTZaTgXpSamocwDaLGSCEgvySxJD+1GM0KFAkgF2iaf04KsmBIuKsPdrtQXRTi6qej4OrjGubqR1gx0PpYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [L1column = _t, L2column = _t, Number_ext = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"L1column", type text}, {"L2column", type text}, {"Number_ext", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"L1column"}, {{"AllRows", each _, type table [L1column=text, L2column=text, Number_ext=text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Conc", each Text.Combine([AllRows][#"Number_ext"])),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Added Custom", "AllRows", {"L1column", "Number_ext"}, {"L1column.1", "Number_ext"})
in
    #"Expanded AllRows"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

2 REPLIES 2
Jimmy801
Community Champion
Community Champion

Hello @dsbuilder 

 

check out this solution. It uses Table.Group and AddColumn. This will write your requested data in every column, no only in the first 🙂

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtQzVAjKTE5V0lFSAONYHRRBIBPIccopTYWJuHmGuWJTZaTgXpSamocwDaLGSCEgvySxJD+1GM0KFAkgF2iaf04KsmBIuKsPdrtQXRTi6qej4OrjGubqR1gx0PpYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [L1column = _t, L2column = _t, Number_ext = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"L1column", type text}, {"L2column", type text}, {"Number_ext", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"L1column"}, {{"AllRows", each _, type table [L1column=text, L2column=text, Number_ext=text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Conc", each Text.Combine([AllRows][#"Number_ext"])),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Added Custom", "AllRows", {"L1column", "Number_ext"}, {"L1column.1", "Number_ext"})
in
    #"Expanded AllRows"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

Thank you @Jimmy801 ! Thanks for your quick reply!  

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors
Top Kudoed Authors