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
Anonymous
Not applicable

Combining data from different sources based on data readiness

Capture.JPG

Hi All, 

 

I have 3 different data sources and would like to combine them to one "end result" table. I need the data to be combined based on "latest" data. Data source A is in its early stages, then B, then data C is in the latest, most recent stage. Therefore, the end result is the combination of data sources A B and C based on whatever opportunity is the most recent. How would I tackle this in the query? Any ideas? 

 

Thanks a lot for the help!!! 

2 ACCEPTED SOLUTIONS
amitchandak
Super User
Super User

@Anonymous , I used A, B, C as table names

 

a New table in DAX

 

New Table =
var _tab1 = union(calculateTable(B, B[opportunity] in except(all(B[opportunity]),all(C[opportunity]))),C)
return
union(calculateTable(A, A[opportunity] in except(all(A[opportunity]),all(_tab1[opportunity]))),_tab1)

View solution in original post

v-jayw-msft
Community Support
Community Support

Hi @Anonymous ,

 

You will need to add a custom column for each table, for example tablea is 1 tableb is 2 and tablec is 3.

Then use append queries feature to combine these 3 tables.

Here's the query.

let
    Source = Table.Combine({#"Table a", #"Table b", #"Table c"}),
    #"Grouped Rows" = Table.Group(Source, {"opportunity"}, {{"max", each List.Max([Custom]), type number}, {"amount", each _, type table [opportunity=nullable text, amount=nullable number, Custom=number]}}),
    #"Expanded amount" = Table.ExpandTableColumn(#"Grouped Rows", "amount", {"opportunity", "amount", "Custom"}, {"amount.opportunity", "amount.amount", "amount.Custom"}),
    #"Added Custom" = Table.AddColumn(#"Expanded amount", "Custom", each if [max] = [amount.Custom] then 1 else 0),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Custom] = 1)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"max", "amount.opportunity", "amount.Custom", "Custom"})
in
    #"Removed Columns"

Pbix as attached.

 

Best Regards,

Jay

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.

View solution in original post

3 REPLIES 3
v-jayw-msft
Community Support
Community Support

Hi @Anonymous ,

 

You will need to add a custom column for each table, for example tablea is 1 tableb is 2 and tablec is 3.

Then use append queries feature to combine these 3 tables.

Here's the query.

let
    Source = Table.Combine({#"Table a", #"Table b", #"Table c"}),
    #"Grouped Rows" = Table.Group(Source, {"opportunity"}, {{"max", each List.Max([Custom]), type number}, {"amount", each _, type table [opportunity=nullable text, amount=nullable number, Custom=number]}}),
    #"Expanded amount" = Table.ExpandTableColumn(#"Grouped Rows", "amount", {"opportunity", "amount", "Custom"}, {"amount.opportunity", "amount.amount", "amount.Custom"}),
    #"Added Custom" = Table.AddColumn(#"Expanded amount", "Custom", each if [max] = [amount.Custom] then 1 else 0),
    #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([Custom] = 1)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"max", "amount.opportunity", "amount.Custom", "Custom"})
in
    #"Removed Columns"

Pbix as attached.

 

Best Regards,

Jay

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.
Anonymous
Not applicable

Amazing!!!!!

amitchandak
Super User
Super User

@Anonymous , I used A, B, C as table names

 

a New table in DAX

 

New Table =
var _tab1 = union(calculateTable(B, B[opportunity] in except(all(B[opportunity]),all(C[opportunity]))),C)
return
union(calculateTable(A, A[opportunity] in except(all(A[opportunity]),all(_tab1[opportunity]))),_tab1)

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.