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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
michaelccdf
Helper I
Helper I

Remove a single filter from a table

I'm trying to remove just one filter (from the filter pane) from a table below.  There are other filters from slicers that I would like to keep, thus I can't use ALL.  I suppose I could use ALLEXCEPT but then I would have to name all the filters I'd like to keep (which will be all except one).  Is there a simpler way?

 

 

 

Att Taken = 
//Unfilter just the IsAbsenceTaken column in the Attendance table, this is the line that I can't figure out
var AttendanceUnfiltered = FILTER(Attendance,ALL(Attendance[IsAbsenceTaken]))

//Build a summary table
var SummaryTable = SUMMARIZE(AttendanceUnfiltered,
                            Attendance[CourseGroupKey],
                            Attendance[date],
                            Attendance[period],
                            "IsAttendanceTaken",MAX(Attendance[IsAbsenceTaken])
                                )
RETURN
//return the percentage of periods in which attendance was taken
SUMX(SummaryTable,[IsAttendanceTaken]) / COUNTROWS(SummaryTable)

 

 

SOLUTION:

I'm putting the solution here, both answers below led me to it (I accepted the chronologically first one as the answer):

 

Solution 1: Create a calculated column (CourseGroupDatePeriodKey) with the columns I was passing into SUMMARIZE above.  The calculated column is a single column which then allows me to use DISTINCTCOUNT.  DISTINCTCOUNT can be wrapped in CALCULATE which can change the filter context.

 

Att Taken = 

//count of distinct number of course groups, dates and periods (class sessions).  Clear the IsAbsenceTaken filter in the calculate statement
var AllClassSessions = CALCULATE(DISTINCTCOUNT(Attendance[CourseGroupDatePeriodKey]),ALL(Attendance[IsAbsenceTaken]))

//count of class sessions where attendance was taken
var AttendanceTaken =  CALCULATE(DISTINCTCOUNT(Attendance[CourseGroupDatePeriodKey]),Attendance[IsAbsenceTaken] = 1)


RETURN
// divide class sessions in which attendance was taken by all class sessions.
AttendanceTaken / AllClassSessions

 

 

Solution 2: Create a new calculated table for periods as suggested in the second reply. (Actually, I ended up creating this in the database rather than in Power BI but it could be done with a calculated table).

tablesPNG.PNG

 

This table links to the main fact table using the CourseGroupDatePeriodKey column created in solution 1 above, with a bidirectional relationship.  Anything I filter with slicers on the main fact table is thus also filtered in the new table.  I then change the filter context using CALCULATE such that all rows are taken into account (ALL(AttTaken[IsAbsenceTaken]):

 

Att Taken 2 = 
var AttendanceTaken= CALCULATE(COUNTROWS(AttTaken),AttTaken[IsAbsenceTaken] = 1)
var AllClassSessions = CALCULATE(COUNTROWS(AttTaken),ALL(AttTaken[IsAbsenceTaken]))

RETURN
AttendanceTaken / AllClassSessions

 

 

Note that I wanted to keep the model as simple star schema so that I can use bidirectional filters without introducing ambiguity. 

1 ACCEPTED SOLUTION
JustJan
Responsive Resident
Responsive Resident

Hi, 

 

if you use calculate with all(columnname) then you release the filter on the column. (Only CALCULATE and CALCULATETABLE change the filter context)

 

so it would be something like:
calculate( "your calculation" like max(A) or sum(B),

All(columnname)
)

 

https://docs.microsoft.com/en-us/dax/calculate-function-dax

 

 

View solution in original post

2 REPLIES 2
kentyler
Solution Sage
Solution Sage

I'm not clear on what you mean by "simpler". It seems like ALLEXCEPT is designed explicitly to do what you need to do. There is no parallel function like REMOVEFILTER() that would just remove one filter.

 

Your desire for "simplification" may be linked to some issue that makes you data model "complicated" that is coming out when you try to write this code.

Perhaps if your data model had one table for ROLL, that is, the students who where expected to attend, and another for ACTUALATTENDENCE, which recorded the students from ROLL who actually attended, then you would no need the "isAbsenceTaken" flag. This would change a lot about how you calculated attendance.... 

Another possibility that this issue might point to is that taking attendance for "Periods" where attendance is taken for some periods and not for others might mean "Period" is a FACT table and not a DIMENSION of attendance. and the flag "IsAbsenceTaken" really applies to a period and not to a student (since it is probably not a question you would ask about each student in a period, but about the period as a whole).

If you'd like to talk over your data model send me an email, with a day and time that suits you, and I'd be glad to take a look with you in a screen share.

I'm a personal Power Bi Trainer I learn something every time I answer a question

The Golden Rules for Power BI

  1. Use a Calendar table. A custom Date tables is preferable to using the automatic date/time handling capabilities of Power BI. https://www.youtube.com/watch?v=FxiAYGbCfAQ
  2. Build your data model as a Star Schema. Creating a star schema in Power BI is the best practice to improve performance and more importantly, to ensure accurate results! https://www.youtube.com/watch?v=1Kilya6aUQw
  3. Use a small set up sample data when developing. When building your measures and calculated columns always use a small amount of sample data so that it will be easier to confirm that you are getting the right numbers.
  4. Store all your intermediate calculations in VARs when you’re writing measures. You can return these intermediate VARs instead of your final result  to check on your steps along the way.

 





Did this post answer your question? Mark it as a solution so others can find it!

Help when you know. Ask when you don't!




Join the conversation at We Talk BI find out more about me at Slow BI


JustJan
Responsive Resident
Responsive Resident

Hi, 

 

if you use calculate with all(columnname) then you release the filter on the column. (Only CALCULATE and CALCULATETABLE change the filter context)

 

so it would be something like:
calculate( "your calculation" like max(A) or sum(B),

All(columnname)
)

 

https://docs.microsoft.com/en-us/dax/calculate-function-dax

 

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors