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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Juan_CGR94
New Member

How to Calculate the Avg. and sum from different tables

Hi comunity,

 

I have this data to analyze, I have three different tables (below): Package, Raws and Product. each has the same SKU's and its Cost per month. I need first to calculate the average cost per category (Package, Raws and Product) between the SKU's per month (e.g. average cost between A, B and C in January, in February, etc.)

 

The expected result will be the average package cost for January between A, B and C, the average package cost for February between A, B and C, and so on.

 

Then I need to sum the calculated average of each category (avg. package cost for Jan + avg. raws cost for Jan + avg. product cost for Jan) and repeat this for each month. and plot this in a Matrix (Months in columns and SKU in rows, and the sum of the avg. package + avg raws + avg. product would be the values)

 

Thanks a lot,

 

Package  
SKUMonthCost
AJanuary145
AFebruary105
AMarch126
AApril143
BJanuary133
BFebruary149
BMarch120
BApril139
CJanuary115
CFebruary130
CMarch116
CApril111

 

Raws  
SKUMonthCost
AJanuary221
AFebruary229
AMarch215
AApril231
BJanuary228
BFebruary230
BMarch248
BApril234
CJanuary243
CFebruary201
CMarch231
CApril201

 

 

Product  
SKUMonthCost
AJanuary437
AFebruary443
AMarch434
AApril441
BJanuary409
BFebruary416
BMarch402
BApril415
CJanuary447
CFebruary421
CMarch450
CApril441
1 ACCEPTED SOLUTION
V-lianl-msft
Community Support
Community Support

Hi @Juan_CGR94 ,

 

1. Add a column as the table name for each table first in the query editor.

test_custom_columns.PNG

2. Append queries as new.

test_append_3tables.PNG

3.Create measures

avg_table&month = CALCULATE(AVERAGE(Append1[Cost]),ALLEXCEPT(Append1,Append1[Month],Append1[table]))
sum_avg = 
var sum_3table = CALCULATE(SUMX(Append1,[avg_table&month]),ALLEXCEPT(Append1,Append1[Month],Append1[SKU]))
return IF(ISINSCOPE(Append1[SKU]),sum_3table,sum_3table/3)

test_matrix_visual.PNG

Sample .pbix

 

Best Regards,
Liang
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

2 REPLIES 2
V-lianl-msft
Community Support
Community Support

Hi @Juan_CGR94 ,

 

1. Add a column as the table name for each table first in the query editor.

test_custom_columns.PNG

2. Append queries as new.

test_append_3tables.PNG

3.Create measures

avg_table&month = CALCULATE(AVERAGE(Append1[Cost]),ALLEXCEPT(Append1,Append1[Month],Append1[table]))
sum_avg = 
var sum_3table = CALCULATE(SUMX(Append1,[avg_table&month]),ALLEXCEPT(Append1,Append1[Month],Append1[SKU]))
return IF(ISINSCOPE(Append1[SKU]),sum_3table,sum_3table/3)

test_matrix_visual.PNG

Sample .pbix

 

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

amitchandak
Super User
Super User

@Juan_CGR94 , Create a month/date and SKU and any common tables an then do like

One of the measure should work against common table

 

Sum(Package[Cost])+ Sum(Raw[Cost])+Sum(Product[Cost])/3


average(Package[Cost])+ average(Raw[Cost])+average(Product[Cost])/3

 

average(list{average(Package[Cost]), average(Raw[Cost]),average(Product[Cost])})

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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