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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
Anonymous
Not applicable

Expanding Dates List to Have Months Start Only

Hi Guys,

 

I seek your support please.

 

I have 2 DateTime columns in my query, they are labelled as: 1) "From" and 2) "To"

 

What I need to do is to create a list which by expanding, I get new column that has the involved months starts.

 

For instance, in case I have entry in "From" Column that got the value: 12/7/2020 12:00:00 Am and entry in "To" Column that got the value: 3/15/2021 12:00:00 AM, so the custom column created from the list should have the entries:

12/1/2020

1/1/2021

2/1/2021

3/1/2021

 

How could I do that?

 

I have a script that could expand for me a custom column by with interval of 1 day each, it is as follows:

 

List.Dates(DateTime.Date([From]),Duration.Days(DateTime.Date([To])- DateTime.Date([From]))+1,Duration.From(1))

1 ACCEPTED SOLUTION
jennratten
Super User
Super User

Here you go.  🙂

jennratten_0-1658836911312.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjTSN9c3MjAyUDA0sjIwACIFx1wlHSVjfUNTkLghkrivUmwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [From = _t, To = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"From", type datetime}, {"To", type datetime}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "ListDates", each List.Distinct(List.Transform ( List.Dates(DateTime.Date([From]),Duration.Days(DateTime.Date([To])- DateTime.Date([From]))+1,Duration.From(1)), each Date.StartOfMonth(_))))
in
    #"Added Custom"

View solution in original post

1 REPLY 1
jennratten
Super User
Super User

Here you go.  🙂

jennratten_0-1658836911312.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjTSN9c3MjAyUDA0sjIwACIFx1wlHSVjfUNTkLghkrivUmwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [From = _t, To = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"From", type datetime}, {"To", type datetime}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "ListDates", each List.Distinct(List.Transform ( List.Dates(DateTime.Date([From]),Duration.Days(DateTime.Date([To])- DateTime.Date([From]))+1,Duration.From(1)), each Date.StartOfMonth(_))))
in
    #"Added Custom"

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel

Power BI Monthly Update - May 2024

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

LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

Top Solution Authors
Top Kudoed Authors