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

Filter Data with Multiple Filter Conditions

Hello,

I'm looking for a solution to implement filtering capability that will allow end-user to find individuals with matching skillset. I have two tables loaded into Power BI:

 

Employee

UserIDNameDepartment
1JohnDev
2JaneHR
3DonSales

 

Skills

UserIDSkill
1SQL
1Power BI
1Excel
1C#
2SQL
2Power BI
2Python
2Tableau
3SAP
3SalesForce

 

In Power BI dashboar, when multiple skills are selected, I need to show the individuals with the exact matching skills. For example, when I select "SQL, Power BI, Excel", the dashboard should return one employee record.

UserIDNameDepartment
1JohnDev

 

Any ideas? Thanks for your help!

 

 

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

Hi @Anonymous ,

I created a sample pbix file(see the attachment), please check if that is what you want.

1. Please DO NOT create any relationship between the table 'Employee' and 'Skills'

yingyinr_3-1675669823932.png

2. Create a measure as below 

Flag =
VAR _seluserid =
    SELECTEDVALUE ( 'Employee'[UserID] )
VAR _selskills =
    ALLSELECTED ( 'Skills'[Skill] )
VAR _scount =
    COUNTROWS ( _selskills )
VAR _tab =
    SUMMARIZE (
        'Skills',
        'Skills'[UserID],
        "@count",
            CALCULATE (
                DISTINCTCOUNT ( 'Skills'[Skill] ),
                FILTER (
                    'Skills',
                    'Skills'[UserID] = _seluserid
                        && 'Skills'[Skill] IN _selskills
                )
            )
    )
VAR _ecount =
    SUMX ( _tab, [@count] )
RETURN
    IF ( _ecount >= _scount, 1, 0 )

3. Create a visual and apply the visual-level filter on the visual with the condition(Flag is 1)

yingyinr_2-1675669804786.png

If the above one can't help you get the expected result, could you please provide some raw data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples? It would be helpful to find out the solution. You can refer the following links to share the required info:

How to provide sample data in the Power BI Forum

How to Get Your Question Answered Quickly

And It is better if you can share a simplified pbix file. You can refer the following link to upload the file to the community. Thank you.

How to upload PBI in Community

Best Regards

Community Support Team _ Rena
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

5 REPLIES 5
v-yiruan-msft
Community Support
Community Support

Hi @Anonymous ,

I created a sample pbix file(see the attachment), please check if that is what you want.

1. Please DO NOT create any relationship between the table 'Employee' and 'Skills'

yingyinr_3-1675669823932.png

2. Create a measure as below 

Flag =
VAR _seluserid =
    SELECTEDVALUE ( 'Employee'[UserID] )
VAR _selskills =
    ALLSELECTED ( 'Skills'[Skill] )
VAR _scount =
    COUNTROWS ( _selskills )
VAR _tab =
    SUMMARIZE (
        'Skills',
        'Skills'[UserID],
        "@count",
            CALCULATE (
                DISTINCTCOUNT ( 'Skills'[Skill] ),
                FILTER (
                    'Skills',
                    'Skills'[UserID] = _seluserid
                        && 'Skills'[Skill] IN _selskills
                )
            )
    )
VAR _ecount =
    SUMX ( _tab, [@count] )
RETURN
    IF ( _ecount >= _scount, 1, 0 )

3. Create a visual and apply the visual-level filter on the visual with the condition(Flag is 1)

yingyinr_2-1675669804786.png

If the above one can't help you get the expected result, could you please provide some raw data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples? It would be helpful to find out the solution. You can refer the following links to share the required info:

How to provide sample data in the Power BI Forum

How to Get Your Question Answered Quickly

And It is better if you can share a simplified pbix file. You can refer the following link to upload the file to the community. Thank you.

How to upload PBI in Community

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Anonymous
Not applicable

Worked like a charm! Thank you so much.

SidTrengove
Advocate III
Advocate III

@Anonymous 
An option for you here would be to merge these tables in Power Query.

To do this follow these steps:

 

1. Open Power Query

SidTrengove_0-1675154384240.png

 

2. Right click and create a blank query

SidTrengove_1-1675154430170.png

 

3. Add this M script to the formula bar

 

 

 

= Table.NestedJoin(Skills, {"UserID"}, Employee, {"UserID"}, "Employee", JoinKind.LeftOuter)

 

 

 

 

SidTrengove_2-1675154530212.png

4. Expand the name and department columns

SidTrengove_3-1675154589865.png

5. Close an apply your changes

SidTrengove_4-1675154622502.png

6. You can now use your new filter to achieve your goal

SidTrengove_5-1675154682927.png

Bonus tip: 

Ideally you would alter the steps above slightly to create a star schema

SidTrengove_6-1675154739856.png

 

 

 


Appreciate your Kudos!

Please accept the solution if it answers your question 🙂

 

Easy Power BI Tutorials

Unleash the full potential of Power BI with Help Xel

Visit HelpXel
2.png


Anonymous
Not applicable

Thank you for this. I couldn't get it to work on my end, must have been something that I missed.

Ahmedx
Super User
Super User

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.