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
andresp_g
New Member

join tables vs relation between tables

Hi everyone,

 let me explain what I'm trying to achieve. I have a table with my inventory information like this

 

DateProductColorValue
111500
112300
121400
122

250

 

Also I have the information about how this product should be allocated by client like this

 

DateProductClientAllocation
11130%
11270%
12150%
12250%

 

The expected result is each client knows in units how many they have. The solution right now is to combine the two tables using a left join and multiply units per Allocation, but it significally increase the model size. Is there a way to relate this two tables, and create a measure instead?

 

Thank you so much for your help

1 ACCEPTED SOLUTION

Xue's formula has a flaw in it at the total level, because it is filtering 'Table' on MAX(Table1[ProductID] ) at the grand total level the max is equal to 2. So the SUM(Value) returns 650 and the SUM(Table1[Allocation]) is not filtered at all as the filter is applied to the other table, so it returns the sum of all Allocations which is 200%. So 650 x 200% = 1300

 

For logic like this you would be better to use a SUMX pattern to loop over one of the tables row by row. (I'm also filtering on both date and product as per your original requirement)

Allocated Value = SUMX( 'Table 1', 
  Var _date = 'Table 1'[Date]
  var _product = 'Table 1'[Product]
return 'Table 1'[Allocation] * CALCULATE( SUM('Table'[Value]), 'Table'[Date] = _date, 'Table'[Product] = _product) )

View solution in original post

4 REPLIES 4
v-xuding-msft
Community Support
Community Support

Hi @andresp_g ,

I created a measure that you can have a try.

Measure = CALCULATE(SUM('Table'[Value])*SUM('Table 1'[Allocation]),FILTER(ALLEXCEPT('Table','Table'[Color]),'Table'[Product] = MAX('Table 1'[Product])))

1.PNG

If it is not what you want, please share your expected results.

 

Best Regards,

Xue Ding

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Best Regards,
Xue Ding
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Hi @v-xuding-msft , thank you for your reply!!

 

this is the expected result by line, however the total units doesnt seem to be equal, do you know how to fix it? Also I have the next questions for you:

 

- since there will be several products and days, how should be the relation between the two tables, should be a combined key made by date & product? or tables are not related?

 

- if the inventory table would have other columns as the color column, should be added in the filter parameter?

 

Once again thank you so much

Hi @andresp_g ,
>this is the expected result by line, however the total units doesnt seem to be equal, do you know how to fix it?
For the sample data, the date is always 1. It can't be shown as a continuous line chart. Suggest you to try the measure and add the columns into Line chart based on your actual scenario. And which column do you mean for total unites?

 

>since there will be several products and days, how should be the relation between the two tables, should be a combined key made by date & product? or tables are not related?

For my sample, there is no relationship between the tables. You could try it firstly without relationship and check if it is what you want. And if there is any other calculation in your report, maybe you should create it.

 

>if the inventory table would have other columns as the color column, should be added in the filter parameter?

If you just what the result of the measure, you don't need filter. If you want to view the result of different color, you could add a color slicer to filter them.

 

(I don't understand your actual report, so probably can't reply you acurately. )

 

Best Regards,

Xue Ding

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Best Regards,
Xue Ding
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Xue's formula has a flaw in it at the total level, because it is filtering 'Table' on MAX(Table1[ProductID] ) at the grand total level the max is equal to 2. So the SUM(Value) returns 650 and the SUM(Table1[Allocation]) is not filtered at all as the filter is applied to the other table, so it returns the sum of all Allocations which is 200%. So 650 x 200% = 1300

 

For logic like this you would be better to use a SUMX pattern to loop over one of the tables row by row. (I'm also filtering on both date and product as per your original requirement)

Allocated Value = SUMX( 'Table 1', 
  Var _date = 'Table 1'[Date]
  var _product = 'Table 1'[Product]
return 'Table 1'[Allocation] * CALCULATE( SUM('Table'[Value]), 'Table'[Date] = _date, 'Table'[Product] = _product) )

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.