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
Anonymous
Not applicable

Extracting from column data to rows

I have 2 date columns (begin and end) with other attribute columns (attr1/2/3) that I need to expand out on dependent on begin and end date. The last date range in the series happens over 3 days and I need 1 day per row. How to do in Power Query.

 

I have tried to add columns and caculate out but I cannot get there

 

Before

Begin,End,Attr1,Attr2,Attr3
1/1/2020,1/1/2020,a,b,c
1/2/2020,1/2/2020,a,b,c
1/3/2020,1/5/2020,a,b,d

 

After

EventDate,Attr1,Attr2,Attr3
1/1/2020,a,b,c
1/2/2020,a,b,c
1/3/2020,a,b,d
1/4/2020,a,b,d
1/5/2020,a,b,d

 

Thanks in advance

1 ACCEPTED SOLUTION
camargos88
Community Champion
Community Champion

@Anonymous ,

 

Try this mcode:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtQ31DcyMDLQgTMSdZJ0kpVidUByRjA5I0w5Y5icKUIuRSk2FgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Begin,End,Attr1,Attr2,Attr3" = _t]),
    #"Demoted Headers" = Table.DemoteHeaders(Source),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Demoted Headers", "Column1", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Column1.1", "Column1.2", "Column1.3", "Column1.4", "Column1.5"}),
    #"Promoted Headers" = Table.PromoteHeaders(#"Split Column by Delimiter", [PromoteAllScalars=true]),
    #"Changed Type3" = Table.TransformColumnTypes(#"Promoted Headers",{{"Attr1", type text}, {"Attr2", type text}, {"Attr3", type text}}),
    #"Changed Type with Locale" = Table.TransformColumnTypes(#"Changed Type3", {{"Begin", type date}, {"End", type date}}, "en-US"),
    #"Added Custom" = Table.AddColumn(#"Changed Type with Locale", "Custom", each List.Dates(
    [Begin],
    Duration.TotalDays([End] - [Begin]) + 1,
    #duration(1,0,0,0)
)),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Custom",{"Begin", "End"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Custom", "EventDate"}}),
    #"Changed Type" = Table.TransformColumnTypes(#"Renamed Columns",{{"Attr1", type text}, {"Attr2", type text}, {"Attr3", type text}, {"EventDate", type date}})
in
    #"Changed Type"

 

Capture.PNG



Did I answer your question? Mark my post as a solution!

Proud to be a Super User!



View solution in original post

2 REPLIES 2
ziying35
Impactful Individual
Impactful Individual

Hi, @Anonymous try the code below:

// output
let
    Source = Table.FromRecords(Json.Document(Binary.Decompress(Binary.FromText("i65WckpNz8xTslIyjNEHIiMDIwMlHSXXvBR0IceSkiJDoGAilG0EZCdB2cZAdrJSrQ6KaUaYphmRb5oxpmmmRJuWolQbCwA=", BinaryEncoding.Base64),Compression.Deflate))),
    fx = (row)=> List.Generate(()=>Date.From(row{0}), each _<= Date.From(row{1}), each Date.AddDays(_, 1), each {_}&List.Skip(row,2)),
    rows = Table.ToRows(Source),
    n = List.Count(rows),
    gen = List.Generate(()=>{null, {}}, each (_{0}<n)??true, each let i = _{0}+1??0 in {i, fx(rows{i})}, each _{1}),
    result = Table.FromRows(List.Combine(gen), {"EventDate"}&List.Skip(Table.ColumnNames(Source), 2))
in
    result

 

camargos88
Community Champion
Community Champion

@Anonymous ,

 

Try this mcode:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtQ31DcyMDLQgTMSdZJ0kpVidUByRjA5I0w5Y5icKUIuRSk2FgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Begin,End,Attr1,Attr2,Attr3" = _t]),
    #"Demoted Headers" = Table.DemoteHeaders(Source),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Demoted Headers", "Column1", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Column1.1", "Column1.2", "Column1.3", "Column1.4", "Column1.5"}),
    #"Promoted Headers" = Table.PromoteHeaders(#"Split Column by Delimiter", [PromoteAllScalars=true]),
    #"Changed Type3" = Table.TransformColumnTypes(#"Promoted Headers",{{"Attr1", type text}, {"Attr2", type text}, {"Attr3", type text}}),
    #"Changed Type with Locale" = Table.TransformColumnTypes(#"Changed Type3", {{"Begin", type date}, {"End", type date}}, "en-US"),
    #"Added Custom" = Table.AddColumn(#"Changed Type with Locale", "Custom", each List.Dates(
    [Begin],
    Duration.TotalDays([End] - [Begin]) + 1,
    #duration(1,0,0,0)
)),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Custom",{"Begin", "End"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Custom", "EventDate"}}),
    #"Changed Type" = Table.TransformColumnTypes(#"Renamed Columns",{{"Attr1", type text}, {"Attr2", type text}, {"Attr3", type text}, {"EventDate", type date}})
in
    #"Changed Type"

 

Capture.PNG



Did I answer your question? Mark my post as a solution!

Proud to be a Super User!



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