Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
I have a scenario to get discrepancy records across 2 different JSON objects. I will import the 2 objects into PowerBI Desktop and name as 1 VS 2.
Therefore, what I have is:
Table1 | Name | Industry | City | Table 2 | Name | Industry | City | |
record 1 | A | A | C | record 1 | A | B | C | |
record 2 | A | B | C | record 2 | A | B | C | |
record 3 | A | B | C | record 3 | A | B | C |
The result I am looking for is a new table showing:
New Table | Name | Industry | City |
record 1 | Yes | No | Yes |
record 2 | Yes | Yes | Yes |
record 3 | Yes | Yes | Yes |
Could anyone point me with some direction how to get the new table generated? Appreciated a million!
Solved! Go to Solution.
@Anonymous,
Try this in Power Query:
let
Source = Table.NestedJoin(Table1, {"Record ID"}, Table2, {"Record ID"}, "Table2", JoinKind.Inner),
RenameColumns = Table.RenameColumns(
Source,
{{"Name", "Table1.Name"}, {"Industry", "Table1.Industry"}, {"City", "Table1.City"}}
),
ExpandTable2 = Table.ExpandTableColumn(
RenameColumns,
"Table2",
{"Name", "Industry", "City"},
{"Table2.Name", "Table2.Industry", "Table2.City"}
),
AddName = Table.AddColumn(
ExpandTable2,
"Name",
each if [Table1.Name] = [Table2.Name] then "Yes" else "No"
),
AddIndustry = Table.AddColumn(
AddName,
"Industry",
each if [Table1.Industry] = [Table2.Industry] then "Yes" else "No"
),
AddCity = Table.AddColumn(
AddIndustry,
"City",
each if [Table1.City] = [Table2.City] then "Yes" else "No"
),
RemoveColumns = Table.RemoveColumns(
AddCity,
{
"Table1.Name",
"Table1.Industry",
"Table1.City",
"Table2.Name",
"Table2.Industry",
"Table2.City"
}
)
in
RemoveColumns
Proud to be a Super User!
@Anonymous,
Try this in Power Query:
let
Source = Table.NestedJoin(Table1, {"Record ID"}, Table2, {"Record ID"}, "Table2", JoinKind.Inner),
RenameColumns = Table.RenameColumns(
Source,
{{"Name", "Table1.Name"}, {"Industry", "Table1.Industry"}, {"City", "Table1.City"}}
),
ExpandTable2 = Table.ExpandTableColumn(
RenameColumns,
"Table2",
{"Name", "Industry", "City"},
{"Table2.Name", "Table2.Industry", "Table2.City"}
),
AddName = Table.AddColumn(
ExpandTable2,
"Name",
each if [Table1.Name] = [Table2.Name] then "Yes" else "No"
),
AddIndustry = Table.AddColumn(
AddName,
"Industry",
each if [Table1.Industry] = [Table2.Industry] then "Yes" else "No"
),
AddCity = Table.AddColumn(
AddIndustry,
"City",
each if [Table1.City] = [Table2.City] then "Yes" else "No"
),
RemoveColumns = Table.RemoveColumns(
AddCity,
{
"Table1.Name",
"Table1.Industry",
"Table1.City",
"Table2.Name",
"Table2.Industry",
"Table2.City"
}
)
in
RemoveColumns
Proud to be a Super User!
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
79 | |
73 | |
57 | |
36 | |
31 |
User | Count |
---|---|
91 | |
60 | |
60 | |
49 | |
45 |