cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
StanleyBlack
Helper I
Helper I

DAX: Attendance that excludes nursery and reception ONLY when aggregated

Hi everyone,

 

I have a simple problem but one thats frustrating me. I have school attendance data and I want to show on a table or matrix what the attendance is per year group but when it is aggregated at the bottom in the total it filters out Nursery and Recepetion year group data as this is not counted towards official statistics.

 

It should look something like this:

 

Year Group

Attendance

Nursery

90%

Reception

95%

Year 01

100%

Year 02

100%

Year 03

100%

Year 04

100%

Year 05

100%

Year 06

100%

Total

100%

 

I thought I had it but this is as close as I came:

 

Attendance Test1 = 
VAR __NumberOfYearGroups = DISTINCTCOUNT(Attendance[Year])
VAR __AttendancePerYearGroup = 
                            Divide(
                                SUM(Attendance[Attendance]),
                                SUM(Attendance[Sessions]))
VAR __AttendanceAggregated =
                            CALCULATE(
                                Divide(
                                    SUM(Attendance[Attendance]),
                                    SUM(Attendance[Sessions])),
                                NOT(Attendance[Year] IN {"Nursery", "Reception"}))
RETURN
IF(__NumberOfYearGroups = 1, __AttendancePerYearGroup,__AttendanceAggregated)

The problem is that it aggregates to the correct attendance but it adds all possible year groups and provides the aggregated attendance against those year groups not in the subset as shown in the picture below. What can I change to the meausre to make it both optimised and only return against Year groups with data?

 

Thanks in advance guys.

 

AttendanceTest Example.png

1 ACCEPTED SOLUTION
jdbuchanan71
Super User II
Super User II

Hello @StanleyBlack ,

I think we can get there with an ISINSCOPE and KEEPFILTERS.  Give this a try:

Attendance Pct Corrected = 
IF (
    ISINSCOPE ( Attendance[Year] ),
    DIVIDE ( SUM ( Attendance[Attendance] ), SUM ( Attendance[Sessions] ) ),
    CALCULATE (
        DIVIDE ( SUM ( Attendance[Attendance] ), SUM ( Attendance[Sessions] ) ),
        KEEPFILTERS ( NOT ( Attendance[Year] IN { { "Nursery" }, { "Reception" } } ) )
    )
)

AttendancePct.jpg

View solution in original post

2 REPLIES 2
jdbuchanan71
Super User II
Super User II

Hello @StanleyBlack ,

I think we can get there with an ISINSCOPE and KEEPFILTERS.  Give this a try:

Attendance Pct Corrected = 
IF (
    ISINSCOPE ( Attendance[Year] ),
    DIVIDE ( SUM ( Attendance[Attendance] ), SUM ( Attendance[Sessions] ) ),
    CALCULATE (
        DIVIDE ( SUM ( Attendance[Attendance] ), SUM ( Attendance[Sessions] ) ),
        KEEPFILTERS ( NOT ( Attendance[Year] IN { { "Nursery" }, { "Reception" } } ) )
    )
)

AttendancePct.jpg

View solution in original post

@jdbuchanan71 

 

Worked like a charm. I hadn't come across ISINSCOPE before but off to research it now.

 

Thanks alot!

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

MBAS Attendee Badge

Claim Your Badge & Digital Swag!

Check out how to claim yours today!

Top Solution Authors
Top Kudoed Authors