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 all,
apologies if this has been treated already.
I have to manage a simple Sales YTD calculation for a FY starting Dec 1 and ending Nov 30. I have a calendar table with all needed field but for multiple reasons I cannot use the time intelligence functions in all report. I have started therefore to build the following YTD measure:
Solved! Go to Solution.
Hi @PabloDeheza, thanks for this. I did try with VALUES but unfortunately it did not work. After multiple reads I solved as follows via a quite simple CALCULATE with REMOVEFILTERS:
NSV_YTD_A =
VAR __Date = MAX('Fact_Actuals'[Date_comp])
VAR __StartOf = IF( MONTH(__Date)<12,DATE(YEAR(__Date)-1,12,1), DATE(YEAR(__Date),12,1))
VAR __DATESYTD = FILTER(SELECTCOLUMNS(ALL('Fact_Actuals'),"Date_comp",[Date_comp]),[Date_comp] >= __StartOf && [Date_comp] <= __Date)
VAR __MyTD = if(countrows(Fact_Actuals)>0,
CALCULATE(
sum(Fact_Actuals[NSV]),
REMOVEFILTERS ( Dim_Dates[FY_Period] ),
Fact_Actuals[Date_comp] IN __DATESYTD
))
RETURN
__MyTD
C.
Hi @PabloDeheza, thanks for this. I did try with VALUES but unfortunately it did not work. After multiple reads I solved as follows via a quite simple CALCULATE with REMOVEFILTERS:
NSV_YTD_A =
VAR __Date = MAX('Fact_Actuals'[Date_comp])
VAR __StartOf = IF( MONTH(__Date)<12,DATE(YEAR(__Date)-1,12,1), DATE(YEAR(__Date),12,1))
VAR __DATESYTD = FILTER(SELECTCOLUMNS(ALL('Fact_Actuals'),"Date_comp",[Date_comp]),[Date_comp] >= __StartOf && [Date_comp] <= __Date)
VAR __MyTD = if(countrows(Fact_Actuals)>0,
CALCULATE(
sum(Fact_Actuals[NSV]),
REMOVEFILTERS ( Dim_Dates[FY_Period] ),
Fact_Actuals[Date_comp] IN __DATESYTD
))
RETURN
__MyTD
C.
Hi @Anonymous !
To allow the measure to get filtered, then you need to use another function instead of ALL(), you can try using VALUES instead.
Let me know if that helps!
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 |
---|---|
89 | |
88 | |
82 | |
64 | |
49 |
User | Count |
---|---|
125 | |
111 | |
88 | |
69 | |
66 |