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
Anonymous
Not applicable

Calculate average by group ignoring certain filter

Hello,

 

my data looks like the following

 

Date                 Emloyee      Group        Task         Duration

2020-01-01       A                 1                aa            2

2020-01-01       A                 1                aa            4

2020-01-01       A                 1                bb           8

2020-01-01       B                  1               aa            4

2020-01-01       B                  1               bb            3

2020-01-01       B                  1               bb           11

2020-01-01       C                  2               cc           3

2020-01-01       C                  2               cc           3

2020-01-01       D                  2              cc            4

2020-01-01       D                  2              cc            4

2020-01-02       A                 1                aa            2 

2020-01-02       A                 1                aa            2

2020-01-02       A                 1                bb           3

2020-01-02       B                  1               aa           5

2020-01-02       B                  1               bb           2

2020-01-02       B                  1               bb           4

2020-01-02       C                  2               cc            6

2020-01-02       C                  2               cc            4

2020-01-02       D                  2              cc            2

2020-01-02       D                  2              cc            6

.                        .                   .                 .              .

.                        .                   .                 .              .

.                        .                   .                 .              .

 

My aim is to calculate the average duaration for every employee and every task and compare them across their group.

So for example Employee A completed Task aa in 2,5 Minutes ((2+4+2+2)/4 = 2,5) on average whereas the average time for the whole group for this task was 3,2 minutes ((2+4+4+2+2+5)/6 = 3,166).  I want to do this for all tasks and all groups.

I want to show only one employee ( which can be selecte via the filter pane) and the average duaration for every task he did in a certain period and the group average for every task. So I would display 2 minutes for task aa for employee A and 3,2 minutes for his group. The measure should ignore the employee filter on page level but not others like Date (I want to compare results across months) or group.

 

Thanks.

4 REPLIES 4
v-alq-msft
Community Support
Community Support

Hi, @Anonymous 

 

Based on my research, you may create two measures as below.

 

EmpAvg = 
var _emp = SELECTEDVALUE('Table'[Employee])
var _task = SELECTEDVALUE('Table'[Task])
return
CALCULATE(
    AVERAGE('Table'[Duration]),
    ALLEXCEPT('Table','Table'[Employee],'Table'[Task],'Table'[Date])
)

GroupAvg = 
var _emp = SELECTEDVALUE('Table'[Employee])
var _task = SELECTEDVALUE('Table'[Task])
return
CALCULATE(
    AVERAGE('Table'[Duration]),
    FILTER(
        ALLEXCEPT('Table','Table'[Task],'Table'[Date]),
        'Table'[Group] in 
        CALCULATETABLE(
            DISTINCT('Table'[Group]),
            FILTER(
                ALL('Table'),
                'Table'[Employee] =_emp
            )
        )
        
    )
)

 

 

Result:

e1.png

 

Best Regards

Allan

 

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

Anonymous
Not applicable

Hi @v-alq-msft 

 

thanks for your answer!

I tried it, however, I forgot to mention that my data is in three different tables - one fact table with the tasks and their durations and two dimension tables (one for employees and one for dates). Due to this your mesaure GroupAvg doesn't work. How can I use your measure with multiple tables? Thanks!

amitchandak
Super User
Super User

@Anonymous ,

 

Refer this can help. You have to use all except and filters

https://community.powerbi.com/t5/Desktop/SUM-of-AVERAGE/td-p/197013

Mariusz
Community Champion
Community Champion

Hi @Anonymous 

 

try this measure

Measure = 
CALCULATE(
    AVERAGE( 'Table'[Duration] ),
    ALLEXCEPT( 'Table', 'Table'[Task], 'Table'[Emloyee] ),
    ALLSELECTED( 'Table'[Emloyee] )
)

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
LinkedIn

 

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.