March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hello!
First Post.
I have data of my country's position on a ranking list.
I need to determine the average of that position for each month separately.
Currently im using:
Promedio = CALCULATE(
AVERAGE(PowerBI[Posición]);
FILTER(PowerBI;
PowerBI[Fecha].[Month]<=EARLIER(PowerBI[Fecha].[Month])
&& PowerBI[Fecha].[Day]<=EARLIER(PowerBI[Fecha].[Day]))
)
But the averages are wrongly calculated.
I also noticed that on the first day of the month if position is 50 the average shows 55.5 which means its carrying values from the previous months.
Please help me fix my formula. Thanks in advance.
Solved! Go to Solution.
Hi @Anonymous ,
We can use the following steps to meet your requirement.
1. Create two calculate columns, one is year, another is month.
Month = MONTH('Table'[Date])
year = YEAR('Table'[Date])
2. Then we can create a measure,
Each month AVG =
var current_month = MAX('Table'[Month])
var Total_value = CALCULATE(SUM('Table'[value]))
var Month_day = CALCULATE(DISTINCTCOUNT('Table'[Date]),FILTER('Table','Table'[Month] = current_month))
return
DIVIDE(Total_value,Month_day)
The result like this,
3. Or we can create a calculate column,
AVG column =
var total_month = CALCULATE(DISTINCTCOUNT('Table'[Date]),FILTER(ALLSELECTED('Table'),'Table'[Month]=EARLIER('Table'[Month])&& 'Table'[year]=EARLIER('Table'[year])))
var current_month = CALCULATE(SUM('Table'[value]),FILTER(ALLSELECTED('Table'),'Table'[Month]=EARLIER('Table'[Month]) && 'Table'[year]=EARLIER('Table'[year])))
return
DIVIDE(current_month,total_month)
The result like this,
If it doesn’t meet your requirement, could you please show the exact expected result based on the table that you have shared?
BTW, pbix as attached.
Best regards,
Community Support Team _ zhenbw
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Anonymous ,
We can use the following steps to meet your requirement.
1. Create two calculate columns, one is year, another is month.
Month = MONTH('Table'[Date])
year = YEAR('Table'[Date])
2. Then we can create a measure,
Each month AVG =
var current_month = MAX('Table'[Month])
var Total_value = CALCULATE(SUM('Table'[value]))
var Month_day = CALCULATE(DISTINCTCOUNT('Table'[Date]),FILTER('Table','Table'[Month] = current_month))
return
DIVIDE(Total_value,Month_day)
The result like this,
3. Or we can create a calculate column,
AVG column =
var total_month = CALCULATE(DISTINCTCOUNT('Table'[Date]),FILTER(ALLSELECTED('Table'),'Table'[Month]=EARLIER('Table'[Month])&& 'Table'[year]=EARLIER('Table'[year])))
var current_month = CALCULATE(SUM('Table'[value]),FILTER(ALLSELECTED('Table'),'Table'[Month]=EARLIER('Table'[Month]) && 'Table'[year]=EARLIER('Table'[year])))
return
DIVIDE(current_month,total_month)
The result like this,
If it doesn’t meet your requirement, could you please show the exact expected result based on the table that you have shared?
BTW, pbix as attached.
Best regards,
Community Support Team _ zhenbw
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
The second Solution/Formula worked perfectly!
Thank you for you quick response.
I would actually just need the average of the whole month I dont really need it to be daily. So that i can Display this table containing ech month:
Any idea would be appreciated! Thanks.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
129 | |
90 | |
75 | |
58 | |
53 |
User | Count |
---|---|
200 | |
104 | |
101 | |
67 | |
55 |