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
ljx0648
Helper I
Helper I

Average sales in fiscal year calculation

Hi guys, 

 

I am working on an analysis to calculate average sales in every fiscal year. 

 

Sample data:

Year_MthStaffSales
Sep-21A9
Oct-21A10
Nov-21A15
Dec-21A20
Jan-22A25
Feb-22A30
Dec-21B12
Jan-22B17
Feb-22B22

 

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:

ljx0648_0-1680055234665.png

 

 

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!

1 ACCEPTED SOLUTION
v-rzhou-msft
Community Support
Community Support

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.

vrzhoumsft_0-1680165566965.png

 

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.

 

View solution in original post

2 REPLIES 2
v-rzhou-msft
Community Support
Community Support

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.

vrzhoumsft_0-1680165566965.png

 

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

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.