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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
mvyskala
Helper I
Helper I

Fiscal YTD from YYYY-MM format

Hello, we have table with date stored in YYYY-MM format, I'd like to find out a way how to make YTD function based on this record. We also have fiscal year starting in March so 2018-01 is March 2018. Any ideas how to format DAX function?
Thanks

1 ACCEPTED SOLUTION
v-piga-msft
Resident Rockstar
Resident Rockstar

Hi @mvyskala,

 

If you want to calculate the YTD value, the data type of your date should be the Date or Date/Time.

 

Please check if your format of "YYYY-MM" is Date type. If it is you could try the formula below.

 

Measure =
CALCULATE (
    SUM ( 'YTD'[Sales] ),
    FILTER (
        ALL ( 'YTD' ),
        'YTD'[Date] <= MAX ( 'YTD'[Date] )
            && YEAR ( 'YTD'[Date] ) = YEAR ( MAX ( 'YTD'[Date] ) )
    )
)

Or 

total_ytd = TOTALYTD(SUM('YTD'[Sales]),'YTD'[Date])

If your format of "YYYY-MM" is text type, you could follow the steps below.

 

1. Change your data type to Date and create a Calendar table with the formula;

 

Date2 = 
ADDCOLUMNS (
CALENDAR (DATE(2017,1,1), DATE(2018,10,31)),
"YearMonth", FORMAT ( [Date], "YYYY-MM" )
)

2. Create the relationship of the two tables and create the measure with the formula below.

 

Measure 2 = TOTALYTD(SUM('YTD'[Sales]),'Date2'[Date])

3. Create the visual below.

 

Capture.PNG

In addition, you could have a reference of my attachments.

 

Best Regards,

Cherry

Community Support Team _ Cherry Gao
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

2 REPLIES 2
v-piga-msft
Resident Rockstar
Resident Rockstar

Hi @mvyskala,

 

If you want to calculate the YTD value, the data type of your date should be the Date or Date/Time.

 

Please check if your format of "YYYY-MM" is Date type. If it is you could try the formula below.

 

Measure =
CALCULATE (
    SUM ( 'YTD'[Sales] ),
    FILTER (
        ALL ( 'YTD' ),
        'YTD'[Date] <= MAX ( 'YTD'[Date] )
            && YEAR ( 'YTD'[Date] ) = YEAR ( MAX ( 'YTD'[Date] ) )
    )
)

Or 

total_ytd = TOTALYTD(SUM('YTD'[Sales]),'YTD'[Date])

If your format of "YYYY-MM" is text type, you could follow the steps below.

 

1. Change your data type to Date and create a Calendar table with the formula;

 

Date2 = 
ADDCOLUMNS (
CALENDAR (DATE(2017,1,1), DATE(2018,10,31)),
"YearMonth", FORMAT ( [Date], "YYYY-MM" )
)

2. Create the relationship of the two tables and create the measure with the formula below.

 

Measure 2 = TOTALYTD(SUM('YTD'[Sales]),'Date2'[Date])

3. Create the visual below.

 

Capture.PNG

In addition, you could have a reference of my attachments.

 

Best Regards,

Cherry

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

Thanks a lot. It's indeed in text format, but your solution work.
MV

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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