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
ErikBI
Resolver I
Resolver I

Creating multiple date tables in one table

Hey guys,

 

I have this certain thing I'm trying to create, but I lack the skills for it. It's hard to exlain in the title, so Ill try to be as clear as possible with my data below:

 

My input data looks like this:

Phase is just a code for a project. Start and end mark the start and end date of said phase.

ErikBI_0-1593688183375.png

 

 

 

What I'm trying to achieve is a date table that looks like this, where a row is created for each day between the start and end per phase. So for phase A I'd have 356 rows created for each day of the year, and after that it goes on to phase B where it creates a row for each day between 1-5-2019 and 31-12-2019, etc.

ErikBI_1-1593688191850.png

 

 

I recently learned how to create a date table, but this phase thing adds an element that is beyond my skill level. I hope some someone knows how to achieve this, because it will help me a lot!

 

Thanks!

1 ACCEPTED SOLUTION
v-easonf-msft
Community Support
Community Support

Hi , @ErikBI 

Click New source ->create  a blank query->advanced Editor

Then paste following M code:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTLUN9Q3MjC0BDGN9I2hnFidaCUnoJAppqyRAVjWGbteqKwLUMhc38gIJm2qb2SJkHXFK+uGJovmLHe8mj3wynrilfXCK+uNWzYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Phase = _t, start = _t, end = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Phase", type text}, {"start", type date}, {"end", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Duration.TotalDays(Date.StartOfDay([end])-Date.StartOfDay([start]))),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Custom.1", each List.Generate(()=>[Custom], each _ >= 0, each _ - 1)),
    #"Expanded Custom.1" = Table.ExpandListColumn(#"Added Custom1", "Custom.1"),
    #"Added Custom2" = Table.AddColumn(#"Expanded Custom.1", "Date", each if [Custom.1]=[Custom] then [start] else  Date.AddDays(Date.StartOfDay([start]),[Custom]-[Custom.1])),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom2",{"start", "end", "Custom", "Custom.1"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Removed Columns",{{"Date", type date}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type1",{{"Phase", Order.Ascending}, {"Date", Order.Ascending}})
in
    #"Sorted Rows"

 For more detail, please double click the step  in "APPLIED STEPS".

90.png

 

sample pbix attached

 

Best Regards,
Community Support Team _ Eason
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
v-easonf-msft
Community Support
Community Support

Hi , @ErikBI 

Click New source ->create  a blank query->advanced Editor

Then paste following M code:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTLUN9Q3MjC0BDGN9I2hnFidaCUnoJAppqyRAVjWGbteqKwLUMhc38gIJm2qb2SJkHXFK+uGJovmLHe8mj3wynrilfXCK+uNWzYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Phase = _t, start = _t, end = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Phase", type text}, {"start", type date}, {"end", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Duration.TotalDays(Date.StartOfDay([end])-Date.StartOfDay([start]))),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Custom.1", each List.Generate(()=>[Custom], each _ >= 0, each _ - 1)),
    #"Expanded Custom.1" = Table.ExpandListColumn(#"Added Custom1", "Custom.1"),
    #"Added Custom2" = Table.AddColumn(#"Expanded Custom.1", "Date", each if [Custom.1]=[Custom] then [start] else  Date.AddDays(Date.StartOfDay([start]),[Custom]-[Custom.1])),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom2",{"start", "end", "Custom", "Custom.1"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Removed Columns",{{"Date", type date}}),
    #"Sorted Rows" = Table.Sort(#"Changed Type1",{{"Phase", Order.Ascending}, {"Date", Order.Ascending}})
in
    #"Sorted Rows"

 For more detail, please double click the step  in "APPLIED STEPS".

90.png

 

sample pbix attached

 

Best Regards,
Community Support Team _ Eason
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Brilliant! it took a bit of fiddling with the advanced editor to adjust the source data, but it seems to work perfectly now.

 

Thanks!

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.