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
UserID | Name | Department |
1 | John | Dev |
2 | Jane | HR |
3 | Don | Sales |
Skills
UserID | Skill |
1 | SQL |
1 | Power BI |
1 | Excel |
1 | C# |
2 | SQL |
2 | Power BI |
2 | Python |
2 | Tableau |
3 | SAP |
3 | SalesForce |
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.
UserID | Name | Department |
1 | John | Dev |
Any ideas? Thanks for your help!
Solved! Go to Solution.
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'
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)
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
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'
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)
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
Worked like a charm! Thank you so much.
@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
2. Right click and create a blank query
3. Add this M script to the formula bar
= Table.NestedJoin(Skills, {"UserID"}, Employee, {"UserID"}, "Employee", JoinKind.LeftOuter)
4. Expand the name and department columns
5. Close an apply your changes
6. You can now use your new filter to achieve your goal
Bonus tip:
Ideally you would alter the steps above slightly to create a star schema
Appreciate your Kudos!
Please accept the solution if it answers your question 🙂
Thank you for this. I couldn't get it to work on my end, must have been something that I missed.
maybe this article will help you
https://www.sqlbi.com/tv/differences-between-generate-and-crossjoin-solving-business-scenarios-unplu...
User | Count |
---|---|
106 | |
88 | |
69 | |
52 | |
49 |
User | Count |
---|---|
148 | |
94 | |
79 | |
71 | |
70 |