Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
I like explaining with pictures a lot more:
https://i.ibb.co/gy0PLcZ/pbi.png
Some sample data you can copy for testing:
Antivirus
Company (AV) | Computer (AV) | Antivirus Version |
Yipee | BACONATOR | 12.445 |
Tundra | ALOHA | 12.367 |
Tundra | GRANDPA | 12.367 |
Yipee | NETHERLANDS | 12.445 |
Live Monitoring
Company (M) | Computer (M) | Monitor Version |
Yipee | BACONATOR | 120.812 |
Tundra | ALOHA | 120.812 |
Yipee | NETHERLANDS | 118.554 |
Tundra | SUPERCALI | 120.812 |
Tundra | OSTEOPOROSIS | 118.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:
I look forward to any help--Thank you
Solved! Go to Solution.
Hi,
You may download my PBI file from here.
Hope this helps.
Hi,
You may download my PBI file from here.
Hope this helps.
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"
User | Count |
---|---|
119 | |
65 | |
62 | |
56 | |
50 |
User | Count |
---|---|
177 | |
85 | |
70 | |
63 | |
55 |