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

View all the Fabric Data Days sessions on demand. View schedule

Reply
Zabeer
Helper I
Helper I

create date value for each row in a table

Hello,

I have a table in the below format:

NameValue
A36000
B48000

I would like to create a new date column using Power Query giving me an end result like this:

Name ValueDate
A3600001/01/2021
A3600001/02/2021
A3600001/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.

3 ACCEPTED SOLUTIONS
HotChilli
Super User
Super User

 

 

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

View solution in original post

Jimmy801
Community Champion
Community Champion

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

Jimmy801_0-1614756690209.png

 

into this

Jimmy801_1-1614756701167.png

 

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

 

View solution in original post

Icey
Community Support
Community Support

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"

dayslist.JPG

days list.JPG

 

 

Best Regards,

Icey

 

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
Icey
Community Support
Community Support

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"

dayslist.JPG

days list.JPG

 

 

Best Regards,

Icey

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Jimmy801
Community Champion
Community Champion

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

Jimmy801_0-1614756690209.png

 

into this

Jimmy801_1-1614756701167.png

 

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

 

HotChilli
Super User
Super User

 

 

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

Helpful resources

Announcements
November Power BI Update Carousel

Power BI Monthly Update - November 2025

Check out the November 2025 Power BI update to learn about new features.

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.