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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
dancarr22
Helper V
Helper V

Calculate AVERAGE based on grouped SUM - with filter

Hello,

 

We have data - example below - where we'd like to calculate the Average based on the SUM of given grouped values.

For example - using data below - for Burger King marketing - we have 3 values: 120, 220 and 85.  The average of these is 141.66.  This is not the answer we want.  Want to group by Project (Company Name, Group A and Group B) and SUM AMOUNT.  Also want to have filter work on date. column.  So, answer should be 212.5 (120+220=340 and 85) - take average of those.

Tried creating a table which calculates this dynamically but it doesn't update when the date filter changes.  Any help appreciated.

 

Thanks,

Dan

SUMMARIZE(FILTER(TestData, TestData[Amount]>= [EarliestDate] && TestData[Amount]<= [LatestDate]),
    TestData[CompanyName],
    TestData[GroupA],
    TestData[GroupB],
    TestData[Project],
    "Total Amount Billed", SUM(TestData[Amount]))

 

dancarr22_0-1624896039930.png

 

2 REPLIES 2
PaulOlding
Solution Sage
Solution Sage

This measure gets the 212.5 result and can filter by date.

 

Avg =
AVERAGEX(
    ADDCOLUMNS(
        SUMMARIZE(
            Example,
            Example[CompanyName],
            Example[GroupA],
            Example[GroupB],
            Example[Project]
        ),
        "@Amount", CALCULATE(SUM(Example[Amount]))
    ),
    [@Amount]
)

Thanks @PaulOlding!  Appreciate your help with this.  That worked for everything except for the total - that it is not displaying the average of everything being calcualted.  Thoughts on how to make that work?

 

Thanks,

Dan

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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