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
Anonymous
Not applicable

Filtering a Multi-Select Slicer via AND instead of OR logic

In Power BI, slicer visuals work by restricting the rows of data accessible by visuals in the report. Multiselecting slicers unions the criteria by giving rows for all criteria. What is not possible with the default way Power BI filters things is to multiselect data with an intersection (using AND instead of OR logic) to only give rows that fit BOTH the selected criteria.

piechart.png

 

For the report I am working on, I was asked to configure a way so that multi-selecting of our filter categories would filter data via this AND intersection opposed to the Power BI default.

 

Other Solutions:

Upon initial research (read: extensive googling!) I came across the following four articles which detail different approaches to achieving this. They all generally tackle the issue in a similar way – using measures to compare counts of selected items versus the count of rows matching these selected criteria.

Slicer with AND condition in Power BI - RADACAD

Apply AND Logic to Multiple Selection in DAX Slicer - SQLBI

Changing “OR” to “AND” Logic for Power BI Slicers | by Orysya Stus | Seismic Innovation Labs | Mediu...

Power BI: Implement AND/OR Selection | by ZhongTr0n | Towards Data Science

However, due to the structure of the data I was working with and the specific needs of the report, none of these solutions exactly worked.

 

 

The Data:

For the sake of privacy I cannot share the actual data of the report although for developing the right method to replicate this ‘AND’ filter I can show a snippet of the structure of the data I am working with.charlottetowell_0-1657257559695.png

 

Requirements:

The specific solution I was tasked to create was a way to multi-select a slicer based on [Course] to filter visuals that all concerned the number of distinct Employees (based on unique key field [Email]). Without any of the AND logic implemented, the report looked like the following:

charlottetowell_1-1657257590478.png

 

You can see we have a count of the number of trainees broken down by different categories (hidden for the sake of privacy). When different courses are selected the data shown dynamically changes to include rows relating to either Course 1 OR Course 2 OR Course 3… and so on.

 

Solution:

To change this logic to instead give rows of one table (Employee Head Count) relating to multiple rows in another one (Course 1 AND Course 2 AND Course 3 …): DAX Measures!

I have broken down my solution into two different parts corresponding to the two measures I have made.

   

Pt 1. Trainees Count

Without any AND logic, our original measure to count the number of employees who had completed training was the following:

 

Trainees = DISTINCTCOUNT('Training Records'[Email])

 

 

To implement AND logic, we result in the following:

 

	numTraineesCompletedALLSelected = 
	//the number of trainees who have selected all completed courses
	 
	// count the number of criteria (courses) selected
	var selectedCourses = VALUES(Course[Course])
	var numSelectedCourses = COUNTROWS(selectedCourses)
	 
	//count number of selected courses completed per trainee
	var result = COUNTROWS(
	    FILTER(
	        GROUPBY(
	            FILTER('Training Records', RELATED('Course'[Course]) in selectedCourses),
	            'Employee Head Count'[Email],
	            "SelectedCoursesCompleted",
	            COUNTX(CURRENTGROUP(), [Course])
	        ),
	    [SelectedCoursesCompleted] >= numSelectedCourses)
	)
	 
	//if courses are being filtered: filter with AND condition
	//else count trainees normally
	return IF(ISFILTERED(Course[Course]),
	result, DISTINCTCOUNT('Training Records'[Email])
	)

 

 

Let’s break this down,

To start off we create two variables selectedCourses and numSelectedCourses which extract the courses we have selected via the slicer.

Then we have the result variable – the main chunk of the logic. If we focus into the middle bit we have a GROUPBY function wrapping COUNTX with a filtered table. What this does is, from our training records table filtered to only have rows corresponding to the selected criteria, we count the number of courses (as per the COUNTX) grouped by each employee email. This gives us a table for each employee with a corresponding count of how many of the selected courses they have completed. We then further filter this resulting table to only give us employees who have completed at least the same number as the amount of selected courses. The final function is to COUNTROWS of this table to provide a number of how many employees have completed ALL of the selected courses.

The final return part of the measure has an extra logic check to see if our criteria is being filtered at all. If it is, we return the result just calculated, if not, we default back to the usual way to count the number of employees.

This new measure numtraineesCompeltedALLSelected (pending a name improvement lol) is what we use to replace the original Trainees measure.

 

    Pt 2. Count Courses Per Trainee

While the previous measure sorts us out for visuals directly using the count of trainees (eg. Our bar graph, or card), what this does not account for is our table visualisations which have data rows corresponding to individual trainees from the Employee Head Count table.

To solve this issue, I created a second measure,

 

	coursesCompletedPerTrainee = 
	 
	// count the number of criteria (courses) selected
	var selectedCourses = VALUES(Course[Course])
	var numSelectedCourses = COUNTROWS(selectedCourses)
	
// count the number of courses per trainee
	var coursesPerTrainee = COUNTX(
	    FILTER('Training Records', RELATED(Course[Course]) in selectedCourses),
	    'Training Records'[Email])
	 
	var ANDCheck = IF(coursesPerTrainee >= numSelectedCourses, 1)
	 
	//return non-blank if courses are not being filtered
	return IF(ISFILTERED(Course[Course]),
	ANDCheck, "Non-Blank")

 

 

Looking very similar to our previous measure, our main difference is that this measure no longer uses a GROUPBY function. Instead, our return value is the number of courses (of the selected courses) completed per trainee (calculated with the COUNTX function).

This is then used to filter our table by charlottetowell_2-1657257894796.png

 

If we are not filtering at all we simply return a string “Non-Blank” which avoids errors when no criteria is selected.

 

Summary

When attempting this solution I found it necessary to have two measures to achieve two main things: 1) A total count of trainees who had completed selected courses (pt. 1) and  2) a measure by which to filter table visuals to only return relevant employee records (pt. 2). This is the main difference I found between my solution and the four previous articles I read in research. I found the difference in how the data I was using was structured compared to the sample data in solutions brought about this requirement as I was concerned with counting the records in one table (Training Records) grouped by the rows of another (Employee Head Count). I would be very interested in hearing of a way to optimize this and perhaps result in only one measure which can be used for the two purposes – the similarity in their code makes me believe this may be possible.

 

For the time being however, I have developed this as the solution to meet the needs of the project as it results in the relevant output being provided for the report.

1 ACCEPTED SOLUTION
v-jianboli-msft
Community Support
Community Support

Hi @Anonymous ,

 

Here is my data:

vjianbolimsft_0-1657705542415.png

 

vjianbolimsft_1-1657705542416.png

 

vjianbolimsft_2-1657705542417.png

 

After my test, it seems that your first Measure can be directly applied to filter Table:

 

numTraineesCompletedALLSelected =

    //the number of trainees who have selected all completed courses

    

    // count the number of criteria (courses) selected

    var selectedCourses = VALUES(Course[Course])

    var numSelectedCourses = COUNTROWS(selectedCourses)

    

    //count number of selected courses completed per trainee

    var result = COUNTROWS(

        FILTER(

            GROUPBY(

                FILTER('Training Records', RELATED('Course'[Course]) in selectedCourses),

                'Employee Head Count'[Email],

                "SelectedCoursesCompleted",

                COUNTX(CURRENTGROUP(), [Course])

            ),

        [SelectedCoursesCompleted] >= numSelectedCourses)

    )

    

    //if courses are being filtered: filter with AND condition

    //else count trainees normally

    return IF(ISFILTERED(Course[Course]),

    result, DISTINCTCOUNT('Training Records'[Email])

    )

 

Use it to filter table:

vjianbolimsft_3-1657705542418.png

 

Final output:

vjianbolimsft_4-1657705542420.png

 

vjianbolimsft_5-1657705542422.png

 

Maybe I misunderstood ?

 

Best Regards,

Jianbo Li

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
v-jianboli-msft
Community Support
Community Support

Hi @Anonymous ,

 

Here is my data:

vjianbolimsft_0-1657705542415.png

 

vjianbolimsft_1-1657705542416.png

 

vjianbolimsft_2-1657705542417.png

 

After my test, it seems that your first Measure can be directly applied to filter Table:

 

numTraineesCompletedALLSelected =

    //the number of trainees who have selected all completed courses

    

    // count the number of criteria (courses) selected

    var selectedCourses = VALUES(Course[Course])

    var numSelectedCourses = COUNTROWS(selectedCourses)

    

    //count number of selected courses completed per trainee

    var result = COUNTROWS(

        FILTER(

            GROUPBY(

                FILTER('Training Records', RELATED('Course'[Course]) in selectedCourses),

                'Employee Head Count'[Email],

                "SelectedCoursesCompleted",

                COUNTX(CURRENTGROUP(), [Course])

            ),

        [SelectedCoursesCompleted] >= numSelectedCourses)

    )

    

    //if courses are being filtered: filter with AND condition

    //else count trainees normally

    return IF(ISFILTERED(Course[Course]),

    result, DISTINCTCOUNT('Training Records'[Email])

    )

 

Use it to filter table:

vjianbolimsft_3-1657705542418.png

 

Final output:

vjianbolimsft_4-1657705542420.png

 

vjianbolimsft_5-1657705542422.png

 

Maybe I misunderstood ?

 

Best Regards,

Jianbo Li

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

Hi @v-jianboli-msft 

 

I've gone back to my solution and you are right using the first measure as a filter does seem to now work for filtering the table!

 

This is what I initially expected it to do so makes perfect sense it works. Not sure why I was running into an issue before. Previously applying this filter returned a blank table and would not output any rows - I'll see if I can replicate the error and figure out what was going wrong previously!

 

At least it works now though without the need for the second measure haha! Thank you for the help 🙂

 

Charlotte

v-jianboli-msft
Community Support
Community Support

Hi @Anonymous 

 

Thanks for your sharing,

“I would be very interested in hearing of a way to optimize this and perhaps result in only one measure which can be used for the two purposes – the similarity in their code makes me believe this may be possible.”

So what you hope to get is a measure that can not only calculate the trainees for completing the course, but also filter the visual?Can you please share more details to help us clarify your scenario?

 

Best Regards,

Jianbo Li

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

Hi @v-jianboli-msft,

 

In the other solutions/articles I read they had a common thing where they had (in my case) a measure to calculate courses completed per employee (like my second measure) and filtered visuals simply by when [2nd measure] is not blank. 

 

My attempt at this was the following:

Original Measure:

Trainees = DISTINCTCOUNT('Training Records'[Email])

Count By Row Measure:

coursesCompletedPerTrainee =

// count the number of criteria (courses) selected
var selectedCourses = VALUES(Course[Course])
var numSelectedCourses = COUNTROWS(selectedCourses)

// count the number of courses per trainee
var coursesPerTrainee = COUNTX(
FILTER('Training Records', RELATED(Course[Course]) in selectedCourses),
'Training Records'[Email])

var ANDCheck = IF(coursesPerTrainee >= numSelectedCourses, 1)

//return non-blank if courses are not being filtered
return IF(ISFILTERED(Course[Course]),
ANDCheck, "Non-Blank")

 

This is the exact same as part of my current solution and it worked the same to filter some visuals (like tables) when it was not blank.

The issue/missing piece I needed was the total number of employees who had completed all selected courses while this measure only gave me the number of selected courses per employee.

 

Here is an old version of the report:

charlottetowell_1-1657518623639.png

 

Although blurred out, the bottom right table gave me the correct employee records (a total of 18 rows) by filtering the visual when coursesCompletedPerTrainee is not blank.

 

The issue I was having is that the card visual 'Trainees' and the bar chart could not be filtered by this measure. (The card is just the original Trainees measure) and the bar chart is the Trainees measure by a column in the employee head count table.

 

You can see in the matrix visual though, the total it generated (18) is the value I was after instead of 32. If there was a way to filter my original measure by the second one so that it only counts the distinct Email rows returned when coursesCompletedPerTrainee is not blank (basically what the matrix visual is doing) to produce a total value - it would also need to work with the bar graph however - only include the rows when the other measure is not blank.

 

I wasn't able to figure out a way to do this/if it was possible so I instead came up with my workaround solution to get the job done.

 

The fact that the total is able to be calculated by the matrix though made me wonder if the entire first measure was necessary when it seems to (kind of) be calculated via the second measure anyway.

 

Let me know what you think!

 

Charlotte 🙂

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