Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Anonymous
Not applicable

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
v-huizhn-msft
Microsoft Employee
Microsoft Employee

Hi @Anonymous,

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.

picture1picture1  picture2picture2



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

Picture3Picture3
3. Then click "Group by" as the picture4 shown.

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

Picture5Picture5

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
v-huizhn-msft
Microsoft Employee
Microsoft Employee

Hi @Anonymous,

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.

picture1picture1  picture2picture2



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

Picture3Picture3
3. Then click "Group by" as the picture4 shown.

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

Picture5Picture5

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

mow700
Resolver I
Resolver I

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

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.