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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
mahsan_ojaghian
Frequent Visitor

create a column that does cumulate sum on another column with 2 conditions

Hi guys!

I want to create a column that does cumulate sum on another column with 2 conditions:

1 ) when ID changes this function that cumulates values resets 

2 ) And when sum of values is negative resets again and returns 0 and starts again with positive value.

 i NEED YOUR HELP as soon as possible.

1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bcpBDoAgDAXRu3QNCVQtdKl4C9L7X0OxCd8Fu5fJ9E4nBVIlC07hyd15jZo/tlHrJKPGCm8JB6P6cL/MsmLUY5kLzKD8jpyQC5k9", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}, {"Value", Int64.Type}}),
    ListOfIDs = List.Buffer(#"Changed Type"[ID]),
    ListOfValues = List.Buffer(#"Changed Type"[Value]),
    //Function Start
    fxGetCumTotal=(ListOfIDs, ListOfValues)=>
        let
            FunctionResult = List.Generate(()=>[x=ListOfValues{0},i=0], each [i]<List.Count(ListOfValues), each [i=[i]+1, x=(if ListOfIDs{i}=ListOfIDs{[i]} then List.Max({0,[x]}) else 0) + ListOfValues{i}], each List.Max({0,[x]}))
        in
            FunctionResult,
    //Function End
    Result = Table.FromColumns(Table.ToColumns(#"Changed Type")&{fxGetCumTotal(ListOfIDs, ListOfValues)},Table.ColumnNames(#"Changed Type")&{"CumulativeTotal"})
in
    Result

 

 

View solution in original post

2 REPLIES 2
Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bcpBDoAgDAXRu3QNCVQtdKl4C9L7X0OxCd8Fu5fJ9E4nBVIlC07hyd15jZo/tlHrJKPGCm8JB6P6cL/MsmLUY5kLzKD8jpyQC5k9", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}, {"Value", Int64.Type}}),
    ListOfIDs = List.Buffer(#"Changed Type"[ID]),
    ListOfValues = List.Buffer(#"Changed Type"[Value]),
    //Function Start
    fxGetCumTotal=(ListOfIDs, ListOfValues)=>
        let
            FunctionResult = List.Generate(()=>[x=ListOfValues{0},i=0], each [i]<List.Count(ListOfValues), each [i=[i]+1, x=(if ListOfIDs{i}=ListOfIDs{[i]} then List.Max({0,[x]}) else 0) + ListOfValues{i}], each List.Max({0,[x]}))
        in
            FunctionResult,
    //Function End
    Result = Table.FromColumns(Table.ToColumns(#"Changed Type")&{fxGetCumTotal(ListOfIDs, ListOfValues)},Table.ColumnNames(#"Changed Type")&{"CumulativeTotal"})
in
    Result

 

 

Thank you Vijay Your Solution is Perfect!!!!!!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors