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

Unpivot and transform annual financial data

Dear all,

 

I am really struggeling with transforming data from a data provider I have access to. All data comes in csv/xml on the format below;

 

Source

 

My goal is to set up a routine in power query / power bi to transform/unpivot this structure into a "database format";

Goal

 

The biggest challenge is that the the routine needs to be scalable. In other words; 

  • Support up to "-10y"
  • Additional variables, up to 15 at once (all ends with i.e "-1y" or nothing of it is "-0y"

I have spent way to much time trying to figure this out, both through books and googling - so this is my last resort.

 

In advance, thank you very much!

1 ACCEPTED SOLUTION
v-yuezhe-msft
Employee
Employee

@Anonymous,

From the sample data you provided, as it’s not a standard data structure which could be unpivoted, so it’s not able to meet your requirement dynamically via M query. You can refer to below steps:

 

1. Add a new blank query and paste the following code to the Advanced Editor of  the blank query. Assume the CSV is named PIVOTTest.

let
    Source = Csv.Document(File.Contents("YourPath\PIVOTTest.csv"),[Delimiter=",", Columns=10, Encoding=1252, QuoteStyle=QuoteStyle.None]),
    #"Promoted Headers" = Table.PromoteHeaders(Source, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"CustomerID", type text}, {"Revenue", Int64.Type}, {"Revenue(-1y)", Int64.Type}, {"Revenue(-2y)", Int64.Type}, {"Accounts Payable", Int64.Type}, {"Accounts Payable(-1y)", Int64.Type}, {"Accounts Payable(-2y)", Int64.Type}, {"Year", Int64.Type}, {"Year(-1y)", Int64.Type}, {"Year(-2y)", Int64.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"CustomerID"}, "Attribute", "Value"),
    #"Replaced Value" = Table.ReplaceValue(#"Unpivoted Other Columns","(-1y)","",Replacer.ReplaceText,{"Attribute"}),
    #"Replaced Value1" = Table.ReplaceValue(#"Replaced Value","(-2y)","",Replacer.ReplaceText,{"Attribute"}),
    #"Added Index" = Table.AddIndexColumn(#"Replaced Value1", "Index", 0, 1),
    #"Pivoted Column" = Table.Pivot(#"Added Index", List.Distinct(#"Added Index"[Attribute]), "Attribute", "Value")
in
#"Pivoted Column"

1.png
2. Add a new blank query and paste the following code to the Advanced Editor of  the blank query

let
    Source = PIVOTTest,
    #"Removed Columns" = Table.RemoveColumns(Source,{"Index"}),
    #"Filtered Rows" = Table.SelectRows(#"Removed Columns", each ([Accounts Payable] <> null)),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"Revenue", "Year"}),
    #"Added Index" = Table.AddIndexColumn(#"Removed Columns1", "Index", 0, 1)
in
#"Added Index"

2.png

3. Add a new blank query and paste the following code to the Advanced Editor of  the blank query.

let
    Source = PIVOTTest,
    #"Removed Columns" = Table.RemoveColumns(Source,{"Index"}),
    #"Filtered Rows" = Table.SelectRows(#"Removed Columns", each [Year] <> null),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"Revenue", "Accounts Payable"}),
    #"Added Index" = Table.AddIndexColumn(#"Removed Columns1", "Index", 0, 1)
in
    #"Added Index"

3.JPG

4. Add a new blank query and paste the following code to the Advanced Editor of  the blank query.

let
    Source = PIVOTTest,
    #"Removed Columns" = Table.RemoveColumns(Source,{"Index"}),
    #"Filtered Rows" = Table.SelectRows(#"Removed Columns", each [Revenue] <> null),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"Accounts Payable", "Year"}),
    #"Added Index" = Table.AddIndexColumn(#"Removed Columns1", "Index", 0, 1),
    #"Merged Queries" = Table.NestedJoin(#"Added Index",{"Index"},#"PIVOTTest (3)",{"Index"},"PIVOTTest (3)",JoinKind.LeftOuter),
    #"Expanded PIVOTTest (3)" = Table.ExpandTableColumn(#"Merged Queries", "PIVOTTest (3)", {"Accounts Payable"}, {"PIVOTTest (3).Accounts Payable"}),
    #"Merged Queries1" = Table.NestedJoin(#"Expanded PIVOTTest (3)",{"Index"},#"PIVOTTest (4)",{"Index"},"PIVOTTest (4)",JoinKind.LeftOuter),
    #"Expanded PIVOTTest (4)" = Table.ExpandTableColumn(#"Merged Queries1", "PIVOTTest (4)", {"Year"}, {"PIVOTTest (4).Year"}),
    #"Removed Columns2" = Table.RemoveColumns(#"Expanded PIVOTTest (4)",{"Index"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns2",{{"PIVOTTest (3).Accounts Payable", "Accounts Payable"}, {"PIVOTTest (4).Year", "Year"}})
in
    #"Renamed Columns"

4.png

Regards,
Lydia

Community Support Team _ Lydia Zhang
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-yuezhe-msft
Employee
Employee

@Anonymous,

From the sample data you provided, as it’s not a standard data structure which could be unpivoted, so it’s not able to meet your requirement dynamically via M query. You can refer to below steps:

 

1. Add a new blank query and paste the following code to the Advanced Editor of  the blank query. Assume the CSV is named PIVOTTest.

let
    Source = Csv.Document(File.Contents("YourPath\PIVOTTest.csv"),[Delimiter=",", Columns=10, Encoding=1252, QuoteStyle=QuoteStyle.None]),
    #"Promoted Headers" = Table.PromoteHeaders(Source, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"CustomerID", type text}, {"Revenue", Int64.Type}, {"Revenue(-1y)", Int64.Type}, {"Revenue(-2y)", Int64.Type}, {"Accounts Payable", Int64.Type}, {"Accounts Payable(-1y)", Int64.Type}, {"Accounts Payable(-2y)", Int64.Type}, {"Year", Int64.Type}, {"Year(-1y)", Int64.Type}, {"Year(-2y)", Int64.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"CustomerID"}, "Attribute", "Value"),
    #"Replaced Value" = Table.ReplaceValue(#"Unpivoted Other Columns","(-1y)","",Replacer.ReplaceText,{"Attribute"}),
    #"Replaced Value1" = Table.ReplaceValue(#"Replaced Value","(-2y)","",Replacer.ReplaceText,{"Attribute"}),
    #"Added Index" = Table.AddIndexColumn(#"Replaced Value1", "Index", 0, 1),
    #"Pivoted Column" = Table.Pivot(#"Added Index", List.Distinct(#"Added Index"[Attribute]), "Attribute", "Value")
in
#"Pivoted Column"

1.png
2. Add a new blank query and paste the following code to the Advanced Editor of  the blank query

let
    Source = PIVOTTest,
    #"Removed Columns" = Table.RemoveColumns(Source,{"Index"}),
    #"Filtered Rows" = Table.SelectRows(#"Removed Columns", each ([Accounts Payable] <> null)),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"Revenue", "Year"}),
    #"Added Index" = Table.AddIndexColumn(#"Removed Columns1", "Index", 0, 1)
in
#"Added Index"

2.png

3. Add a new blank query and paste the following code to the Advanced Editor of  the blank query.

let
    Source = PIVOTTest,
    #"Removed Columns" = Table.RemoveColumns(Source,{"Index"}),
    #"Filtered Rows" = Table.SelectRows(#"Removed Columns", each [Year] <> null),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"Revenue", "Accounts Payable"}),
    #"Added Index" = Table.AddIndexColumn(#"Removed Columns1", "Index", 0, 1)
in
    #"Added Index"

3.JPG

4. Add a new blank query and paste the following code to the Advanced Editor of  the blank query.

let
    Source = PIVOTTest,
    #"Removed Columns" = Table.RemoveColumns(Source,{"Index"}),
    #"Filtered Rows" = Table.SelectRows(#"Removed Columns", each [Revenue] <> null),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"Accounts Payable", "Year"}),
    #"Added Index" = Table.AddIndexColumn(#"Removed Columns1", "Index", 0, 1),
    #"Merged Queries" = Table.NestedJoin(#"Added Index",{"Index"},#"PIVOTTest (3)",{"Index"},"PIVOTTest (3)",JoinKind.LeftOuter),
    #"Expanded PIVOTTest (3)" = Table.ExpandTableColumn(#"Merged Queries", "PIVOTTest (3)", {"Accounts Payable"}, {"PIVOTTest (3).Accounts Payable"}),
    #"Merged Queries1" = Table.NestedJoin(#"Expanded PIVOTTest (3)",{"Index"},#"PIVOTTest (4)",{"Index"},"PIVOTTest (4)",JoinKind.LeftOuter),
    #"Expanded PIVOTTest (4)" = Table.ExpandTableColumn(#"Merged Queries1", "PIVOTTest (4)", {"Year"}, {"PIVOTTest (4).Year"}),
    #"Removed Columns2" = Table.RemoveColumns(#"Expanded PIVOTTest (4)",{"Index"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns2",{{"PIVOTTest (3).Accounts Payable", "Accounts Payable"}, {"PIVOTTest (4).Year", "Year"}})
in
    #"Renamed Columns"

4.png

Regards,
Lydia

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

This is just perfect - thank you!!!

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.