cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Andmi00
Helper I
Helper I

Date difference based on condition on a separate table

Hi, I have 2 tables with indirect relationships (relationship through another table).

 

Table A has a structure like this with one row for each user in the database.

 

UserIDCreated DateAccount ID
12ABC25/06/2022CAU123
12FDF18/01/2022CAU124
12DFD15/12/2021CAU125

 

And the second table B has one row for each session each user had, sessions are either Active or Inactive

 

UserIDDateSessionAccount ID
12ABC26/06/2022InactiveCAU123
12FDF03/02/2022ActiveCAU124
12DFD16/12/2021ActiveCAU125
12ABC27/06/2022ActiveCAU123
12FDF17/04/2022ActiveCAU124

 

What I want to see is a column in Table A with the time difference between the Create Date in the first table and the first "Active" session in the second table.

 

So in this case:

User 12ABC was created the 25/06/2022 and the first active session was the one on the 27/6/2022 (not the one on the 26/06/2022)

User 12FDF was created the 18/01/2022 and the first active session was the 03/02/2022

User 12DFD was created the 15/12/2021 and the first active session was the 16/12/2022

 

 

Can someone help with this?

1 ACCEPTED SOLUTION
v-stephen-msft
Community Support
Community Support

Hi @Andmi00 ,

 

I create a sample file for your reference.

First Active Date = CALCULATE(MIN('TableB'[Date]),FILTER('TableB',[UserID]=EARLIER(TableA[UserID])&&[Session]="Active"))
Difference = DATEDIFF([Created Date],[First Active Date],DAY)

vstephenmsft_0-1657012307047.png

 

 

 

Best Regards,

Stephen Tao

 

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

View solution in original post

2 REPLIES 2
v-stephen-msft
Community Support
Community Support

Hi @Andmi00 ,

 

I create a sample file for your reference.

First Active Date = CALCULATE(MIN('TableB'[Date]),FILTER('TableB',[UserID]=EARLIER(TableA[UserID])&&[Session]="Active"))
Difference = DATEDIFF([Created Date],[First Active Date],DAY)

vstephenmsft_0-1657012307047.png

 

 

 

Best Regards,

Stephen Tao

 

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

amitchandak
Super User
Super User

@Andmi00 , a new column in table 1

 

 

datediff(Table1[Created Date], Minx(Filter(Table2, Table2[User ID] = Table1[User ID] && [Session] = "Active") , Table2[Date]) , Day)

 



Power BI Features || Datamarts: https://youtu.be/8tskWsJTEpg || Field Parameters : https://youtu.be/lqF3Wa1FllE?t=70
Time Intelligence Decoded : https://youtu.be/aU2aKbnHuWs&t=145s
Did I answer your question? Mark my post as a solution! Appreciate your Kudos !! Proud to be a Super User! !!
Dashboard of My Blogs !! Connect on Linkedin !! Subscribe to my youtube Channel !!
Want To Learn Power BI | Beginners !! Advance Concepts !! Power BI For Tableau User !!

Helpful resources

Announcements
August 2022 update 768x460.jpg

Check it Out!

Click here to learn more about the August 2022 updates!

August 1 episode 9_no_dates 768x460.jpg

The Power BI Community Show

Watch the playback when Priya Sathy and Charles Webb discuss Datamarts! Kelly also shares Power BI Community updates.

Power Platform Conf 2022 768x460.jpg

Join us for Microsoft Power Platform Conference

The first Microsoft-sponsored Power Platform Conference is coming in September. 100+ speakers, 150+ sessions, and what's new and next for Power Platform.

Top Solution Authors
Top Kudoed Authors