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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

Reply

Measure to determine if item is within 5 year / 10 year periods

Hi all, 

 

Struggling with some date work based on years against TODAY and a static date. I have never used calendars and Im wondering if this is what I need. 

 

I have a table of components which have a column called PRIORTY DATE, this column has both past and future dates, I want to concentrate on the past dates. The components are considered as overdue if the PRIOROTY DATE is before TODAY, however I need to be able to determine HOW overdue they are and split them into one of 3 categories. 

 

Overdue within 5 years (from TODAY)

Overdue between 5 years & 10 years (from TODAY)

Overdue over 10 years (from TODAY).

 

Example data 

 

One is under 5 years overdue 

One is between 5 & 6 years overdue 

One is over 10 years overdue 

 

component_refpriority_dateOverdue_Current
57338412/10/1996Overdue
26010819/02/2016Overdue
26032619/02/2018Overdue

 

Any suggestions on either a column or a measure most welcome 😁

 

Thanks! 

 

 

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

@Googlecanthelp 

Please find the solution below using measure:

shwetadalal_0-1646661256837.png

 

Dax Measure:

 

OverdueCurent =
VAR datedifference =
DATEDIFF ( SELECTEDVALUE ( Data[priority_date] ), TODAY (), YEAR )
VAR diff =
IF (
datedifference <= 5,
"Under 5 years",
IF (
datedifference > 5
&& datedifference <= 10,
"Between 5-10 years",
IF ( datedifference > 10, "Over 10 years", BLANK () )
)
)
RETURN
diff
 
 
Please accept it as a solution if it matches your requirement🙂

View solution in original post

Anonymous
Not applicable

Hi @Googlecanthelp ,

 

Please check the measure.

Measure = 
var _5year = EDATE(TODAY(),-60)
var _10year = EDATE(TODAY(),-120)
var _prio = SELECTEDVALUE('Table'[priority_date])
return
SWITCH(TRUE(),
_prio<TODAY()&&_prio>=_5year,"Overdue within 5 years",
_prio<_5year&&_prio>=_10year,"Overdue between 5 years & 10 years",
_prio<_10year,"Overdue over 10 years")

1.jpg

 

Best Regards,

Jay

View solution in original post

4 REPLIES 4
Anonymous
Not applicable

Hi @Googlecanthelp ,

 

Please check the measure.

Measure = 
var _5year = EDATE(TODAY(),-60)
var _10year = EDATE(TODAY(),-120)
var _prio = SELECTEDVALUE('Table'[priority_date])
return
SWITCH(TRUE(),
_prio<TODAY()&&_prio>=_5year,"Overdue within 5 years",
_prio<_5year&&_prio>=_10year,"Overdue between 5 years & 10 years",
_prio<_10year,"Overdue over 10 years")

1.jpg

 

Best Regards,

Jay

Anonymous
Not applicable

@Googlecanthelp 

Please find the solution below using measure:

shwetadalal_0-1646661256837.png

 

Dax Measure:

 

OverdueCurent =
VAR datedifference =
DATEDIFF ( SELECTEDVALUE ( Data[priority_date] ), TODAY (), YEAR )
VAR diff =
IF (
datedifference <= 5,
"Under 5 years",
IF (
datedifference > 5
&& datedifference <= 10,
"Between 5-10 years",
IF ( datedifference > 10, "Over 10 years", BLANK () )
)
)
RETURN
diff
 
 
Please accept it as a solution if it matches your requirement🙂

Thank you @Anonymous this worked a treat 🙂 

Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

One of ways to solve this is to create a helper table, like Overdue Table in a model, and create a measure.

 

Picture1.png

 

Overdue_current: =
IF (
HASONEVALUE ( Data[component_ref] ),
CALCULATE (
VALUES ( Overdue[Overdue] ),
FILTER (
Overdue,
( TODAY () - MAX ( Data[priority_date] ) ) / 365.25 >= Overdue[Min]
&& ( TODAY () - MAX ( Data[priority_date] ) ) / 365.25 < Overdue[Max]
)
)
)


If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Click here to visit my LinkedIn page

Click here to schedule a short Teams meeting to discuss your question.

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

September Power BI Update Carousel

Power BI Monthly Update - September 2025

Check out the September 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.