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

Don'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.

Reply
NickDSL
Helper I
Helper I

Extracting start and end dates

Extracting Start and End Dates from a single column based on a set of unique values.
10m ago

Hi I have the following data:

 

ContactIDEffectiveDateTotalPts
4059501/26/202386
40595012/8/202257
4059508/23/2023204
4059508/7/2023129
4059926/23/202378
4059921/15/202362

 

I'm trying to get it in the following format in power query to be transformed/expanded later in the query.

ContactIDStartDateEndDateTotalPts
40595012/8/20221/26/202357
4059501/27/20238/7/202386
4059508/8/20238/23/2023129
4059508/24/2023PRESENTDATE204
4059921/15/20236/23/202362
4059926/24/2023PRESENTDATE78

Where PRESENTDATE is equal to today so in this case it would be equal to 10/3/2023.

 

Looking for a how to here. Or if its even possible.

 

Please note my EffectiveDate ARE NOT ordered. This is how they would appear in the raw data.

 

Thanks.

1 ACCEPTED SOLUTION
lbendlin
Super User
Super User

let
    Convert = (tbl)=>
    let
        #"Sorted Rows" = Table.Sort(tbl,{{"EffectiveDate", Order.Ascending}}),
        #"Added Index" = Table.AddIndexColumn(#"Sorted Rows", "Index", 0, 1, Int64.Type),
        #"Added Custom" = Table.AddColumn(#"Added Index", "StartDate", each if [Index]=0 then [EffectiveDate] else [EffectiveDate]+#duration(1,0,0,0),type date),
        #"Added Custom1" = Table.AddColumn(#"Added Custom", "EndDate", each try #"Added Custom"{[Index]+1}[EffectiveDate] otherwise null,type date)
    in
        #"Added Custom1",
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("XczBCQAhDETRXnIWkowmai1i/20YDy66tw+PmTGoiHUTSqQMZwhydHOa6TZw24Zoq68F5LODlD/WY4r+Wd9Hfg1re01Z7ZiD5lw=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ContactID = _t, EffectiveDate = _t, TotalPts = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ContactID", type text}, {"EffectiveDate", type date}, {"TotalPts", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ContactID"}, {{"Rows", each _, type table [ContactID=nullable text, EffectiveDate=nullable date, TotalPts=nullable number]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Convert([Rows])),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Added Custom", "Custom", {"TotalPts", "StartDate", "EndDate"}, {"TotalPts", "StartDate", "EndDate"}),
    #"Removed Other Columns" = Table.SelectColumns(#"Expanded Custom",{"ContactID", "TotalPts", "StartDate", "EndDate"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Removed Other Columns",{{"TotalPts", Int64.Type}, {"StartDate", type date}, {"EndDate", type date}})
in 
    #"Changed Type1"

How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done".

View solution in original post

1 REPLY 1
lbendlin
Super User
Super User

let
    Convert = (tbl)=>
    let
        #"Sorted Rows" = Table.Sort(tbl,{{"EffectiveDate", Order.Ascending}}),
        #"Added Index" = Table.AddIndexColumn(#"Sorted Rows", "Index", 0, 1, Int64.Type),
        #"Added Custom" = Table.AddColumn(#"Added Index", "StartDate", each if [Index]=0 then [EffectiveDate] else [EffectiveDate]+#duration(1,0,0,0),type date),
        #"Added Custom1" = Table.AddColumn(#"Added Custom", "EndDate", each try #"Added Custom"{[Index]+1}[EffectiveDate] otherwise null,type date)
    in
        #"Added Custom1",
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("XczBCQAhDETRXnIWkowmai1i/20YDy66tw+PmTGoiHUTSqQMZwhydHOa6TZw24Zoq68F5LODlD/WY4r+Wd9Hfg1re01Z7ZiD5lw=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ContactID = _t, EffectiveDate = _t, TotalPts = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ContactID", type text}, {"EffectiveDate", type date}, {"TotalPts", Int64.Type}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ContactID"}, {{"Rows", each _, type table [ContactID=nullable text, EffectiveDate=nullable date, TotalPts=nullable number]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Custom", each Convert([Rows])),
    #"Expanded Custom" = Table.ExpandTableColumn(#"Added Custom", "Custom", {"TotalPts", "StartDate", "EndDate"}, {"TotalPts", "StartDate", "EndDate"}),
    #"Removed Other Columns" = Table.SelectColumns(#"Expanded Custom",{"ContactID", "TotalPts", "StartDate", "EndDate"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Removed Other Columns",{{"TotalPts", Int64.Type}, {"StartDate", type date}, {"EndDate", type date}})
in 
    #"Changed Type1"

How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done".

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!

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.