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
tamara_nsb
Frequent Visitor

Convert Monthly Columns To Rows and plotting

Hello,

I have some data I am trying to graph in this Format (see subset below) As you can see there are columns for each month of the year for each value tracked ex.  Jan-Norm,  Jan-Transfers.  and more.  

We soon need to be able to handle displaying multiple years of data and be able to select the year via a slicer.  For this particular visual the project is irrelevant,  we want the sum over all projects.   

ProjectIDYearJan - NormFeb - NormMar - NormApr - NormMay - NormJun - NormJul - NormAug - NormSep - NormOct - NormNov - NormDec - NormJan - TransfersFeb - TransfersMar - TransfersApr - TransfersMay - TransfersJun - TransfersJul - TransfersAug - TransfersSep - TransfersOct - TransfersNov - TransfersDec - Transfers
7272022111213141516171819202122000000000000
7372022102201111121000000000000
72820222345678910111213000000000000
7302023888888833333000000000000

 

They want to see the data as a Line Chart showing the months on the bottom axis and data points as cumulative values as the year progresses broken down by each month and subfield.  So with the above data set would have a line that Jan = Jan-Norm, Feb = Jan-Norm+Feb-Norm,  March = Jan-Norm + Feb-Norm + Mar-Norm, etc.   And a second line with the same for Jan-Transfers, Feb-Transfers

tamara_nsb_0-1669847599182.png

Previously this was done by using a calculated table with 12 Rows and hardcoded a month name and number to each row and added calculated columns for the cumulative.  But I don't believe this will work as a slicer does not seem to work dynamically on calculated tables.  I need to apply the Year Slicer filter to the above table before calculating the data below.  

tamara_nsb_1-1669847992846.png

Totals = {
(1, "Jan", SUM(input[Jan - Norm]), SUM(input[Jan - Transfers]),
(2, "Feb", SUM(input[Feb - Norm]), SUM(input[Feb- Transfers]),
...
(2, "Feb", SUM(input[Dec - Norm]), SUM(input[Dec- Transfers]),
 
I beleive I need to transpose or unpivot the table to get the data in the format I need but can't figure out how.   Maybe Sum or Group by Year first then try to get the Jan - Field columns into rows and split around Month name?  I do have a Date table with months in it.
Also I have been trying to create measures with the original table that will do this also.  These measures change with the slicer as I want, I can display them in a table but now how do I relate these measures into a chart with Months? 
Jan - CumNormTotal = CALCULATE(SUM('input'[Jan - Norm]))
Feb - CumNormTotal = CALCULATE(SUM('input'[Jan - Norm]) + SUM('input'[Feb - Norm])))
 
Any help would be appreciated.  I am open to any ideas on how to better handle this data to display what is required,  it seems like it should be pretty easy?  Is there another way besides a slicer that a user can filter this table by selecting a year and have it affect the calculated table?  I am new to Power BI and maybe I am just not aware of some of the basics.

 

Thanks

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

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

Hi @tamara_nsb 

 

You can put the following code in advanced editor in power query

let

    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("dY5BDoAgDAT/wplDaVXwLYb/f8NOIWo0HnYgZHfZ40hVa8pJRdWPUkDcDCxgBRvAWRrYIwNIeLZnr7JnlSsMUzLf3hreiGu744gJLGAA/9OOhc+LXHNtYCyQUWHT+if7qPcT", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Project ID" = _t, Year = _t, Jan = _t, Feb = _t, Mar = _t, Apr = _t, May = _t, Jun = _t, Jul = _t, Aug = _t, Sep = _t, Oct = _t, Nov = _t, Dec = _t]),

    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Project ID", Int64.Type}, {"Year", Int64.Type}, {"Jan", Int64.Type}, {"Feb", Int64.Type}, {"Mar", Int64.Type}, {"Apr", Int64.Type}, {"May", Int64.Type}, {"Jun", Int64.Type}, {"Jul", Int64.Type}, {"Aug", Int64.Type}, {"Sep", Int64.Type}, {"Oct", Int64.Type}, {"Nov", Int64.Type}, {"Dec", Int64.Type}}),

    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Year", "Project ID"}, "Attribute", "Value"),

    #"Renamed Columns" = Table.RenameColumns(#"Unpivoted Other Columns",{{"Attribute", "Month"}}),

    #"Grouped Rows" = Table.Group(#"Renamed Columns", {"Month", "Year"}, {{"Sum", each List.Sum([Value]), type number}}),

    #"Reordered Columns" = Table.ReorderColumns(#"Grouped Rows",{"Year", "Month", "Sum"}),

    #"Added Custom" = Table.AddColumn(#"Reordered Columns", "Custom", each Date.Month(Date.FromText([Month],[Format="MMM"]))),

    #"Reordered Columns1" = Table.ReorderColumns(#"Added Custom",{"Custom", "Year", "Month", "Sum"}),

    #"Changed Type1" = Table.TransformColumnTypes(#"Reordered Columns1",{{"Custom", Int64.Type}})

in

    #"Changed Type1"

 

then apply it to report, then create a new column in table

Sum_ = SUMX(FILTER('Table (3)','Table (3)'[Custom]<=EARLIER('Table (3)'[Custom])&&'Table (3)'[Year]=EARLIER('Table (3)'[Year])),[Sum])

vxinruzhumsft_0-1669970717054.png

 

Best Regards,

Yolo Zhu

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

4 REPLIES 4
v-xinruzhu-msft
Community Support
Community Support

Hi @tamara_nsb 

 

You can put the following code in advanced editor in power query

let

    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("dY5BDoAgDAT/wplDaVXwLYb/f8NOIWo0HnYgZHfZ40hVa8pJRdWPUkDcDCxgBRvAWRrYIwNIeLZnr7JnlSsMUzLf3hreiGu744gJLGAA/9OOhc+LXHNtYCyQUWHT+if7qPcT", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Project ID" = _t, Year = _t, Jan = _t, Feb = _t, Mar = _t, Apr = _t, May = _t, Jun = _t, Jul = _t, Aug = _t, Sep = _t, Oct = _t, Nov = _t, Dec = _t]),

    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Project ID", Int64.Type}, {"Year", Int64.Type}, {"Jan", Int64.Type}, {"Feb", Int64.Type}, {"Mar", Int64.Type}, {"Apr", Int64.Type}, {"May", Int64.Type}, {"Jun", Int64.Type}, {"Jul", Int64.Type}, {"Aug", Int64.Type}, {"Sep", Int64.Type}, {"Oct", Int64.Type}, {"Nov", Int64.Type}, {"Dec", Int64.Type}}),

    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Year", "Project ID"}, "Attribute", "Value"),

    #"Renamed Columns" = Table.RenameColumns(#"Unpivoted Other Columns",{{"Attribute", "Month"}}),

    #"Grouped Rows" = Table.Group(#"Renamed Columns", {"Month", "Year"}, {{"Sum", each List.Sum([Value]), type number}}),

    #"Reordered Columns" = Table.ReorderColumns(#"Grouped Rows",{"Year", "Month", "Sum"}),

    #"Added Custom" = Table.AddColumn(#"Reordered Columns", "Custom", each Date.Month(Date.FromText([Month],[Format="MMM"]))),

    #"Reordered Columns1" = Table.ReorderColumns(#"Added Custom",{"Custom", "Year", "Month", "Sum"}),

    #"Changed Type1" = Table.TransformColumnTypes(#"Reordered Columns1",{{"Custom", Int64.Type}})

in

    #"Changed Type1"

 

then apply it to report, then create a new column in table

Sum_ = SUMX(FILTER('Table (3)','Table (3)'[Custom]<=EARLIER('Table (3)'[Custom])&&'Table (3)'[Year]=EARLIER('Table (3)'[Year])),[Sum])

vxinruzhumsft_0-1669970717054.png

 

Best Regards,

Yolo Zhu

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

Thanks for this PowerQuery code.  I had managed to get a working solution using the Unpivot as suggested by Mike,  but your solutions is much cleaner.   But in the end it was good for learning to go through trying to solve it.  

Thanks for the help,  sometimes you just need to know your heading in the right direction.. 🙂

Mikelytics
Resident Rockstar
Resident Rockstar

Hi @tamara_nsb 

 

Have you worked with the unpivot feature in Power Query?

Mikelytics_0-1669909449528.png

Mikelytics_1-1669909475767.png

Best regards

Michael

-----------------------------------------------------

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

@ me in replies or I'll lose your thread.

-----------------------------------------------------

LinkedIn

 

 

------------------------------------------------------------------
Visit my blog datenhungrig which I recently started with content about business intelligence and Power BI in German and English or follow me on LinkedIn!

Thanks Mike,  I had started looking at that option but was not sure it was the best solution.  I wanted to make sure I am at least on the right track before trying to figure out how to unpivot the table.   I will accept this as the answer and give the final solution if I am able to get it working.  

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