Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Hello,
I would like to know if it's posible to do an acumulative sum in rows with power query, for example:
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.
Solved! Go to Solution.
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:
(2)You can put this M code in the "Advanced Editor" to refer to :
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:
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
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.
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:
(2)You can put this M code in the "Advanced Editor" to refer to :
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:
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
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
58 | |
56 | |
56 | |
38 | |
29 |
User | Count |
---|---|
75 | |
62 | |
45 | |
40 | |
39 |