March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
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
Solved! Go to Solution.
Hi @PaisleyPrince Try this in custom column:
= if [Index] < 8 then "" else List.Sum(List.Range(#"Changed Type"[Value], [Index] - 8, 8))
See image:
Hope this helps!!
If this solved your problem, please accept it as a solution and a kudos!!
Best Regards,
Shahariar Hafiz
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
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
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
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
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
= if [Index] < 8 then "" else List.Sum(List.LastN(List.FirstN(Source[Value], [Index] ), 8))
Hi @PaisleyPrince Try this in custom column:
= if [Index] < 8 then "" else List.Sum(List.Range(#"Changed Type"[Value], [Index] - 8, 8))
See image:
Hope this helps!!
If this solved your problem, please accept it as a solution and a kudos!!
Best Regards,
Shahariar Hafiz
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.