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

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
MartaBak
Regular Visitor

Data compare to average.

Hello, 

 

I have two problems 😞

 

FIRST I need to compare 'sum of all ID email per employee' with 'all team average'

 

Table[Data]

employeeDATEid EMAIL 
X20.02.2024123456
Y20.02.2024123456
Z20.02.2024123456
Z20.02.2024123456
Z20.02.2024123456
Z20.02.2024123457
Z20.02.2024123458
Z20.02.2024123459
X20.02.2024123459
X20.02.2024123459
Y20.02.2024123459
X20.02.2024112345
X20.02.2024112549
Y20.02.2024123584
Z20.02.2024123695

 

example : 

sum of e-mail = 15

amount of employess =3 (X,Y,Z)

ave. email = 15/3=5

x -> 5 emails

y-> 3 emails

z -> 7 emails

employee participation X =5/5 = 100% , Y= 3/5 = 60%, Z=7/5= 140%

 

Output

EMPLOYEElp%
X5100%
Y360%
Z7140%
AVERAGE5100%

 

 

SECOND : I would like the summed average value to be provided in the pivot table for the average calculated in the query above, but only for non-empty records ( I don't want emty records to lower the average )

My output : AVERAGE COUNT WITHOUT non empty records ( below )

 XYZAVERAGEXYZ
01.01.2024495667%150%83%
02.01.2024556594%94%113%
03.01.20246825113%150%38%
04.01.2024225367%67%167%
05.01.2024558683%83%133%
06.01.20248 36145%0%55%
07.01.2024 3960%50%150%
08.01.20246 66100%0%100%
09.01.20245223167%67%67%
10.01.202444 4100%100%0%
11.01.202426 450%150%0%
12.01.202469 880%120%0%
AVERAGE WITH ALL RECORDS    89%86%75%

AVERAGE COUNT WITHOUT non empty records

    97%103%101%
1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @MartaBak ,

Depending on the information you have provided, you can follow these steps below:

1.Add an index column.

vyifanwmsft_0-1709101254864.png

2.Add two columns.

IP = 
VAR _1 =
    CALCULATE (
        MIN ( 'Table'[Index] ),
        FILTER ( 'Table', 'Table'[employee] = EARLIER ( 'Table'[employee] ) )
    )
VAR _2 =
    CALCULATE (
        COUNTROWS ( 'Table' ),
        FILTER ( 'Table', 'Table'[employee] = EARLIER ( 'Table'[employee] ) )
    )
RETURN
    IF ( _1 = 'Table'[Index], _2, BLANK () )
% = 
VAR _1 =
    COUNTROWS ( 'Table' )
VAR _2 =
    DISTINCTCOUNTNOBLANK ( 'Table'[employee] )
VAR _3 = _1 / _2
VAR _4 =
    CALCULATE (
        COUNTROWS ( 'Table' ),
        FILTER ( 'Table', 'Table'[employee] = EARLIER ( 'Table'[employee] ) )
    )
VAR _5 = _4 / _3
VAR _6 =
    CALCULATE (
        MIN ( 'Table'[Index] ),
        FILTER ( 'Table', 'Table'[employee] = EARLIER ( 'Table'[employee] ) )
    )
RETURN
    IF ( _6 = 'Table'[Index], _5, BLANK () )

Final output:

vyifanwmsft_1-1709101361866.png

You can use the AVERAGEX function in a matrix to calculate the average of non-null data. For example, you can use the following formula to calculate the average of non-null data:

AVERAGE TOTAL =
AVERAGEX (
    FILTER ( 'Table', NOT ( ISBLANK ( 'Table'[Column] ) ) ),
    'Table'[Column]
)

This formula will filter out the null values and then calculate the average of the remaining data.

How to Get Your Question Answered Quickly - Microsoft Fabric Community

If it does not help, please provide more details with your desired out put and pbix file without privacy information.

 

Best Regards,

Ada Wang

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

1 REPLY 1
Anonymous
Not applicable

Hi @MartaBak ,

Depending on the information you have provided, you can follow these steps below:

1.Add an index column.

vyifanwmsft_0-1709101254864.png

2.Add two columns.

IP = 
VAR _1 =
    CALCULATE (
        MIN ( 'Table'[Index] ),
        FILTER ( 'Table', 'Table'[employee] = EARLIER ( 'Table'[employee] ) )
    )
VAR _2 =
    CALCULATE (
        COUNTROWS ( 'Table' ),
        FILTER ( 'Table', 'Table'[employee] = EARLIER ( 'Table'[employee] ) )
    )
RETURN
    IF ( _1 = 'Table'[Index], _2, BLANK () )
% = 
VAR _1 =
    COUNTROWS ( 'Table' )
VAR _2 =
    DISTINCTCOUNTNOBLANK ( 'Table'[employee] )
VAR _3 = _1 / _2
VAR _4 =
    CALCULATE (
        COUNTROWS ( 'Table' ),
        FILTER ( 'Table', 'Table'[employee] = EARLIER ( 'Table'[employee] ) )
    )
VAR _5 = _4 / _3
VAR _6 =
    CALCULATE (
        MIN ( 'Table'[Index] ),
        FILTER ( 'Table', 'Table'[employee] = EARLIER ( 'Table'[employee] ) )
    )
RETURN
    IF ( _6 = 'Table'[Index], _5, BLANK () )

Final output:

vyifanwmsft_1-1709101361866.png

You can use the AVERAGEX function in a matrix to calculate the average of non-null data. For example, you can use the following formula to calculate the average of non-null data:

AVERAGE TOTAL =
AVERAGEX (
    FILTER ( 'Table', NOT ( ISBLANK ( 'Table'[Column] ) ) ),
    'Table'[Column]
)

This formula will filter out the null values and then calculate the average of the remaining data.

How to Get Your Question Answered Quickly - Microsoft Fabric Community

If it does not help, please provide more details with your desired out put and pbix file without privacy information.

 

Best Regards,

Ada Wang

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

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

Check out the August 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors