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

Join 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.

Reply
Anonymous
Not applicable

Comparing 1 json object against another json objects

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: 

Table1NameIndustryCity Table 2NameIndustryCity
record 1AAC record 1ABC
record 2ABC record 2ABC
record 3 ABC record 3 ABC

 

The result I am looking for is a new table showing: 

New TableNameIndustryCity
record 1YesNoYes
record 2YesYesYes
record 3YesYesYes

 

Could anyone point me with some direction how to get the new table generated? Appreciated a million! 

 

 

1 ACCEPTED SOLUTION
DataInsights
Super User
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

 

DataInsights_0-1658497910568.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

1 REPLY 1
DataInsights
Super User
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

 

DataInsights_0-1658497910568.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.