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
JVos
Helper IV
Helper IV

Conditional join with conditions (=, <>) stored in columns

I want to join records in Table A with records in Table B, based on conditions in Table B. How can this be done the easiest way, probably with a SelectRows statement?

 

Contents of Table A:

IDNameCoatingUsage
10AF-CTCommercial
11AF-CTBasic Seed
12A Commercial
13A Basic Seed
14AF+I-CTCommercial
15AF+I-CTBasic Seed
16B Commercial

 

Contents of Table B:

NameCoatingConditionUsageConditionOutcome
A  O-1
A= "F+I-CT" O-2
A = "Basic Seed"O-3
A <> "Basic Seed"O-4
B  O-5

 

The match must be on the Name and on the Condition-columns. Note: an empty condition means that condition is not relevant. So for example the first record in Table B will match with all records in Table A where Name = "A".

 

The expected results are the following:

IDNameOutcome
10AO-1
10AO-4
11AO-1
11AO-3
12AO-1
12AO-4
13AO-1
13AO-3
14AO-1
14AO-2
14AO-4
15AO-1
15AO-2
15AO-3
16BO-5

 

This is the basic code that I think I have to extend (based on PowerQuery(M)agic: Conditional Joins using Table.SelectRows() - P3 (powerpivotpro.com):

 

 

 

 

let
    TableA = Excel.CurrentWorkbook(){[Name="tblRoute"]}[Content],
    TableB = Excel.CurrentWorkbook(){[Name="tblBAAM"]}[Content],

    TableA_TableB = Table.AddColumn(TableA, "Outcome", each Table.SelectRows(TableB, (Magic) => [RouteName]=Magic[RouteName])),
    Result = Table.ExpandTableColumn(TableA_TableB, "Outcome", {"Outcome"})

in

    Result

 

 

 

 

1 ACCEPTED SOLUTION
AlB
Super User
Super User

Hi @JVos 

Try this

let
    TableA = Excel.CurrentWorkbook(){[Name="tblRoute"]}[Content],
    TableB = Excel.CurrentWorkbook(){[Name="tblBAAM"]}[Content],
    TableA_TableB = Table.AddColumn(TableA, "Outcome", each Table.SelectRows(TableB,
         
         (Magic) => Magic[Name]=[Name] and (if Magic[CoatingCondition] = null then true else Expression.Evaluate("[Coating]" & Magic[CoatingCondition], [_=_])) 
                and (if Magic[UsageCondition] = null then true else Expression.Evaluate("[Usage]" & Magic[UsageCondition], [_=_])))
    ),    
    Result = Table.ExpandTableColumn(TableA_TableB, "Outcome", {"Outcome"}),
    #"Removed Columns" = Table.RemoveColumns(Result,{"Coating", "Usage"})
in
    #"Removed Columns"

 

Please mark the question solved when done and consider giving a thumbs up if posts are helpful.

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

Cheers 

SU18_powerbi_badge

 

View solution in original post

2 REPLIES 2
AlB
Super User
Super User

Hi @JVos 

Try this

let
    TableA = Excel.CurrentWorkbook(){[Name="tblRoute"]}[Content],
    TableB = Excel.CurrentWorkbook(){[Name="tblBAAM"]}[Content],
    TableA_TableB = Table.AddColumn(TableA, "Outcome", each Table.SelectRows(TableB,
         
         (Magic) => Magic[Name]=[Name] and (if Magic[CoatingCondition] = null then true else Expression.Evaluate("[Coating]" & Magic[CoatingCondition], [_=_])) 
                and (if Magic[UsageCondition] = null then true else Expression.Evaluate("[Usage]" & Magic[UsageCondition], [_=_])))
    ),    
    Result = Table.ExpandTableColumn(TableA_TableB, "Outcome", {"Outcome"}),
    #"Removed Columns" = Table.RemoveColumns(Result,{"Coating", "Usage"})
in
    #"Removed Columns"

 

Please mark the question solved when done and consider giving a thumbs up if posts are helpful.

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

Cheers 

SU18_powerbi_badge

 

@AlB Great! Wonderful! With some minor changes in column names, it worked! Now I'm going to try to understand it...

JVos

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.

Top Solution Authors
Top Kudoed Authors