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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
Anonymous
Not applicable

Lookupvalue between Start Date and End Date

I need to create a calculated column named Printer[Department], with a lookup formula from Employees table, considering start date and end date.

 

I tried this with no sucess:

Calculate(Values(Employees[Department]);
Filter ( Employees;
Printer[Date] >= Employees[Start Date] && Printer[Date] <= Employees[End Date] && Printer[Username] = Employees[Username]))

The relation is many to many, because at employees table a username(employee) can have one or more Department, regarding the period.

Example: the first username worked in 2 Departments.:

lookvalue.png

1 ACCEPTED SOLUTION
Stachu
Community Champion
Community Champion

this syntax should work:

Department =
VAR __RelevantEmployeeRows =
    FILTER (
        'Employees',
        'Employees'[Username] = 'Printer'[Username]
            && 'Employees'[Start Date] <= 'Printer'[Date]
            && 'Employees'[End Date] >= 'Printer'[Date]
    )
VAR __RelevantDepartments =
    DISTINCT (
        SELECTCOLUMNS ( __RelevantEmployeeRows, "Departments", 'Employees'[Department] )
    )
RETURN
    CONCATENATEX ( __RelevantDepartments, [Departments], "," )

the code assumes that there always is not null end date for each row in the Employees table

 

I'd also suggest to remove the many:many relationship in favour of a separate table with unique Usernames and 1:many, many2many relationships are not what most users think they are AND quite often if they have Both filtering direction are causing the relationship ambiguity - see detailed explanation here:
https://sqlbits.com/Sessions/Event18/Different_types_of_many-to-many_relationships_in_Power_BI



Did I answer your question? Mark my post as a solution!
Thank you for the kudos 🙂

View solution in original post

1 REPLY 1
Stachu
Community Champion
Community Champion

this syntax should work:

Department =
VAR __RelevantEmployeeRows =
    FILTER (
        'Employees',
        'Employees'[Username] = 'Printer'[Username]
            && 'Employees'[Start Date] <= 'Printer'[Date]
            && 'Employees'[End Date] >= 'Printer'[Date]
    )
VAR __RelevantDepartments =
    DISTINCT (
        SELECTCOLUMNS ( __RelevantEmployeeRows, "Departments", 'Employees'[Department] )
    )
RETURN
    CONCATENATEX ( __RelevantDepartments, [Departments], "," )

the code assumes that there always is not null end date for each row in the Employees table

 

I'd also suggest to remove the many:many relationship in favour of a separate table with unique Usernames and 1:many, many2many relationships are not what most users think they are AND quite often if they have Both filtering direction are causing the relationship ambiguity - see detailed explanation here:
https://sqlbits.com/Sessions/Event18/Different_types_of_many-to-many_relationships_in_Power_BI



Did I answer your question? Mark my post as a solution!
Thank you for the kudos 🙂

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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