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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
diegoa2f
Frequent Visitor

Cumulative sum in rows with Power query

Hello,

 

I would like to know if it's posible to do an acumulative sum in rows with power query, for example:

diegoa2f_0-1675264986560.png

diegoa2f_1-1675265062649.png

 

I've a mother table that give me how many incidences have the client per day and the Acumulative Sum Table that gives the acumulative sum per day.

 

It's posbile to do this in power query or it's better to do it in Power BI?

 

Hope you can give the solution.

 

Best regards. 

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

Hi , @diegoa2f 

According to your description, you want to  "do an acumulative sum in rows with power query".

Here are the steps you can refer to :
(1)This is my test data:

vyueyunzhmsft_0-1675306936797.png

(2)You can put this M code in the "Advanced Editor" to refer to :

vyueyunzhmsft_1-1675306969052.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bY7LCUAhDAR7ydmD+RjtJdh/GyYSH/LwMLAkw7JmgMTSoEB10CGHM1eYxSAE7debMgeylTDGdT0l9BnaG7OwPCpwyyHFFh2aa+jnujMX", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Installation = _t, #"1/1/2023" = _t, #"2/1/2023" = _t, #"3/1/2023" = _t, #"4/1/2023" = _t, #"5/1/2023" = _t, #"6/1/2023" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Installation", Int64.Type}, {"1/1/2023", Int64.Type}, {"2/1/2023", Int64.Type}, {"3/1/2023", Int64.Type}, {"4/1/2023", Int64.Type}, {"5/1/2023", Int64.Type}, {"6/1/2023", Int64.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Installation"}, "Attribute", "Value"),
    #"Changed Type1" = Table.TransformColumnTypes(#"Unpivoted Other Columns",{{"Attribute", type date}}),
    Custom1 = Table.Group(#"Changed Type1",{"Installation","Attribute"},{"test",(x)=>List.Sum(Table.SelectRows(#"Changed Type1",(y)=> y[Installation]=x[Installation]{0} and y[Attribute]<=x[Attribute]{0})[Value])    }),
    #"Pivoted Column" = Table.Pivot(Table.TransformColumnTypes(Custom1, {{"Attribute", type text}}, "en-US"), List.Distinct(Table.TransformColumnTypes(Custom1, {{"Attribute", type text}}, "en-US")[Attribute]), "Attribute", "test", List.Max)
in
    #"Pivoted Column"

Then we can get the table you need:

vyueyunzhmsft_2-1675306998874.png

Thank you for your time and sharing, and thank you for your support and understanding of PowerBI! 

 

Best Regards,

Aniya 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
Ashish_Mathur
Super User
Super User

Hi,

Your initial step should be to use the "Unpivot Other columns" feature on the Mother table.  Then create a Calendar Table.  Create a relationship (Many to One and Single) from the Value column of the Mother table to the Date column of the Calendar Table.  You should then be able to write measures.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
v-yueyunzh-msft
Community Support
Community Support

Hi , @diegoa2f 

According to your description, you want to  "do an acumulative sum in rows with power query".

Here are the steps you can refer to :
(1)This is my test data:

vyueyunzhmsft_0-1675306936797.png

(2)You can put this M code in the "Advanced Editor" to refer to :

vyueyunzhmsft_1-1675306969052.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bY7LCUAhDAR7ydmD+RjtJdh/GyYSH/LwMLAkw7JmgMTSoEB10CGHM1eYxSAE7debMgeylTDGdT0l9BnaG7OwPCpwyyHFFh2aa+jnujMX", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Installation = _t, #"1/1/2023" = _t, #"2/1/2023" = _t, #"3/1/2023" = _t, #"4/1/2023" = _t, #"5/1/2023" = _t, #"6/1/2023" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Installation", Int64.Type}, {"1/1/2023", Int64.Type}, {"2/1/2023", Int64.Type}, {"3/1/2023", Int64.Type}, {"4/1/2023", Int64.Type}, {"5/1/2023", Int64.Type}, {"6/1/2023", Int64.Type}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Installation"}, "Attribute", "Value"),
    #"Changed Type1" = Table.TransformColumnTypes(#"Unpivoted Other Columns",{{"Attribute", type date}}),
    Custom1 = Table.Group(#"Changed Type1",{"Installation","Attribute"},{"test",(x)=>List.Sum(Table.SelectRows(#"Changed Type1",(y)=> y[Installation]=x[Installation]{0} and y[Attribute]<=x[Attribute]{0})[Value])    }),
    #"Pivoted Column" = Table.Pivot(Table.TransformColumnTypes(Custom1, {{"Attribute", type text}}, "en-US"), List.Distinct(Table.TransformColumnTypes(Custom1, {{"Attribute", type text}}, "en-US")[Attribute]), "Attribute", "test", List.Max)
in
    #"Pivoted Column"

Then we can get the table you need:

vyueyunzhmsft_2-1675306998874.png

Thank you for your time and sharing, and thank you for your support and understanding of PowerBI! 

 

Best Regards,

Aniya Zhang

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

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

Find out what's new and trending in the Fabric Community.

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

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! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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