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
h4tt3n
Resolver II
Resolver II

Convert table with year rows and month columns to table with date column

Hi,

 

I have got a table where rows represent years and columns represent months.

The table also contains a "Normal" row with averages per month, and a "Total" column with sums per year.

 

h4tt3n_0-1650967776356.png

(The values are degree-days, and I need them for energy consumption calculations and optimization) 

 

I would like to give it a structure similar to a calendar- or time-series table, with a Year-Month / Date, and Value column, so I can relate it to my calendar table.

As I see it, we would need an extra column for "Normal", and an extra row per year for "Total", alternatively skip this value, since it can be easily calculated.

 

I have spent the last couple of hours testing different solutions, eg. crossjoining separate month and year based tables, without much progress. How would I do this?

 

Cheers, Mike

 

 

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

If that's not what you want, spend another hour to publish a copyable table

 

let
    Origine = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("TZNLksMgDAXv4nUW1geQzpLK/a8xpgWDN6qUX/ml3Yjv99Jb7utzyc2s38o0pjMbszMHM5g5p/KuPu/+PhQKhY3CQWFSxfNmVJEO0khKhJKZqs5UbexCfbE5bEEVz3t/8ThVQYlSMlOFX7vvQhgEBoPKIek8H9AmDHyL6kzVYWvQDtKUXegvb8UG1eB56vIzq2DzvnieGTM1HJrELoQND+LtGAv+F7fLEqmSKqmRGqk96Srs50zL22KDRIqqLEEbTlWnaqaGQxu6CzFmUOFEAj83rrCqDSp82m1UDaqEKggzd2GcfaszXd6KDVfsnmZR4c1h41sch659F+axN+zsGNuobRxj7IOxn9ahzUHVTP3Z2CrU112IvfP/3mBb54hn475YFhWTdz32TdG6EXWy8EixwYlPkzpHvGHS2UlnGx2H7d43RetGvO5C7VudaXlbbJxvztRtpo7zBn+z56b8/gA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [year = _t, gen = _t, feb = _t, mar = _t, apr = _t, mag = _t, giu = _t, lug = _t, ago = _t, set = _t, ott = _t, nov = _t, dic = _t]),
    #"Modificato tipo" = Table.TransformColumnTypes(Origine,{{"year", Int64.Type}, {"gen", Int64.Type}, {"feb", Int64.Type}, {"mar", Int64.Type}, {"apr", Int64.Type}, {"mag", Int64.Type}, {"giu", Int64.Type}, {"lug", Int64.Type}, {"ago", Int64.Type}, {"set", Int64.Type}, {"ott", Int64.Type}, {"nov", Int64.Type}, {"dic", Int64.Type}}),
    #"Trasformate altre colonne tramite UnPivot" = Table.UnpivotOtherColumns(#"Modificato tipo", {"year"}, "Attributo", "Valore")
in
    #"Trasformate altre colonne tramite UnPivot"

 

View solution in original post

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)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("XZA7DgIxDETvknqL2HFs5xJcYLUFPQiJ+xfkhdBQ7MifyRtrz7No1VqOItqmUpk5mn33w2OqJnUXdl5977IqilirUa5jAQVrByDxw4gnVpfd/399oahUp2mTmI00QoOdJ9FhUHPEOpx5rPMjx9TWUBuoN/IG9pDIhb293s/7g0gMIAjlIc/oZXERRsLhAu37p8TKdX0A", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Year = _t, January = _t, February = _t, March = _t, April = _t, May = _t, June = _t, July = _t, August = _t, September = _t, October = _t, November = _t, December = _t, Total = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Year", type text}, {"January", Int64.Type}, {"February", Int64.Type}, {"March", Int64.Type}, {"April", Int64.Type}, {"May", Int64.Type}, {"June", Int64.Type}, {"July", Int64.Type}, {"August", Int64.Type}, {"September", Int64.Type}, {"October", Int64.Type}, {"November", Int64.Type}, {"December", Int64.Type}, {"Total", Int64.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Year"}, "Attribute", "Value"),
    #"Filtered Rows" = Table.SelectRows(#"Unpivoted Other Columns", each ([Year] <> "Normal")),
    #"Added Index" = Table.AddIndexColumn(#"Filtered Rows", "Index", 0, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Date", each try Date.From("1"&[Attribute]&[Year]) otherwise [Year]&"-"&[Attribute]),
    Custom1 = Table.SelectRows(#"Unpivoted Other Columns", each ([Year] = "Normal")),
    #"Merged Queries" = Table.NestedJoin(#"Added Custom", {"Attribute"}, Custom1, {"Attribute"}, "Custom1", JoinKind.LeftOuter),
    #"Expanded Custom1" = Table.ExpandTableColumn(#"Merged Queries", "Custom1", {"Value"}, {"Value.1"}),
    #"Sorted Rows" = Table.Sort(#"Expanded Custom1",{{"Index", Order.Ascending}}),
    #"Removed Columns" = Table.RemoveColumns(#"Sorted Rows",{"Year", "Attribute", "Index"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{"Date", "Value", "Value.1"}),
    #"Renamed Columns" = Table.RenameColumns(#"Reordered Columns",{{"Value.1", "Normal"}})
in
    #"Renamed Columns"

 

View solution in original post

6 REPLIES 6
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)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("XZA7DgIxDETvknqL2HFs5xJcYLUFPQiJ+xfkhdBQ7MifyRtrz7No1VqOItqmUpk5mn33w2OqJnUXdl5977IqilirUa5jAQVrByDxw4gnVpfd/399oahUp2mTmI00QoOdJ9FhUHPEOpx5rPMjx9TWUBuoN/IG9pDIhb293s/7g0gMIAjlIc/oZXERRsLhAu37p8TKdX0A", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Year = _t, January = _t, February = _t, March = _t, April = _t, May = _t, June = _t, July = _t, August = _t, September = _t, October = _t, November = _t, December = _t, Total = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Year", type text}, {"January", Int64.Type}, {"February", Int64.Type}, {"March", Int64.Type}, {"April", Int64.Type}, {"May", Int64.Type}, {"June", Int64.Type}, {"July", Int64.Type}, {"August", Int64.Type}, {"September", Int64.Type}, {"October", Int64.Type}, {"November", Int64.Type}, {"December", Int64.Type}, {"Total", Int64.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Year"}, "Attribute", "Value"),
    #"Filtered Rows" = Table.SelectRows(#"Unpivoted Other Columns", each ([Year] <> "Normal")),
    #"Added Index" = Table.AddIndexColumn(#"Filtered Rows", "Index", 0, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Date", each try Date.From("1"&[Attribute]&[Year]) otherwise [Year]&"-"&[Attribute]),
    Custom1 = Table.SelectRows(#"Unpivoted Other Columns", each ([Year] = "Normal")),
    #"Merged Queries" = Table.NestedJoin(#"Added Custom", {"Attribute"}, Custom1, {"Attribute"}, "Custom1", JoinKind.LeftOuter),
    #"Expanded Custom1" = Table.ExpandTableColumn(#"Merged Queries", "Custom1", {"Value"}, {"Value.1"}),
    #"Sorted Rows" = Table.Sort(#"Expanded Custom1",{{"Index", Order.Ascending}}),
    #"Removed Columns" = Table.RemoveColumns(#"Sorted Rows",{"Year", "Attribute", "Index"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{"Date", "Value", "Value.1"}),
    #"Renamed Columns" = Table.RenameColumns(#"Reordered Columns",{{"Value.1", "Normal"}})
in
    #"Renamed Columns"

 

@Vijay_A_Verma 

 

Thank you for a very detailed answer. This has given me all the toos I need to solve the challenge.

 

Cheers, Mike

Anonymous
Not applicable

If that's not what you want, spend another hour to publish a copyable table

 

let
    Origine = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("TZNLksMgDAXv4nUW1geQzpLK/a8xpgWDN6qUX/ml3Yjv99Jb7utzyc2s38o0pjMbszMHM5g5p/KuPu/+PhQKhY3CQWFSxfNmVJEO0khKhJKZqs5UbexCfbE5bEEVz3t/8ThVQYlSMlOFX7vvQhgEBoPKIek8H9AmDHyL6kzVYWvQDtKUXegvb8UG1eB56vIzq2DzvnieGTM1HJrELoQND+LtGAv+F7fLEqmSKqmRGqk96Srs50zL22KDRIqqLEEbTlWnaqaGQxu6CzFmUOFEAj83rrCqDSp82m1UDaqEKggzd2GcfaszXd6KDVfsnmZR4c1h41sch659F+axN+zsGNuobRxj7IOxn9ahzUHVTP3Z2CrU112IvfP/3mBb54hn475YFhWTdz32TdG6EXWy8EixwYlPkzpHvGHS2UlnGx2H7d43RetGvO5C7VudaXlbbJxvztRtpo7zBn+z56b8/gA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [year = _t, gen = _t, feb = _t, mar = _t, apr = _t, mag = _t, giu = _t, lug = _t, ago = _t, set = _t, ott = _t, nov = _t, dic = _t]),
    #"Modificato tipo" = Table.TransformColumnTypes(Origine,{{"year", Int64.Type}, {"gen", Int64.Type}, {"feb", Int64.Type}, {"mar", Int64.Type}, {"apr", Int64.Type}, {"mag", Int64.Type}, {"giu", Int64.Type}, {"lug", Int64.Type}, {"ago", Int64.Type}, {"set", Int64.Type}, {"ott", Int64.Type}, {"nov", Int64.Type}, {"dic", Int64.Type}}),
    #"Trasformate altre colonne tramite UnPivot" = Table.UnpivotOtherColumns(#"Modificato tipo", {"year"}, "Attributo", "Valore")
in
    #"Trasformate altre colonne tramite UnPivot"

 

Hi @Anonymous 

 

That did the trick - Unpivot columns. Thank you!

h4tt3n_0-1650976833396.png

In the future I will include a copyable table.

 

Cheers, Mike

 

HotChilli
Super User
Super User

I think you want to Unpivot the month columns (in Power Query).

You can then construct a Yr/Month column from the result.  This can be a date column if you want e.g. 1 feb 2011 (use Add column from examples if you are having trouble doing this) or a text column with your own design e.g. 2011/Feb

Hi @HotChilli 

 

This is exactly what I have been attempting to do, but the details elude me a bit here. By unpivoting months, you also pivot years - the two are always at right angles to each other. Creating two separate month- and year columned tables and crossjoining them creates a mess. 

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.

Top Solution Authors
Top Kudoed Authors