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 dateJoin 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.
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.:
Solved! Go to Solution.
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
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
Check out the July 2025 Power BI update to learn about new features.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
User | Count |
---|---|
16 | |
8 | |
7 | |
7 | |
6 |
User | Count |
---|---|
23 | |
10 | |
10 | |
9 | |
8 |