cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
TeunVerhagen11
Regular Visitor

Filter/parameter to link activity to a department with date values

Hi all,

 

I am creating a dataset for operation departments with the following (simplyfied) tables:

 

Employee list

NameCodeDepartmentStart dateEnd dateActive?
Ali123Customer Service1-1-20211-5-2021Inactive
Ali123Special Care2-5-20211-6-2021Inactive
Ali123Customer Service2-6-202131-12-2999Active

 

Activity table

Activity numberEmployee codeSolved date
11231-4-2021
212310-5-2021
312310-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 numberEmployee codeSolved dateTrue/False?
11231-4-2021True
212310-5-2021False
312310-6-2021True

 

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

1 ACCEPTED SOLUTION
dedelman_clng
Super User II
Super User II

Hi @TeunVerhagen11  - 

 

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




Proud to be a Super User!




View solution in original post

2 REPLIES 2
TeunVerhagen11
Regular Visitor

It works! Thank you very much!

dedelman_clng
Super User II
Super User II

Hi @TeunVerhagen11  - 

 

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




Proud to be a Super User!




View solution in original post

Helpful resources

Announcements
PBI_User Group Leader_768x460.jpg

Manage your user group events

Check out the News & Announcements to learn more.

MBAS on Demand

2021 Release Wave 2 Plan

Power Platform release plan for the 2021 release wave 2 describes all new features releasing from October 2021 through March 2022.

Get Ready for Power BI Dev Camp

Microsoft named a Leader in The Forrester Wave

Microsoft received the highest score of any vendor in both the strategy and current offering categories.

R2 (Green) 768 x 460px.png

Microsoft Dynamics 365 & Power Platform User Professionals

DynamicsCon is a FREE, 4 half-day virtual learning experience for 11,000+ Microsoft Business Application users and professionals.