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
dakins
Helper II
Helper II

How to calculate Monthly average for only completed month

Hello,

 

I want to caluclate the average sales for only completed months in the year.

 

Desire result = Average sales from Jan - Sept given today is October 14th

 

 

 

 

Thanks,

D

1 ACCEPTED SOLUTION
Ashish_Mathur
Super User
Super User

Hi,

Create a Calendar Table with calculated column formulas for Year, Month name and Month number.  Sort the Month name by the Month number.  Create a relationship (Many to One and Single) from the Date column of your Data Table to the Date column of the Calendar Table.  Create a slicer of Year (from the Calendar Table) and select 2022.  Write these measures:

Total = sum(Data[Sale])

Average sales till end of previous month = averagex(summarize(calculatetable(calendar,datesbetween(calendar[date],min(calendar[date]),eomonth(today(),-1))),calendar[year],calendar[month name],"ABCD",[Total]),[abcd])

Hope this helps.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

View solution in original post

4 REPLIES 4
Ashish_Mathur
Super User
Super User

Hi,

Create a Calendar Table with calculated column formulas for Year, Month name and Month number.  Sort the Month name by the Month number.  Create a relationship (Many to One and Single) from the Date column of your Data Table to the Date column of the Calendar Table.  Create a slicer of Year (from the Calendar Table) and select 2022.  Write these measures:

Total = sum(Data[Sale])

Average sales till end of previous month = averagex(summarize(calculatetable(calendar,datesbetween(calendar[date],min(calendar[date]),eomonth(today(),-1))),calendar[year],calendar[month name],"ABCD",[Total]),[abcd])

Hope this helps.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Thank you. It worked perfectly. 

You are welcome.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
amitchandak
Super User
Super User

@dakins ,  Try a measure like

YTD Today =
var _min = eomonth(today(),-1*month(today()))+1
var _max = if(today() = eomonth( today(),0),eomonth( today(),0),eomonth(today(),-1))
return
CALCULATE(AverageX(values('Date'[Date]) ,[Net]), FILTER('Date','Date'[Date] >=_min && 'Date'[Date] <= _max))

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.