Hi guys,
I am working on an analysis to calculate average sales in every fiscal year.
Sample data:
Year_Mth | Staff | Sales |
Sep-21 | A | 9 |
Oct-21 | A | 10 |
Nov-21 | A | 15 |
Dec-21 | A | 20 |
Jan-22 | A | 25 |
Feb-22 | A | 30 |
Dec-21 | B | 12 |
Jan-22 | B | 17 |
Feb-22 | B | 22 |
For my company, every fiscal year starts from Nov each year.
Thus, if i have a slicer to select year month Feb-22, the average sales for
staff A should be: (15+20+25+30)/4
staff B should be: (12+17+22)/3
Expected Result:
P.s.
Sales is a CALCULATED MEASURE which is Sales = sum(customer sales). (each staff has more than 100 customers)
I have tried to get the average by the two measures below:
Average = calculate(average(sum(customer sales), DATESYTD('calendar'[date],"31/10"))
Average = Averagex(VALUES('calendar'[yr_mth]), calculate(sum(customer sales),DATESYTD('calendar'[date],"31/10")))
Both do not return the correct number as per what I expected above.
May I know if anyone can help showing a formula that works this way?
Thank you!
Solved! Go to Solution.
Hi @ljx0648 ,
Create a calendar as below.
calendar =
ADDCOLUMNS (
CALENDARAUTO (),
"Year", YEAR ( [Date] ),
"Month", MONTH ( [Date] ),
"Year_Mth", FORMAT ( [Date], "MMM-YY" ),
"YearMonth",
YEAR ( [Date] ) * 100
+ MONTH ( [Date] ),
"Fiscal Start",
VAR _MONTH =
MONTH ( [Date] )
RETURN
IF (
_MONTH < 11,
EOMONTH ( [Date], -2 - _MONTH ) + 1,
EOMONTH ( [Date], - _MONTH + 10 ) + 1
)
)
Then use measure as below.
Average =
VAR _COUNT =
CALCULATE (
DISTINCTCOUNT ( 'calendar'[Year_Mth] ),
FILTER (
ALL ( 'calendar' ),
'calendar'[Fiscal Start] = MAX ( 'calendar'[Fiscal Start] )
&& 'calendar'[YearMonth] <= MAX ( 'calendar'[YearMonth] )
&& [Sales] <> BLANK ()
)
)
VAR _SUM =
SUMX ( DATESYTD ( 'calendar'[date], "31/10" ), [Sales] )
RETURN
IF([Sales]<>BLANK(),DIVIDE ( _SUM, _COUNT ))
Result is as below.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @ljx0648 ,
Create a calendar as below.
calendar =
ADDCOLUMNS (
CALENDARAUTO (),
"Year", YEAR ( [Date] ),
"Month", MONTH ( [Date] ),
"Year_Mth", FORMAT ( [Date], "MMM-YY" ),
"YearMonth",
YEAR ( [Date] ) * 100
+ MONTH ( [Date] ),
"Fiscal Start",
VAR _MONTH =
MONTH ( [Date] )
RETURN
IF (
_MONTH < 11,
EOMONTH ( [Date], -2 - _MONTH ) + 1,
EOMONTH ( [Date], - _MONTH + 10 ) + 1
)
)
Then use measure as below.
Average =
VAR _COUNT =
CALCULATE (
DISTINCTCOUNT ( 'calendar'[Year_Mth] ),
FILTER (
ALL ( 'calendar' ),
'calendar'[Fiscal Start] = MAX ( 'calendar'[Fiscal Start] )
&& 'calendar'[YearMonth] <= MAX ( 'calendar'[YearMonth] )
&& [Sales] <> BLANK ()
)
)
VAR _SUM =
SUMX ( DATESYTD ( 'calendar'[date], "31/10" ), [Sales] )
RETURN
IF([Sales]<>BLANK(),DIVIDE ( _SUM, _COUNT ))
Result is as below.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thank you Rico! Works perfectly
User | Count |
---|---|
132 | |
59 | |
55 | |
55 | |
46 |
User | Count |
---|---|
129 | |
74 | |
53 | |
52 | |
51 |