Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon'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.
Hi experts! 🙂
I am trying to create a dynamic average of the sales based on the current year sales (calendar year to date)
so it would be the average sales from jan'2020 until july'2020
and then when I ad August, it would add up August and calculate the new average based on the 8 months from the year
What formula should I use? I tried using Averagex, but I think I missed something.
thanks for the help
Solved! Go to Solution.
Hi, @Anonymous
Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.
Table:
You may create calculated columns and a measure as below to get the average of Sales from January2020 until the latest month(August) that year.
Calculated column:
Year = YEAR('Table'[Date])
Month = MONTH('Table'[Date])
YearMonth = YEAR('Table'[Date])*100+MONTH('Table'[Date])
Measure:
Avg =
DIVIDE(
CALCULATE(
SUM('Table'[Sell Out(MSU)]),
FILTER(
ALL('Table'),
[Year]=YEAR(TODAY())&&
[Month]>=1&&
[Month]<=MONTH(TODAY())
)
),
CALCULATE(
DISTINCTCOUNT('Table'[YearMonth]),
FILTER(
ALL('Table'),
[Year]=YEAR(TODAY())&&
[Month]>=1&&
[Month]<=MONTH(TODAY())
)
)
)
Result:
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @Anonymous
If you take the answer of someone, please mark it as the solution to help the other members who have same problems find it more quickly. If not, let me know and I'll try to help you further. Thanks.
Best Regards
Allan
Hi @Anonymous
Can you try this ----- YTD Avg = CALCULATE(AVERAGE(Table[Value]), DATESYTD(Table[Date], "mention the date here"))
In order to make YTD dynamic at the place of "mention the date here" you can use some time intelligence table probably.
it didnt work 😞
@mhossain
this is my table set, I am trying to get the average of Sales from January2020 until the latest month that year.
Hi, @Anonymous
Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.
Table:
You may create calculated columns and a measure as below to get the average of Sales from January2020 until the latest month(August) that year.
Calculated column:
Year = YEAR('Table'[Date])
Month = MONTH('Table'[Date])
YearMonth = YEAR('Table'[Date])*100+MONTH('Table'[Date])
Measure:
Avg =
DIVIDE(
CALCULATE(
SUM('Table'[Sell Out(MSU)]),
FILTER(
ALL('Table'),
[Year]=YEAR(TODAY())&&
[Month]>=1&&
[Month]<=MONTH(TODAY())
)
),
CALCULATE(
DISTINCTCOUNT('Table'[YearMonth]),
FILTER(
ALL('Table'),
[Year]=YEAR(TODAY())&&
[Month]>=1&&
[Month]<=MONTH(TODAY())
)
)
)
Result:
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
User | Count |
---|---|
117 | |
73 | |
58 | |
49 | |
48 |
User | Count |
---|---|
171 | |
122 | |
60 | |
59 | |
56 |