cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
PowerQueryFTW Frequent Visitor
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

Accepted Solutions
Super User IV
Super User IV

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

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
Super User IV
Super User IV

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

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

PowerQueryFTW Frequent Visitor
Frequent Visitor

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

Thank you very much!

Super User IV
Super User IV

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

You are welcome.


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

Helpful resources

Announcements
Coming Soon: T-Shirt Design Contest

Coming Soon: T-Shirt Design Contest

Keep your eyes open for our upcoming T-shirt design contest!

Meet the 2020 Season 1 Power BI Super Users!

Meet the 2020 Season 1 Power BI Super Users!

It’s the start of a new Super User season! Learn all about the new Super Users and brand-new tiered recognition system.

Super User Challenge: Can You Solve These?

Super User Challenge: Can You Solve These?

We're celebrating the start of the New Super User season with our first ever Super User 'Can You Solve These?' challenge.

Power Platform Online Conference

Power Platform Online Conference

Join us for the first ever Power Platform Online Conference!

Top Solution Authors
Top Kudoed Authors