cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Per-J
Helper II
Helper II

Date filtering - Getting last 5 calendar years plus this year to date

Hello! I'm trying to create a simple filter in my reports using the "filter-pane" in PBI Desktop, using relative filtering. There are two options, either last x calendar years OR last x years. What I need however is a combination of the two. I want the filter to include five calendar years back PLUS current year to date. In other words, I need it to count from 1.1.2015 TO "TODAY" (then after new years, the relative filtering moves earliest date to 1.1.2016). Is this achievable?
1 ACCEPTED SOLUTION
amitchandak
Super User IV
Super User IV

@Per-J , Try with a date table

5 Yr YTD =
var _max = today()
// or // maxx(allselected('Date'),[date])
var _min = date(year(_max)-5,1,1)
return
CALCULATE(Sum('Table'[Column]),filter(all('Date'),'Date'[Date]<=_max && 'Date'[Date]>=_min))

 

To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s. Refer :
https://radacad.com/creating-calendar-table-in-power-bi-using-dax-functions
https://www.archerpoint.com/blog/Posts/creating-date-table-power-bi
https://www.sqlbi.com/articles/creating-a-simple-date-table-in-dax/

See if my webinar on Time Intelligence can help: https://community.powerbi.com/t5/Webinars-and-Video-Gallery/PowerBI-Time-Intelligence-Calendar-WTD-Y...


Appreciate your Kudos.



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

Proud to be a Super User!

View solution in original post

3 REPLIES 3
Anonymous
Not applicable

Hi,

I think the better option is to use a top N filter rather than the relative date filter for your scenario...
If you filter the top N year by the latest date I think you get the results you're wanting.

image.png
image.png

Thanks for this solution. I bet this sloves the case for many, but in my case I get no such option as "top n" to chose from. Must be some reason for that. 

 

Not to worry though. A version of solution above solved the matter. 

 

Best, PJ

amitchandak
Super User IV
Super User IV

@Per-J , Try with a date table

5 Yr YTD =
var _max = today()
// or // maxx(allselected('Date'),[date])
var _min = date(year(_max)-5,1,1)
return
CALCULATE(Sum('Table'[Column]),filter(all('Date'),'Date'[Date]<=_max && 'Date'[Date]>=_min))

 

To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s. Refer :
https://radacad.com/creating-calendar-table-in-power-bi-using-dax-functions
https://www.archerpoint.com/blog/Posts/creating-date-table-power-bi
https://www.sqlbi.com/articles/creating-a-simple-date-table-in-dax/

See if my webinar on Time Intelligence can help: https://community.powerbi.com/t5/Webinars-and-Video-Gallery/PowerBI-Time-Intelligence-Calendar-WTD-Y...


Appreciate your Kudos.



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

Proud to be a Super User!

View solution in original post

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS Attendee Badge

Claim Your Badge & Digital Swag!

Check out how to claim yours today!

secondImage

Are You Ready?

Test your skills now with the Cloud Skills Challenge.

Top Solution Authors