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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Anonymous
Not applicable

Advanced filter experience: "AND", "OR" , "NOT" filter logic using slicer visuals and DAX!!

Overview

There are a number of examples that have shown how to add logic so that you can use filters with an "AND" operator rather than the standard "OR" logic when using a slicer. This example shows how to also add the ability for a "NOT" statement as well, to create what I think is an incredibly powerful level of flexibility for end users.

 

AlexBarnett_0-1606341448741.png

 

The attached example has been built using open data and shows how the approach works

Download PBIX example 

 

Limitations - slow performance with large datasets

I am looking for help and suggestions on how to improve performance of these measures using DAX Studio or by re-engineering the approach. In my actual report the tables have millions of rows and performance is slow, the current approach results in a very large number of engine queries and depending on capacity in Power BI server can even result in visuals timing out due to lack of memory.

 

How it works (be warned, it may get confusing...)

I won't go over the full extent of how to implement AND filter logic. The approach I have used is based on the following excellent blog post.

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

In my example, I have extended the logic to also allow users to EXCLUDE items. The core logic is the same, and the EXCLUSION criteria can be applied using either an OR logic or AND logic operator (i.e. Filter for Items that DON'T  have X OR Y attribute versus Items that DONT have X AND Y attribute)

1. If the attribute slicer is filtered, the measure below either counts the number of distinct items in the attribute list (if using an AND logic) or returns a 1 if using the OR logic

 

 

AndOrLogicSwitch (NOT) = IF (
    ISFILTERED ( 'LSOA Attributes - Filter (NOT)'[Attribute] ),
    IF (
        SUM ( 'ANDOR_Table (NOT)'[Binary] ) = 0,
        CALCULATE (
            DISTINCTCOUNT ( 'LSOA Attributes - Filter (NOT)'[Attribute] ),
            ALL ( 'LSOA Master')
        ),
        1
    ),
    CALCULATE (
        DISTINCTCOUNT ( 'LSOA Attributes - Filter (NOT)'[Attribute] ),
        ALL ( 'LSOA Master')
    )
)

 

 

2. A further measure then compares, for each item in the master table, the number of attributes the item has compared to the measure value. If the item has fewer attributes than the number of attributes in the above measure, then it does NOT meet the exclusion criteria and is therefore included. This is also combined with similar logic for the INCLUSION criteria, which is essentially the same logic but in reverse.

 

ANDORNOT Logic = 
VAR ANDORCondition = [AndOrLogicSwitch]
VAR NOTCondition = [AndOrLogicSwitch (NOT)]

VAR Include =

    and(
// This logic determines if the item meets the INCLUDE criteria
        or(not(isfiltered('LSOA Attributes - Filter'[Attribute])),DISTINCTCOUNT ( 'LSOA Attributes - Filter'[Attribute]) >= ANDORCondition)

// This logic determines if the item meets the EXCLUDE criteria
        , or(not(isfiltered('LSOA Attributes - Filter (NOT)'[Attribute])),DISTINCTCOUNT ( 'LSOA Attributes - Filter (NOT)'[Attribute] ) < NOTCondition))
RETURN
    Include

 

 

3. Further measures can then be calculated, using this logic to filter the master table, for example

 

Count of LSOAs = 
var LSOACount = countrows(filter('LSOA Master',[ANDORNOT Logic]))
return
LSOACount

 

 

Hopefully this will be helpful to others, and I would be very grateful for any ideas on how to improve on what I have done, particularly to improve performance for larger datasets.

 

Thank you

 

Alex

1 REPLY 1
AntrikshSharma
Super User
Super User

@Anonymous Thanks for sharing your knowledge, try to get it posted here, so that it gets more traction: 

 

Community Blog - Microsoft Power BI Community

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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