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
BobKoenen
Helper IV
Helper IV

Sum all values dependend on value on another column

Hi all,

 

I have a large database of entered Hours. And I want to calculate the overall average hourRate using an ALL measure so I can show the overal average hourrate in comparison per employee/projectleader etc. 

However my dataset also contains overhead = Hour ID 2 and sales hours Hour ID 3. I want to calculate the average Hour rate only for hour ID 1. And this should not be dependent on filters in the report, therefore I was thinking about an ALL measure. But I cannot seem to use and all measure which does contain a filter in de measure.

 

Does anyone have an idea about how I could do this.  

 

Hour IDAmount hoursSales amount
1440
1660
25100
25120
360
1 ACCEPTED SOLUTION
AlB
Super User
Super User

Hi @BobKoenen 

 

You can create a measure and place it in a card visual for instance.

If you want the average per line:

 

Measure =
AVERAGEX (
    FILTER ( ALL ( Table1 ); Table1[Hour ID] = 1 );
    DIVIDE ( Table1[Sales Amount]; Table1[Amount Hours] )
)

 

If you want the weighted average (by number of hours):

 

Measure =
DIVIDE (
    CALCULATE ( SUM ( Table1[Sales Amount] ); Table1[HOURS ID] = 1; ALL ( Table1 ) );
    CALCULATE ( SUM ( Table1[Amount Hours] ); Table1[HOURS ID] = 1; ALL ( Table1 ) )
)

View solution in original post

2 REPLIES 2
AlB
Super User
Super User

Hi @BobKoenen 

 

You can create a measure and place it in a card visual for instance.

If you want the average per line:

 

Measure =
AVERAGEX (
    FILTER ( ALL ( Table1 ); Table1[Hour ID] = 1 );
    DIVIDE ( Table1[Sales Amount]; Table1[Amount Hours] )
)

 

If you want the weighted average (by number of hours):

 

Measure =
DIVIDE (
    CALCULATE ( SUM ( Table1[Sales Amount] ); Table1[HOURS ID] = 1; ALL ( Table1 ) );
    CALCULATE ( SUM ( Table1[Amount Hours] ); Table1[HOURS ID] = 1; ALL ( Table1 ) )
)

Thanx for your answer!

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.