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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

Filter Projects based on 2 criteria

I'm trying (and trying) to filter a list of Projects that are both Forks AND Knives Only (see Venn Diagram)

 

Venn DiagramVenn 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

ProjectUtensilRelease
Proj AFork1
Proj AKnives2
Proj AKnives3

 

1 ACCEPTED SOLUTION
Greg_Deckler
Super User
Super User

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.  


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Mastering Power BI 2nd Edition

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

3 REPLIES 3
v-eachen-msft
Community Support
Community Support

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.

 

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.
mahoneypat
Employee
Employee

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





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


Greg_Deckler
Super User
Super User

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.  


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Mastering Power BI 2nd Edition

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors
Top Kudoed Authors