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

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
barbaracruvinel
Frequent Visitor

Create a new table with monthly dates and other repeated lines in Power BI

I have a data that has CNPJ information,
Region, Inicial Date, Final Date and other information, like this:

barbaracruvinel_1-1628109437035.png

And I need a column with all monthly dates on the first day of the month of each month to be created for each month from the start date to the end, repeating the other columns, like this:

 

barbaracruvinel_2-1628109518780.png

Does anyone know how I can create a new table, like in the second photo, based on the data that is in the first photo?

 

Helppppp, please

 

 

1 ACCEPTED SOLUTION
Ashish_Mathur
Super User
Super User

Hi,

This M code works

let
    Source = Excel.CurrentWorkbook(){[Name="Data"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"CNPJ", Int64.Type}, {"Region", type text}, {"Value", Int64.Type}, {"User", type text}, {"Initial Date", type date}, {"Final Date", type date}}),
    #"Duplicated Column" = Table.DuplicateColumn(#"Changed Type", "Initial Date", "Initial Date - Copy"),
    #"Calculated Start of Month" = Table.TransformColumns(#"Duplicated Column",{{"Initial Date - Copy", Date.StartOfMonth, type datetime}}),
    #"Duplicated Column1" = Table.DuplicateColumn(#"Calculated Start of Month", "Final Date", "Final Date - Copy"),
    #"Calculated Start of Month1" = Table.TransformColumns(#"Duplicated Column1",{{"Final Date - Copy", Date.StartOfMonth, type datetime}}),
    #"Added Custom" = Table.AddColumn(#"Calculated Start of Month1", "Mensal Date", each {Number.From([#"Initial Date - Copy"])..Number.From([#"Final Date - Copy"])}),
    #"Expanded Mensal Date" = Table.ExpandListColumn(#"Added Custom", "Mensal Date"),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Mensal Date",{"Initial Date - Copy", "Final Date - Copy"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Removed Columns",{{"Mensal Date", type date}}),
    #"Reordered Columns" = Table.ReorderColumns(#"Changed Type1",{"Mensal Date", "CNPJ", "Region", "Value", "User", "Initial Date", "Final Date"})
in
    #"Reordered Columns"

Hope this helps.

Untitled.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

View solution in original post

5 REPLIES 5
Ashish_Mathur
Super User
Super User

Hi,

This M code works

let
    Source = Excel.CurrentWorkbook(){[Name="Data"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"CNPJ", Int64.Type}, {"Region", type text}, {"Value", Int64.Type}, {"User", type text}, {"Initial Date", type date}, {"Final Date", type date}}),
    #"Duplicated Column" = Table.DuplicateColumn(#"Changed Type", "Initial Date", "Initial Date - Copy"),
    #"Calculated Start of Month" = Table.TransformColumns(#"Duplicated Column",{{"Initial Date - Copy", Date.StartOfMonth, type datetime}}),
    #"Duplicated Column1" = Table.DuplicateColumn(#"Calculated Start of Month", "Final Date", "Final Date - Copy"),
    #"Calculated Start of Month1" = Table.TransformColumns(#"Duplicated Column1",{{"Final Date - Copy", Date.StartOfMonth, type datetime}}),
    #"Added Custom" = Table.AddColumn(#"Calculated Start of Month1", "Mensal Date", each {Number.From([#"Initial Date - Copy"])..Number.From([#"Final Date - Copy"])}),
    #"Expanded Mensal Date" = Table.ExpandListColumn(#"Added Custom", "Mensal Date"),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Mensal Date",{"Initial Date - Copy", "Final Date - Copy"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Removed Columns",{{"Mensal Date", type date}}),
    #"Reordered Columns" = Table.ReorderColumns(#"Changed Type1",{"Mensal Date", "CNPJ", "Region", "Value", "User", "Initial Date", "Final Date"})
in
    #"Reordered Columns"

Hope this helps.

Untitled.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

How does the monthly date appear from month to month? 01/01/2018, 02/01/2018, 03/01/2018 .... ? Is it the first day of every month?

Sorry but i do not understand your question.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

it is like this
1/1/2018
1/2/2018
1/3/2018
1/4/2018
1/5/2018
1/6/2018
1/7/2018
1/8/2018
1/9/2018
1/10/2018
1/11/2018
1/12/2018
1/13/2018
1/14/2018
1/15/2018
1/16/2018

 

and I need dates like this:

 

I need it like this
1/1/2018
2/1/2018
3/1/2018
4/1/2018
5/1/2018
6/1/2018
7/1/2018
8/1/2018
9/1/2018
10/1/2018
11/1/2018
12/1/2018
1/1/2019
2/1/2019
3/1/2019
4/1/2019

from month to month.

Hi,

My solution returns one row for every day.  If you want one row for every month, then refer to the steps in this link - Generating Rows by Month for Date Ranges in Power Query


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

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

August 2025 community update carousel

Fabric Community Update - August 2025

Find out what's new and trending in the Fabric community.

Top Solution Authors