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

Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now

Reply
Jay0610
Frequent Visitor

Cumulative Totals

Hi,

 

I'm struggling with the DAX for calculating  the monthly cumulative shown below. (resets on each month)

 

Jay0610_0-1645923449547.png

 

Ive tried using the following but no joy! Any help would be really appreciated.

 

 

 

Monthly Cumulative = 
CALCULATE(
    SUM([Margin]),
    FILTER(ALL('Table'[date],
   'Table'[date] >= STARTOFMONTH('Table'[date] ) &&
'Table'[date]  <= MAX('Table'[date])
 ))

 

 

 

 

 

2 ACCEPTED SOLUTIONS
Ashish_Mathur
Super User
Super User

Hi,

Assuming Date and Margin are columns already present in your source data table, perform the following steps:

  1. Create a Calendar Table
  2. Build a relationship (Many to One and Single) from the Date column of your Data Table to the Date column of your Calendar Table
  3. To your Table/Matrix visual, drag Date from the Calendar Table
  4. Write these measures:

Total = sum(Data[Margin])

MTD Total = calculate([Total],datesmtd(calendar[date]))

Hope this helps.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

View solution in original post

Hi Ashish, I decided to group by date in power query as that was effectively what I was doing on the table visual in power BI. I was then able to use your method for cumulative totals on the daily target. Many thanks for your assistance with this, really appreciated

View solution in original post

10 REPLIES 10
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

 

Picture1.png

 

Monthly Cumulative =
VAR currentdate = 'Table'[Date]
VAR currentmonth =
STARTOFMONTH ( 'Table'[Date] )
VAR currentmargin = 'Table'[Margin]
RETURN
CALCULATE (
SUM ( [Margin] ),
FILTER (
'Table',
STARTOFMONTH ( 'Table'[Date] ) = currentmonth
&& 'Table'[date] <= currentdate
&& 'Table'[Margin] <= currentmargin
)
)
 

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Visit my LinkedIn page by clicking here.


Schedule a meeting with me to discuss further by clicking here.

Hi, I tried to leverage your solution for my own challenge, so I already have a Calendar dim table set as date table, and a table with events that have a value 'Converted Amount (m€)' which is recurring revenue ie need to be cumulated each month from a start date and then continued til end of calendar.

The issue with I have with your solution is that I have a message error "a single value for date cannot be determined". Any idea? thanks

many thanks Jihwan, interesting to see the use of variables in the calculation. Im not sure why but this method didnt quite work for me, I'll need to spend more time looking at this to understand why. I tried the calendar table association as described by Ashish and this worked 👍

Ashish_Mathur
Super User
Super User

Hi,

Assuming Date and Margin are columns already present in your source data table, perform the following steps:

  1. Create a Calendar Table
  2. Build a relationship (Many to One and Single) from the Date column of your Data Table to the Date column of your Calendar Table
  3. To your Table/Matrix visual, drag Date from the Calendar Table
  4. Write these measures:

Total = sum(Data[Margin])

MTD Total = calculate([Total],datesmtd(calendar[date]))

Hope this helps.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Hi Ashish, do you know if I could I use a similar approach for a 'daily cumulative total' as shown below? Happy to post this as a new topic if thats better?

Saying 'maximum' might be misleading here. The target value will be repeated for each date. So for example, all rows for 01/02/2022 will be 100.

Also the daily cumulative total would need to reset each month as shown.

 

Jay0610_1-1646059526264.png

 

 

 

Hi,

Share the link from where i can download your PBI file.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Hi Ashish, I decided to group by date in power query as that was effectively what I was doing on the table visual in power BI. I was then able to use your method for cumulative totals on the daily target. Many thanks for your assistance with this, really appreciated

You are welcome.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Excellent thanks Ashish, Im starting to see the importance of calendar tables!

You are welcome.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

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! Early Bird pricing ends December 9th.

October NL Carousel

Fabric Community Update - October 2024

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