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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
FelipMark
Helper II
Helper II

how to append query without grabbing existing data

Hello everyone, I want to use the function to add queries, but without adding data that already correspond to the ID column so as not to duplicate information. Example:

Table 1:

DEAL_IDACCOUNT_IDVALUEORIGIN_IDPIPELINE_ID
1234223310025
5678223350026
9012334460015


Table 2:

DEAL_IDCAMPAING_IDVALUEADSET_ID
33338802
123491003
567863001


Final result:

DEAL_IDACCOUNT_IDVALUEORIGIN_IDPIPELINE_IDCAMPAING_IDADSET_ID
12342233

100

2593
567822335002661
9012334460015NULLNULL
3333NULL80NULLNULL82
1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

Use this code for Table1

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyNlHSUTIyMjYGUoYGBiAOEJsqxepEK5mamVsgZE3hsmZgWUsDQxDH2NgEZIQZWNYQojcWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [DEAL_ID = _t, ACCOUNT_ID = _t, VALUE = _t, ORIGIN_ID = _t, PIPELINE_ID = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"DEAL_ID", Int64.Type}, {"ACCOUNT_ID", Int64.Type}, {"VALUE", Int64.Type}, {"ORIGIN_ID", Int64.Type}, {"PIPELINE_ID", Int64.Type}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"DEAL_ID"}, Table2, {"DEAL_ID"}, "Table2", JoinKind.FullOuter),
    #"Expanded Table2" = Table.ExpandTableColumn(#"Merged Queries", "Table2", {"DEAL_ID", "CAMPAING_ID", "VALUE", "ADSET_ID"}, {"DEAL_ID.1", "CAMPAING_ID", "VALUE.1", "ADSET_ID"}),
    Custom1 = Table.ReplaceValue(#"Expanded Table2", each [DEAL_ID], each [DEAL_ID]??[DEAL_ID.1], Replacer.ReplaceValue, {"DEAL_ID"}),
    Custom2 = Table.ReplaceValue(Custom1, each [VALUE], each [VALUE]??[VALUE.1], Replacer.ReplaceValue, {"VALUE"}),
    #"Removed Columns" = Table.RemoveColumns(Custom2,{"DEAL_ID.1", "VALUE.1"})
in
    #"Removed Columns"

View solution in original post

2 REPLIES 2
Vijay_A_Verma
Super User
Super User

Use this code for Table1

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyNlHSUTIyMjYGUoYGBiAOEJsqxepEK5mamVsgZE3hsmZgWUsDQxDH2NgEZIQZWNYQojcWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [DEAL_ID = _t, ACCOUNT_ID = _t, VALUE = _t, ORIGIN_ID = _t, PIPELINE_ID = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"DEAL_ID", Int64.Type}, {"ACCOUNT_ID", Int64.Type}, {"VALUE", Int64.Type}, {"ORIGIN_ID", Int64.Type}, {"PIPELINE_ID", Int64.Type}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"DEAL_ID"}, Table2, {"DEAL_ID"}, "Table2", JoinKind.FullOuter),
    #"Expanded Table2" = Table.ExpandTableColumn(#"Merged Queries", "Table2", {"DEAL_ID", "CAMPAING_ID", "VALUE", "ADSET_ID"}, {"DEAL_ID.1", "CAMPAING_ID", "VALUE.1", "ADSET_ID"}),
    Custom1 = Table.ReplaceValue(#"Expanded Table2", each [DEAL_ID], each [DEAL_ID]??[DEAL_ID.1], Replacer.ReplaceValue, {"DEAL_ID"}),
    Custom2 = Table.ReplaceValue(Custom1, each [VALUE], each [VALUE]??[VALUE.1], Replacer.ReplaceValue, {"VALUE"}),
    #"Removed Columns" = Table.RemoveColumns(Custom2,{"DEAL_ID.1", "VALUE.1"})
in
    #"Removed Columns"
ToddChitt
Super User
Super User

Do a FULL OUTER JOIN between the two tables. Expand the joined table and include all columns.

You will have some rows that exist in both tables (1234, 5678) and some that exist in only ONE table (9012) and some that exist only in the OTHER table (3333).

Now you need to create a calculated column that looks at the two resptive DEAL_ID fields and if null in one, use the other DEAL_ID.




Did I answer your question? If so, mark my post as a solution. Also consider helping someone else in the forums!

Proud to be a Super User!





Helpful resources

Announcements
PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

Top Solution Authors
Top Kudoed Authors