Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
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).
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.
Solved! Go to Solution.
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
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
Help when you know. Ask when you don't!
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
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
21 | |
15 | |
14 | |
11 | |
7 |
User | Count |
---|---|
26 | |
24 | |
12 | |
11 | |
10 |