Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Be 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

Reply
vin26
Resolver I
Resolver I

Get the Max Available Month on Selection

Hello,

 

I am trying to calculate average of value for last 6 months by skipping selected month. When I select a specific month if the data exist for the specific employee in the selected month I am getting correct numbers. But the issue is, if the selected month does not have any value, the measure is not picking up previous month numbers. Please help me to get the Max available month for the specific Employee and calculation should be based on available numbers of months during those selected 6 months. Eg: if I select Aug’24, Avg would be Feb to July or any available data between these time period. Here is my data and measures:

 

MonthEMP IDAmount
2024-01A1004657
2024-02A1003480
2024-03A1004965
2024-04A1001510
2024-05A1004384
2024-06A1001374
2024-01A2003369
2024-02A2002445
2024-03A2004494
2024-04A2003621
2024-05A2002093
2024-06A2001350
2024-01A3003447
2024-02A3003603
2024-03A3003010
2024-04A3002305
2024-01A4001470
2024-02A4004998
2024-03A4002158

 

Data Modeling

vin26_0-1727251068653.png

 

Measure:

 

Measure = CALCULATE(Average(Table1[Amount]),DATESINPERIOD('DimDate'[Month],EOMONTH(MAX('DimDate'[Month]),-1),-6,MONTH))

 

 

Max Month

 

Measure 2 = EOMONTH(MAX(Table1[Month]),-1)

 

 

vin26_1-1727251232212.png

 

2 ACCEPTED SOLUTIONS
rajendraongole1
Super User
Super User

Hi @vin26 -Create a Measure to Get the Max Available Month for Each Employee

 

Max Available Month =
CALCULATE(
MAX(Table1[Month]),
FILTER(
ALL(Table1),
Table1[EMP ID] = MAX(Table1[EMP ID]) && Table1[Month] <= MAX('DimDate'[Month])
)
)

 

Measure for last 6 months calc.

Average Last 6 Months =
CALCULATE(
AVERAGE(Table1[Amount]),
DATESINPERIOD(
'DimDate'[Month],
[Max Available Month],
-6,
MONTH
),
Table1[Amount] <> BLANK()
)

 

check with above measures, if still issue exist please share the pbix file by removing the sensitive data.





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!





View solution in original post

v-zhengdxu-msft
Community Support
Community Support

Hi @vin26 

 

Please try this:
Maybe you can delete the relationship between the Table1 and the DimDate:

vzhengdxumsft_0-1727320125523.png

Then add a measure:

 

MEASURE =
VAR _slicer =
    MONTH ( MAX ( 'DimDate'[Month] ) )
RETURN
    CALCULATE (
        AVERAGE ( 'Table'[Amount] ),
        FILTER (
            ALLSELECTED ( 'Table' ),
            MONTH ( 'Table'[Month] ) < _slicer
                && MONTH ( 'Table'[Month] ) >= _slicer - 6
        )
    )

 

Then add a slicer with DimDate[Month]:

vzhengdxumsft_1-1727320175647.png

The result is as follow:

vzhengdxumsft_2-1727320192810.png

 

Best Regards

Zhengdong Xu
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

3 REPLIES 3
vin26
Resolver I
Resolver I

@v-zhengdxu-msft @rajendraongole1 Thanks a lot for your responses. Both the solution works and my logic also working. Actual issue was with my Data modelling, I had used  'Both' in cross filter direction in connection between DimDate and Table1, after making the connection to single worked fine. Thanks again

v-zhengdxu-msft
Community Support
Community Support

Hi @vin26 

 

Please try this:
Maybe you can delete the relationship between the Table1 and the DimDate:

vzhengdxumsft_0-1727320125523.png

Then add a measure:

 

MEASURE =
VAR _slicer =
    MONTH ( MAX ( 'DimDate'[Month] ) )
RETURN
    CALCULATE (
        AVERAGE ( 'Table'[Amount] ),
        FILTER (
            ALLSELECTED ( 'Table' ),
            MONTH ( 'Table'[Month] ) < _slicer
                && MONTH ( 'Table'[Month] ) >= _slicer - 6
        )
    )

 

Then add a slicer with DimDate[Month]:

vzhengdxumsft_1-1727320175647.png

The result is as follow:

vzhengdxumsft_2-1727320192810.png

 

Best Regards

Zhengdong Xu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

rajendraongole1
Super User
Super User

Hi @vin26 -Create a Measure to Get the Max Available Month for Each Employee

 

Max Available Month =
CALCULATE(
MAX(Table1[Month]),
FILTER(
ALL(Table1),
Table1[EMP ID] = MAX(Table1[EMP ID]) && Table1[Month] <= MAX('DimDate'[Month])
)
)

 

Measure for last 6 months calc.

Average Last 6 Months =
CALCULATE(
AVERAGE(Table1[Amount]),
DATESINPERIOD(
'DimDate'[Month],
[Max Available Month],
-6,
MONTH
),
Table1[Amount] <> BLANK()
)

 

check with above measures, if still issue exist please share the pbix file by removing the sensitive data.





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!





Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.