Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
Hi,
I'm sure someone has asked this before but I've trawled through a heap of posts and can't quite find one that works for me.
I have a date slicer with start and end dates, and I have the below measure which gives me the average sales quantity over the last 8 weeks.
Qty Avg 8Wks =
VAR previousWeekDate =
TODAY () - WEEKDAY ( TODAY (), 1 )
RETURN
CALCULATE (
SUM ( ItemSales[Qty] ),
FILTER (
ItemSales,
ItemSales[WkStartDate] <= previousWeekDate
&& ItemSales[WkStartDate] >= ( previousWeekDate - 56 )
)
) / 8
The measure gives me the last 8 weeks average quantity from today, but I want it to give me the last 8 weeks from the end date of the slicer selection.
Can anyone help please?
Thanks,
Michael
Solved! Go to Solution.
Hi @mboucher_rcr ,
According to your description, as in your formula below, you specify the end date is the closest Saturday before today, not the end date of the slicer selection.
VAR previousWeekDate =
TODAY () - WEEKDAY ( TODAY (), 1 )
Modify you formula like this:
Qty Avg 8Wks =
VAR SelectedDay =
MAXX ( ALLSELECTED ( 'Date' ), 'Date'[Date] )
VAR previousWeekDate =
SelectedDay - WEEKDAY ( SelectedDay, 1 )
RETURN
CALCULATE (
SUM ( ItemSales[Qty] ),
FILTER (
ItemSales,
ItemSales[WkStartDate] <= previousWeekDate
&& ItemSales[WkStartDate] >= ( previousWeekDate - 56 )
)
) / 8
Get the correct result in my sample.
I attach my sample below for reference.
Best Regards,
Community Support Team _ kalyj
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @mboucher_rcr ,
According to your description, as in your formula below, you specify the end date is the closest Saturday before today, not the end date of the slicer selection.
VAR previousWeekDate =
TODAY () - WEEKDAY ( TODAY (), 1 )
Modify you formula like this:
Qty Avg 8Wks =
VAR SelectedDay =
MAXX ( ALLSELECTED ( 'Date' ), 'Date'[Date] )
VAR previousWeekDate =
SelectedDay - WEEKDAY ( SelectedDay, 1 )
RETURN
CALCULATE (
SUM ( ItemSales[Qty] ),
FILTER (
ItemSales,
ItemSales[WkStartDate] <= previousWeekDate
&& ItemSales[WkStartDate] >= ( previousWeekDate - 56 )
)
) / 8
Get the correct result in my sample.
I attach my sample below for reference.
Best Regards,
Community Support Team _ kalyj
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi,
Create a Calendar Table with a relationship (Many to One and Single) from the WkStartDate column of the ItemSales table to the Date column of the Calendar Table. Write this measure:
= CALCULATE(SUM(ItemSales[Qty]),DATESBETWEEN('Calendar'[Date],max('Calendar'[Date])-56,max('Calendar'[Date])))/8
Hope this helps.
Please define what you mean by "week" . Ideally you have a calendar table with week numbers. How do you handle transitions between (fiscal) years ? Say, "today" is February 1. What's your definition of "past 8 weeks" in that scenario?
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
87 | |
87 | |
84 | |
66 | |
49 |
User | Count |
---|---|
127 | |
109 | |
93 | |
70 | |
67 |