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
PaisleyPrince
Helper I
Helper I

Calculate running sum of previous n rows

Hi,

I'm trying to create a loop in power query to calculate the total of the previous 8 rows as per the screenshot below. Any advice would be much appreciated.

thanks

Scott

sm1.png

3 ACCEPTED SOLUTIONS
shafiz_p
Resident Rockstar
Resident Rockstar

Hi @PaisleyPrince  Try this in custom column:

= if [Index] < 8 then "" else List.Sum(List.Range(#"Changed Type"[Value], [Index] - 8, 8))

 

See image:

shafiz_p_0-1732419240736.png

 

 

 

Hope this helps!!

If this solved your problem, please accept it as a solution and a kudos!!

 

 

Best Regards,
Shahariar Hafiz

View solution in original post

AlienSx
Super User
Super User

this one works 100 times (literally - one hundred times) faster on a small set of 5000 rows.

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content], 
    values = List.Buffer(Source[Value]),
    rt = List.Generate(
        () => [i = 0, ttl = values{0}],
        (x) => x[i] < List.Count(values),
        (x) => [i = x[i] + 1, ttl = x[ttl] + values{i}],
        (x) => x[ttl]
    ), 
    last_n = List.Transform(List.Zip({rt, List.Repeat({null}, 8 - 1) & {0} & List.RemoveLastN(rt, 8)}), (x) => x{0} - x{1}),
    result = Table.FromColumns(Table.ToColumns(Source) & {last_n}, Table.ColumnNames(Source) & {"Running Sum"})
in
    result

 

View solution in original post

slorin
Super User
Super User

Hi @PaisleyPrince 

 

Adapt @shafiz_p's  solution with List.Buffer

simplier but twice slower than @AlienSx 's proposition with 20000 rows

 

let
Source = YourSource,
Values = List.Buffer(Source[Value]),
#"Running Sum" = Table.AddColumn(Source, "Running Sum",
each if [Index] < 8 then "" else List.Sum(List.Range(Values, [Index] - 8, 8)))
in
#"Running Sum"

Stéphane

View solution in original post

5 REPLIES 5
slorin
Super User
Super User

Hi @PaisleyPrince 

 

Adapt @shafiz_p's  solution with List.Buffer

simplier but twice slower than @AlienSx 's proposition with 20000 rows

 

let
Source = YourSource,
Values = List.Buffer(Source[Value]),
#"Running Sum" = Table.AddColumn(Source, "Running Sum",
each if [Index] < 8 then "" else List.Sum(List.Range(Values, [Index] - 8, 8)))
in
#"Running Sum"

Stéphane

AlienSx
Super User
Super User

this one works 100 times (literally - one hundred times) faster on a small set of 5000 rows.

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content], 
    values = List.Buffer(Source[Value]),
    rt = List.Generate(
        () => [i = 0, ttl = values{0}],
        (x) => x[i] < List.Count(values),
        (x) => [i = x[i] + 1, ttl = x[ttl] + values{i}],
        (x) => x[ttl]
    ), 
    last_n = List.Transform(List.Zip({rt, List.Repeat({null}, 8 - 1) & {0} & List.RemoveLastN(rt, 8)}), (x) => x{0} - x{1}),
    result = Table.FromColumns(Table.ToColumns(Source) & {last_n}, Table.ColumnNames(Source) & {"Running Sum"})
in
    result

 

v-junyant-msft
Community Support
Community Support

Hi @PaisleyPrince ,

It looks like shafiz_p's answer can help you solve your problem. If solved please accept the reply in this post which you think is helpful as a solution to help more others facing the same problem to find a solution quickly, thank you very much!

Best Regards,
Dino Tao

Omid_Motamedise
Memorable Member
Memorable Member

= if [Index] < 8 then "" else List.Sum(List.LastN(List.FirstN(Source[Value], [Index] ), 8))

 

shafiz_p
Resident Rockstar
Resident Rockstar

Hi @PaisleyPrince  Try this in custom column:

= if [Index] < 8 then "" else List.Sum(List.Range(#"Changed Type"[Value], [Index] - 8, 8))

 

See image:

shafiz_p_0-1732419240736.png

 

 

 

Hope this helps!!

If this solved your problem, please accept it as a solution and a kudos!!

 

 

Best Regards,
Shahariar Hafiz

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.