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
Rudz
Kudo Collector
Kudo Collector

Merge tables using wildcards

I have a small fact table of about 10,000 records. Based on 5 columns in each row, I need to add 3 extra columns from a small dimension table of around 70 records.

 

The problem is that the rules in the dimension table include wildcards. The Reference column in the dim table uses prefixes to match. So Fact References of 20123 and 20999 need to match the Dim Reference of 20*. Other columns need a wildcard to match any value, so Fact assignment of A, B, or Z would match a Dim Assignment of *.

 

In SQL, I can do a join with wildcards:

WHERE fact.company LIKE dim.company + '%'

AND fact.reference LIKE dim.reference+'%'

AND fact.assignment LIKE dim.assignment+'%'

AND fact.plant LIKE dim.plant+'%'

AND fact.customer LIKE dim.customer+'%'

 

I haven't figured out any way to do this in Power Query. Chris Webb has a Power Query LIKE function, but it looks like it would only work to filter a single column. I need to join on 5 columns. I also found a post that matched on multiple columns using Table.MatchesAnyRows, but it simply indicated where there was a match without returning any columns.

 

Here is sample data:

 

FACT

CompanyAssignmentReferencePlantCustomer
Anull20123J5
Anull20999J5
AZM123Jnull
BCMIXCMIXGnull
Znull99999J5

 

DIM

CompanyReferenceAssignmentPlantCustomerResult1Result2Result3
A20*nullJ5GPG
A21*GJnullGGP
AC M**JnullZPO
AM**JnullZOP
B10*nullD8ELI
*ADJ****nullnullnull
*CMI****nullnullnull

The goal is to match records here to the fact table and add the 3 result columns. If there is no match, I need to identify those rows as grief, either in the output or in a separate query. It would be acceptable to return nulls if no match.

The * character in the Dim table indicates match of 0 or more characters (needs to match null).

All values in the reference column are prefixes with the wildcard at the end.

The * character could be changed to % or anything else as needed or removed.

 

Desired output

CompanyAssignmentReferencePlantCustomerResult1Result2Result3
Anull20123J5GPG
Anull20999J5GPG
AZM123JnullZOP
BCMIXCMIXGnullnullnullnull
Znull99999J5griefgriefgrief

 

I have a sample file I could attach if I can figure out how!

 

Thanks for any help!

1 ACCEPTED SOLUTION
wdx223_Daniel
Super User
Super User

@Rudz 

let
    Fact = Excel.CurrentWorkbook(){[Name="Fact"]}[Content],
    Dim = Excel.CurrentWorkbook(){[Name="Dim"]}[Content],
    fx=(t1,t2)=>
        let
            a=Text.From(t2),
            b=Text.From(t1),
            c=if Text.End(a,1)="*" then Text.StartsWith(b??"",Text.Start(a,Text.Length(a)-1)) else a=b
        in if a="*" then true else c,
    Custom1 = Table.AddColumn(
                              Fact,
                              "n",
                              each let
                                      col=Table.ColumnNames(Fact),
                                      b=Table.SelectRows(
                                                         Dim,
                                                         (x)=>List.AllTrue(List.Transform(col,(y)=>fx(Record.Field(_,y),Record.Field(x,y))))
                                                        )
                                   in if b{0}?=null 
                                      then {null,null,null}
                                      else Record.ToList(Record.SelectFields(b{0},{"Result1","Result2","Result3"}))
                             ),
    Custom2 = Table.SplitColumn(Custom1,"n",each _,{"Result1","Result2","Result3"})
in
    Custom2

View solution in original post

1 REPLY 1
wdx223_Daniel
Super User
Super User

@Rudz 

let
    Fact = Excel.CurrentWorkbook(){[Name="Fact"]}[Content],
    Dim = Excel.CurrentWorkbook(){[Name="Dim"]}[Content],
    fx=(t1,t2)=>
        let
            a=Text.From(t2),
            b=Text.From(t1),
            c=if Text.End(a,1)="*" then Text.StartsWith(b??"",Text.Start(a,Text.Length(a)-1)) else a=b
        in if a="*" then true else c,
    Custom1 = Table.AddColumn(
                              Fact,
                              "n",
                              each let
                                      col=Table.ColumnNames(Fact),
                                      b=Table.SelectRows(
                                                         Dim,
                                                         (x)=>List.AllTrue(List.Transform(col,(y)=>fx(Record.Field(_,y),Record.Field(x,y))))
                                                        )
                                   in if b{0}?=null 
                                      then {null,null,null}
                                      else Record.ToList(Record.SelectFields(b{0},{"Result1","Result2","Result3"}))
                             ),
    Custom2 = Table.SplitColumn(Custom1,"n",each _,{"Result1","Result2","Result3"})
in
    Custom2

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