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
OAkanbi
Frequent Visitor

Transforming a Single Column into Two Dates - Start and End

Hi There,


I'm having trouble converting a single column into a start and end date column using power query. The sticking point is that the column Status is used as an indicator for the end date. Here's what the data looks like.


Customer Date Status Overall_Rank Granular_rank
A 01/06/2021 Opt-In 1 1
A 10/06/2021 Opt-In 2 2
A 15/06/2021 OptOut 3 1
A 20/06/2021 Opt-In 4 3
A 30/06/2021 OptOut 5 2


I want to eventually arrive at this:


Customer StartDate EndDate
A 01/06/2021 15/06/2021
A 20/06/2021 30/06/2021


Any Ideas?


Jimmy

1 ACCEPTED SOLUTION
CNENFRNL
Community Champion
Community Champion

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTIw1Dcw0zcyMDIEcvwLSnQ984AMQzCO1YGoMTTApsYIjOFqTFHV+JeWABnGKOYYYTXHBKwOpsbYAJs5phC7YgE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Date = _t, Status = _t, Overall_Rank = _t, Granular_rank = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Overall_Rank", Int64.Type}}),
    Pos = List.Transform(List.PositionOf(#"Changed Type"[Status], "out", Occurrence.All, (x,y) => Text.Contains(x, y, Comparer.OrdinalIgnoreCase)), each _+2),
    Grouped = Table.Group(#"Changed Type", {"Customer", "Overall_Rank"}, {"ar", each let l=[Date] in [Start=l{0}, End=List.Last(l)]}, 0, (x,y) => Number.From(List.Contains(Pos, y[Overall_Rank]))),
    #"Expanded ar" = Table.RemoveColumns(Table.ExpandRecordColumn(Grouped, "ar", {"Start", "End"}, {"Start", "End"}), "Overall_Rank")
in
    #"Expanded ar"

Screenshot 2021-06-16 170858.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

View solution in original post

3 REPLIES 3
CNENFRNL
Community Champion
Community Champion

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTIw1Dcw0zcyMDIEcvwLSnQ984AMQzCO1YGoMTTApsYIjOFqTFHV+JeWABnGKOYYYTXHBKwOpsbYAJs5phC7YgE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Date = _t, Status = _t, Overall_Rank = _t, Granular_rank = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Overall_Rank", Int64.Type}}),
    Pos = List.Transform(List.PositionOf(#"Changed Type"[Status], "out", Occurrence.All, (x,y) => Text.Contains(x, y, Comparer.OrdinalIgnoreCase)), each _+2),
    Grouped = Table.Group(#"Changed Type", {"Customer", "Overall_Rank"}, {"ar", each let l=[Date] in [Start=l{0}, End=List.Last(l)]}, 0, (x,y) => Number.From(List.Contains(Pos, y[Overall_Rank]))),
    #"Expanded ar" = Table.RemoveColumns(Table.ExpandRecordColumn(Grouped, "ar", {"Start", "End"}, {"Start", "End"}), "Overall_Rank")
in
    #"Expanded ar"

Screenshot 2021-06-16 170858.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Perfect. Brilliant.

CNENFRNL
Community Champion
Community Champion

Here's a generic solution to your senario, which leverage an index column instead of Overall_Rank.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTIw1Dcw0zcyMDIEcvwLSnQ985RidSByhgZ45ExR5fxLS+ByRnj0GRtg0RcLAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Date = _t, Status = _t]),
    #"Added Index" = Table.AddIndexColumn(Source, "Index", 0, 1, Int64.Type),
    Pos = List.Transform(List.PositionOf(#"Added Index"[Status], "out", Occurrence.All, (x,y) => Text.Contains(x, y, Comparer.OrdinalIgnoreCase)), each _+1),
    Grouped = Table.Group(#"Added Index", {"Customer", "Index"}, {"ar", each let l=[Date] in [Start=l{0}, End=List.Last(l)]}, 0, (x,y) => Number.From(List.Contains(Pos, y[Index]))),
    #"Expanded ar" = Table.RemoveColumns(Table.ExpandRecordColumn(Grouped, "ar", {"Start", "End"}, {"Start", "End"}), "Index")
in
    #"Expanded ar"

Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

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.

Top Solution Authors
Top Kudoed Authors