cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
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

Accepted Solutions
Highlighted
Community Support
Community Support

Re: Group then Transpose/Pivot with Text values

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
Highlighted
Super User I
Super User I

Re: Group then Transpose/Pivot with Text values

can you copy and paste the data in text format?





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Highlighted
Frequent Visitor

Re: Group then Transpose/Pivot with Text values

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

Highlighted
Super User I
Super User I

Re: Group then Transpose/Pivot with Text values

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

 

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Highlighted
Frequent Visitor

Re: Group then Transpose/Pivot with Text values

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

Highlighted
Community Support
Community Support

Re: Group then Transpose/Pivot with Text values

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

Highlighted
Frequent Visitor

Re: Group then Transpose/Pivot with Text values

That worked perfectly Lin- thank you! 

-Carol

Helpful resources

Announcements
Community Blog

Community Blog

Visit our Community Blog for articles, guides, and information created by fellow community members.

Using the Community

Using the Community

Need help with the Power BI Community? Our 'Using the Community' support articles are a great place to start.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Power Platform 2020 release wave 2 plan

Power Platform 2020 release wave 2 plan

Features releasing from October 2020 through March 2021

Top Solution Authors
Top Kudoed Authors