Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
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.
@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
Proud to be a Datanaut!
@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
Proud to be a Datanaut!
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
Proud to be a Datanaut!
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
User | Count |
---|---|
116 | |
73 | |
58 | |
49 | |
48 |
User | Count |
---|---|
171 | |
122 | |
60 | |
59 | |
56 |