Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more
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.
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.
Solved! Go to 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:
For the related .pbix file,pls see attached.
Best Regards,
Kelly
Did I answer your question? Mark my reply as a solution!
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
To learn more about Power BI, follow me on Twitter or subscribe 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:
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.
 
					
				
				
			
		
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
Check out the October 2025 Power BI update to learn about new features.
 
            | User | Count | 
|---|---|
| 80 | |
| 49 | |
| 35 | |
| 31 | |
| 30 |