Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon'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.
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))
Solved! Go to Solution.
Here you go. 🙂
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"
If this post helps to answer your questions, please consider marking it as a solution so others can find it more quickly when faced with a similar challenge.
Proud to be a Microsoft Fabric Super User
Here you go. 🙂
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"
If this post helps to answer your questions, please consider marking it as a solution so others can find it more quickly when faced with a similar challenge.
Proud to be a Microsoft Fabric Super User
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
21 | |
20 | |
10 | |
10 | |
10 |