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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
renzhaj
Helper I
Helper I

equivalent T-SQL Merge in Power Query

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

1 ACCEPTED SOLUTION
dax
Community Support
Community Support

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.

View solution in original post

5 REPLIES 5
dax
Community Support
Community Support

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

IDColum_A
1TTT
4YYY

Query B

IDColum_AColum_B
1AAA1111
2BBB2222
3CCC3333

 

Output:

Query B

IDColum_AColum_B
1TTT1111
2BBB2222
3CCC3333
4YYYnull
dax
Community Support
Community Support

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.

artemus
Employee
Employee

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. 

Anonymous
Not applicable

Hi @renzhaj,

Not as a standard function as far as I am aware. You can of course write you custom function to do this, and use it as a shortcut.

Kind regards,
JB

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors