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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
radu92
Helper I
Helper I

Choose second row per group

I have the following data: 

 

Case no. Activity typeDate
1New01-01-2016
1update02-01-2016
1update03-01-2016
1update03-01-2016
2new05-01-2016
2update05-01-2016
2update07-01-2016

 

I would like to create two new columns:

1.) FirstUpdateDate column should have the date of the first update for the specific case 

2.) SecondUpdateDate collumn should have the date of the second update, if available, otherwise null

 

Thanks in advance! 

2 ACCEPTED SOLUTIONS
ImkeF
Super User
Super User

This is one option:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUfJLLQeSBoZ6QGRkYGimFKsDkSgtSEksSQXJGeGRMyZazggolAexzBRDAqEJn5w5ipwxwkATDAmsBsYCAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"Case no. " = _t, #"Activity type" = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Case no. ", Int64.Type}, {"Activity type", type text}, {"Date", type date}}),
    FilterOnlyUpdate = Table.SelectRows(#"Changed Type", each ([Activity type] = "update")),
    GroupOnCaseNo = Table.Group(FilterOnlyUpdate, {"Case no. "}, {{"Partition", each _[Date], type table}}),
    FirstUpdate = Table.AddColumn(GroupOnCaseNo, "FirstUpdate", each List.First([Partition])),
    SecondUpdate = Table.AddColumn(FirstUpdate, "SecondUpdate", each try List.Range(List.FirstN([Partition],2),1){0} otherwise null),
    MergeWithStepChangedType = Table.NestedJoin(#"Changed Type",{"Case no. "},SecondUpdate,{"Case no. "},"NewColumn",JoinKind.LeftOuter),
    ExpandDesiredColumns = Table.ExpandTableColumn(MergeWithStepChangedType, "NewColumn", {"FirstUpdate", "SecondUpdate"}, {"FirstUpdate", "SecondUpdate"})
in
    ExpandDesiredColumns

You have to replace the Source-step by the reference to your table.

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

View solution in original post

v-sihou-msft
Employee
Employee

@radu92

 

In this scenario, to get the second update date, you need to give an index column for dates wihtin each Case Number and Actuvity Type group. Then you can get the first and second update date based on this index column. Please refer to steps below:

 

1. Create a date value column (integer).

 

87.PNG

 

2. Create an index column with RANKX() function.

 

Rank within Group = RANKX(FILTER(Table6,Table6[Case no. ]=EARLIER(Table6[Case no. ])&&Table6[Activity type]=EARLIER(Table6[Activity type])),Table6[Date Value],,ASC)

88.PNG

 

3. Create two measures to get the first and second update date.

 

First Update = CALCULATE(MIN(Table6[Date]),FILTER(Table6,Table6[Rank within Group]=1 && Table6[Activity type]="update"))
Second Update = CALCULATE(MIN(Table6[Date]),FILTER(Table6,Table6[Rank within Group]=2 && Table6[Activity type]="update"))

89.PNG

 

 

Regards,

View solution in original post

3 REPLIES 3
v-sihou-msft
Employee
Employee

@radu92

 

In this scenario, to get the second update date, you need to give an index column for dates wihtin each Case Number and Actuvity Type group. Then you can get the first and second update date based on this index column. Please refer to steps below:

 

1. Create a date value column (integer).

 

87.PNG

 

2. Create an index column with RANKX() function.

 

Rank within Group = RANKX(FILTER(Table6,Table6[Case no. ]=EARLIER(Table6[Case no. ])&&Table6[Activity type]=EARLIER(Table6[Activity type])),Table6[Date Value],,ASC)

88.PNG

 

3. Create two measures to get the first and second update date.

 

First Update = CALCULATE(MIN(Table6[Date]),FILTER(Table6,Table6[Rank within Group]=1 && Table6[Activity type]="update"))
Second Update = CALCULATE(MIN(Table6[Date]),FILTER(Table6,Table6[Rank within Group]=2 && Table6[Activity type]="update"))

89.PNG

 

 

Regards,

Thank you both for your help! It's exactly what I was looking for! Smiley Very Happy

ImkeF
Super User
Super User

This is one option:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUfJLLQeSBoZ6QGRkYGimFKsDkSgtSEksSQXJGeGRMyZazggolAexzBRDAqEJn5w5ipwxwkATDAmsBsYCAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [#"Case no. " = _t, #"Activity type" = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Case no. ", Int64.Type}, {"Activity type", type text}, {"Date", type date}}),
    FilterOnlyUpdate = Table.SelectRows(#"Changed Type", each ([Activity type] = "update")),
    GroupOnCaseNo = Table.Group(FilterOnlyUpdate, {"Case no. "}, {{"Partition", each _[Date], type table}}),
    FirstUpdate = Table.AddColumn(GroupOnCaseNo, "FirstUpdate", each List.First([Partition])),
    SecondUpdate = Table.AddColumn(FirstUpdate, "SecondUpdate", each try List.Range(List.FirstN([Partition],2),1){0} otherwise null),
    MergeWithStepChangedType = Table.NestedJoin(#"Changed Type",{"Case no. "},SecondUpdate,{"Case no. "},"NewColumn",JoinKind.LeftOuter),
    ExpandDesiredColumns = Table.ExpandTableColumn(MergeWithStepChangedType, "NewColumn", {"FirstUpdate", "SecondUpdate"}, {"FirstUpdate", "SecondUpdate"})
in
    ExpandDesiredColumns

You have to replace the Source-step by the reference to your table.

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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