Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hi all,
I am creating a dataset for operation departments with the following (simplyfied) tables:
Employee list
Name | Code | Department | Start date | End date | Active? |
Ali | 123 | Customer Service | 1-1-2021 | 1-5-2021 | Inactive |
Ali | 123 | Special Care | 2-5-2021 | 1-6-2021 | Inactive |
Ali | 123 | Customer Service | 2-6-2021 | 31-12-2999 | Active |
Activity table
Activity number | Employee code | Solved date |
1 | 123 | 1-4-2021 |
2 | 123 | 10-5-2021 |
3 | 123 | 10-6-2021 |
These tables have a relation on Employee Code. The problem is that the department name is not registered in the system that holds the activity data.
In this example I want to make a dashboard for Customer Service so I filter in the employee list on Customer Service. Since the tables are linked on employee code the result will be 3 activities. The result should be 2 activities because the second activity was solved by the employee when he worked for Special Care department.
How can I create a parameter/measure/filter to check if the solved date is in the date ranges that the employee worked for Customer Service? This should be the outcome:
Activity number | Employee code | Solved date | True/False? |
1 | 123 | 1-4-2021 | True |
2 | 123 | 10-5-2021 | False |
3 | 123 | 10-6-2021 | True |
In conslusion: I use the employee table to filter on a department. I need a solution to filter the right activities by checking if the solved date is included in the date range of an employee working for a department.
Thanks in advance and if more information is necessary I can provide it.
Teun
Solved! Go to Solution.
Hi @Anonymous -
Add this calculated column to the Activity table, then you can tie it to the filter on Department
Department =
VAR __Solve = [Solved date]
VAR __Code = [Employee code]
RETURN
MAXX (
FILTER (
ALL ( EmpDept ),
EmpDept[Code] = __Code
&& EmpDept[Start date] <= __Solve
&& EmpDept[End date] > __Solve
),
EmpDept[Department]
)
Hope this helps,
David
It works! Thank you very much!
Hi @Anonymous -
Add this calculated column to the Activity table, then you can tie it to the filter on Department
Department =
VAR __Solve = [Solved date]
VAR __Code = [Employee code]
RETURN
MAXX (
FILTER (
ALL ( EmpDept ),
EmpDept[Code] = __Code
&& EmpDept[Start date] <= __Solve
&& EmpDept[End date] > __Solve
),
EmpDept[Department]
)
Hope this helps,
David
User | Count |
---|---|
25 | |
12 | |
8 | |
6 | |
6 |
User | Count |
---|---|
26 | |
12 | |
12 | |
10 | |
6 |