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
mpataki32
Helper III
Helper III

Average - Group by calculation

Hi, 

I am trying to calculate average and I am trying to calculate measure which will return the following:

We have some workers and I would like to calculate a measure in DAX which will return the workers time / the average working time in the department. 

I am not able to calculate that average working time in the department part. 

So what I would like to reach is the "Working time of the Worker / Average working time by department" in the table below. 

Is it possible in DAX or should I use SQL?

WorkplaceTable.Workplace WorkplaceTable.DepartmentWorkerTable.WorkerWorking time of the WorkerWorking time by departmentAverage working time by departmentWorking time of the Worker / Average working time by department
Company ADepartment A.AWorker A.A.A                                                  23                                                 589                                                                19611.7%
Company ADepartment A.AWorker A.A.B                                                345                                                 589                                                                196175.7%
Company ADepartment A.AWorker A.A.C                                                221                                                 589                                                                196112.6%
Company ADepartment A.BWorker A.B.A                                                554                                              8,442                                                             2,81419.7%
Company ADepartment A.BWorker A.B.B                                                234                                              8,442                                                             2,8148.3%
Company ADepartment A.BWorker A.B.C                                             7,654                                              8,442                                                             2,814272.0%
Company ADepartment A.CWorker A.C.A                                                432                                                 576                                                                192225.0%
Company ADepartment A.CWorker A.C.B                                                  21                                                 576                                                                19210.9%
Company ADepartment A.CWorker A.C.C                                                123                                                 576                                                                19264.1%
1 ACCEPTED SOLUTION
serpiva64
Super User
Super User

Hi, 

you can use this measure

%WTofWorker/AvWTbyDept = var WTbyDept = CALCULATE([WTofWorker],ALL('Work'[WorkerTable.Worker]))
var NrofWorkerbyDept = calculate(count('Work'[WorkerTable.Worker]),all('Work'[WorkerTable.Worker]))
var AvWTbyDept = DIVIDE(WTbyDept, NrofWorkerbyDept)
var Perc = if (HASONEVALUE('Work'[WorkerTable.Worker]), DIVIDE([WTofWorker],AvWTbyDept))
return
Perc
 

(you can divide the formula in many steps)

serpiva64_1-1648811555494.png

 

If this post is useful to help you to solve your issue consider giving the post a thumbs up 

 and accepting it as a solution !

 

View solution in original post

5 REPLIES 5
serpiva64
Super User
Super User

Hi, 

you can use this measure

%WTofWorker/AvWTbyDept = var WTbyDept = CALCULATE([WTofWorker],ALL('Work'[WorkerTable.Worker]))
var NrofWorkerbyDept = calculate(count('Work'[WorkerTable.Worker]),all('Work'[WorkerTable.Worker]))
var AvWTbyDept = DIVIDE(WTbyDept, NrofWorkerbyDept)
var Perc = if (HASONEVALUE('Work'[WorkerTable.Worker]), DIVIDE([WTofWorker],AvWTbyDept))
return
Perc
 

(you can divide the formula in many steps)

serpiva64_1-1648811555494.png

 

If this post is useful to help you to solve your issue consider giving the post a thumbs up 

 and accepting it as a solution !

 

AliceW
Impactful Individual
Impactful Individual

Brilliant solution, Serpiva! Thank you!

Hi @serpiva64

One more question - your solution is brilliant - how should I take care of when we have workers where there are no value regarding the working time and how did you define the 

"WTofWorker" variable? 

Thanks!

Sorry

WTofWorker = sum('Work'[Working time of the Worker])
regarding the first question i think you have to count number of worker of each department not from the fact table but from the dimension table (if you have otherwise you have to create it) 
 
AilleryO
Memorable Member
Memorable Member

Hi,

 

You can do it with DAX, you just need to consider the lines of your table as filters to reach your goal.

Here is an example, to group by invoice and calculate the average amount of invoices for each customer.

 

Average Amount of Invoices by client =
CALCULATE(//to modify the calculation context
AVERAGEX(//Average by iteration (line / line)
SUMMARIZE(Sales,//Name of table you want to group in
Sales[NumInvoice],//First column to be taken in the grouping
Sales[Date Invoice],//Second column to be taken in the grouping...
Sales[Date Due]),
[Sales Revenue Global]),//Calculation or Measure to calculate Average
Clients[Type Client]="XXX")//Filter on table clients if needed

 

Hope it helps

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