Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

The 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.

Reply
viwinski7
Frequent Visitor

Creating Conditional Date Column based on Individual Client ID Variable

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: 

 

viwinski7_0-1645558492123.png

The end goal would look like this: 

viwinski7_1-1645558554672.png

 

Any help would be greatly appreciated! Thank you! 

 

1 ACCEPTED SOLUTION
AlexisOlson
Super User
Super User

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"

 

AlexisOlson_0-1645560041707.png

View solution in original post

2 REPLIES 2
AlexisOlson
Super User
Super User

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"

 

AlexisOlson_0-1645560041707.png

That worked like a charm!!! Thanks so much!!! 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

FebPBI_Carousel

Power BI Monthly Update - February 2025

Check out the February 2025 Power BI update to learn about new features.

Feb2025 NL Carousel

Fabric Community Update - February 2025

Find out what's new and trending in the Fabric community.