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
greenlover
Frequent Visitor

Compute YTD Value based on Period Selected

Hi Guys, 

 

I just need your help in computing the YTD value based on the period selected (Start Date & End Date). Note that the value of the YTD must be minus 1 month from the End Date selected. 

 

For example: 

 

Period Selected: January 1, 2021 to November 15, 2021

 

YTD Value must show: Jan 1 to October 15. (Minus 1 month from the End Date selected) 

 

Thank you! 

 



1 ACCEPTED SOLUTION
VahidDM
Super User
Super User

Hi @greenlover 

 

Try this measure to find the YTD value:

 

 

 

Measure =
VAR _MinD =
    MIN ( table[date] ) -- find the MIN date in the selected period
VAR _MaxD =
    MAX ( table[date] ) -- find the MAX date in the selected period
VAR _MaxD1ML =
    DATE ( YEAR ( _MaxD ), MONTH ( _MaxD ), 1 ) - 1 -- find the last date of the month before MAX date
VAR _MaxD1M =
    DATE ( YEAR ( _MaxD1ML ), MONTH ( _MaxD1ML ), DAY ( _MaxD ) ) -- find the same day in the last month of the MAX date
RETURN
    CALCULATE (
        SUM ( table[column] ),
        FILTER ( ALL ( table ), table[date] >= _MinD && table[date] <= _MaxD1M )
    )

 

 

 

If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
LinkedIn: 
www.linkedin.com/in/vahid-dm/

 

 



View solution in original post

3 REPLIES 3
v-angzheng-msft
Community Support
Community Support

Hi, @greenlover 

The formula @VahidDM  provided works, but be aware that you can show the correct value on the total or on the card viusal.
I have tried to make some modifications to the formula above, and you could try this formula:

Measure 2 = 
var _minD=CALCULATE(MIN('Table'[Date]),ALLSELECTED('Table'))
var _maxD=CALCULATE(MAX('Table'[Date]))

var _r=CALCULATE(SUM('Table'[Value]),FILTER(ALL('Table'),'Table'[Date]>=_minD&&'Table'[Date]<=EDATE(_maxD,-1)))

return _r

Result:

vangzhengmsft_0-1637907593018.png

If you have a calendar table, then the formula @Ashish_Mathur  provided will work for you too, but note that the Edate function is followed by max(Date), like:

Total till previous month =
CALCULATE (
    [Total],
    DATESBETWEEN (
        calendar[date],
        MIN ( calendar[date] ),
        EDATE ( MAX ( calendar[date] ), -1 )
    )
)

Please refer to the attachment below for details. Hope this helps.

 

 

Best Regards,
Community Support Team _ Zeon Zheng


If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Ashish_Mathur
Super User
Super User

Hi,

Try these measures

Total = sum(Data[Sales])

Total till previous month = calculate([Total],datesbetween(calendar[date],min(calendar[date]),edate(min(calendar[date]),-1)))

Ensure that the Date slicer is built from the Calendar Table.

Hope this helps.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
VahidDM
Super User
Super User

Hi @greenlover 

 

Try this measure to find the YTD value:

 

 

 

Measure =
VAR _MinD =
    MIN ( table[date] ) -- find the MIN date in the selected period
VAR _MaxD =
    MAX ( table[date] ) -- find the MAX date in the selected period
VAR _MaxD1ML =
    DATE ( YEAR ( _MaxD ), MONTH ( _MaxD ), 1 ) - 1 -- find the last date of the month before MAX date
VAR _MaxD1M =
    DATE ( YEAR ( _MaxD1ML ), MONTH ( _MaxD1ML ), DAY ( _MaxD ) ) -- find the same day in the last month of the MAX date
RETURN
    CALCULATE (
        SUM ( table[column] ),
        FILTER ( ALL ( table ), table[date] >= _MinD && table[date] <= _MaxD1M )
    )

 

 

 

If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
LinkedIn: 
www.linkedin.com/in/vahid-dm/

 

 



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.