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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
Eesa
Frequent Visitor

Calculate the average

Hi,

I want to create a DAX formula that calculates the average price of product category.

 

I have the following SALES table, I want DAX to sum the prices for each category and divide it by the number of category present in my dataset. 

Mathematically, it will be like this:

Sum of Clothing = 47

Sum of Electronics = 1300 

Sum of Home = 250 

Average by Category = 532.33


Product.PNG

 

 

 

 

 

 

 

If want to filter from another table for one category the sum is the same as the average because it will divide by one. 

 

Thank you

2 ACCEPTED SOLUTIONS
bcdobbs
Super User
Super User

Try something like:

 

 

 

AVERAGEX (
    VALUES ( SALES[Category] ),
    CALCULATE ( SUM ( SALES[Price] ) )
)

 

 


VALUES gives a distinct list of categories.

 

AVERAGEX then iterates over this list of categories and calculates the sum of prices for each.

 

You need the CALCULATE statement there to turn the row context that you're on into a filter context on the table. If you leave it out it will just return the total price for the whole table.

 

Once it has a sum for each category averagex divides by the number of categories.

 

 

 



Ben Dobbs

LinkedIn | Twitter | Blog

Did I answer your question? Mark my post as a solution! This will help others on the forum!
Appreciate your Kudos!!

View solution in original post

Hi,

Please follow below steps

1. Create a measure with below Dax

Distinct Category = DISTINCTCOUNT('Table'[Category])
2. Create one more measure for calculating Average 
Average Price by category = sum('Table'[Price])/[Distinct Category]

Average calculation.JPG

I have attached solution in sample file and uploaded on Sharepoint

https://onedrive.live.com/?cid=9429FE789841BAAD&id=9429FE789841BAAD%21106&parId=root&o=OneUp 

 

Please confirm if the solution works..!!

View solution in original post

2 REPLIES 2

Hi,

Please follow below steps

1. Create a measure with below Dax

Distinct Category = DISTINCTCOUNT('Table'[Category])
2. Create one more measure for calculating Average 
Average Price by category = sum('Table'[Price])/[Distinct Category]

Average calculation.JPG

I have attached solution in sample file and uploaded on Sharepoint

https://onedrive.live.com/?cid=9429FE789841BAAD&id=9429FE789841BAAD%21106&parId=root&o=OneUp 

 

Please confirm if the solution works..!!

bcdobbs
Super User
Super User

Try something like:

 

 

 

AVERAGEX (
    VALUES ( SALES[Category] ),
    CALCULATE ( SUM ( SALES[Price] ) )
)

 

 


VALUES gives a distinct list of categories.

 

AVERAGEX then iterates over this list of categories and calculates the sum of prices for each.

 

You need the CALCULATE statement there to turn the row context that you're on into a filter context on the table. If you leave it out it will just return the total price for the whole table.

 

Once it has a sum for each category averagex divides by the number of categories.

 

 

 



Ben Dobbs

LinkedIn | Twitter | Blog

Did I answer your question? Mark my post as a solution! This will help others on the forum!
Appreciate your Kudos!!

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

Check out the February 2024 Power BI update to learn about new features.

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.

Top Solution Authors