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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
sgv2000
Frequent Visitor

Average of Dates over Year

I have been searching for a way to do this for a couple days.  Hopefully someone has a simple solution that I am missing.
Basically what I want to do is average weekly or monthly totals by year.  So, I have detailed data and I put it in a grid and can get the sum by week easy enough.  If I try to average that, I get the average of the detail values, not the average of the total.  I figured out how to get around that and get the average of the totals at the bottom of the grid.  Now what I want to do is get that average split by year and repeated on every row of the grid so I can put it on a chart.  Here is a picture that might explain it better.  Any thoughts would be greatly appreciated.

YearlyAverages.JPG

1 ACCEPTED SOLUTION

HI @sgv2000 ,

 

12 here is the number of months in a year.

 

Incase you do not want to hardcode

 

AVR of Year = 

var a= CALCULATE(DISTINCTCOUNT('Table'[Month]),FILTER(ALL('Table'),'Table'[Year] = MAX('Table'[Year])))
RETURN

SUMX(FILTER(ALL('Table'),'Table'[Year] = MAX('Table'[Year])),[VAl]/a)

 

Regards,
Harsh Nathani
Did I answer your question? Mark my post as a solution! Appreciate with a Kudos!! (Click the Thumbs Up Button)

View solution in original post

10 REPLIES 10
Greg_Deckler
Community Champion
Community Champion

@sgv2000 This looks like a measure aggregation problem. See my blog article about that here: https://community.powerbi.com/t5/Community-Blog/Design-Pattern-Groups-and-Super-Groups/ba-p/138149

The pattern is:
MinScoreMeasure = MINX ( SUMMARIZE ( Table, Table[Group] , "Measure",[YourMeasure] ), [Measure])
MaxScoreMeasure = MAXX ( SUMMARIZE ( Table, Table[Group] , "Measure",[YourMeasure] ), [Measure])
AvgScoreMeasure = AVERAGEX ( SUMMARIZE ( Table, Table[Group] , "Measure",[YourMeasure] ), [Measure])
etc.



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

@Greg_Deckler  This is an interesting article.  I find it a little difficult to follow.  From what I can tell, it explain how to do what I figure out.  It shows how to use the group or summarize function to group by date or month then average that to get a total at the bottom of the grid or by a specific category, like customer.  I need to be able to use something like ALLEXCEPT to group the group by year and get the average for the year and the display that back on every date for the year.  This will make a flat line for the year and show how the average is changing one year over the next.

@sgv2000 - So like 

 

AVERAGEX(ALLEXCEPT('Table'[Year]),'Table'[Value])

 

?

 

If not, would potentially help to post sample data as text and expected outcome. 

https://community.powerbi.com/t5/Community-Blog/Before-You-Post-Read-This/ba-p/1116882

Also, please see this post regarding How to Get Your Question Answered Quickly: https://community.powerbi.com/t5/Community-Blog/How-to-Get-Your-Question-Answered-Quickly/ba-p/38490

The most important parts are:
1. Sample data as text, use the table tool in the editing bar
2. Expected output from sample data
3. Explanation in words of how to get from 1. to 2.



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

@Greg_Deckler 

Here is a table of data.  I want this to end up looking like the table and chart in the original post.  I need to group by Month and have the total for the month.  Easy enough, just add that to a grid, done.  Next I need a column that is the average os the monthly totals for the year repeated on every month in the grid.  Just like the original picture I posted.

YearMonthDayValue 
20191/1/20191/1/201925 
20191/1/20191/2/201950 
20191/1/20191/3/201925 
20192/1/20192/1/201920 
20192/1/20192/2/201910 
20192/1/20192/3/201920 
20193/1/20193/1/201925 
20193/1/20193/2/201915 
20193/1/20193/3/201935 
20194/1/20194/1/20195 
20194/1/20194/2/201910 
20194/1/20194/3/201910 
20195/1/20195/1/2019100 
20195/1/20195/2/2019100 
20195/1/20195/3/2019100 
20196/1/20196/1/201950 
20196/1/20196/2/201920 
20196/1/20196/3/201920 
20197/1/20197/1/201925 
20197/1/20197/2/201915 
20197/1/20197/3/201935 
20198/1/20198/1/201920 
20198/1/20198/2/201910 
20198/1/20198/3/201920 
20199/1/20199/1/201950 
20199/1/20199/2/2019125 
20199/1/20199/3/201975 
201910/1/201910/1/201925 
201910/1/201910/2/201950 
201910/1/201910/3/201925 
201911/1/201911/1/2019100 
201911/1/201911/2/2019100 
201911/1/201911/3/2019100 
201912/1/201912/1/201955 
201912/1/201912/2/201920 
201912/1/201912/3/201920 
20201/1/20201/1/202025 
20201/1/20201/2/202015 
20201/1/20201/3/202035 
20202/1/20202/1/202050 
20203/1/20203/1/2020450 
20204/1/20204/1/2020200 
20205/1/20205/1/2020100 
20206/1/20206/1/2020325 
20207/1/20207/1/202075 
20208/1/20208/1/2020150 
20209/1/20209/1/2020125 
202010/1/202010/1/202095 
202011/1/202011/1/2020120 
202012/1/202012/1/2020300 

HI @sgv2000 ,

 

 

Create these measures

 

VAl = 
SUMX(
        SUMMARIZE('Table','Table'[Month],"Ave",SUM('Table'[Value])),[Ave])

 

AVR of Year = SUMX(FILTER(ALL('Table'),'Table'[Year] = MAX('Table'[Year])),[VAl]/12)

 

 

1.jpg

 

Regards,
Harsh Nathani
Did I answer your question? Mark my post as a solution! Appreciate with a Kudos!! (Click the Thumbs Up Button)

 

@harshnathani this looks close.  The 12 can't be hard coded though.  It is variable.  I am playing with this to see if I can make it work.

 

Thanks,

HI @sgv2000 ,

 

12 here is the number of months in a year.

 

Incase you do not want to hardcode

 

AVR of Year = 

var a= CALCULATE(DISTINCTCOUNT('Table'[Month]),FILTER(ALL('Table'),'Table'[Year] = MAX('Table'[Year])))
RETURN

SUMX(FILTER(ALL('Table'),'Table'[Year] = MAX('Table'[Year])),[VAl]/a)

 

Regards,
Harsh Nathani
Did I answer your question? Mark my post as a solution! Appreciate with a Kudos!! (Click the Thumbs Up Button)

@harshnathani, Thanks again for your reply.  I have been working today to implement this in my report.  I finally figured out why I am having an issue now.  Your use of the ALL key work basically ignores any slicers on the report.  See, I showed you data without all of the many dimensions in the report.  You solution will work if you have no other slicers on the report.  Once you introduce a slicer, this becomes a problem.  Example would be to add another column to the data and duplicate the data.  Call it fruit and lable half apples and half bananas.  Increase all the numbers in bananas by *10 just to verify.  Setup a slicer on fruit and see if it will work.

@harshnathani , I was able to make your solution work by changing ALL to ALLSELECTED.  Thanks for your help.  Just wish I had caught that ealier. 

Hi @sgv2000 ,

 

Great that the solution helped. 🙂

 

Regards,
Harsh Nathani
Did I answer your question? Mark my post as a solution! Appreciate with a Kudos!! (Click the Thumbs Up Button)

 

 

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

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

August 2025 community update carousel

Fabric Community Update - August 2025

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