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.
Hi guys,
with T-SQL Merge I can insert new data and update the existing in one statement. I guess I can split data and use the Power BI merge/append to achieve the same result in the end. But is there any easier way to make it?
Thanks
Solved! Go to Solution.
Hi @renzhaj ,
You could try below M code to see whether it work or not
let
Source = Table.NestedJoin(#"Query B", {"ID"}, #"Query A", {"ID"}, "Query A", JoinKind.FullOuter),
#"Expanded Query A" = Table.ExpandTableColumn(Source, "Query A", {"ID", "Colum_A"}, {"ID.1", "Colum_A.1"}),
Custom1 = Table.ReplaceValue(#"Expanded Query A", each [ID.1], each if [ID.1]=null then [ID] else [ID.1], Replacer.ReplaceValue, {"ID.1"}),
Custom2 = Table.ReplaceValue(Custom1, each [Colum_A.1], each if [Colum_A.1]=null then [Colum_A] else [Colum_A.1], Replacer.ReplaceValue, {"Colum_A.1"}),
#"Removed Columns" = Table.RemoveColumns(Custom2,{"ID", "Colum_A"})
in
#"Removed Columns"
Best Regards,
Zoe Zhi
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @renzhaj ,
I think this need to be based on your detailed requirement, so if possible, could you please inform me more detailed information(such as your expected output and your sample data)? Then I will help you more correctly.
Please do mask sensitive data before uploading.
Thanks for your understanding and support.
Best Regards,
Zoe Zhi
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thanks, Zoe.
It's a straightforward T-SQL Merge scenario. Query A is daily refreshed with new data(ID:4) and updated data(ID:1) only from the source system. Query B is not refreshed but updated by Query A and other queries every day.
Input:
Query A
ID | Colum_A |
1 | TTT |
4 | YYY |
Query B
ID | Colum_A | Colum_B |
1 | AAA | 1111 |
2 | BBB | 2222 |
3 | CCC | 3333 |
Output:
Query B
ID | Colum_A | Colum_B |
1 | TTT | 1111 |
2 | BBB | 2222 |
3 | CCC | 3333 |
4 | YYY | null |
Hi @renzhaj ,
You could try below M code to see whether it work or not
let
Source = Table.NestedJoin(#"Query B", {"ID"}, #"Query A", {"ID"}, "Query A", JoinKind.FullOuter),
#"Expanded Query A" = Table.ExpandTableColumn(Source, "Query A", {"ID", "Colum_A"}, {"ID.1", "Colum_A.1"}),
Custom1 = Table.ReplaceValue(#"Expanded Query A", each [ID.1], each if [ID.1]=null then [ID] else [ID.1], Replacer.ReplaceValue, {"ID.1"}),
Custom2 = Table.ReplaceValue(Custom1, each [Colum_A.1], each if [Colum_A.1]=null then [Colum_A] else [Colum_A.1], Replacer.ReplaceValue, {"Colum_A.1"}),
#"Removed Columns" = Table.RemoveColumns(Custom2,{"ID", "Colum_A"})
in
#"Removed Columns"
Best Regards,
Zoe Zhi
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
It would look something like:
Table.FromRecords(Table.TransformRows(Source, if <where clause> then _ & [ColumnA = ..., ColumnC = ...] else _))
Note performance might be bad. Also note that columns that are ommited are left unchanged.