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
clgrantmidd
Frequent Visitor

Group then Transpose/Pivot with Text values

I'm looking to group values by FundID then list do a pivot or transpose for 3 new columns (Relationship Type) and have the Relationship Names underneath.  If there is more than one value, have it comma separated.  I posted this in Power Query but didn't get much of a response.  I know to Group then do All Rows, Don't Aggregate.  It's working with the subtable that I'm not getting correct.  The second part is the way I need it.

Thanks for any help!

-Carol

data_sample.PNG

1 ACCEPTED SOLUTION
v-lili6-msft
Community Support
Community Support

hi  @clgrantmidd 

Just try these steps in the edit queries:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("rZI9a8NADIb/ivCcwc3QkNFNaYuhEGLSDiaD6lOw4HxndLKD/33OLmkgmUo8CX3wvHqFyjJZrtJ09ZQski+sUNk7eOucifkYgAMcvcClF8sbFG+haFjry9COWi+aHBb/p71izwZy7yjErKhqb1FCze0j0A0qfPou0HzInEQGyKT7wRlcF2jtAN9sLWMzGdfOkFPITiiGzC/0OV2uY++dHAnGk1+d3PiKAnsnFFS4Uhp1c0/wgQ1bnfTu9n0A/UI9ybg9apgdviUl+Xuuu6sczg==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [FundID = _t, FundDesc = _t, #"Fund Notes" = _t, #"Relationship Name" = _t, #"Relationship Type" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"FundID", Int64.Type}, {"FundDesc", type text}, {"Fund Notes", type text}, {"Relationship Name", type text}, {"Relationship Type", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"FundID", "FundDesc", "Fund Notes", "Relationship Type"}, {{"Data", each _, type table [FundID=number, FundDesc=text, Fund Notes=text, Relationship Name=text, Relationship Type=text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.Column([Data],"Relationship Name")),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Data"}),
    #"Extracted Values" = Table.TransformColumns(#"Removed Columns", {"Custom", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    #"Pivoted Column" = Table.Pivot(#"Extracted Values", List.Distinct(#"Extracted Values"[#"Relationship Type"]), "Relationship Type", "Custom")
in
    #"Pivoted Column"

Result:

1.JPG

 

and here is sample pbix file, please try it.

 

Regards,

Lin

Community Support Team _ Lin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

6 REPLIES 6
v-lili6-msft
Community Support
Community Support

hi  @clgrantmidd 

Just try these steps in the edit queries:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("rZI9a8NADIb/ivCcwc3QkNFNaYuhEGLSDiaD6lOw4HxndLKD/33OLmkgmUo8CX3wvHqFyjJZrtJ09ZQski+sUNk7eOucifkYgAMcvcClF8sbFG+haFjry9COWi+aHBb/p71izwZy7yjErKhqb1FCze0j0A0qfPou0HzInEQGyKT7wRlcF2jtAN9sLWMzGdfOkFPITiiGzC/0OV2uY++dHAnGk1+d3PiKAnsnFFS4Uhp1c0/wgQ1bnfTu9n0A/UI9ybg9apgdviUl+Xuuu6sczg==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [FundID = _t, FundDesc = _t, #"Fund Notes" = _t, #"Relationship Name" = _t, #"Relationship Type" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"FundID", Int64.Type}, {"FundDesc", type text}, {"Fund Notes", type text}, {"Relationship Name", type text}, {"Relationship Type", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"FundID", "FundDesc", "Fund Notes", "Relationship Type"}, {{"Data", each _, type table [FundID=number, FundDesc=text, Fund Notes=text, Relationship Name=text, Relationship Type=text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Table.Column([Data],"Relationship Name")),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Data"}),
    #"Extracted Values" = Table.TransformColumns(#"Removed Columns", {"Custom", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    #"Pivoted Column" = Table.Pivot(#"Extracted Values", List.Distinct(#"Extracted Values"[#"Relationship Type"]), "Relationship Type", "Custom")
in
    #"Pivoted Column"

Result:

1.JPG

 

and here is sample pbix file, please try it.

 

Regards,

Lin

Community Support Team _ Lin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

That worked perfectly Lin- thank you! 

-Carol

vanessafvg
Super User
Super User

can you copy and paste the data in text format?





If I took the time to answer your question and I came up with a solution, please mark my post as a solution and /or give kudos freely for the effort 🙂 Thank you!

Proud to be a Super User!




Here you go.  Would you like it as a csv format or does this work?

 

FundID FundDesc Fund Notes Relationship Name Relationship Type
270071 Vacation Fund Fund is for Vacation Carol Smith Fund Report
270071 Vacation Fund Fund is for Vacation David Jones Scholarship Report
270071 Vacation Fund Fund is for Vacation Cat Mouse Scholarship Report
270071 Vacation Fund Fund is for Vacation Jerry Aruba Fund Report
270071 Vacation Fund Fund is for Vacation Sally Williams Student Awarded
26029 General Scholarship Scholarship is Unrestricted Joe Hamilton Fund Report
26029 General Scholarship Scholarship is Unrestricted Beverly Watson Fund Report
26029 General Scholarship Scholarship is Unrestricted Peter Smith Student Awarded

if you can separate the values that would be best, as it would still require me to manually type and fix stuff in that format

 

 





If I took the time to answer your question and I came up with a solution, please mark my post as a solution and /or give kudos freely for the effort 🙂 Thank you!

Proud to be a Super User!




Here you go, thank you

 

FundID,FundDesc,Fund Notes,Relationship Name,Relationship Type
270071,Vacation Fund,Fund is for Vacation,Carol Smith,Fund Report
270071,Vacation Fund,Fund is for Vacation,David Jones,Scholarship Report
270071,Vacation Fund,Fund is for Vacation,Cat Mouse,Scholarship Report
270071,Vacation Fund,Fund is for Vacation,Jerry Aruba,Fund Report
270071,Vacation Fund,Fund is for Vacation,Sally Williams,Student Awarded
26029,General Scholarship,Scholarship is Unrestricted,Joe Hamilton,Fund Report
26029,General Scholarship,Scholarship is Unrestricted,Beverly Watson,Fund Report
26029,General Scholarship,Scholarship is Unrestricted,Peter Smith,Student Awarded

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.