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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
Anonymous
Not applicable

Exclude values from a table dynamically based on a attribute via a slicer

Hi,

 

let's say I have this sales table:

 

CustomerIDProductIDProductName
15Shirt
16Pants
25Shirt
28Shoes

 

In my table visual, I only want to select the Customer ID. Without any filters it looks like this:

CustomerId
1
2

Now I want to select all customers who bought shirts(5), but exclude them, if they bought pants(6). So in the end only customerId 2 should be displayed, because he bought a shirt and no pants. How would I do that dynamically via a slicer?

Thanks!

1 ACCEPTED SOLUTION
PaulDBrown
Community Champion
Community Champion

@Anonymous 

Here is one way.
Firstly, create two Dimension tables for Product name. Name one"Select Product" and link it to the Data table in a one-to-many relationship. Name the other "Exclude Product", and leave this table disconnected.

The model looks like this:

Model.JPG

Next create a measure to show the IDs which include the selected products but exclude the products you wish:

 

IDs Selected = 
VAR products = VALUES('DataTable'[CustomerID]) //Creates a table of values of IDs with selected products
VAR ExcProducts = CALCULATETABLE(VALUES('DataTable'[CustomerID]), 
                   REMOVEFILTERS('Select Product'[ProductName]),
                    TREATAS(VALUES('Exclude Product'[ExclProduct]), 'DataTable'[ProductName]))
                    //Creates a table of values of IDs with products you wish to exclude
RETURN
IF(ISFILTERED('Exclude Product'[ExclProduct]), 
COUNTROWS(
    EXCEPT(products, ExcProducts)), //Creates a table of IDs which include products selected but not products excluded
    COUNTROWS(VALUES('DataTable'[CustomerID]))) //Returns a count of IDs selected if no product is excluded

 

 

Create another measure to filter the "Excluded product" slicer to only show products which are not selected in the "Select Product" Slicer and add this to the Filters on this visual in the filter pane setting the value to 1:

 

Filter Exclude  table = 
VAR Prods = VALUES('DataTable'[ProductName])
VAR _Exclude = VALUES('Exclude Product'[ExclProduct])
RETURN
COUNTROWS(
    EXCEPT(_Exclude, Prods))

 

 

And you will get this:

result.JPG

 I've attached the sample PBIX file for you





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






View solution in original post

4 REPLIES 4
PaulDBrown
Community Champion
Community Champion

@Anonymous 

Here is one way.
Firstly, create two Dimension tables for Product name. Name one"Select Product" and link it to the Data table in a one-to-many relationship. Name the other "Exclude Product", and leave this table disconnected.

The model looks like this:

Model.JPG

Next create a measure to show the IDs which include the selected products but exclude the products you wish:

 

IDs Selected = 
VAR products = VALUES('DataTable'[CustomerID]) //Creates a table of values of IDs with selected products
VAR ExcProducts = CALCULATETABLE(VALUES('DataTable'[CustomerID]), 
                   REMOVEFILTERS('Select Product'[ProductName]),
                    TREATAS(VALUES('Exclude Product'[ExclProduct]), 'DataTable'[ProductName]))
                    //Creates a table of values of IDs with products you wish to exclude
RETURN
IF(ISFILTERED('Exclude Product'[ExclProduct]), 
COUNTROWS(
    EXCEPT(products, ExcProducts)), //Creates a table of IDs which include products selected but not products excluded
    COUNTROWS(VALUES('DataTable'[CustomerID]))) //Returns a count of IDs selected if no product is excluded

 

 

Create another measure to filter the "Excluded product" slicer to only show products which are not selected in the "Select Product" Slicer and add this to the Filters on this visual in the filter pane setting the value to 1:

 

Filter Exclude  table = 
VAR Prods = VALUES('DataTable'[ProductName])
VAR _Exclude = VALUES('Exclude Product'[ExclProduct])
RETURN
COUNTROWS(
    EXCEPT(_Exclude, Prods))

 

 

And you will get this:

result.JPG

 I've attached the sample PBIX file for you





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






Fowmy
Super User
Super User

@Anonymous 

Are you going to enter the product IDs in the formula or have you got them in two separate lists in tables?

 

________________________

If my answer was helpful, please click Accept it as the solution to help other members find it useful

Click on the Thumbs-Up icon if you like this reply 🙂


Website YouTube  LinkedIn 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Fowmy
Super User
Super User

@Anonymous 

Add the following measure to your table visual:

 

Cust M = 

  IF( 5 IN VALUES(Table13[ProductID]) &&  NOT 6 IN VALUES(Table13[ProductID])  , 1 , 0)

Fowmy_0-1607432078935.png

________________________

If my answer was helpful, please click Accept it as the solution to help other members find it useful

Click on the Thumbs-Up icon if you like this reply 🙂


Website YouTube  LinkedIn

 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Anonymous
Not applicable

Hi,

 

this would work for these two IDs, but not if I want to select/exclude multuple productIds. Is there anyway to make this dynamic?

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

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.