cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
New Member

Merge 2 tables into 1 overview

Good evening,

 

I want to merge table 1 and table 2 into 1 overview.

But there is not a normal relation between the 2 tables.

 

Sources:

Table 1

FileIDSupplier
LFI223081Dunga-dunga
LFI223747Sonac-Gent
LFI224207Trob-Dong
LFI225815Moyp-Ballym
LFI225820Dunga-Dunga

 

Table 2

SupplieractiveFFAPHNPHPENi
Dunga-dungano5201539700
Sonac-Gentyes110520550
Trob-Dongyes35040120
Moyp-Ballymyes6300250351000
Dunga-dungayes4251040650

 

 

New overview

FileID          SupplierFFAPHNPHPENi
LFI223081Dunga-dunga4251040650
LFI223747Sonac-Gent110520550
LFI224207Trob-Dong35040120
LFI225815Moyp-Ballym6300250351000
LFI225820Dunga-Dunga4251040650

 

What I want:

Combine table 1 and 2.

In table 2 there are a lot lines with the same supplier.

But in table 2 there is only 1 active line per supplier.

 

So i need to combine the active line and get them as above overview.

 

Can someone help me with this?

1 ACCEPTED SOLUTION
Super User III
Super User III

Hello @johnkorten 

 

first you need to filter your second table to delete inactive suppliers. As you want to compare this two columns ignoring the case, you need to add a new column where you filter the second table, ignoring the case. Here an example

let
    Table1 = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8nHzNDIyNrAwVNJRcinNS0/UTQGRSrE6MDlzE3OgXHB+XmKyrntqXglCysTIACQVUpSfpOuSn5eOkDG1MDQFyvjmVxboOiXm5FTmIssZGcAtc4FYFgsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [FileID = _t, Supplier = _t]),
    Table2 = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcinNS0/UTQGRSjpKeflAwhSIjQyAhCGIZWwJJMwNDJRidaKVgvPzEpN13VPzSoCClanFIEUgbICszdQUojikKD9J1yU/Lx2u1hgkC1JiYgDVaQRR6ptfWaDrlJiTU5kLV2wG0mAAUmgE1mNsCrYJ6hJUd0N0mIDVwtwDtsMM5JZYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Supplier = _t, active = _t, FFA = _t, PH = _t, NPH = _t, PE = _t, Ni = _t]),
    FilterTable2 = Table.SelectRows(Table2, each ([active] = "yes")),
    JoinTable1WithTable2 = Table.AddColumn
    (
        Table1,
        "Table2",
        (row)=> Table.SelectRows(FilterTable2, each if Comparer.OrdinalIgnoreCase([Supplier],row[Supplier])=0 then true else false)
    ),
    #"Expanded Table2" = Table.ExpandTableColumn(JoinTable1WithTable2, "Table2", {"active", "FFA", "PH", "NPH", "PE", "Ni"}, {"active", "FFA", "PH", "NPH", "PE", "Ni"})
in 
    #"Expanded Table2"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

2 REPLIES 2
Super User III
Super User III

Hello @johnkorten 

 

first you need to filter your second table to delete inactive suppliers. As you want to compare this two columns ignoring the case, you need to add a new column where you filter the second table, ignoring the case. Here an example

let
    Table1 = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8nHzNDIyNrAwVNJRcinNS0/UTQGRSrE6MDlzE3OgXHB+XmKyrntqXglCysTIACQVUpSfpOuSn5eOkDG1MDQFyvjmVxboOiXm5FTmIssZGcAtc4FYFgsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [FileID = _t, Supplier = _t]),
    Table2 = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WcinNS0/UTQGRSjpKeflAwhSIjQyAhCGIZWwJJMwNDJRidaKVgvPzEpN13VPzSoCClanFIEUgbICszdQUojikKD9J1yU/Lx2u1hgkC1JiYgDVaQRR6ptfWaDrlJiTU5kLV2wG0mAAUmgE1mNsCrYJ6hJUd0N0mIDVwtwDtsMM5JZYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Supplier = _t, active = _t, FFA = _t, PH = _t, NPH = _t, PE = _t, Ni = _t]),
    FilterTable2 = Table.SelectRows(Table2, each ([active] = "yes")),
    JoinTable1WithTable2 = Table.AddColumn
    (
        Table1,
        "Table2",
        (row)=> Table.SelectRows(FilterTable2, each if Comparer.OrdinalIgnoreCase([Supplier],row[Supplier])=0 then true else false)
    ),
    #"Expanded Table2" = Table.ExpandTableColumn(JoinTable1WithTable2, "Table2", {"active", "FFA", "PH", "NPH", "PE", "Ni"}, {"active", "FFA", "PH", "NPH", "PE", "Ni"})
in 
    #"Expanded Table2"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

Super User III
Super User III

Hi @johnkorten 

I don't see thelogic of how the Dunga-dunga rows are connetced between the tables.  How do I know which row in Table 2 joins to which row in table 1?

Phil

Helpful resources

Announcements
secondImage

Happy New Year from Power BI

This is a must watch for a message from Power BI!

December Update

Check it Out!

Click here to read more about the December 2020 Updates!

Community Blog

Check it Out!

Click here to read the latest blog and learn more about contributing to the Power BI blog!

Get Ready for Power BI Dev Camp

Get Ready for Power BI Dev Camp

Mark your calendars and join us for our next Power BI Dev Camp!.

Top Solution Authors
Top Kudoed Authors