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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
RMV
Helper V
Helper V

dynamic time filter

Hi,

 

I need to create a report. I have 2 reports to create in mind, i.e.

1. To display the comparison of average YTD and average value from 1-Jan-17 to Monday last week

2. To display the comparison of average YTD and average value within last 1 week period

To be more efficient, I'm thinking of providing a slicer for the period of time used to calculate the 2nd value in #1 & #2 points above.

I'm not sure whether this is possible or not. Any advise on it and the formula to used is welcomed.

 

Thanks.

1 ACCEPTED SOLUTION
v-yulgu-msft
Employee
Employee

Hi @RMV,

 

Suppose source table contains two columns [Sales Date] and [Sales].

 

You can refer to below measure formulas to calculate average in different period.

Average YTD =
TOTALYTD ( AVERAGE ( 'Sales table'[Sales] ), 'Sales table'[Sales Date] )

Average to last Monday =
TOTALYTD (
    AVERAGE ( 'Sales table'[Sales] ),
    'Sales table'[Sales Date],
    FILTER (
        'Sales table',
        'Sales table'[Sales Date]
            <= TODAY ()
                - (
                    WEEKDAY ( TODAY () - 2 )
                        + 7
                )
    )
)

Average last week =
CALCULATE (
    AVERAGE ( 'Sales table'[Sales] ),
    FILTER (
        'Sales table',
        WEEKNUM ( 'Sales table'[Sales Date], 2 )
            = WEEKNUM ( TODAY (), 2 ) - 1
    )
)

If you want to dynamically show average based on slicer selection, you need to create an extra table which lists all selection items like this. Later, we should add this column into slicer.

1.PNG

 

Create a measure

Average =
IF (
    LASTNONBLANK ( 'Slicer Table'[Period selection], 1 ) = "Last Monday",
    [Average to last Monday],
    [Average last week]
)

Result.

2.PNG3.PNG

Best regards,
Yuliana Gu

Community Support Team _ Yuliana Gu
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

5 REPLIES 5
v-yulgu-msft
Employee
Employee

Hi @RMV,

 

Have you worked it out? If so, would you please mark the corresponding reply as an answer or share your resolution so that it can benefit others having similar requirements?

 

Regards,
Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Hi @v-yulgu-msft,

 

Actually my question is to have a flexible start date & end date to filter 1 calculation, and does not effect the other calculation.

Thus, when a side-by-side bar is created using the calculation, 1 bar will have a fix filter (i.e. YTD average) & the other bar will be effected by the start date &/ end date filter applied.

 

Any advise please?

Hi @RMV,

 

Sorry for my misunderstanding.

 

Unfortunately, I don't think this is available to achieve such a requirement. The filter will apply to all bars in a chart. This is by default.

 

Regards,
Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
v-yulgu-msft
Employee
Employee

Hi @RMV,

 

Suppose source table contains two columns [Sales Date] and [Sales].

 

You can refer to below measure formulas to calculate average in different period.

Average YTD =
TOTALYTD ( AVERAGE ( 'Sales table'[Sales] ), 'Sales table'[Sales Date] )

Average to last Monday =
TOTALYTD (
    AVERAGE ( 'Sales table'[Sales] ),
    'Sales table'[Sales Date],
    FILTER (
        'Sales table',
        'Sales table'[Sales Date]
            <= TODAY ()
                - (
                    WEEKDAY ( TODAY () - 2 )
                        + 7
                )
    )
)

Average last week =
CALCULATE (
    AVERAGE ( 'Sales table'[Sales] ),
    FILTER (
        'Sales table',
        WEEKNUM ( 'Sales table'[Sales Date], 2 )
            = WEEKNUM ( TODAY (), 2 ) - 1
    )
)

If you want to dynamically show average based on slicer selection, you need to create an extra table which lists all selection items like this. Later, we should add this column into slicer.

1.PNG

 

Create a measure

Average =
IF (
    LASTNONBLANK ( 'Slicer Table'[Period selection], 1 ) = "Last Monday",
    [Average to last Monday],
    [Average last week]
)

Result.

2.PNG3.PNG

Best regards,
Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Hi @v-yulgu-msft,

 

In another case of my original question, I'm interested with your calculation to have slicer options of measure to be viewed.

Can I use the same concept to create a chart?

Tried once and it didn't succeed.

 

Regards,

viyona

 

 

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.