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
pbijess857
Frequent Visitor

Multiply Sum with Average

Hello. I am trying to figure out how to get this to work in Power BI.  The rows on my table represent tickets with a number value (hours of work.) This table is joined with a separate table that contains some additional information about the tickets from a different database, including the hours available for each team.  I'm trying to sum up the hours of work associated with each ticket and divide by the time each team has available.  I'm able to represent the sum of hours of work and the average hours available in a table, but riding the struggle bus trying to use them in additional calculations. 

 

The underlying data would look something like this: 

pbijess857_0-1639614043673.png

 

I think the next step is to get the data summarized by team which would ideally look something like this:  (this is where I'm stuck)

pbijess857_1-1639614091190.png

 

And the end goal would be to sum up the average hours available by team (and sum of hours of work) to get a final utilization percentage. 

pbijess857_2-1639614152919.png

 

Any help would be appreciated. I can't seem to find the right solution thus far. 

1 ACCEPTED SOLUTION
VahidDM
Super User
Super User

Hi @pbijess857 

Try this code to add a new table:

calctables_formulabarempty

 

Table 2 =
VAR _A =
    ADDCOLUMNS (
        SUMMARIZE (
            'Table',
            'Table'[Group],
            'Table'[Team],
            "SUM Hours of Works", SUM ( 'Table'[Hours of Work] ),
            "AVG Hours Available", AVERAGE ( 'Table'[Team Hours Available] )
        ),
        "Sum Points / AVG Capacity", [SUM Hours of Works] / [AVG Hours Available]
    )
RETURN
    ADDCOLUMNS (
        GROUPBY (
            _A,
            [Group],
            "SUM Hours of Works", SUMX ( CURRENTGROUP (), [SUM Hours of Works] ),
            "SUM AVG Hours Available", SUMX ( CURRENTGROUP (), [AVG Hours Available] )
        ),
        "Work/Available", [SUM Hours of Works] / [SUM AVG Hours Available]
    )

 

output:

VahidDM_0-1639615979263.png

If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
LinkedIn: 
www.linkedin.com/in/vahid-dm/

 

 

View solution in original post

2 REPLIES 2
VahidDM
Super User
Super User

Hi @pbijess857 

Try this code to add a new table:

calctables_formulabarempty

 

Table 2 =
VAR _A =
    ADDCOLUMNS (
        SUMMARIZE (
            'Table',
            'Table'[Group],
            'Table'[Team],
            "SUM Hours of Works", SUM ( 'Table'[Hours of Work] ),
            "AVG Hours Available", AVERAGE ( 'Table'[Team Hours Available] )
        ),
        "Sum Points / AVG Capacity", [SUM Hours of Works] / [AVG Hours Available]
    )
RETURN
    ADDCOLUMNS (
        GROUPBY (
            _A,
            [Group],
            "SUM Hours of Works", SUMX ( CURRENTGROUP (), [SUM Hours of Works] ),
            "SUM AVG Hours Available", SUMX ( CURRENTGROUP (), [AVG Hours Available] )
        ),
        "Work/Available", [SUM Hours of Works] / [SUM AVG Hours Available]
    )

 

output:

VahidDM_0-1639615979263.png

If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
LinkedIn: 
www.linkedin.com/in/vahid-dm/

 

 

This looks like it has me back on the right track. Thank you for the help! 

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.