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

Don't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.

Reply
Kauto2007
Regular Visitor

Calculate Average by Month and Category

A relative newbie to DAX so take it easy on me if it's a simple solution. So i have several years of data of different info and i want to calculate an average of the monthly total by a certain category as each category may have several entries per month. An example of the data and what i would expect the result to be is as follows:

 

Kauto2007_0-1716118791237.png

 

1 ACCEPTED SOLUTION
v-jiewu-msft
Community Support
Community Support

Hi @Kauto2007 ,

First of all, many thanks to  for your very quick and effective replies.

Based on my testing, please try the following methods:

1.Create the simple table.

vjiewumsft_0-1716355762665.png

2.Create the new column to filter the month.

Month = MONTH('Table'[Date])

vjiewumsft_1-1716355779893.png

3.Create the new measure to calculate average for category.

Average = 
VAR categ = SELECTEDVALUE('Table'[Category])
VAR total_val = CALCULATE(SUM('Table'[Value]), FILTER(ALLSELECTED('Table'), 'Table'[Category] = categ))
VAR month_num = CALCULATE(DISTINCTCOUNT('Table'[Month]), 'Table'[Category] = categ)
RETURN
CALCULATE(
    DIVIDE(total_val, month_num)
)

4.Select Drag the category field into the slicer.

vjiewumsft_2-1716355817146.png

5.Select the Category A. The result is shown below.

vjiewumsft_3-1716355853365.png

Best Regards,

Wisdom Wu

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
v-jiewu-msft
Community Support
Community Support

Hi @Kauto2007 ,

First of all, many thanks to  for your very quick and effective replies.

Based on my testing, please try the following methods:

1.Create the simple table.

vjiewumsft_0-1716355762665.png

2.Create the new column to filter the month.

Month = MONTH('Table'[Date])

vjiewumsft_1-1716355779893.png

3.Create the new measure to calculate average for category.

Average = 
VAR categ = SELECTEDVALUE('Table'[Category])
VAR total_val = CALCULATE(SUM('Table'[Value]), FILTER(ALLSELECTED('Table'), 'Table'[Category] = categ))
VAR month_num = CALCULATE(DISTINCTCOUNT('Table'[Month]), 'Table'[Category] = categ)
RETURN
CALCULATE(
    DIVIDE(total_val, month_num)
)

4.Select Drag the category field into the slicer.

vjiewumsft_2-1716355817146.png

5.Select the Category A. The result is shown below.

vjiewumsft_3-1716355853365.png

Best Regards,

Wisdom Wu

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Kauto2007
Regular Visitor

I know i can just add an average in from the Analystics part of the time series analysis but i need the average to calculate the STD of the averages to create my upper and lower control limits..

Kauto2007
Regular Visitor

@xifeng_L  Thanks for that. I tried that measure and although it doesnt come up with any errors so it is accepted, when i add it into a visual it is blank

Monthly Average =
                IF(HASONEFILTER(FACT_Finance_Data[Staffing Category]),AVERAGEX(ALL(FACT_Finance_Data[Month_Year]),CALCULATE(SUM(FACT_Finance_Data[Agency Actual]))))

This is the measure i used.

Basically im trying to create an average for an SPC chart, which is dynamic depending on the team that is selected in the slicer, if that info helps.
xifeng_L
Super User
Super User

Hi @Kauto2007 ,

 

You can try below measure.

 

xifeng_L_0-1716121311627.png

 

average of the monthly total = IF(HASONEFILTER('Table'[Category]),AVERAGEX(ALL('Table'[Month]),CALCULATE(SUM('Table'[Value]))))

 

 

Demo - Calculate Average by Month and Category.pbix

 

 

 

Did I answer your question? If yes, pls mark my post as a solution and appreciate your Kudos !

 

Thank you~

 

 

 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Jan25PBI_Carousel

Power BI Monthly Update - January 2025

Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.

Jan NL Carousel

Fabric Community Update - January 2025

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