Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
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 November 2025 Power BI update to learn about new features.
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
| User | Count |
|---|---|
| 21 | |
| 10 | |
| 9 | |
| 4 | |
| 4 |
| User | Count |
|---|---|
| 34 | |
| 31 | |
| 20 | |
| 13 | |
| 11 |