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

Get 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

Reply
Anonymous
Not applicable

Tricky YTD calculation with Fiscal Year

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:

 

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)
RETURN
    SUMX(FILTER(ALL('Fact_Actuals'),[Date_comp] IN __DATESYTD),Fact_Actuals[NSV])
 
In my assumption this should give the YTD NSV but unfortunately doesnt as is releasing all other filters made via report slicers (e.g. IsIntco below):
 
cfugge_1-1674724341046.png

 

How can I amend the measure above to maintain all other filters and calculate correctly YTD?
 
Many thanks in advance.
 
C. 
1 ACCEPTED SOLUTION
Anonymous
Not applicable

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.

View solution in original post

2 REPLIES 2
Anonymous
Not applicable

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.

PabloDeheza
Solution Sage
Solution Sage

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!

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

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! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

Check out the November 2024 Power BI update to learn about new features.