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
AnilKumar
Helper II
Helper II

Is it Possible to calculate the sum of a measure?

Hi All,

 

We have the data regarding the employees worked hours and their worked dates in excel.

So to calculate the average work hours we have created a measure like ,

Avg worked hours = Sum(work hours)/distinctcount(worked dates)

 

So,now we want to calculate the average of total Avg Worked hours  of all employees to check the avg on over all employees.

 

Is there any way to apply the sum of the Avg worked hours (which is previously created measure)?

 

2 ACCEPTED SOLUTIONS

Hi @AnilKumar,

 

Assume the table name is DimSalesTerritory, you can create a measure below:

 

sum of avgwrk hours =IF(COUNTROWS(DimSalesTerritory)=COUNTROWS(ALLSELECTED(DimSalesTerritory)),SUMX(SUMMARIZE('DimSalesTerritory',[EMP_NAME],"AVG",[Avg jrney hrs]),[AVG]),[Avg jrney hrs])

 

sum of avgjourney hours=IF(COUNTROWS(DimSalesTerritory)=COUNTROWS(ALLSELECTED(DimSalesTerritory)),SUMX(SUMMARIZE('DimSalesTerritory',[EMP_NAME],"AVG",[Avg work hrs]),[AVG]),[Avg work hrs])

 

Best Regards,
Qiuyun Yu

Community Support Team _ Qiuyun Yu
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

Thank you very much for your reply. The measure is working correctly

View solution in original post

4 REPLIES 4
v-qiuyu-msft
Community Support
Community Support

Hi @AnilKumar,

 

You can try the measure below:

 

Avg worked hours = Calculate(Sum(work hours),allselected('table'))/Calculate(distinctcount(worked dates),allselected('table'))

 

Best Regards,
Qiuyun Yu

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

Hi Qiuyun Yu,

 

The given calculation has been done already and kept in  a table visual based on employee wise.

Avg worked hours = Calculate(Sum(work hours),allselected('table'))/Calculate(distinctcount(worked dates),allselected('table'))

 

Capture.PNG

Suppose our sample data is like this. Here Avg jrney hrs and avg wrk hrs are already measures.

 

Avg jrney hrs = calculate(sum(journeyhours)/distinctcount(dates)

Avg work hrs = calculate(sum(workhours)/distinctcount(dates).

 

But here we want to calculate the average of already calculated measures(Avg jrney hrs,Avg work hrs)

i.e Avg of avgjrney hrs = sum(Avg jrney hrs)/count(employees)

Avg of avgwork hrs = sum(Avg work hrs)/count(employees)

 

But total we are getting is based on our previously calculated measures.

From the above screenshots, the totals should be

sum of avgwrk hours = 24.87 ( but actually displaying 11.22)

sum of avgjourney hours = 21.34 ( but actually displaying 10.61)

 

Is there any way to get the actual sums that has described above.

Hi @AnilKumar,

 

Assume the table name is DimSalesTerritory, you can create a measure below:

 

sum of avgwrk hours =IF(COUNTROWS(DimSalesTerritory)=COUNTROWS(ALLSELECTED(DimSalesTerritory)),SUMX(SUMMARIZE('DimSalesTerritory',[EMP_NAME],"AVG",[Avg jrney hrs]),[AVG]),[Avg jrney hrs])

 

sum of avgjourney hours=IF(COUNTROWS(DimSalesTerritory)=COUNTROWS(ALLSELECTED(DimSalesTerritory)),SUMX(SUMMARIZE('DimSalesTerritory',[EMP_NAME],"AVG",[Avg work hrs]),[AVG]),[Avg work hrs])

 

Best Regards,
Qiuyun Yu

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

Thank you very much for your reply. The measure is working correctly

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.