cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Memorable Member
Memorable Member

Running Sum variant

say there is a Values column

5

5

5

-2

-1

5

 

the Running Sum measure would be:

5

10

15

13

12

17

 

if one needed a maximum of 12 and applied a simple IF/Switch result would be

5

10

12

12

12

12

 

but for the running sum to be based on the prior value of its own field/column - intellisense will not allow that measure to get written because of circular reference.  The result sought is:

 

 5    5

 5    10

 5    12

-2   10

-1    9

 5   12

 

perhaps there is another function that will work - or approach

 

would welcome advice on this one - has me stumped...... I should add one can assume that adding an Index column is possible.

 

@conniedevina

www.CahabaData.com
1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted

It should be something like this:

 

let
    Source = Excel.Workbook(File.Contents("D:\Projects\Internal CRM\Leave Data.xlsx"), null, true),
    Sheet1_Sheet = Source{[Item="Sheet1",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Sheet1_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Date", type date}, {"Type", type text}, {"Debit/Credit", type number}}),
    RunningSum = List.Skip(List.Accumulate(#"Changed Type"[#"Debit/Credit"],{0},(sum,value) => sum & {List.Min({12,List.Last(sum)+value})})),
    TableWithRunningSum = Table.FromColumns(Table.ToColumns(#"Changed Type")&{RunningSum},Value.Type(Table.AddColumn(#"Changed Type","Running Sum", each 0, type number)))
in
    TableWithRunningSum

 

Specializing in Power Query Formula Language (M)

View solution in original post

14 REPLIES 14
Highlighted
Community Champion
Community Champion

You can try Power Query, it has no intellisense Smiley LOL

 

let
    Source = Table.Buffer(#table(type table[Values = Int64.Type],List.Zip({{5,5,5,-2,-1,5}}))),
    RunningSum = List.Skip(List.Accumulate(Source[Values],{0},(sum,value) => sum & {List.Min({12,List.Last(sum)+value})})),
    TableWithRunningSum = Table.FromColumns(Table.ToColumns(Source)&{RunningSum},Value.Type(Table.AddColumn(Source,"Running Sum", each 0, Int64.Type)))
in
    TableWithRunningSum

 

Remark: the part in the last step:

Value.Type(Table.AddColumn(Source,"Running Sum", each 0, Int64.Type))

takes care of naming and typing the columns of the resulting table, using the table definition from Source with an added column that has the right name and type, but with a dummy value of 0.

 

Specializing in Power Query Formula Language (M)
Highlighted

Hi @MarcelBeug,

 

Thanks for replying, can you explain how to change the name? I'm actually using Dynamics as the data source. And for testing I create dummy data in excel for it.

And I still not familiar with Power Query.

 

Thanks,
Regards,
Connie

Highlighted

If you mean the name of the column, then adjust the name in double quotes ("Running Sum") in the last step.

 

You can copy my code from step 2 onwards and add it to your query, similar to this video I just creaed for another question.

 

In case you use Direct Query mode, I don't think my solution won't work.

 

Otherwise I didn't quite understand your question, so I hope I provided the answer you are looking for.

Specializing in Power Query Formula Language (M)
Highlighted

Hi @MarcelBeug,

 

Can you open my thread? Here is the Link.

I already put the explanation there. And I'm interested with your method I hope it will work.

And in there there is my pbix file maybe you can guide me.

 

Thank you

Highlighted

It should be something like this:

 

let
    Source = Excel.Workbook(File.Contents("D:\Projects\Internal CRM\Leave Data.xlsx"), null, true),
    Sheet1_Sheet = Source{[Item="Sheet1",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Sheet1_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Date", type date}, {"Type", type text}, {"Debit/Credit", type number}}),
    RunningSum = List.Skip(List.Accumulate(#"Changed Type"[#"Debit/Credit"],{0},(sum,value) => sum & {List.Min({12,List.Last(sum)+value})})),
    TableWithRunningSum = Table.FromColumns(Table.ToColumns(#"Changed Type")&{RunningSum},Value.Type(Table.AddColumn(#"Changed Type","Running Sum", each 0, type number)))
in
    TableWithRunningSum

 

Specializing in Power Query Formula Language (M)

View solution in original post

Highlighted

Hi @MarcelBeug,

 

Thank you and it works in power bi!! Now I will try to implement it that with Data source Dynamics.

I have a few question:

1. It will be sorted by date for the runningsum? Or I need to add something to make it sorted by date?

2. Can I use group by? example:

aaaa.png

 

So when later I filter by A the running sum will be right value.

 

Thanks!

Highlighted

That will be quite a different solution.

 

In the code below, replace "LeaveData" by the name of your source data.

 

let

    fnRunningSum = (MyTable as table, MyDateColumn as text,  MyLeaveColumn as text, MyRunningSumColumnName as text, MyMaxValue as number) as table =>
    let
        SortedOnDate = Table.Sort(MyTable, {MyDateColumn, Order.Ascending}),
        RunningSum = List.Skip(List.Accumulate(Table.Column(MyTable,MyLeaveColumn),{0},(sum,value) => sum & {List.Min({MyMaxValue,List.Last(sum)+value})})),
        TableWithRunningSum = Table.FromColumns(Table.ToColumns(MyTable)&{RunningSum},Value.Type(Table.AddColumn(MyTable,MyRunningSumColumnName, each 0, type number)))
    in
        TableWithRunningSum,

    Source = LeaveData,
    #"Added Index" = Table.AddIndexColumn(Source, "OriginalSort", 1, 1),
    #"Grouped Rows" = Table.Group(#"Added Index", {"Name"}, {{"AllData", each fnRunningSum(_,"Date", "Leave Taken", "RunningSum", 20), Value.Type(Table.AddColumn(#"Added Index","RunningSum", each 0, type number))}}),
    #"Expanded AllData" = Table.ExpandTableColumn(#"Grouped Rows", "AllData", {"Date", "Leave Taken", "OriginalSort", "RunningSum"}),
    #"Sorted Rows1" = Table.Sort(#"Expanded AllData",{{"OriginalSort", Order.Ascending}}),
    #"Removed Columns" = Table.RemoveColumns(#"Sorted Rows1",{"OriginalSort"})
in
    #"Removed Columns"
Specializing in Power Query Formula Language (M)
Highlighted

Hi,

 

Is there any other way? I already found that if we want to sort it I just change #"Changed Type" with #"Sorted Rows"

 

 

    RunningSum = List.Skip(List.Accumulate( #"Sorted Rows""[#"Debit/Credit"],{0},(sum,value) => sum & {List.Min({12,List.Last(sum)+value})})),
    TableWithRunningSum = Table.FromColumns(Table.ToColumns( #"Sorted Rows")&{RunningSum},Value.Type(Table.AddColumn( #"Sorted Rows","Running Sum", each 0, type number)))
in
    TableWithRunningSum

and it will sorted by the date that I already sorted before.

And I still don't understand about the grouping there it seems when I apply your code I always get error they can't found "Leave Type" but actually I already create the "Leave Type" column first before apply your code.

 

Please take a look for my code

let
    Source = OData.Feed("https://xxxxx.crm5.dynamics.com/api/data/v8.2/"),
    new_leavesummaries_table = Source{[Name="new_leavesummaries",Signature="table"]}[Data],
    #"Removed Other Columns" = Table.SelectColumns(new_leavesummaries_table,{"new_leavetype", "new_entrystatus", "new_description", "new_date", "new_totalleave", "new_BookableResource", "new_Project"}),
    #"Expanded new_BookableResource" = Table.ExpandRecordColumn(#"Removed Other Columns", "new_BookableResource", {"name"}, {"new_BookableResource.name"}),  
    #"Expanded new_Project" = Table.ExpandRecordColumn(#"Expanded new_BookableResource", "new_Project", {"msdyn_subject"}, {"new_Project.msdyn_subject"}),
    #"Changed Type with Locale" = Table.TransformColumns(#"Expanded new_Project",{{"new_date", DateTimeZone.ToLocal}}),
    #"Added Conditional Column" = Table.AddColumn(#"Changed Type with Locale", "Leave Taken", each if [new_leavetype] = "Medical Leave" then "0" else if [new_leavetype] = "Childcare Leave" then "0" else if [new_leavetype] = "Other Leave" then "0" else [new_totalleave] ),
    #"Changed Type" = Table.TransformColumnTypes(#"Added Conditional Column",{{"Leave Taken", type number}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type",{{"new_date", Order.Ascending}}),
    #"Grouped Rows" = Table.Group(#"Sorted Rows", {"new_BookableResource.name"}, {{"Leave", each _, type table}}),
    #"Expanded Leave" = Table.ExpandTableColumn(#"Grouped Rows", "Leave", {"new_leavetype", "new_entrystatus", "new_description", "new_date", "new_totalleave", "new_BookableResource.name", "new_Project.msdyn_subject", "Leave Taken"}, {"Leave.new_leavetype", "Leave.new_entrystatus", "Leave.new_description", "Leave.new_date", "Leave.new_totalleave", "Leave.new_BookableResource.name", "Leave.new_Project.msdyn_subject", "Leave.Leave Taken"})
in
    #"Expanded Leave"

Here is my code before applying your code, because I need to clean my data first from dynamics

 

Please take a note:

new_BookableResource is the name that I want to group by

and Leave Taken is such as "Debit/Credit"

 

Thanks

 

Highlighted

Only iIf you demonstrate that you tried my solution and it doesn't work, I'm willing to take another look.

 

 

Specializing in Power Query Formula Language (M)

Helpful resources

Announcements
Community Conference

Power Platform Community Conference

Check out the on demand sessions that are available now!

Community Conference

Microsoft Power Platform Communities

Check out the Winners!

secondImage

Create an end-to-end data and analytics solution

Learn how Power BI works with the latest Azure data and analytics innovations at the digital event with Microsoft CEO Satya Nadella.

Top Solution Authors
Top Kudoed Authors