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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
PowerQueryFTW
Frequent Visitor

Finding Duplicate ID's based on an overlapping start and end date

I have a table with a column of IDs with a start and end date for those IDs.  I need a DAX formula that will identify duplicate IDs but only if the start and end dates overlap.  

 

For example on a 3 column table with the ID, Start Date, End Date.

If the first 3 rows are ID 1.

The first row has a start date of Jan 1 2018 and an end date of jan 31st.  2nd row has start date of Feb 1 and end date of feb 28th.  Thats ok and no duplicate would exist.  However if the 3rd row in this example has a start date of Jan 15 and an end date of Jan 20 then it should flag this ID as a duplicate ID. 

Example File

https://ufile.io/318mh

 

1 ACCEPTED SOLUTION
Ashish_Mathur
Super User
Super User

Hi,

 

This is the calculated column formula i wrote

 

=if(ISNUMBER(CALCULATE(MAX(Data[Start Date]),FILTER(Data,Data[ID]=EARLIER(Data[ID])&&Data[Start Date]<=EARLIER(Data[End Date])&&Data[Start Date]>EARLIER(Data[Start Date])))+CALCULATE(MIN(Data[End Date]),FILTER(Data,Data[ID]=EARLIER(Data[ID])&&Data[End Date]>=EARLIER(Data[Start Date])&&Data[End Date]<>EARLIER(Data[End Date])&&Data[Start Date]<=EARLIER(Data[End Date])))),"Duplicate","OK!")

 

Hope this helps.

 

Untitled.png


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

View solution in original post

3 REPLIES 3
Ashish_Mathur
Super User
Super User

Hi,

 

This is the calculated column formula i wrote

 

=if(ISNUMBER(CALCULATE(MAX(Data[Start Date]),FILTER(Data,Data[ID]=EARLIER(Data[ID])&&Data[Start Date]<=EARLIER(Data[End Date])&&Data[Start Date]>EARLIER(Data[Start Date])))+CALCULATE(MIN(Data[End Date]),FILTER(Data,Data[ID]=EARLIER(Data[ID])&&Data[End Date]>=EARLIER(Data[Start Date])&&Data[End Date]<>EARLIER(Data[End Date])&&Data[Start Date]<=EARLIER(Data[End Date])))),"Duplicate","OK!")

 

Hope this helps.

 

Untitled.png


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

Thank you very much!

You are welcome.


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

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.