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
PolarBear
Helper I
Helper I

Lookup (on multiple tables) with If condition on date

I need to create a table based on the values from three other tables. Anytime a new date for an ID is entered in any one of the three tables, the new date needs to be added to the new table along with the most recent entry for the ID from all three tables. 

IDDateStatus
33211/10/20 8:34 AMRed
34001/10/20 1:52 PMnull
34121/11/20 7:28 AMGreen
34821/12/20 2:24 PMYellow
35121/13/20 9:32 AMYellow
34001/13/20 11:22 AMYellow
 
IDDateCustomers Affected
33211/10/20 8:34 AMAll
34001/10/20 1:52 PMnull
34121/11/20 7:28 AMNone
34821/12/20 2:24 PMNone
35121/13/20 9:32 AMAll
34001/13/20 11:22 AMNone
33211/15/20 3:41 PMNone
 
IDDateSeverity
33211/10/20 8:34 AMHigh
34001/10/20 1:52 PMnull
34121/11/20 7:28 AMLow
34821/12/20 2:24 PMLow
35121/13/20 9:32 AMHigh
34001/13/20 11:22 AMLow

 

Expected Results

IDDateStatusCustomers AffectedSeverity
33211/10/20 8:34 AMRedAllHigh
34001/10/20 1:52 PMnullnullnull
34121/11/20 7:28 AMGreenNoneLow
34821/12/20 2:24 PMYellowNoneLow
35121/13/20 9:32 AMYellowAllHigh
34001/13/20 11:22 AMYellowNoneLow
33211/15/20 3:41 PMRedNoneHigh
1 ACCEPTED SOLUTION

Hi @PolarBear ,

You can handle it in Power Query Editor,please paste the following code in Advance Editor and replace the table name with corrected one:

let
    Source = Table.NestedJoin(t2, {"ID", "Date"}, t1, {"ID", "Date"}, "t1", JoinKind.LeftOuter),
    #"Expanded t1" = Table.ExpandTableColumn(Source, "t1", {"ID", "Date", "Status"}, {"t1.ID", "t1.Date", "t1.Status"}),
    #"Merged Queries" = Table.NestedJoin(#"Expanded t1", {"ID", "Date"}, t3, {"ID", "Date"}, "t3", JoinKind.LeftOuter),
    #"Expanded t3" = Table.ExpandTableColumn(#"Merged Queries", "t3", {"ID", "Date", "Severity"}, {"t3.ID", "t3.Date", "t3.Severity"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded t3",{"t1.ID", "t1.Date", "t3.ID", "t3.Date"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{"ID", "Date", "t1.Status", "Customers Affected", "t3.Severity"}),
    #"Sorted Rows1" = Table.Sort(#"Reordered Columns",{{"ID", Order.Ascending}, {"Date", Order.Ascending}}),
    #"Sorted Rows" = Table.Sort(#"Sorted Rows1",{{"ID", Order.Ascending}}),
    #"Filled Down" = Table.FillDown(#"Sorted Rows",{"t1.Status", "t3.Severity"}),
    #"Renamed Columns" = Table.RenameColumns(#"Filled Down",{{"t1.Status", "Status"}, {"t3.Severity", "Severity"}})
in
    #"Renamed Columns"

merge.JPG

You can find my sample PBIX file by this link.

Best Regards

Rena

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

5 REPLIES 5
Greg_Deckler
Super User
Super User

I cannot get your sample data to jive with the expected results, specifically for 3321, the second entry.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

@Greg_Deckler , 

I apologize, I pasted incorrect data... I updated my expected results.

thank you

amitchandak
Super User
Super User

@PolarBear ,

Try like

summarize(
New Table =
union(
selectcolumns(Table1,"ID",[ID],"Date",Table[Date],"Status",Table[Status],"Customers Affected","","Severity",""),

selectcolumns(Table2,"ID",[ID],"Date",Table[Date],"Status","","Customers Affected",Table[Customers Affected],"Severity",""),

selectcolumns(Table2,"ID",[ID],"Date",Table[Date],"Status","","Customers Affected","","Severity",Table[[Severity])

),
[ID],"Date",Max([Date]),"Status",max(Status),"	Customers Affected",max([Customers Affected]),"Severity",max([Severity]))

@amitchandak , this is close, but I need each date any of them changed, with the new value and the most recent value of the one(s) that didn't change.

Hi @PolarBear ,

You can handle it in Power Query Editor,please paste the following code in Advance Editor and replace the table name with corrected one:

let
    Source = Table.NestedJoin(t2, {"ID", "Date"}, t1, {"ID", "Date"}, "t1", JoinKind.LeftOuter),
    #"Expanded t1" = Table.ExpandTableColumn(Source, "t1", {"ID", "Date", "Status"}, {"t1.ID", "t1.Date", "t1.Status"}),
    #"Merged Queries" = Table.NestedJoin(#"Expanded t1", {"ID", "Date"}, t3, {"ID", "Date"}, "t3", JoinKind.LeftOuter),
    #"Expanded t3" = Table.ExpandTableColumn(#"Merged Queries", "t3", {"ID", "Date", "Severity"}, {"t3.ID", "t3.Date", "t3.Severity"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded t3",{"t1.ID", "t1.Date", "t3.ID", "t3.Date"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{"ID", "Date", "t1.Status", "Customers Affected", "t3.Severity"}),
    #"Sorted Rows1" = Table.Sort(#"Reordered Columns",{{"ID", Order.Ascending}, {"Date", Order.Ascending}}),
    #"Sorted Rows" = Table.Sort(#"Sorted Rows1",{{"ID", Order.Ascending}}),
    #"Filled Down" = Table.FillDown(#"Sorted Rows",{"t1.Status", "t3.Severity"}),
    #"Renamed Columns" = Table.RenameColumns(#"Filled Down",{{"t1.Status", "Status"}, {"t3.Severity", "Severity"}})
in
    #"Renamed Columns"

merge.JPG

You can find my sample PBIX file by this link.

Best Regards

Rena

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

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.