- Subscribe to RSS Feed
- Mark Topic as New
- Mark Topic as Read
- Float this Topic for Current User
- Bookmark
- Subscribe
- Printer Friendly Page

- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content

Most recent calculation
Dear all,
I am looking for a calculation which does the following:
If the STACK is the same and the TYPE is the same and the DATE is the same, calculate the MOST_RECENT_TIME_STAMP.
In below example the outcome is is 23-10-2020 08:00.
Thanks!
John
stack | position | type | date | time_stamp | most_recent_time_Stamp |
WP2 | WP2.12 | Waiting Estimate | 23-10-2020 | 23-10-2020 08:00 | 23-10-2020 08:00 |
WP2 | WP2.11 | Waiting Estimate | 23-10-2020 | 23-10-2020 08:00 | 23-10-2020 08:00 |
WP2 | WP2.10 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:59 | 23-10-2020 08:00 |
WP2 | WP2.09 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:59 | 23-10-2020 08:00 |
WP2 | WP2.08 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:59 | 23-10-2020 08:00 |
WP2 | WP2.07 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:58 | 23-10-2020 08:00 |
WP2 | WP2.06 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:58 | 23-10-2020 08:00 |
WP2 | WP2.05 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:58 | 23-10-2020 08:00 |
WP2 | WP2.04 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:57 | 23-10-2020 08:00 |
WP2 | WP2.03 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:57 | 23-10-2020 08:00 |
WP2 | WP2.02 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:57 | 23-10-2020 08:00 |
WP2 | WP2.01 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:56 | 23-10-2020 08:00 |
WP2 | WP2.12 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:28 | 23-10-2020 08:00 |
WP2 | WP2.13 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:27 | 23-10-2020 08:00 |
WP2 | WP2.14 | Waiting Estimate | 23-10-2020 | 23-10-2020 07:27 | 23-10-2020 08:00 |
Solved! Go to Solution.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
@Anonymous ,
In Power Query, go to New Source>Blank Query then in Advanced Editor paste my code over the default code. You can then follow the steps I took to complete this.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCg8wUtIBkXqGYEZiZklmXrqCa3FJZm5iSSpQyMhY19BA18jAyACFo2BgYWWAVShWB8VYQ9oYa0CiseZWppaEjTWwpI2xFrQx1px0Yy2IMNaMNsaa0sZYE9KNNSfCWGPaGEtqLiPSWFJzGdBYMyJyGemuNSIiygxJD1sjIgLBkPSUgMPYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [stack = _t, position = _t, #"type" = _t, date = _t, time_stamp = _t, most_recent_time_Stamp = _t]),
chgSourceTypes = Table.TransformColumnTypes(Source,{{"stack", type text}, {"position", type text}, {"type", type text}, {"date", type date}, {"time_stamp", type datetime}, {"most_recent_time_Stamp", type datetime}}),
groupWithData = Table.Group(chgSourceTypes, {"stack", "type", "date"}, {{"data", each _, type table [stack=nullable text, position=nullable text, type=nullable text, date=nullable date, time_stamp=nullable datetime, most_recent_time_Stamp=nullable datetime]}, {"calcMostRecent", each List.Max([time_stamp]), type nullable datetime}}),
expandDataCol = Table.ExpandTableColumn(groupWithData, "data", {"position", "time_stamp", "most_recent_time_Stamp"}, {"position", "time_stamp", "most_recent_time_Stamp"})
in
expandDataCol
This will need to be tested on a more diverse dataset as the example data provided only seemed to include one relevant grouping, but it should work fine.
Let me know if you have any trouble applying this solution to your actual data.
Pete
Now accepting Kudos! If my post helped you, why not give it a thumbs-up?
Proud to be a Datanaut!
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
@Anonymous ,
In Power Query, go to New Source>Blank Query then in Advanced Editor paste my code over the default code. You can then follow the steps I took to complete this.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCg8wUtIBkXqGYEZiZklmXrqCa3FJZm5iSSpQyMhY19BA18jAyACFo2BgYWWAVShWB8VYQ9oYa0CiseZWppaEjTWwpI2xFrQx1px0Yy2IMNaMNsaa0sZYE9KNNSfCWGPaGEtqLiPSWFJzGdBYMyJyGemuNSIiygxJD1sjIgLBkPSUgMPYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [stack = _t, position = _t, #"type" = _t, date = _t, time_stamp = _t, most_recent_time_Stamp = _t]),
chgSourceTypes = Table.TransformColumnTypes(Source,{{"stack", type text}, {"position", type text}, {"type", type text}, {"date", type date}, {"time_stamp", type datetime}, {"most_recent_time_Stamp", type datetime}}),
groupWithData = Table.Group(chgSourceTypes, {"stack", "type", "date"}, {{"data", each _, type table [stack=nullable text, position=nullable text, type=nullable text, date=nullable date, time_stamp=nullable datetime, most_recent_time_Stamp=nullable datetime]}, {"calcMostRecent", each List.Max([time_stamp]), type nullable datetime}}),
expandDataCol = Table.ExpandTableColumn(groupWithData, "data", {"position", "time_stamp", "most_recent_time_Stamp"}, {"position", "time_stamp", "most_recent_time_Stamp"})
in
expandDataCol
This will need to be tested on a more diverse dataset as the example data provided only seemed to include one relevant grouping, but it should work fine.
Let me know if you have any trouble applying this solution to your actual data.
Pete
Now accepting Kudos! If my post helped you, why not give it a thumbs-up?
Proud to be a Datanaut!
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Hi @Anonymous ,
You said you need a calculation to do this. Do you specifically need this done in DAX, or would a Power Query/M solution suit?
Pete
Now accepting Kudos! If my post helped you, why not give it a thumbs-up?
Proud to be a Datanaut!
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
HI @BA_Pete ,
Well, I am not an expert, but lets give it a try in Power Query/ M 😀
Thanks upfront for your help!
John

Helpful resources
Join us at the Microsoft Fabric Community Conference
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Power BI Monthly Update - February 2025
Check out the February 2025 Power BI update to learn about new features.

Subject | Author | Posted | |
---|---|---|---|
05-01-2024 01:27 AM | |||
10-24-2024 08:57 PM | |||
11-01-2024 09:53 AM | |||
11-13-2024 10:51 AM | |||
01-29-2025 04:51 AM |
User | Count |
---|---|
87 | |
81 | |
53 | |
37 | |
35 |