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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
Catalanello
New Member

Transfer data from column to line

Hi,

I have a table with the following line structure:

CostCenter LineNo Period1Amount Period2Amount Period3Amount ...

To compare the information in PowerBi I need for each Period one line, for example:

CostCenter LineNo PeriodNo  PeriodAmount

Is there a way to transform the data using power query?

Thanks in forward,

Catalanello

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

Hi @Catalanello ,

 

You can try it out with the Unpivot feature.

Here's an example.

vstephenmsft_0-1651737552499.png

 

Select the CostCenter column and the LineNo column, then click 'Unpivot Other Columns'.

vstephenmsft_1-1651737873019.png

vstephenmsft_2-1651737901082.png

Rename the columns.

vstephenmsft_3-1651737949916.png

 

 

Best Regards,

Stephen Tao

 

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

2 REPLIES 2
v-stephen-msft
Community Support
Community Support

Hi @Catalanello ,

 

You can try it out with the Unpivot feature.

Here's an example.

vstephenmsft_0-1651737552499.png

 

Select the CostCenter column and the LineNo column, then click 'Unpivot Other Columns'.

vstephenmsft_1-1651737873019.png

vstephenmsft_2-1651737901082.png

Rename the columns.

vstephenmsft_3-1651737949916.png

 

 

Best Regards,

Stephen Tao

 

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

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)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("TY1BDsAgCAT/wtkDCAY8tt8w/v8bQou1CUvIMtkdAy4oQC52qaFvcRnF1cJrCLO8XE2va3zPxP/OnFBnTJqexMgWxo+r6ZnuPrHdx+1wnGylf0p2zgU=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [CostCenter = _t, LineNo = _t, Period1 = _t, Amount = _t, Period2 = _t, Amount.1 = _t, Period3 = _t, Amount.2 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"CostCenter", type text}, {"LineNo", Int64.Type}, {"Period1", Int64.Type}, {"Amount", Int64.Type}, {"Period2", Int64.Type}, {"Amount.1", Int64.Type}, {"Period3", Int64.Type}, {"Amount.2", Int64.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"CostCenter", "LineNo"}, "Attribute", "Value"),
    #"Added Index" = Table.AddIndexColumn(#"Unpivoted Other Columns", "Index", 0, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "PeriodNo", each if Text.Contains([Attribute], "Period") then [Value] else null),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "PeriodAmount", each if Text.Contains([Attribute],"Period") then #"Added Custom"[Value]{[Index]+1} else null),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom1", each ([PeriodNo] <> null)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Index", "Attribute", "Value"})
in
    #"Removed Columns"

 

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

Power BI Carousel June 2024

Power BI Monthly Update - June 2024

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

RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

Top Solution Authors
Top Kudoed Authors