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

Don't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.

Reply
qasimawan
Frequent Visitor

Collapse data to single

Hello community!

 

I have the following dataset and I want to collapse this to a single row:

 

How this looks like in Power Query:

First NameLast NameEmployee NumberExpiry DateDate  AwardedTraining 1Training 2 Training 3Training 4Training 5
JoeBloggs12345678  Required Required  
JoeBloggs12345678 43963     
JoeBloggs123456784568545320     
JoeBloggs123456784574945384     
JoeBloggs123456784575844663     
JoeBloggs123456784577244677   Match 
JoeBloggs123456784577544680     
JoeBloggs123456784577645411    Match
JoeBloggs123456784581544720     
JoeBloggs123456784605045320     
JoeBloggs123456784608944994     
JoeBloggs123456784613945044 Match   
JoeBloggs123456784620245107     
JoeBloggs123456784627145176     

 

How I want this to look:

First NameLast NameEmployee NumberExpiry DateDate  AwardedTraining 1Training 2 Training 3Training 4Training 5
JoeBloggs12345678  RequiredMatchRequiredMatchMatch

 

Can I do this using the user interface?

 

Thanks ever so much for your help!

3 ACCEPTED SOLUTIONS
lbendlin
Super User
Super User

1. Your data is not in a usable format. Unpivot it to make it usable.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("pZKxCsIwEIZfpWTucJdc7pLVUXBxLR1ESxWEotb3t+QUpRQa4hD+ZPh+jvvSNGY7dKY2m+vQ94/pgtaRZwnTtXqffXd7Xu7daflZmbZeayEX2f00VpnslMGndBaKeKGofKAy3qckLpxfxCovMmN3h/F4zuzw2hEKdyCckhAXeJ1jrSOgziBlHhg8/OORISSPFGORR0an/wDow3/3n9thIbn0CHOXmbyg8snHAt++AA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"First Name" = _t, #"Last Name" = _t, #"Employee Number" = _t, #"Expiry Date" = _t, #"Date  Awarded" = _t, #"Training 1" = _t, #"Training 2 " = _t, #"Training 3" = _t, #"Training 4" = _t, #"Training 5" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Expiry Date", Int64.Type}, {"Date  Awarded", Int64.Type}}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Changed Type",{{"Expiry Date", type date}, {"Date  Awarded", type date}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type1", {"Date  Awarded", "Expiry Date", "Employee Number", "Last Name", "First Name"}, "Attribute", "Value"),
    #"Filtered Rows" = Table.SelectRows(#"Unpivoted Other Columns", each ([Value] <> " "))
in
    #"Filtered Rows"

lbendlin_0-1730209980558.png

 

2.  Once you did that you can let the visual do the rest of the work.

lbendlin_1-1730210069510.png

 

 

View solution in original post

SamWiseOwl
Super User
Super User

Hi @qasimawan 
Could you use Group By to achieve what you are looking for

SamWiseOwl_0-1730210078672.png

SamWiseOwl_1-1730210100182.png

 


If you are happy with this answer please mark as a solution for others to find !

Kudos are always appreciated! Check out our free Power BI video courses.

View solution in original post

Omid_Motamedise
Super User
Super User

Just copy the below code and past it into advance editor

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("pZKxCsIwEIZfpWTucJdc7pLVUXBxLR1ESxWEotb3t+QUpRQa4hD+ZPh+jvvSNGY7dKY2m+vQ94/pgtaRZwnTtXqffXd7Xu7daflZmbZeayEX2f00VpnslMGndBaKeKGofKAy3qckLpxfxCovMmN3h/F4zuzw2hEKdyCckhAXeJ1jrSOgziBlHhg8/OORISSPFGORR0an/wDow3/3n9thIbn0CHOXmbyg8snHAt++AA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"First Name" = _t, #"Last Name" = _t, #"Employee Number" = _t, #"Expiry Date" = _t, #"Date  Awarded" = _t, #"Training 1" = _t, #"Training 2 " = _t, #"Training 3" = _t, #"Training 4" = _t, #"Training 5" = _t]),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(Source, {"First Name", "Last Name"}, "Attribute", "Value"),
    #"Filtered Rows" = Table.SelectRows(#"Unpivoted Other Columns", each ([Value] <> " ")),
    #"Pivoted Column" = Table.Pivot(#"Filtered Rows", List.Distinct(#"Filtered Rows"[Attribute]), "Attribute", "Value", each Text.Combine(_,", "))
in
    #"Pivoted Column"

View solution in original post

4 REPLIES 4
Omid_Motamedise
Super User
Super User

Just copy the below code and past it into advance editor

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("pZKxCsIwEIZfpWTucJdc7pLVUXBxLR1ESxWEotb3t+QUpRQa4hD+ZPh+jvvSNGY7dKY2m+vQ94/pgtaRZwnTtXqffXd7Xu7daflZmbZeayEX2f00VpnslMGndBaKeKGofKAy3qckLpxfxCovMmN3h/F4zuzw2hEKdyCckhAXeJ1jrSOgziBlHhg8/OORISSPFGORR0an/wDow3/3n9thIbn0CHOXmbyg8snHAt++AA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"First Name" = _t, #"Last Name" = _t, #"Employee Number" = _t, #"Expiry Date" = _t, #"Date  Awarded" = _t, #"Training 1" = _t, #"Training 2 " = _t, #"Training 3" = _t, #"Training 4" = _t, #"Training 5" = _t]),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(Source, {"First Name", "Last Name"}, "Attribute", "Value"),
    #"Filtered Rows" = Table.SelectRows(#"Unpivoted Other Columns", each ([Value] <> " ")),
    #"Pivoted Column" = Table.Pivot(#"Filtered Rows", List.Distinct(#"Filtered Rows"[Attribute]), "Attribute", "Value", each Text.Combine(_,", "))
in
    #"Pivoted Column"
Anonymous
Not applicable

Yes, just hold control and click on the first three rows, and then the last row, then click, remove duplicates.

 

--Nate

SamWiseOwl
Super User
Super User

Hi @qasimawan 
Could you use Group By to achieve what you are looking for

SamWiseOwl_0-1730210078672.png

SamWiseOwl_1-1730210100182.png

 


If you are happy with this answer please mark as a solution for others to find !

Kudos are always appreciated! Check out our free Power BI video courses.

lbendlin
Super User
Super User

1. Your data is not in a usable format. Unpivot it to make it usable.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("pZKxCsIwEIZfpWTucJdc7pLVUXBxLR1ESxWEotb3t+QUpRQa4hD+ZPh+jvvSNGY7dKY2m+vQ94/pgtaRZwnTtXqffXd7Xu7daflZmbZeayEX2f00VpnslMGndBaKeKGofKAy3qckLpxfxCovMmN3h/F4zuzw2hEKdyCckhAXeJ1jrSOgziBlHhg8/OORISSPFGORR0an/wDow3/3n9thIbn0CHOXmbyg8snHAt++AA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"First Name" = _t, #"Last Name" = _t, #"Employee Number" = _t, #"Expiry Date" = _t, #"Date  Awarded" = _t, #"Training 1" = _t, #"Training 2 " = _t, #"Training 3" = _t, #"Training 4" = _t, #"Training 5" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Expiry Date", Int64.Type}, {"Date  Awarded", Int64.Type}}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Changed Type",{{"Expiry Date", type date}, {"Date  Awarded", type date}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type1", {"Date  Awarded", "Expiry Date", "Employee Number", "Last Name", "First Name"}, "Attribute", "Value"),
    #"Filtered Rows" = Table.SelectRows(#"Unpivoted Other Columns", each ([Value] <> " "))
in
    #"Filtered Rows"

lbendlin_0-1730209980558.png

 

2.  Once you did that you can let the visual do the rest of the work.

lbendlin_1-1730210069510.png

 

 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Jan25PBI_Carousel

Power BI Monthly Update - January 2025

Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.

Jan NL Carousel

Fabric Community Update - January 2025

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