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
Anonymous
Not applicable

Data Transformation & Aggregation - Multiple cell values to columns

Hi all, 

 

currently I am struggling with a messy excel file that I need to transform. Here is an example of the input I get in Power Query and the desired output:

danielvoss01_0-1651664413690.png

I am glad about any help on how to get the output.

Best,

Daniel

1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

Note - I am not sure whether you are picking up your project name from column 3 or column 1. Hence, in last step, I have kept both. You can delete one as per your requirement.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCijKz0pNLok31KvIKc5V0oEJKOQl5qZagfiGSILFJYlFJSBRQ30jfSMDIyMkufT8xBwQ191QKVYHj8G5iXmJ6alFYLN9kQ1PzUuBGG1sCDPbKTUvNS2zBMRCNdUIp3ONsDnXSN8Up3ON8BuM4lwjTOca6xsZY3Eu0NRYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Column 1" = _t, #"Column 2" = _t, #"Column 3" = _t, #"Column 4" = _t, #"Column 5" = _t, #"Column 6" = _t, #"Column 7" = _t]),
    #"Extracted Text Before Delimiter" = Table.TransformColumns(Source, {{"Column 1", each Text.BeforeDelimiter(_, "."), type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Extracted Text Before Delimiter", {"Column 1"}, "Attribute", "Value"),
    #"Removed Columns" = Table.RemoveColumns(#"Unpivoted Other Columns",{"Attribute"}),
    #"Added Index" = Table.AddIndexColumn(#"Removed Columns", "Index", 0, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Custom", each try #"Added Index"[Value]{[Index]+1} otherwise null),
    #"Calculated Modulo" = Table.TransformColumns(#"Added Custom", {{"Index", each Number.Mod(_, 2), type number}}),
    #"Filtered Rows" = Table.SelectRows(#"Calculated Modulo", each ([Index] = 0)),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"Index"}),
    #"Replaced Value" = Table.ReplaceValue(#"Removed Columns1",":","",Replacer.ReplaceText,{"Value"}),
    #"Pivoted Column" = Table.Pivot(#"Replaced Value", List.Distinct(#"Replaced Value"[Value]), "Value", "Custom"),
    #"Reordered Columns" = Table.ReorderColumns(#"Pivoted Column",{"Column 1", "Project name", "Project manager", "Project start", "Project end", "Project goal", "Benefit"}),
    #"Changed Type" = Table.TransformColumnTypes(#"Reordered Columns",{{"Column 1", type text}, {"Project name", type text}, {"Project manager", type text}, {"Project start", type date}, {"Project end", type date}, {"Project goal", type text}, {"Benefit", type text}})
in
    #"Changed Type"

 

View solution in original post

2 REPLIES 2
Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

Note - I am not sure whether you are picking up your project name from column 3 or column 1. Hence, in last step, I have kept both. You can delete one as per your requirement.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCijKz0pNLok31KvIKc5V0oEJKOQl5qZagfiGSILFJYlFJSBRQ30jfSMDIyMkufT8xBwQ191QKVYHj8G5iXmJ6alFYLN9kQ1PzUuBGG1sCDPbKTUvNS2zBMRCNdUIp3ONsDnXSN8Up3ON8BuM4lwjTOca6xsZY3Eu0NRYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Column 1" = _t, #"Column 2" = _t, #"Column 3" = _t, #"Column 4" = _t, #"Column 5" = _t, #"Column 6" = _t, #"Column 7" = _t]),
    #"Extracted Text Before Delimiter" = Table.TransformColumns(Source, {{"Column 1", each Text.BeforeDelimiter(_, "."), type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Extracted Text Before Delimiter", {"Column 1"}, "Attribute", "Value"),
    #"Removed Columns" = Table.RemoveColumns(#"Unpivoted Other Columns",{"Attribute"}),
    #"Added Index" = Table.AddIndexColumn(#"Removed Columns", "Index", 0, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Custom", each try #"Added Index"[Value]{[Index]+1} otherwise null),
    #"Calculated Modulo" = Table.TransformColumns(#"Added Custom", {{"Index", each Number.Mod(_, 2), type number}}),
    #"Filtered Rows" = Table.SelectRows(#"Calculated Modulo", each ([Index] = 0)),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"Index"}),
    #"Replaced Value" = Table.ReplaceValue(#"Removed Columns1",":","",Replacer.ReplaceText,{"Value"}),
    #"Pivoted Column" = Table.Pivot(#"Replaced Value", List.Distinct(#"Replaced Value"[Value]), "Value", "Custom"),
    #"Reordered Columns" = Table.ReorderColumns(#"Pivoted Column",{"Column 1", "Project name", "Project manager", "Project start", "Project end", "Project goal", "Benefit"}),
    #"Changed Type" = Table.TransformColumnTypes(#"Reordered Columns",{{"Column 1", type text}, {"Project name", type text}, {"Project manager", type text}, {"Project start", type date}, {"Project end", type date}, {"Project goal", type text}, {"Benefit", type text}})
in
    #"Changed Type"

 

Anonymous
Not applicable

Hey,

 

that works! TY so much for your help!

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! Prices go up Feb. 11th.

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.