Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
Hello community!
So I am looking to create a new column that is based on Individual Client IDS and the first known date of the assessment. I am hoping to take these two variables and then the end goal be "Initial" or "reassessment" as the new column labels based on each Client. However, I'm finding it hard to figure out exactly how to create this code for this.
So what I have now is this:
The end goal would look like this:
Any help would be greatly appreciated! Thank you!
Solved! Go to Solution.
You can group by ClientID and take the min over the date column to find the Initial dates. Then merge that back with the original query and add a custom column that returns different results if the date equals the initial date.
Here's a full sample query you can paste into the Advanced Editor of a new blank query:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("VczLCQAgEAPRXnIWYlZFrUW2/zb8HcTrg5kxIASIirSoDg9XGtMC0wFbkKkfKmWvSfsili0N7hM=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ClientID = _t, LastPRAPAREDate = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ClientID", Int64.Type}, {"LastPRAPAREDate", type date}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"ClientID"}, {{"InitialDate", each List.Min([LastPRAPAREDate]), type nullable date}}),
#"Merged Queries" = Table.NestedJoin(#"Changed Type", {"ClientID"}, #"Grouped Rows", {"ClientID"}, "Grouped Rows", JoinKind.LeftOuter),
#"Expanded Grouped Rows" = Table.ExpandTableColumn(#"Merged Queries", "Grouped Rows", {"InitialDate"}, {"InitialDate"}),
#"Added Custom" = Table.AddColumn(#"Expanded Grouped Rows", "AssementType", each if [LastPRAPAREDate] = [InitialDate] then "Initial" else "Reassessment", type text)
in
#"Added Custom"
You can group by ClientID and take the min over the date column to find the Initial dates. Then merge that back with the original query and add a custom column that returns different results if the date equals the initial date.
Here's a full sample query you can paste into the Advanced Editor of a new blank query:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("VczLCQAgEAPRXnIWYlZFrUW2/zb8HcTrg5kxIASIirSoDg9XGtMC0wFbkKkfKmWvSfsili0N7hM=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ClientID = _t, LastPRAPAREDate = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ClientID", Int64.Type}, {"LastPRAPAREDate", type date}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"ClientID"}, {{"InitialDate", each List.Min([LastPRAPAREDate]), type nullable date}}),
#"Merged Queries" = Table.NestedJoin(#"Changed Type", {"ClientID"}, #"Grouped Rows", {"ClientID"}, "Grouped Rows", JoinKind.LeftOuter),
#"Expanded Grouped Rows" = Table.ExpandTableColumn(#"Merged Queries", "Grouped Rows", {"InitialDate"}, {"InitialDate"}),
#"Added Custom" = Table.AddColumn(#"Expanded Grouped Rows", "AssementType", each if [LastPRAPAREDate] = [InitialDate] then "Initial" else "Reassessment", type text)
in
#"Added Custom"
That worked like a charm!!! Thanks so much!!!
User | Count |
---|---|
19 | |
10 | |
10 | |
9 | |
7 |
User | Count |
---|---|
23 | |
19 | |
16 | |
13 | |
11 |