Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
I have a date slicer which allows someone to pick a date for example 31st March 2022. I want to try create a couple of calculations that calculated the average value over the QTR, YTD , -5 year and -10 year. But the issue i am having when it comes to my date slicer all these numbers are currently showing the same. What i would expect is for YTD it would look at the date that has been selected in the slicer and look from 1st January 2022 up to the 31st March 2022 then give me the average value over that period.
I have tried about 100 calculations and none seem to work and all seem to just filter to the latest date an example of what i have tried is below;
LastQuarter =
VAR MaxDate = MAX(YourTable[EndDate])
RETURN
CALCULATE(
AVERAGE(YourTable[YourValueColumn]),
FILTER(
ALL(YourTable[EndDate]),
YourTable[EndDate] = MaxDate &&
YourTable[EndDate] >= STARTOFQUARTER(MaxDate) &&
YourTable[EndDate] < DATEADD(STARTOFQUARTER(MaxDate), 3, MONTH)
)
)
With this the calculation doesnt work as it doesnt allow me to reference the MaxDate in STARTOFQUARTER. Any help would be great
Solved! Go to Solution.
Hi @Infidti ,
Since you didn't provide sample data, I created my own test set:
I also created an additional date sheet to create the slicer:
Since I don't know whether you are averaging the YTD values by the number of data records or by the total number of days, I'll provide you with two DAXs for each of these two averages:
YTD_PerData =
CALCULATE(
AVERAGE('Table'[test data]),
FILTER(
ALL('Table'),
'Table'[date] <= MAX('Slicer'[Date])
)
)
YTD=(10000+12000+20000+2000+31000+9000+8500+13000)/8=13187.5
YTD_PerDay =
VAR Days_count = DATEDIFF(DATE(2022,1,1), MAX('Slicer'[Date]), DAY) + 1
VAR Date_count = CALCULATE(
SUM('Table'[test data]),
FILTER(
ALL('Table'),
'Table'[date] <= MAX('Slicer'[Date])
)
)
RETURN
Date_count / Days_count
YTD=(10000+12000+20000+2000+31000+9000+8500+13000)/90(Total days between 2022.1.1 and 2022.3.31)=1172.2
And about QTR, -5 year and -10 year, could you please provide me with the sample data and the formula so that I can know how to use the DAX function to do the calculation?
Best Regards,
Dino Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Infidti ,
Since you didn't provide sample data, I created my own test set:
I also created an additional date sheet to create the slicer:
Since I don't know whether you are averaging the YTD values by the number of data records or by the total number of days, I'll provide you with two DAXs for each of these two averages:
YTD_PerData =
CALCULATE(
AVERAGE('Table'[test data]),
FILTER(
ALL('Table'),
'Table'[date] <= MAX('Slicer'[Date])
)
)
YTD=(10000+12000+20000+2000+31000+9000+8500+13000)/8=13187.5
YTD_PerDay =
VAR Days_count = DATEDIFF(DATE(2022,1,1), MAX('Slicer'[Date]), DAY) + 1
VAR Date_count = CALCULATE(
SUM('Table'[test data]),
FILTER(
ALL('Table'),
'Table'[date] <= MAX('Slicer'[Date])
)
)
RETURN
Date_count / Days_count
YTD=(10000+12000+20000+2000+31000+9000+8500+13000)/90(Total days between 2022.1.1 and 2022.3.31)=1172.2
And about QTR, -5 year and -10 year, could you please provide me with the sample data and the formula so that I can know how to use the DAX function to do the calculation?
Best Regards,
Dino Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
The measures would all follow a similar structure:
Qtr =
CALCULATE(AVERAGE('YourTable'[YourColumn]), FILTER(ALL('YourTable'),
YEAR('YourTable'[Date]) = YEAR(SELECTEDVALUE('YourTable'[Date])
&& QUARTER('YourTable'[Date]) = QUARTER(SELECTEDVALUE('YourTable'[Date]))
)
This is assuming that your slicer is only allowing users to select a single value, if you wanted them to be able to select multiple you'd want to use an AVERAGEX over a table that was aggregated by the quarter (let me know if this is the case and I will think about it).
Last 5 Years =
CALCULATE(AVERAGE('YourTable'[YourColumn]), FILTER(ALL('YourTable'),
YEAR('YourTable'[Date]) >= YEAR(SELECTEDVALUE('YourTable'[Date]) - 5
&& YEAR('YourTable'[Date]) < YEAR(SELECTEDVALUE('YourTable'[Date])
)
The above would return an average over the last 5 years, not including the current year, you can play around with the interval and the greater than and less than signs to get the specific period that you want. Hope this helps, let me know if you have any issues or further questions.
Check out the October 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
113 | |
108 | |
108 | |
92 | |
67 |
User | Count |
---|---|
161 | |
129 | |
129 | |
92 | |
91 |