cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Frequent Visitor

Merge Queries Help

Hello there,

 

I am trying to Merge two tables. Table 1 "US_Det_Cust_Ledg" (fig. 1) has been filtered a couple of times and Grouped By [Cust Ledger Entry No] (fig. 2) which is the foreign key linking it to Table 2 "US_Cust_Ledg_Entry"[Entry No_] (fig. 3)

 

I am trying to do "US_Det_Cust_Ledg" Left Outer Join "US_Cust_Ledg_Entry" where [Cust Ledger Entry No] = [Entry No_] (fig. 4). I have confirmed by exporting to Excel that all rows in each table have matching IDs. However, after this merge I end up with several null values coming through (fig. 5). I'm thinking it might have to do with the Group By previously performed in "US_Det_Cust_Ledg", but I don't really know.

 

What am I doing wrong here? Screenshots and code below. 

 

Thank you in advance!

 

Fig. Fig 1. US_Det_Cust_Ledg (Original)Fig 1. US_Det_Cust_Ledg (Original)Fig. 2 US_Det_Cust_Ledg (Grouped)Fig. 2 US_Det_Cust_Ledg (Grouped)Fig. 3 US_Cust_Ledg_EntryFig. 3 US_Cust_Ledg_EntryFig. 4 Merge (Left Outer)Fig. 4 Merge (Left Outer)Fig 5. null Values ReturnedFig 5. null Values ReturnedFig 6. Proof of Matching ValuesFig 6. Proof of Matching Values

let
    Source = #"SQL4: STRENE_NAV2017_PROD",
    #"Filtered Rows" = Table.SelectRows(Source, each Text.Contains([Name.2], "Detailed Cust_ ")),
    #"dbo_Strad Oilfield Services Inc_$Detailed Cust_ Ledg_ Entry" = #"Filtered Rows"{[Schema="dbo",Item="Strad Oilfield Services Inc_$Detailed Cust_ Ledg_ Entry"]}[Data],
    #"Removed Other Columns" = Table.SelectColumns(#"dbo_Strad Oilfield Services Inc_$Detailed Cust_ Ledg_ Entry",{"Cust_ Ledger Entry No_", "Posting Date", "Document No_", "Amount", "Customer No_"}),
    #"Changed Type" = Table.TransformColumnTypes(#"Removed Other Columns",{{"Posting Date", type date}, {"Amount", Currency.Type}}),
    #"Renamed Columns" = Table.RenameColumns(#"Changed Type",{{"Cust_ Ledger Entry No_", "Cust Ledger Entry No"}}),
    #"Added INCLUDE" = Table.AddColumn(#"Renamed Columns", "Include", each if [Posting Date] > #"Report Date" then "False" else "True"),
    #"Filter Include = True" = Table.SelectRows(#"Added INCLUDE", each [Include] = "True"),
    #"Grouped Rows by Cust Ledger Entry No" = Table.Group(#"Filter Include = True", {"Cust Ledger Entry No"}, {{"Amount", each List.Sum([Amount]), type number}}),
    #"Filter Amount <> 0" = Table.SelectRows(#"Grouped Rows by Cust Ledger Entry No", each [Amount] <> 0),
    #"Changed Type1" = Table.TransformColumnTypes(#"Filter Amount <> 0",{{"Cust Ledger Entry No", type number}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type1",{"Cust Ledger Entry No"},US_Cust_Ledg_Entry,{"Entry No_"},"US_Cust_Ledg_Entry",JoinKind.LeftOuter),
    #"Expanded US_Cust_Ledg_Entry" = Table.ExpandTableColumn(#"Merged Queries", "US_Cust_Ledg_Entry", {"Customer No_", "Posting Date", "Document No_", "Open"}, {"Customer No_", "Posting Date", "Document No_", "Open"}),
    #"Filtered Rows1" = Table.SelectRows(#"Expanded US_Cust_Ledg_Entry", each ([Open] = null))
in
    #"Filtered Rows1"

Fig. 7 Code for US_Det_Cust_Ledg

 

 

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Super User IV
Super User IV

Re: Merge Queries Help

Hi,

 

I think the reason i the different data type of the matching column.  In the header, one is formatted as 1.2 and another one as 123.  Standardize the data type and then merge the datasets.

 

Hope this helps.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

View solution in original post

2 REPLIES 2
Highlighted
Super User I
Super User I

Re: Merge Queries Help

Before the merge, the rows in the grouped query get filtered to only keep those where amount<> 0 .

Step #"Filter Amount <> 0"

 

So the rows that have null after the merge are the ones which had amount = 0 in the grouped query.

Highlighted
Super User IV
Super User IV

Re: Merge Queries Help

Hi,

 

I think the reason i the different data type of the matching column.  In the header, one is formatted as 1.2 and another one as 123.  Standardize the data type and then merge the datasets.

 

Hope this helps.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

View solution in original post

Helpful resources

Announcements
Community Blog

Community Blog

Visit our Community Blog for articles, guides, and information created by fellow community members.

Using the Community

Using the Community

Need help with the Power BI Community? Our 'Using the Community' support articles are a great place to start.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Power Platform 2020 release wave 2 plan

Power Platform 2020 release wave 2 plan

Features releasing from October 2020 through March 2021

Top Solution Authors
Top Kudoed Authors