Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Dear all,
I'm working with the following travel table:
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:
Thanks in advance!
Solved! Go to Solution.
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])))
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
@setis , Create a new column like
calculate( distinctcount(departure_time_sk) , filter(Table,[pnrlocatorkey] =earlier([pnrlocatorkey]) && [departure_time_sk] <=earlier([departure_time_sk])))
@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
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!
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
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])))
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