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.
Hello,
I have a table in the below format:
Name | Value |
A | 36000 |
B | 48000 |
I would like to create a new date column using Power Query giving me an end result like this:
Name | Value | Date |
A | 36000 | 01/01/2021 |
A | 36000 | 01/02/2021 |
A | 36000 | 01/03/2021 |
.... and so on for each of the months in 2021 and for each of the 'Name'
How do I achieve this on Power Query?
Thanks for your support.
Solved! Go to Solution.
Create a new Blank Query with
= List.Dates(#date(2021,01,01), 365, #duration(1,0,0,0))
That will give you a list of dates. Give it a name.
Convert to table.
Change to date type.
Filter the dates with :
= Table.SelectRows(#"Changed Type", each Date.Day([Column1]) = 1)
(substitute your step name and column name in that)
---
In the original table, Add a custom column (type # and the name of the query should autocomplete)
Then expand the column from the column header.
Good luck
Hello @Zabeer
add a new column with this formula
List.Transform(List.Numbers(1,12), each #date(2021,_,1))
and then expand the list-column to new rows. Here the complete example
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTI2MzAwUIrViVZyAvJMLMC8WAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, Value = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Value", Int64.Type}}),
AddMonths = Table.AddColumn
(
#"Changed Type",
"MonthsList",
each List.Transform(List.Numbers(1,12), each #date(2021,_,1))
),
#"Expanded MonthsList" = Table.ExpandListColumn(AddMonths, "MonthsList")
in
#"Expanded MonthsList"
this transforms this
into this
Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
Hi @Zabeer ,
If you also want to add each days of each months, please try this:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTI2MzAwUIrViVZyAvJMLMC8WAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, Value = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Value", Int64.Type}}),
AddDays = Table.AddColumn(#"Changed Type", "DaysList", each let
StartDate = #date(2021,01,01),
EndDate = #date(2021,12,31),
DurationDays = Duration.Days( EndDate-StartDate)
in
List.Dates(StartDate, DurationDays, #duration(1,0,0,0))),
#"Expanded DaysList" = Table.ExpandListColumn(AddDays, "DaysList")
in
#"Expanded DaysList"
Best Regards,
Icey
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Zabeer ,
If you also want to add each days of each months, please try this:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTI2MzAwUIrViVZyAvJMLMC8WAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, Value = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Value", Int64.Type}}),
AddDays = Table.AddColumn(#"Changed Type", "DaysList", each let
StartDate = #date(2021,01,01),
EndDate = #date(2021,12,31),
DurationDays = Duration.Days( EndDate-StartDate)
in
List.Dates(StartDate, DurationDays, #duration(1,0,0,0))),
#"Expanded DaysList" = Table.ExpandListColumn(AddDays, "DaysList")
in
#"Expanded DaysList"
Best Regards,
Icey
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hello @Zabeer
add a new column with this formula
List.Transform(List.Numbers(1,12), each #date(2021,_,1))
and then expand the list-column to new rows. Here the complete example
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTI2MzAwUIrViVZyAvJMLMC8WAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, Value = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Value", Int64.Type}}),
AddMonths = Table.AddColumn
(
#"Changed Type",
"MonthsList",
each List.Transform(List.Numbers(1,12), each #date(2021,_,1))
),
#"Expanded MonthsList" = Table.ExpandListColumn(AddMonths, "MonthsList")
in
#"Expanded MonthsList"
this transforms this
into this
Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
Create a new Blank Query with
= List.Dates(#date(2021,01,01), 365, #duration(1,0,0,0))
That will give you a list of dates. Give it a name.
Convert to table.
Change to date type.
Filter the dates with :
= Table.SelectRows(#"Changed Type", each Date.Day([Column1]) = 1)
(substitute your step name and column name in that)
---
In the original table, Add a custom column (type # and the name of the query should autocomplete)
Then expand the column from the column header.
Good luck
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.