Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.
Hi,
I have created the following expression to calculate the average completed jobs per worker per day.
Avg Completions per worker =
DIVIDE (
DIVIDE (
CALCULATE (
COUNTROWS ( 'jobs' ),
FILTER ( 'jobs', 'jobs'[Status] = "complete" )
),
DISTINCTCOUNT ( 'jobs'[date] )
),
DISTINCTCOUNT ( 'jobs'[worker] )
)
This works well for individual workers / individual days.
I need to wrap the expression in some way to sum the result of the averages per day and divide them by the number of days. To give me an average of the average day when looking at data over a week/month an other time period.
example of output, and desired output;
worker | Days | Avg Completions per worker |
worker 1 | 15 | 1.3 |
worker 2 | 15 | 1.3 |
worker 3 | 9 | 1.6 |
worker 4 | 19 | 2.6 |
expression result | 19 | 1.3 |
desired result |
| 1.7 |
|
|
|
It doesn’t work currently because of the mix of workers, i.e., not all will work for the full week or every day.
Can anyone help?
Solved! Go to Solution.
Hi @Anonymous
please use
Avg Completions per worker =
AVERAGEX (
VALUES ( 'jobs'[worker] ),
CALCULATE (
DIVIDE (
DIVIDE (
CALCULATE (
COUNTROWS ( 'jobs' ),
FILTER ( 'jobs', 'jobs'[Status] = "complete" )
),
DISTINCTCOUNT ( 'jobs'[date] )
),
DISTINCTCOUNT ( 'jobs'[worker] )
)
)
)
Hi @Anonymous
please use
Avg Completions per worker =
AVERAGEX (
VALUES ( 'jobs'[worker] ),
CALCULATE (
DIVIDE (
DIVIDE (
CALCULATE (
COUNTROWS ( 'jobs' ),
FILTER ( 'jobs', 'jobs'[Status] = "complete" )
),
DISTINCTCOUNT ( 'jobs'[date] )
),
DISTINCTCOUNT ( 'jobs'[worker] )
)
)
)
Thank you that's working great!
Hi:
It would be great if you had dates for the workers (Start Date End Date) in your fact table. Then you join your fact table to a Date Table. Date Table is marked as Date Table in a one to many relationship with your fact table. You'd also have a dimension table for your workers as well. (Workers table is just the list of unique workers with theri ID with relationship to your fact table. If you have data like this, I can potentially show a solution. Do you have data on excel or sample pbix to share?
Hi thanks for your reply. The workers don't have a start and end date as such, they are assined to the jobs, so a pool of 4 workers would have 3 working on day one, 2 on day two, 4 on day three and 1 on day four but the expression I have will total the workers as 4 and divide the total jobs by that and the days, reducing the average too much. I have a closed model so can't make any amendments to the underliing structure. Only Dax calulations.
Check out the November 2023 Power BI update to learn about new features.
Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.