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

Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now

Reply
setis
Post Partisan
Post Partisan

First repeated occurence

Dear all, 

 

I'm working with the following travel table:

travel.PNG

 

As you can see, every travel has a unique pnrlocatorkey. Travels are usually return trips, as the 3 showed above. 

What I'm trying to identify is which segment of the trip is the return trip. 

I think that It might be necessary to create a calculated table sorting the rows by departure_time_sk and then identifying when the departure country occurs fist time as an Arrival country and the following rows for the same pnrlocatorkey. 

 

the intended result, if trip = 1 and return trip = 2 would be:

 

travel2.PNG

 

Thanks in advance!

 

 

1 ACCEPTED SOLUTION
AllisonKennedy
Super User
Super User

Looks like the Travel_legs.firstleg and Travel_legs.lastleg will get you partly there.

Based on your suggestion, if you just want to see if the Departure and Arrival cities already exist earlier in the table, you could try:
UPDATED: Based on original poster's comments to reflect correct order of arrival and departure country. 


TripReturn = COUNTROWS(FILTER(ALL(Travel), Travel[Departure Country] = EARLIER(Travel[Arrival Country]) && Travel[pnrlocatorkey] = EARLIER(Travel[pnrlocatorkey]) && Travel[Departure date] <= EARLIER(Travel[Departure date])))


Please @mention me in your reply if you want a response.

Copying DAX from this post? Click here for a hack to quickly replace it with your own table names

Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C

I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com

View solution in original post

5 REPLIES 5
amitchandak
Super User
Super User

@setis , Create a new column like

calculate( distinctcount(departure_time_sk) , filter(Table,[pnrlocatorkey] =earlier([pnrlocatorkey]) && [departure_time_sk] <=earlier([departure_time_sk])))
Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

@AllisonKennedy  and @amitchandak thanks a lot for your answers.

 

@amitchandak unfortunately your solution gave me an "out of memory" error. 

 

@AllisonKennedy your solution game me this

 

travel3.PNG

The calculation looks prety much like what I was looking for. However, I don't undestand why if we look at the first trip, it finds 1 row for Mali in departures. It doesn't look right, since that line is departure_time_sk = 16481 and the one it finds (I guess)  is 16561 which isn't <= to 16481.

What's going on?

I managed to solve this switching Arrival country and departure country in the first line of the filter. 

 

Thanks!

Thanks for the update @setis
I will update my original post now so the solution looks more accurate. 🙂

Please @mention me in your reply if you want a response.

Copying DAX from this post? Click here for a hack to quickly replace it with your own table names

Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C

I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com

AllisonKennedy
Super User
Super User

Looks like the Travel_legs.firstleg and Travel_legs.lastleg will get you partly there.

Based on your suggestion, if you just want to see if the Departure and Arrival cities already exist earlier in the table, you could try:
UPDATED: Based on original poster's comments to reflect correct order of arrival and departure country. 


TripReturn = COUNTROWS(FILTER(ALL(Travel), Travel[Departure Country] = EARLIER(Travel[Arrival Country]) && Travel[pnrlocatorkey] = EARLIER(Travel[pnrlocatorkey]) && Travel[Departure date] <= EARLIER(Travel[Departure date])))


Please @mention me in your reply if you want a response.

Copying DAX from this post? Click here for a hack to quickly replace it with your own table names

Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C

I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

Check out the November 2024 Power BI update to learn about new features.

October NL Carousel

Fabric Community Update - October 2024

Find out what's new and trending in the Fabric Community.