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 Guys,
I need help on how to lookup using multiple criteria. I need to update the "Status" of Sheet1 based on the criteria from Sheet2. The criteria is if the employee falls on a specific date range, it will return the corresponding status from Sheet2. Sheet1 below is already populated with desired results.
Sheet 1
Date | ID | NAME | Status |
6/28/2017 | 1234 | Smith, Sam | Production |
6/29/2017 | 1234 | Smith, Sam | Production |
6/30/2017 | 1234 | Smith, Sam | Production |
7/1/2017 | 1234 | Smith, Sam | Nesting |
7/2/2017 | 1234 | Smith, Sam | Nesting |
7/3/2017 | 1234 | Smith, Sam | Nesting |
7/4/2017 | 1234 | Smith, Sam | Nesting |
Sheet2
ID | NAME | START DATE | STOP DATE | Status |
1234 | Smith, Sam | 1/1/2017 | 6/30/2017 | Nesting |
1234 | Smith, Sam | 7/1/2017 | 12/31/2017 | Production |
Thank you in advance guys!
Solved! Go to Solution.
You can add a column in the query editor that checks the conditions like this:
Table.SelectRows(Sheet2, (Sheet2) => Sheet2[START DATE]<=[Date] and Sheet2[STOP DATE] >= [Date] and Sheet2[ID]=[ID])[Status]{0}
If this is too slow, you have to use a function like this:
(Table1 as table, DateColumn1 as text, ListJoinColumns1, TableLookup as table, DateFrom as text, DateUntil as text, ListJoinColumns2, LookupField as text) => let #"Merged Queries" = Table.NestedJoin(Table1,ListJoinColumns1,TableLookup,ListJoinColumns2,"Lookup",JoinKind.LeftOuter), #"Added Custom" = Table.AddColumn(#"Merged Queries", "Custom", each Record.Field(Table.SelectRows([Lookup], (Lookup) => Record.Field(Lookup, DateFrom)<=Record.Field(_, DateColumn1) and Record.Field(Lookup, DateUntil)>=Record.Field(_, DateColumn1)){0}, LookupField)), Result = Table.RemoveColumns(#"Added Custom", {"Lookup"}) in Result
name it "fnEventDurationMultiple" and you can invoke it like this:
fnEventDurationMultiple(Sheet1, "Date", {"ID"}, Sheet2, "START DATE", "STOP DATE", {"ID"}, "Status")
Imke Feldmann (The BIccountant)
If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!
How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries
You can add a column in the query editor that checks the conditions like this:
Table.SelectRows(Sheet2, (Sheet2) => Sheet2[START DATE]<=[Date] and Sheet2[STOP DATE] >= [Date] and Sheet2[ID]=[ID])[Status]{0}
If this is too slow, you have to use a function like this:
(Table1 as table, DateColumn1 as text, ListJoinColumns1, TableLookup as table, DateFrom as text, DateUntil as text, ListJoinColumns2, LookupField as text) => let #"Merged Queries" = Table.NestedJoin(Table1,ListJoinColumns1,TableLookup,ListJoinColumns2,"Lookup",JoinKind.LeftOuter), #"Added Custom" = Table.AddColumn(#"Merged Queries", "Custom", each Record.Field(Table.SelectRows([Lookup], (Lookup) => Record.Field(Lookup, DateFrom)<=Record.Field(_, DateColumn1) and Record.Field(Lookup, DateUntil)>=Record.Field(_, DateColumn1)){0}, LookupField)), Result = Table.RemoveColumns(#"Added Custom", {"Lookup"}) in Result
name it "fnEventDurationMultiple" and you can invoke it like this:
fnEventDurationMultiple(Sheet1, "Date", {"ID"}, Sheet2, "START DATE", "STOP DATE", {"ID"}, "Status")
Imke Feldmann (The BIccountant)
If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!
How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries
Check out the July 2025 Power BI update to learn about new features.
User | Count |
---|---|
73 | |
72 | |
38 | |
30 | |
26 |
User | Count |
---|---|
99 | |
87 | |
45 | |
43 | |
35 |