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
danilomorganti
Frequent Visitor

Calculate cumulative reverse

Hello guys!

I need your help about a reverse cumulative formula. I get data from file with the cumulative of value and I would like to decompose this value with day-by-day value. How can I do it?

 

Source data is like this

DateCumulative
01/01/20210
02/01/202110
03/01/202115
04/01/202123
05/01/202134
06/01/202156
07/01/202178
08/01/202185

 

And I would like to automatically calculate the single day value in the same month, the result should this

 

DateCumulativeResult
01/01/202100
02/01/20211010
03/01/2021155
04/01/2021238
05/01/20213411
06/01/20215622
07/01/20217822
08/01/2021857

 

Could someone help me?

 

Thank you so much!

2 ACCEPTED SOLUTIONS
Jimmy801
Community Champion
Community Champion

Hello @danilomorganti 

 

you can try this approach but it doesn't look on the date but really on the prior cell value. It basically adds a new column with the cumulative-column but shifted down by one row. After that a new column is added where your needed calculation takes place

Here a code example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Tc27DQAhDATRXhwjnT8Y3Aui/zbO0hKsNNFL5hxR+zpXNxmickeTE9mzYEvYJPOAJVlM2CLLBdtku2BFVv24Pw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Cumulative = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"Cumulative", Int64.Type}}),
    GetNewColumnWithPreviousValue = Table.FromColumns
    (
        Table.ToColumns(#"Changed Type")&{{0}&List.RemoveLastN(#"Changed Type"[Cumulative])},
        Table.ColumnNames(#"Changed Type")&{"CumulativeShifted"}
    ),
    #"Added Custom" = Table.AddColumn(GetNewColumnWithPreviousValue, "Result", each [Cumulative]-[CumulativeShifted]),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"CumulativeShifted"})
in
    #"Removed Columns"

Result

Jimmy801_0-1613118940048.png

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

v-alq-msft
Community Support
Community Support

Hi, @danilomorganti 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Table:

h1.png

 

You may create a custom column as below.

let
tab=Table.SelectRows(#"Changed Type",(x)=>Date.Month(x[Date])=Date.Month([Date]) and x[Date]<[Date]),
m=try [Cumulative]-Table.Max(tab,"Date")[Cumulative] otherwise [Cumulative]-0
in 
m

h2.png

 

Result:

h3.png

 

Best Regards

Allan

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
Jimmy801
Community Champion
Community Champion

Hello @danilomorganti 

 

did some replies help you solving the problem?

 

BR

 

Jimmy

v-alq-msft
Community Support
Community Support

Hi, @danilomorganti 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Table:

h1.png

 

You may create a custom column as below.

let
tab=Table.SelectRows(#"Changed Type",(x)=>Date.Month(x[Date])=Date.Month([Date]) and x[Date]<[Date]),
m=try [Cumulative]-Table.Max(tab,"Date")[Cumulative] otherwise [Cumulative]-0
in 
m

h2.png

 

Result:

h3.png

 

Best Regards

Allan

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Jimmy801
Community Champion
Community Champion

Hello @danilomorganti 

 

you can try this approach but it doesn't look on the date but really on the prior cell value. It basically adds a new column with the cumulative-column but shifted down by one row. After that a new column is added where your needed calculation takes place

Here a code example

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Tc27DQAhDATRXhwjnT8Y3Aui/zbO0hKsNNFL5hxR+zpXNxmickeTE9mzYEvYJPOAJVlM2CLLBdtku2BFVv24Pw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Cumulative = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"Cumulative", Int64.Type}}),
    GetNewColumnWithPreviousValue = Table.FromColumns
    (
        Table.ToColumns(#"Changed Type")&{{0}&List.RemoveLastN(#"Changed Type"[Cumulative])},
        Table.ColumnNames(#"Changed Type")&{"CumulativeShifted"}
    ),
    #"Added Custom" = Table.AddColumn(GetNewColumnWithPreviousValue, "Result", each [Cumulative]-[CumulativeShifted]),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"CumulativeShifted"})
in
    #"Removed Columns"

Result

Jimmy801_0-1613118940048.png

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

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