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

Get inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.

Reply
DataAnalystEvo
Regular Visitor

Cumulative sum by row with more values per day

Hello, I'm struggling with a cumulative sum issue. I'm simplifiying the scenario here, however I have a table with date, accounting document reference, reason of accounting movement and amount. I want to create a measure which calculates the cumulative sum of the amount for each row,  without grouping the movements that share the same date. 
The following pictures shows what I want. Look how despite 3 rows share the same date, the cumulative sum is calculated for each row.
Screenshot 2024-06-14 121109.png

 I've tried several filter functions, without reaching the result. The following measure doesn't make the job, since the cumulative sum is grouped for the 3 rows sharing the date.

Cumulative sum =
VAR MaxDate =
    MAX( ' Calendar'[Date] )
VAR CumulativeSum =
        CALCULATE(
            SUM( 'Table'[Amount ),
            ALL( 'Table'[Document] ),
            ALL( 'Table'[Reason] ),
            'Calendar'[Date] <= MaxDate
        )
    )
RETURN CumulativeSum

This is the result of the previous measure, and it's not what I want.
Screenshot 2024-06-14 121118.png

 

Any help, please?

1 ACCEPTED SOLUTION
v-yangliu-msft
Community Support
Community Support

Thanks for the reply from @some_bih , please allow me to provide another insight: 
Hi  @DataAnalystEvo ,

In your data you have the same date, so in the calculation it will add all the values for the same date 2022.4.30 as one, you can consider creating an Index that assigns a separate label to each row.

There are two ways to create an Index, one on Power Query and the other way you can follow the steps below

In Power Query -- add Column – Index Column – From 1.

vyangliumsft_0-1718594118008.jpeg

Here are the steps you can follow:

1. Create calculated column.

Index =
var _search=SEARCH(".",'Table'[Document],1)
return
VALUE(RIGHT(
    [Document],
    LEN([Document]) - _search))

vyangliumsft_1-1718594118009.png

2. Create measure.

Measure =
SUMX(
    FILTER(ALL('Table'),
    'Table'[Index]<=MAX('Table'[Index])),[Amount])

3. Result:

vyangliumsft_2-1718594152037.png

 

Best Regards,

Liu Yang

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
v-yangliu-msft
Community Support
Community Support

Thanks for the reply from @some_bih , please allow me to provide another insight: 
Hi  @DataAnalystEvo ,

In your data you have the same date, so in the calculation it will add all the values for the same date 2022.4.30 as one, you can consider creating an Index that assigns a separate label to each row.

There are two ways to create an Index, one on Power Query and the other way you can follow the steps below

In Power Query -- add Column – Index Column – From 1.

vyangliumsft_0-1718594118008.jpeg

Here are the steps you can follow:

1. Create calculated column.

Index =
var _search=SEARCH(".",'Table'[Document],1)
return
VALUE(RIGHT(
    [Document],
    LEN([Document]) - _search))

vyangliumsft_1-1718594118009.png

2. Create measure.

Measure =
SUMX(
    FILTER(ALL('Table'),
    'Table'[Index]<=MAX('Table'[Index])),[Amount])

3. Result:

vyangliumsft_2-1718594152037.png

 

Best Regards,

Liu Yang

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

Thank you @v-yangliu-msft . 

As I said, I was oversimplifiyng the scenario in my post. I have a huge fact table with a very complex data model, and more filters are included in the measure I have to build. Indeed, I had already tried with a Power Query-calculated index column, but it didn't work, the measure was extremely slow and thus ineffective. However, I found that your advice is effective. For some reason still not so clear to me, SUMX + FILTER(Table) is way more quick and I achieved my goal. Thank you. 

some_bih
Super User
Super User

Hi @DataAnalystEvo try v2 below

Cumulative sum v2 =
VAR MaxDate =
    MAX( ' Calendar'[Date] )
VAR CumulativeSum =
        CALCULATE(
            SUM( 'Table'[Amount ),
 
            'Calendar'[Date] <= MaxDate,
ALL('Calendar')
        )
    )
RETURN CumulativeSum




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!






Helpful resources

Announcements
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!

FebPBI_Carousel

Power BI Monthly Update - February 2025

Check out the February 2025 Power BI update to learn about new features.

March2025 Carousel

Fabric Community Update - March 2025

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