Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
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_ID | ACCOUNT_ID | VALUE | ORIGIN_ID | PIPELINE_ID |
1234 | 2233 | 100 | 2 | 5 |
5678 | 2233 | 500 | 2 | 6 |
9012 | 3344 | 600 | 1 | 5 |
Table 2:
DEAL_ID | CAMPAING_ID | VALUE | ADSET_ID |
3333 | 8 | 80 | 2 |
1234 | 9 | 100 | 3 |
5678 | 6 | 300 | 1 |
Final result:
DEAL_ID | ACCOUNT_ID | VALUE | ORIGIN_ID | PIPELINE_ID | CAMPAING_ID | ADSET_ID |
1234 | 2233 | 100 | 2 | 5 | 9 | 3 |
5678 | 2233 | 500 | 2 | 6 | 6 | 1 |
9012 | 3344 | 600 | 1 | 5 | NULL | NULL |
3333 | NULL | 80 | NULL | NULL | 8 | 2 |
Solved! Go to Solution.
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"
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"
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.
Proud to be a Super User! | |