Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
Hi,
I hope this message finds you well.
I am currently facing difficulties creating a DAX measure or power query code to calculate the local distance between the most recent activity and the previous one, with all the data already present in a single table. Despite extensive research, all the examples I’ve found involve two tables, which doesn't apply to my situation.
The table contains the following columns: the ID of the card that performed the activity, the activity ID, the location ID, the registration date (note that an activity may start on the 10th, for example, but the relevant date is the end date, so in this case, the date would actually be the 11th), start and end date/time, latitude, and longitude.
The goal is for the user to be able to filter the data by the card ID and then by the registration date. Once filtered, the data should be organised by date and time, and the measure I intend to create should calculate the distance from the location of the previous record.
I realise this might sound a bit confusing, so let me clarify with some example data:
| ID_CARD | ID_ACTIVITY | ID_LOCATION | CALDAY | STARTTIME | ENDTIME | latitude | longitude |
| A | XXXX-XXXX-XXXX-XXXXX16 | X1 | 11/08/2024 | 11/08/2024 03:51 | 11/08/2024 04:02 | 41.00000 | -8.00000 |
| A | XXXX-XXXX-XXXX-XXXXX1 | X2 | 11/08/2024 | 11/08/2024 04:07 | 11/08/2024 04:17 | 41.00001 | -8.00001 |
| A | XXXX-XXXX-XXXX-XXXXX2 | X3 | 11/08/2024 | 11/08/2024 04:29 | 11/08/2024 04:59 | 41.00002 | -8.00002 |
| A | XXXX-XXXX-XXXX-XXXXX3 | X4 | 11/08/2024 | 11/08/2024 06:19 | 11/08/2024 06:44 | 41.00003 | -8.00003 |
| A | XXXX-XXXX-XXXX-XXXXX4 | X4 | 11/08/2024 | 11/08/2024 07:37 | 11/08/2024 08:10 | 41.00004 | -8.00004 |
| B | XXXX-XXXX-XXXX-XXXXX5 | X6 | 11/08/2024 | 11/08/2024 07:54 | 11/08/2024 08:58 | 41.00005 | -8.00005 |
| A | XXXX-XXXX-XXXX-XXXXX6 | X6 | 11/08/2024 | 11/08/2024 08:37 | 11/08/2024 08:40 | 41.00006 | -8.00006 |
| A | XXXX-XXXX-XXXX-XXXXX7 | X7 | 11/08/2024 | 11/08/2024 08:40 | 11/08/2024 09:45 | 41.00007 | -8.00007 |
| B | XXXX-XXXX-XXXX-XXXXX8 | X5 | 11/08/2024 | 11/08/2024 18:06 | 11/08/2024 18:32 | 41.00008 | -8.00008 |
| B | XXXX-XXXX-XXXX-XXXXX9 | XX7 | 11/08/2024 | 11/08/2024 18:33 | 11/08/2024 18:56 | 41.00009 | -8.00009 |
| B | XXXX-XXXX-XXXX-XXXXX10 | X7 | 11/08/2024 | 11/08/2024 18:57 | 11/08/2024 19:34 | 41.00010 | -8.00010 |
| B | XXXX-XXXX-XXXX-XXXXX11 | X9 | 11/08/2024 | 11/08/2024 19:35 | 11/08/2024 19:59 | 41.00011 | -8.00011 |
| B | XXXX-XXXX-XXXX-XXXXX12 | X2 | 11/08/2024 | 11/08/2024 20:01 | 11/08/2024 20:21 | 41.00012 | -8.00012 |
| B | XXXX-XXXX-XXXX-XXXXX13 | X3 | 11/08/2024 | 11/08/2024 20:23 | 11/08/2024 21:37 | 41.00013 | -8.00013 |
| A | XXXX-XXXX-XXXX-XXXXX14 | X8 | 11/08/2024 | 11/08/2024 20:57 | 11/08/2024 22:00 | 41.00014 | -8.00014 |
| A | XXXX-XXXX-XXXX-XXXXX15 | X9 | 11/08/2024 | 11/08/2024 22:03 | 11/08/2024 22:34 | 41.00015 | -8.00015 |
Let's suppose that these are the data stored in the database.
Now I will show what the user will see when filtering on the dashboard.
| ID_CARD | ID_ACTIVITY | ID_LOCATION | CALDAY | STARTTIME | ENDTIME | latitude | longitude | .distanceKM |
| A | XXXX-XXXX-XXXX-XXXXX16 | X1 | 11/08/2024 | 11/08/2024 03:51 | 11/08/2024 04:02 | 41.00000 | -8.00000 | 0.0 |
| A | XXXX-XXXX-XXXX-XXXXX1 | X2 | 11/08/2024 | 11/08/2024 04:07 | 11/08/2024 04:17 | 41.00001 | -8.00001 | 0.2 |
| A | XXXX-XXXX-XXXX-XXXXX2 | X3 | 11/08/2024 | 11/08/2024 04:29 | 11/08/2024 04:59 | 41.00002 | -8.00002 | 0.4 |
| A | XXXX-XXXX-XXXX-XXXXX3 | X4 | 11/08/2024 | 11/08/2024 06:19 | 11/08/2024 06:44 | 41.00003 | -8.00003 | 0.7 |
| A | XXXX-XXXX-XXXX-XXXXX4 | X4 | 11/08/2024 | 11/08/2024 07:37 | 11/08/2024 08:10 | 41.00004 | -8.00004 | 0.0 |
| A | XXXX-XXXX-XXXX-XXXXX6 | X6 | 11/08/2024 | 11/08/2024 08:37 | 11/08/2024 08:40 | 41.00006 | -8.00006 | 1.0 |
| A | XXXX-XXXX-XXXX-XXXXX7 | X7 | 11/08/2024 | 11/08/2024 08:40 | 11/08/2024 09:45 | 41.00007 | -8.00007 | 0.9 |
| A | XXXX-XXXX-XXXX-XXXXX14 | X8 | 11/08/2024 | 11/08/2024 20:57 | 11/08/2024 22:00 | 41.00014 | -8.00014 | 0.2 |
| A | XXXX-XXXX-XXXX-XXXXX15 | X9 | 11/08/2024 | 11/08/2024 22:03 | 11/08/2024 22:34 | 41.00015 | -8.00015 | 0.5 |
This is what the user will see when applying the filters; the .distanceKM will be calculated in the order of the records.
I hope this is enough for you to understand my question. I look forward to the resolution of this issue or even a suggestion.
P.S.: I had to create random data to protect confidential information, but I think the idea is clear.
Solved! Go to Solution.
Hi @Joaomatos2002 ,
Not sure I understand your question. Please check the M code below:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hdRLjsMgEATQq4y8TiZU82c3cwpLke9/jQEmUtmQNF5YuCz1E79+Pref7bbt9blfXztC+4H6Ah4mPcSIu3x8GVs8hsgVIzVy+DbtqcN7eg2Pm4K1XDSrFo5ThEgLtKBajdmtbkmeIp9pCS1RrcbsTrNCwWiF4hwtS8uqlltasdhxDVOBoeVouW79frB8y4Nu+TFKxSdanpZX5xWWVno3L3eaV6AVVKuV2aNu9cLnKBfnaUVaUV3DthZ9IT9ZSMWEKbKn+5VoJdXKPdcm1irbKfKBWCaWVayfqBXmhx1DLpanHuwcMDrWW0fWsFrZT9HpOoOtA9AxWfUpMcVgigTE2DsgOmZXjapVHvZM8H8XXhibB/Tmgd49ko6NeyZSDG8Z2D3gdMyv9qxVHmcmlwPC9lGHx/EH", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID_CARD = _t, ID_ACTIVITY = _t, ID_LOCATION = _t, CALDAY = _t, STARTTIME = _t, ENDTIME = _t, latitude = _t, longitude = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"STARTTIME", type datetime}, {"ENDTIME", type datetime}, {"latitude", type number}, {"longitude", type number}}),
#"Sorted Rows" = Table.Sort(#"Changed Type",{{"ID_CARD", Order.Ascending}, {"ENDTIME", Order.Ascending}}),
#"Added Index" = Table.AddIndexColumn(#"Sorted Rows", "Index", 1, 1, Int64.Type),
AddPreviousIndex = Table.AddColumn(#"Added Index", "PreviousIndex", each [Index] - 1),
MergedQueries = Table.NestedJoin(AddPreviousIndex, {"ID_CARD", "PreviousIndex"}, AddPreviousIndex, {"ID_CARD", "Index"}, "PreviousRow", JoinKind.LeftOuter),
ExpandedTable = Table.ExpandTableColumn(MergedQueries, "PreviousRow", {"latitude", "longitude"}, {"Prev_latitude", "Prev_longitude"}),
AddDistanceColumn = Table.AddColumn(ExpandedTable, "Distance_km", each
let
lat1 = [latitude] * Number.PI / 180,
lon1 = [longitude] * Number.PI / 180,
lat2 = [Prev_latitude] * Number.PI / 180,
lon2 = [Prev_longitude] * Number.PI / 180,
dlat = lat2 - lat1,
dlon = lon2 - lon1,
a = Number.Sin(dlat / 2) * Number.Sin(dlat / 2) + Number.Cos(lat1) * Number.Cos(lat2) * Number.Sin(dlon / 2) * Number.Sin(dlon / 2),
c = 2 * Number.Atan2(Number.Sqrt(a), Number.Sqrt(1 - a)),
R = 6371, // Radius of Earth in kilometers
distance = R * c
in
distance
),
#"Removed Columns" = Table.RemoveColumns(AddDistanceColumn,{"Index", "PreviousIndex", "Prev_latitude", "Prev_longitude"})
in
#"Removed Columns"
If I have misunderstood your question, please feel free to contact me.
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum
Hi @Joaomatos2002, I've already replied to you here with both Power Query and DAX solutions.
Hi @Joaomatos2002, I've already replied to you here with both Power Query and DAX solutions.
Hi @Joaomatos2002 ,
Not sure I understand your question. Please check the M code below:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("hdRLjsMgEATQq4y8TiZU82c3cwpLke9/jQEmUtmQNF5YuCz1E79+Pref7bbt9blfXztC+4H6Ah4mPcSIu3x8GVs8hsgVIzVy+DbtqcN7eg2Pm4K1XDSrFo5ThEgLtKBajdmtbkmeIp9pCS1RrcbsTrNCwWiF4hwtS8uqlltasdhxDVOBoeVouW79frB8y4Nu+TFKxSdanpZX5xWWVno3L3eaV6AVVKuV2aNu9cLnKBfnaUVaUV3DthZ9IT9ZSMWEKbKn+5VoJdXKPdcm1irbKfKBWCaWVayfqBXmhx1DLpanHuwcMDrWW0fWsFrZT9HpOoOtA9AxWfUpMcVgigTE2DsgOmZXjapVHvZM8H8XXhibB/Tmgd49ko6NeyZSDG8Z2D3gdMyv9qxVHmcmlwPC9lGHx/EH", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID_CARD = _t, ID_ACTIVITY = _t, ID_LOCATION = _t, CALDAY = _t, STARTTIME = _t, ENDTIME = _t, latitude = _t, longitude = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"STARTTIME", type datetime}, {"ENDTIME", type datetime}, {"latitude", type number}, {"longitude", type number}}),
#"Sorted Rows" = Table.Sort(#"Changed Type",{{"ID_CARD", Order.Ascending}, {"ENDTIME", Order.Ascending}}),
#"Added Index" = Table.AddIndexColumn(#"Sorted Rows", "Index", 1, 1, Int64.Type),
AddPreviousIndex = Table.AddColumn(#"Added Index", "PreviousIndex", each [Index] - 1),
MergedQueries = Table.NestedJoin(AddPreviousIndex, {"ID_CARD", "PreviousIndex"}, AddPreviousIndex, {"ID_CARD", "Index"}, "PreviousRow", JoinKind.LeftOuter),
ExpandedTable = Table.ExpandTableColumn(MergedQueries, "PreviousRow", {"latitude", "longitude"}, {"Prev_latitude", "Prev_longitude"}),
AddDistanceColumn = Table.AddColumn(ExpandedTable, "Distance_km", each
let
lat1 = [latitude] * Number.PI / 180,
lon1 = [longitude] * Number.PI / 180,
lat2 = [Prev_latitude] * Number.PI / 180,
lon2 = [Prev_longitude] * Number.PI / 180,
dlat = lat2 - lat1,
dlon = lon2 - lon1,
a = Number.Sin(dlat / 2) * Number.Sin(dlat / 2) + Number.Cos(lat1) * Number.Cos(lat2) * Number.Sin(dlon / 2) * Number.Sin(dlon / 2),
c = 2 * Number.Atan2(Number.Sqrt(a), Number.Sqrt(1 - a)),
R = 6371, // Radius of Earth in kilometers
distance = R * c
in
distance
),
#"Removed Columns" = Table.RemoveColumns(AddDistanceColumn,{"Index", "PreviousIndex", "Prev_latitude", "Prev_longitude"})
in
#"Removed Columns"
If I have misunderstood your question, please feel free to contact me.
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum
Please define "local". What is the maximum distance you expect, and where is the geographical center? Usually distances are calculated via the Great Circle formula or Haversine.
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 19 | |
| 9 | |
| 8 | |
| 7 | |
| 7 |