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
avanroij
Helper I
Helper I

combine ALL with ALLSELECTED in running total

Hi, 

 

i have an issue with combining a running total with page filters. 

 

my dataset:

date (first of month)regionsales MTD
01-Jan-2021a10
01-Feb-2021a12
01-Mar-2021a4
01-Apr-2021a8
01-Jan-2021b12
01-Feb-2021b6
01-Mar-2021b9
01-Apr-2021b11

 

I have 2 graphs: 1 period to date (sales MTD per date (first of month)) and 1 running total. `This is working fine: 

 

avanroij_0-1620676241373.png

When the date slicer is set to e.g. Feb-01-2021, I want the running total in the first displayed month (Feb-01-2021) to sum the values of Jan-01-2021 and Feb-01-2021 (values 10+12+12+6 = 40) and the other columns the running total. This is also working fine: 

avanroij_1-1620676383349.png

 

I used this formula to calculate the running total:

Sales running total =
CALCULATE(
sum(Blad1[sales MTD]),
FILTER(
ALL(Blad1),
'Blad1'[date (first of month)] <= max(Blad1[date (first of month)])
))

 

so far so good. 

 

but next I want to add a page filter region (in the real dataset on more than 1 column, but for this example I only used region as an page filter).

I have tried several options. I was thinking on combing the Filter All() with Allselected (or in values) or Allexcept. But to no avail.  

 

Is there a way to use a pagefilter with the All() Filter? 

 

1 ACCEPTED SOLUTION
avanroij
Helper I
Helper I

 

 

I found the solution by using ALLEXECEPT:

 

Sales running total = CALCULATE(
sum(Blad1[sales MTD]),
FILTER(
ALLEXCEPT(Blad1,Blad1[region]),
'Blad1'[date (first of month)] <= max(Blad1[date (first of month)])
))
 
now the running total column in the first month of the date slicer is showing the cumulative value up to that period. and I can use the region page filter

View solution in original post

3 REPLIES 3
avanroij
Helper I
Helper I

 

 

I found the solution by using ALLEXECEPT:

 

Sales running total = CALCULATE(
sum(Blad1[sales MTD]),
FILTER(
ALLEXCEPT(Blad1,Blad1[region]),
'Blad1'[date (first of month)] <= max(Blad1[date (first of month)])
))
 
now the running total column in the first month of the date slicer is showing the cumulative value up to that period. and I can use the region page filter
amitchandak
Super User
Super User

@avanroij , Try with allselected

 

Sales running total =
CALCULATE(
sum(Blad1[sales MTD]),
FILTER(
ALLselected(Blad1),
'Blad1'[date (first of month)] <= max(Blad1[date (first of month)])
))

 

 

or

 

Sales running total =
CALCULATE(
sum(Blad1[sales MTD]),
FILTER(
ALL(Blad1[date (first of month)] ),
'Blad1'[date (first of month)] <= max(Blad1[date (first of month)])
))

 

or

 

Sales running total =
CALCULATE(
sum(Blad1[sales MTD]),
FILTER(
Blad1,
'Blad1'[date (first of month)] <= max(Blad1[date (first of month)])
), removefilters(Blad1[date (first of month)] ))

Full Power BI Video 20 Hours YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

thanks for your help. 

CALCULATE(
sum(Blad1[sales MTD]),
FILTER(
ALL(Blad1[date (first of month)] ),
'Blad1'[date (first of month)] <= max(Blad1[date (first of month)])
)) 

is also working, next to my own solution of using:

ALLEXCEPT(Blad1,Blad1[region]),

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 FABINSIDER for a $400 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.

Top Solution Authors