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 (and trying) to filter a list of Projects that are both Forks AND Knives Only (see Venn Diagram)
Venn Diagram
Projects Utensils Release
Proj A Fork 1
Proj A Knives 2
Proj B Fork 1
Proj C Knives 1
Proj B Knives 2
Proj A Knives 3
To Result
Projects
Proj A
Proj B
So when the user chooses either Project, a list of Projects and Releases appears basically saying that "Proj A" and "Proj B" are the only projects that have "Forks" and "Knives" as utensils.
Like This
Project | Utensil | Release |
Proj A | Fork | 1 |
Proj A | Knives | 2 |
Proj A | Knives | 3 |
Solved! Go to Solution.
So this is going to depend on a number of things but the general approach to this is what I call a Complex Selector. Basically, you create a measure that returns 1 or 0 based upon whatever complex logic you wish to implement. So, you might implement something like:
Measure =
VAR __Project = MAX('Table'[Project])
VAR __Forks = COUNTROWS(FILTER(ALL('Table'),'Table'[Project] = __Project && [Utensils] = "Forks"))
VAR __Knives = COUNTROWS(FILTER(ALL('Table'),'Table'[Project] = __Project && [Utensils] = "Knives"))
RETURN
IF(__Forks > 0 && __Knives > 0, 1, 0)
You can then use this in your Filters pane to filter your visualization for example.
Hi @Anonymous ,
You could create a independent table at first.
Table 2 =
DISTINCT('Table'[Projects])
Then create a measure to check if results matched.
Measure =
VAR a =
VALUES ( 'Table 2'[Projects] )
VAR b =
CALCULATETABLE (
VALUES ( 'Table'[Utensils] ),
FILTER ( ALLSELECTED ( 'Table' ), 'Table'[Projects] IN a )
)
RETURN
IF ( COUNTROWS ( EXCEPT ( B, VALUES ( 'Table'[Utensils] ) ) ) > 0, 0, 1 )
Then add this measure into filter pane of your slicer and set it as 1.
Here is my test file for your reference.
Here is a way to do this (if I understood correctly). First create a separate DAX table for your slicer with:
SlicerProjects = Values(Projects[Projects])
Having this separate table with no relationship to your Projects table keeps it from filtering the table visual.
Then use this measure in a table visual with the Projects[Projects] columns:
Projects Same Utensils =
VAR selectedproject =
SELECTEDVALUE ( SlicerProjects[Projects] )
VAR selectedutensils =
CALCULATETABLE (
VALUES ( Projects[Utensils] ),
ALL ( Projects ),
Projects[Projects] = selectedproject
)
VAR currentutensils =
VALUES ( Projects[Utensils] )
VAR sametables =
AND (
ISBLANK ( EXCEPT ( selectedutensils, currentutensils ) ),
ISBLANK ( EXCEPT ( currentutensils, selectedutensils ) )
)
RETURN
IF ( sametables = TRUE (), 1, BLANK () )
If this works for you, please mark it as solution. Kudos are appreciated too. Please let me know if not.
Regards,
Pat
To learn more about Power BI, follow me on Twitter or subscribe on YouTube.
So this is going to depend on a number of things but the general approach to this is what I call a Complex Selector. Basically, you create a measure that returns 1 or 0 based upon whatever complex logic you wish to implement. So, you might implement something like:
Measure =
VAR __Project = MAX('Table'[Project])
VAR __Forks = COUNTROWS(FILTER(ALL('Table'),'Table'[Project] = __Project && [Utensils] = "Forks"))
VAR __Knives = COUNTROWS(FILTER(ALL('Table'),'Table'[Project] = __Project && [Utensils] = "Knives"))
RETURN
IF(__Forks > 0 && __Knives > 0, 1, 0)
You can then use this in your Filters pane to filter your visualization for example.
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 |
---|---|
14 | |
13 | |
12 | |
12 | |
12 |