cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
balumaran Frequent Visitor
Frequent Visitor

Cumulative Sum With Slicer

Hi, 

I am fairly new to Power BI and trying to find my ways in . 

 

I have a requirement to display YTD value ( running sum) on a sales measure with a Month Slicer.  I was able to get the running sum working. However when I select a month in the slicer, I am expecting the running sum to calculate upto the month selected in the slicer, however running sum that I am getting is filtered for the month. 

 

sum sum.PNG

 

In the above example, when MArch 2016 is selected in the slicer , I expect the running sum /YTD sales number to show 80 instead I am getting 20. What is the best way to get the value. Appreciate the help.

-M

1 ACCEPTED SOLUTION

Accepted Solutions
mshparber Established Member
Established Member

Re: Cumulative Sum With Slicer

Of course!

@mattbrice is right.

In order to get YTD using ALL you need to use this:

YTDSales = CALCULATE([Sales],FILTER(ALL('Business Date'),'Business Date'[Date]<MAX('Business Date'[Date])&&'Business Date'[Year]=YEAR(MAX('Business Date'[Date]))))

or just use this staightforward formula:

YTDSales = TOTALYTD([Sales],'Business Date'[Date])

 

And make sure you use Date column from your 'Business Date' table in slicer

Michael

View solution in original post

8 REPLIES 8
mshparber Established Member
Established Member

Re: Cumulative Sum With Slicer

What formula did you use for your CumulativeSales measure?

mshparber Established Member
Established Member

Re: Cumulative Sum With Slicer

This should work:

YTDSales = TOTALYTD([Sales],CalendarTable[Date]) 

Also, make sure that you use your CalendarTable Month column in your slicer (NOT the Month from the Fact table)

Michael

balumaran Frequent Visitor
Frequent Visitor

Re: Cumulative Sum With Slicer

Thanks Michael for responding. 

 

My YTD Sales measure formule is this : 

 

YTD SALES$=
CALCULATE (
FACT[Sales $],
FILTER (
ALLSELECTED ( 'Business Date'[Date] ),
'Business Date'[Date] <= MAX ( 'Business Date'[Date] )
)
)

 

My Fact table granularity is at Date level. The Slicer has the month number. With all values selected in Slicer, the running Sum for YTD sales is displaying correctly where as when I select a month in the Slicer, the result is filtered to the month selected and YTD number/running sum number becomes total for the month. 

 

I used both ALL or ALL selected in the above measure; both behaves the same way. 

 

- M

mshparber Established Member
Established Member

Re: Cumulative Sum With Slicer

@balumaran 

ALLSELECTED should not work.

 

ALL - should:

YTDSales = CALCULATE([Sales],FILTER(ALL('Business Date'),'Business Date'[Date]<MAX('Business Date'[Date])))

 

or this:

 

YTDSales = TOTALYTD([Sales],'Business Date'[Date]) 

 

Also - make sure that you use a Month from your BusinessDate table in the slicer

Michael

balumaran Frequent Visitor
Frequent Visitor

Re: Cumulative Sum With Slicer

Thanks Michael. Let me give it a try and get back to you. 

- Mani

mattbrice Senior Member
Senior Member

Re: Cumulative Sum With Slicer

I hope it is ok to jump into this thread....

 

A couple of observations.   

 

"YTDSales = CALCULATE([Sales],FILTER(ALL('Business Date'),'Business Date'[Date]<MAX('Business Date'[Date])))"

 and

"YTDSales = TOTALYTD([Sales],'Business Date'[Date]) "

 

the two formulas will only return the same value if "Business Date" table only has dates for the current year or if only have Sales data for current year  - otherwise as is the first formula will return a Life-to-Date value.  Need to add : " && YEAR('Business Date'[Date]) = YEAR ( MAX ('Business Date'[Date] ) )" to the FILTER expression to get YTD.

 

And to the OP, the reason your code didn't work using ALL is because it appears you tried to apply it to a single column ALL('Business Date'[Date]) and not the whole 'Business Date' table.  This left your slicer filter on 'Business Date[Month]' intact which is why you got the month-to-date number.   Filters are column specific.  @mshparber code works because his ALL('Business Date') removed the filter on all columns including removing the slicer filter on the month. 

 

Hope this helps...

mshparber Established Member
Established Member

Re: Cumulative Sum With Slicer

Of course!

@mattbrice is right.

In order to get YTD using ALL you need to use this:

YTDSales = CALCULATE([Sales],FILTER(ALL('Business Date'),'Business Date'[Date]<MAX('Business Date'[Date])&&'Business Date'[Year]=YEAR(MAX('Business Date'[Date]))))

or just use this staightforward formula:

YTDSales = TOTALYTD([Sales],'Business Date'[Date])

 

And make sure you use Date column from your 'Business Date' table in slicer

Michael

View solution in original post

Highlighted
balumaran Frequent Visitor
Frequent Visitor

Re: Cumulative Sum With Slicer

Thanks Matt & Michael

Helpful resources

Announcements
Can You Solve These Challenge

Challenge: Can You Solve These?

Find out how to participate in the first Power BI 'Can You Solve These?' challenge.

Community News & Announcements

Community News & Announcements

Get your latest community news and announcements.

Virtual Launch Event

Microsoft Business Applications October Virtual Launch Event

Join us for an in-depth look at the new innovations across Dynamics 365 and the Microsoft Power Platform.

Community Kudopalooza

Win Power BI Swag with Community Kudopalooza!

Each week, complete activities and be qualified in the drawing for cool Power BI Swag.

Users Online
Currently online: 81 members 1,354 guests
Please welcome our newest community members: