cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Tevon713
Helper I
Helper I

Calculating row average within matrix

Hi.

 

I'm trying to find average of a row within a matrix. Might be a simple solution, I may be overthinking it.

 

Got a simple table with the following variables.

Screenshot 2021-09-02 200003.gif

 

When creating the matrix it not giving correct "FTE", instead it culumative sum of each row.

How would I get it to show correctly? Taking average? For example "C" for Jan-Mar only same 2, total for row C should be 2 not sum which is 6.  Thanks.

 

Screenshot 2021-09-02 200020.gif

1 ACCEPTED SOLUTION

Hi  @Tevon713 ,

 

Create a measure as below:

Measure =
VAR _month =
    ISINSCOPE ( 'Table'[Month] )
VAR _site =
    ISINSCOPE ( 'Table'[Site] )
VAR _region =
    ISINSCOPE ( 'Table'[Region] )
VAR _year =
    ISINSCOPE ( 'Table'[Year] )
RETURN
    IF (
        _month,
        SUM ( 'Table'[FTE] ),
        IF (
            _site && NOT ( _month ),
            AVERAGEX (
                FILTER (
                    ALL ( 'Table' ),
                    'Table'[Year] = MAX ( 'Table'[Year] )
                        && 'Table'[Region] = MAX ( 'Table'[Region] )
                        && 'Table'[Site] = MAX ( 'Table'[Site] )
                ),
                'Table'[FTE]
            ),
            IF (
                _region && NOT ( _site ),
                AVERAGEX (
                    FILTER (
                        ALL ( 'Table' ),
                        'Table'[Year] = MAX ( 'Table'[Year] )
                            && 'Table'[Region] = MAX ( 'Table'[Region] )
                    ),
                    'Table'[FTE]
                ),
                IF (
                    _year && NOT ( _region ),
                    AVERAGEX (
                        FILTER ( ALL ( 'Table' ), 'Table'[Year] = MAX ( 'Table'[Year] ) ),
                        'Table'[FTE]
                    )
                )
            )
        )
    )

And you will see:

vkellymsft_0-1630994356360.png

For the related .pbix file,pls see attached.

 

Best Regards,
Kelly

Did I answer your question? Mark my reply as a solution!

View solution in original post

4 REPLIES 4
mahoneypat
Microsoft
Microsoft

You can try this measure.  Replace with your month column, and it should still yield 2 for those rows but 2 also in the subtotal row.

 

NewMeasure = AVERAGEX(DISTINCT(Table[Month]), [FTE])

 

Pat

 





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


I tried, getting this error Column FTE cannot be found or may not be used in this expression.

Hi  @Tevon713 ,

 

Create a measure as below:

Measure =
VAR _month =
    ISINSCOPE ( 'Table'[Month] )
VAR _site =
    ISINSCOPE ( 'Table'[Site] )
VAR _region =
    ISINSCOPE ( 'Table'[Region] )
VAR _year =
    ISINSCOPE ( 'Table'[Year] )
RETURN
    IF (
        _month,
        SUM ( 'Table'[FTE] ),
        IF (
            _site && NOT ( _month ),
            AVERAGEX (
                FILTER (
                    ALL ( 'Table' ),
                    'Table'[Year] = MAX ( 'Table'[Year] )
                        && 'Table'[Region] = MAX ( 'Table'[Region] )
                        && 'Table'[Site] = MAX ( 'Table'[Site] )
                ),
                'Table'[FTE]
            ),
            IF (
                _region && NOT ( _site ),
                AVERAGEX (
                    FILTER (
                        ALL ( 'Table' ),
                        'Table'[Year] = MAX ( 'Table'[Year] )
                            && 'Table'[Region] = MAX ( 'Table'[Region] )
                    ),
                    'Table'[FTE]
                ),
                IF (
                    _year && NOT ( _region ),
                    AVERAGEX (
                        FILTER ( ALL ( 'Table' ), 'Table'[Year] = MAX ( 'Table'[Year] ) ),
                        'Table'[FTE]
                    )
                )
            )
        )
    )

And you will see:

vkellymsft_0-1630994356360.png

For the related .pbix file,pls see attached.

 

Best Regards,
Kelly

Did I answer your question? Mark my reply as a solution!

Thank you. That will work.

Helpful resources

Announcements
May 23 2022 epsiode 5 without aka link.jpg

The Power BI Community Show

Welcome to the Power BI Community Show! Jeroen ter Heerdt talks about the importance of Data Modeling.

charticulator_carousel_with_text (1).png

Charticulator Design Challenge

Put your data visualization and design skills to the test! This exciting challenge is happening now through May 31st!

Power BI Dev Camp Session 22 with aka link 768x460.jpg

Check it out!

Mark your calendars and join us on Thursday, May 26 at 11a PDT for a great session with Ted Pattison!

Power BI Release May 2022 768x460.png

Check it out!

Click here to read more about the May 2022 updates!