cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Anonymous
Not applicable

Merge duplicate columns on full outer join

I like explaining with pictures a lot more:

https://i.ibb.co/gy0PLcZ/pbi.png

pbi.PNG

Some sample data you can copy for testing:

Antivirus

Company (AV)Computer (AV)Antivirus Version
YipeeBACONATOR12.445
TundraALOHA12.367
TundraGRANDPA12.367
YipeeNETHERLANDS12.445

 

Live Monitoring

Company (M)Computer (M)Monitor Version
YipeeBACONATOR120.812
TundraALOHA120.812
YipeeNETHERLANDS118.554
TundraSUPERCALI120.812
TundraOSTEOPOROSIS118.554

-----

Hello, we're trying to audit our computers' software installations: We need to know if they are missing either their Antivirus software or their Monitoring software. We're doing this by comparing the 2 datasets with a "FULL OUTER Join". (If "Monitor Version" or "Antivirus Version" columns have a blank value after the join, we can assume the computer is missing that respective software package.)

 

We're fuzzy-joining the datasets by using the "Company" and "Computer" columns (found in both datasets) as the [foreign] keys.

 

We currently have to retain the "Company" and "Computer" columns from both datasets after the join--to know which Company & Computer a given row belongs to--in case a given computer is missing from one of the datasets.

 

Our goal is this: Merge the data from the duplicate "Company" and "Computer" columns from both datasets into new single master "Company" and "Computer" columns.

New "Company" & "Computer" column conditions:

  • If "Company" and "Computer" data exists from BOTH tables for a given row, only show the company & computer data from the "Live Monitoring" table.
  • (Obviously) If company & computer data are missing from one dataset but exist in the other, show the company & computer data from the table that has it.

 

I look forward to any help--Thank you

1 ACCEPTED SOLUTION
Ashish_Mathur
Super User III
Super User III

Hi,

You may download my PBI file from here.

Hope this helps.

Untitled.png


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

View solution in original post

2 REPLIES 2
Ashish_Mathur
Super User III
Super User III

Hi,

You may download my PBI file from here.

Hope this helps.

Untitled.png


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

View solution in original post

lbendlin
Super User III
Super User III

let
Source = Table.NestedJoin(Antivirus, {"Company (AV)", "Computer (AV)"}, #"Live Monitoring", {"Company (M)", "Computer (M)"}, "Live Monitoring", JoinKind.FullOuter),
#"Expanded Live Monitoring" = Table.ExpandTableColumn(Source, "Live Monitoring", {"Company (M)", "Computer (M)", "Monitor Version"},{"Company", "Computer", "Monitor Version"}),
#"Replaced Value" = Table.ReplaceValue(#"Expanded Live Monitoring",null,each [Company],Replacer.ReplaceValue,{"Company (AV)"}),
#"Replaced Value1" = Table.ReplaceValue(#"Replaced Value",null,each [Computer],Replacer.ReplaceValue,{"Computer (AV)"}),
#"Removed Other Columns" = Table.SelectColumns(#"Replaced Value1",{"Company (AV)", "Computer (AV)", "Antivirus Version", "Monitor Version"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Other Columns",{{"Company (AV)", "Company"}, {"Computer (AV)", "Computer"}})
in
#"Renamed Columns"

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

2021 Release Wave 2 Plan

Power Platform release plan for the 2021 release wave 2 describes all new features releasing from October 2021 through March 2022.

July 2021 Update 768x460.png

Check it out!

Click here to read more about the July 2021 Updates

Top Solution Authors
Top Kudoed Authors