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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

How to calculate Accumulated value per month

Hello Everyone!!

I am trying to obtain the accumulated sales in a chart. I used this formula as a measure:

 

Accumulated Sales = CALCULATE (SUM(orders[value]),FILTER (ALL ( 'Calendar' ),'Calendar'[Date] <= MAX ( 'Calendar'[Date])))

 

So with that, when I use a date FILTER, for example, april, 2021. It won't start the accumulated sales first line as the total sales of april 1st, it will get the accumulated from all the previous days and months, like this:

danlindoso11_0-1620092720529.png

As you can see, the column sales represents total sales from each day of april, but the accumulated sales gets all the data since 2017.

 

I will be very grateful if someone could help me!

Thank you very much in advance!

 

1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi, @Anonymous 

Please try the below.

Instead of using ALL in your measure, replace it with ALLSELECT.

 

Accumulated Sales =
CALCULATE (
SUM ( orders[value] ),
FILTER ( ALLSELECT ( 'Calendar' ), 'Calendar'[Date] <= MAX ( 'Calendar'[Date] ) )
)

 

Hi, My name is Jihwan Kim.

 

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

 

Linkedin: linkedin.com/in/jihwankim1975/

Twitter: twitter.com/Jihwan_JHKIM

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.


Go to My LinkedIn Page


View solution in original post

3 REPLIES 3
Jihwan_Kim
Super User
Super User

Hi, @Anonymous 

Please try the below.

Instead of using ALL in your measure, replace it with ALLSELECT.

 

Accumulated Sales =
CALCULATE (
SUM ( orders[value] ),
FILTER ( ALLSELECT ( 'Calendar' ), 'Calendar'[Date] <= MAX ( 'Calendar'[Date] ) )
)

 

Hi, My name is Jihwan Kim.

 

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

 

Linkedin: linkedin.com/in/jihwankim1975/

Twitter: twitter.com/Jihwan_JHKIM

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.


Go to My LinkedIn Page


Ashish_Mathur
Super User
Super User

Hi,

Try this measure

=calculate(SUM(orders[value]),datesmtd(calendar[date]))

Hope this helps.


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

@Anonymous - Take a look at https://www.daxpatterns.com/cumulative-total/ specifically Measure in the Sales table. With my sample data I got:

Measure 2 = 
VAR LastVisibleDate = MAX(TableName[Date])
VAR DatesToSum =
    FILTER(
        ALLSELECTED(TableName[Date]),
    TableName[Date] <= LastVisibleDate
    )
VAR Result =
    CALCULATE(
        SUM(TableName[Sales]),
        DatesToSum
    )
RETURN
    Result

danlindoso11.gif






Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

Proud to be a Super User!



Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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