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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
nikz26
Regular Visitor

Lookup based on multiple criteria

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

DateIDNAMEStatus
6/28/20171234Smith, SamProduction
6/29/20171234Smith, SamProduction
6/30/20171234Smith, SamProduction
7/1/20171234Smith, SamNesting
7/2/20171234Smith, SamNesting
7/3/20171234Smith, SamNesting
7/4/20171234Smith, SamNesting

 

Sheet2

IDNAMESTART DATESTOP DATEStatus
1234Smith, Sam1/1/20176/30/2017Nesting
1234Smith, Sam7/1/201712/31/2017Production

 

Thank you in advance guys!

1 ACCEPTED SOLUTION
ImkeF
Super User
Super User

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

View solution in original post

1 REPLY 1
ImkeF
Super User
Super User

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

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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