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

Combine Tables with Missing Rows

I have two tables as shown below:

 

Partner

CodePartnerBacklog
1111One500
2222Two100
3333Three300

 

Project History

 

Partner CodeAmountProject
1111300Proj1
1111100Proj2
2222400Proj3

 

When I combine the tables I get the below result:

PartnerCodeAmount
One1111400
Two2222400

 

However, what I'd like to see is the below:

PartnerCodeAmount
One1111400
Two2222400
Three33330

 

Is there anyway to accomplish the above without actually merging the queries? The two tables are already large and would like to avoid that if possible.

1 ACCEPTED SOLUTION

Accepted Solutions
v-huizhn-msft Super Contributor
Super Contributor

Re: Combine Tables with Missing Rows

Hi @jgalus,

I try to reproduce your scenario, and get expected result. Please follow the steps below.

1. In query Editor, please click "Merge query as new" (highlighted in yellow). Merge the two tables by Code shown in picture2.

5.PNGpicture1  1.PNGpicture2



2. You will get the table below(Picture3), then remove the Backlog, Parter Code and Project fields.

2.PNGPicture3
3. Then click "Group by" as the picture4 shown.

8.PNGPicture4
4. Click "Apply" on Home page. You will get expected result shown in Picture5, and review my query statement.

4.PNGPicture5

let
    Source = Table.NestedJoin(Partner,{"Code"},#"Project History",{"Partner Code"},"Project History",JoinKind.LeftOuter),
    #"Expanded Project History" = Table.ExpandTableColumn(Source, "Project History", {"Partner Code", "Amount", "Project"}, {"Project History.Partner Code", "Project History.Amount", "Project History.Project"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Project History",{"Backlog", "Project History.Partner Code", "Project History.Project"}),
    #"Grouped Rows" = Table.Group(#"Removed Columns", {"Code", "Partner"}, {{"Amount", each List.Sum([Project History.Amount]), type number}})
in
    #"Grouped Rows"


Best Regards,
Angelia

View solution in original post

2 REPLIES 2
mow700 Regular Visitor
Regular Visitor

Re: Combine Tables with Missing Rows

If you are merging the two queries you should be able to control the behavior in question with the Join Kind option:

 

snip_20171010160654.png

v-huizhn-msft Super Contributor
Super Contributor

Re: Combine Tables with Missing Rows

Hi @jgalus,

I try to reproduce your scenario, and get expected result. Please follow the steps below.

1. In query Editor, please click "Merge query as new" (highlighted in yellow). Merge the two tables by Code shown in picture2.

5.PNGpicture1  1.PNGpicture2



2. You will get the table below(Picture3), then remove the Backlog, Parter Code and Project fields.

2.PNGPicture3
3. Then click "Group by" as the picture4 shown.

8.PNGPicture4
4. Click "Apply" on Home page. You will get expected result shown in Picture5, and review my query statement.

4.PNGPicture5

let
    Source = Table.NestedJoin(Partner,{"Code"},#"Project History",{"Partner Code"},"Project History",JoinKind.LeftOuter),
    #"Expanded Project History" = Table.ExpandTableColumn(Source, "Project History", {"Partner Code", "Amount", "Project"}, {"Project History.Partner Code", "Project History.Amount", "Project History.Project"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Project History",{"Backlog", "Project History.Partner Code", "Project History.Project"}),
    #"Grouped Rows" = Table.Group(#"Removed Columns", {"Code", "Partner"}, {{"Amount", each List.Sum([Project History.Amount]), type number}})
in
    #"Grouped Rows"


Best Regards,
Angelia

View solution in original post

Helpful resources

Announcements
Can You Solve These Challenge

Challenge: Can You Solve These?

Find out how to participate in the first Power BI 'Can You Solve These?' challenge.

Community News & Announcements

Community News & Announcements

Get your latest community news and announcements.

Virtual Launch Event

Microsoft Business Applications October Virtual Launch Event

Join us for an in-depth look at the new innovations across Dynamics 365 and the Microsoft Power Platform.

Community Kudopalooza

Win Power BI Swag with Community Kudopalooza!

Each week, complete activities and be qualified in the drawing for cool Power BI Swag.

Users Online
Currently online: 57 members 1,290 guests
Please welcome our newest community members: