cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Microsoft
Microsoft

Date Dimension Table that Dynamically Pulls Start and End dates from a Column of Dates

As the title suggests, I am looking to create a date dimension table with M that checks for the earliest and most recent invoice dates and creates a date table from that with 1 day increments.  I have code to create a dimDate table but the user has to manually enter start and end dates.  Similarly, I have two functions that, when invoked, return the earliest and most recent date, respectively.  Can anyone give me some tips on how to integrate these?

 

Below is the code I am using (I did not create this) to generate a user defined dimDate table.  Is it possible to call the functions that return the start date and end date instead of requiring the user to hard code these in?

 

let CreateDateTable = (StartDate as date, EndDate as date, optional Culture as nullable text) as table =>
  let
    DayCount = Duration.Days(Duration.From(EndDate - StartDate)),
    Source = List.Dates(StartDate,DayCount,#duration(1,0,0,0)),
    TableFromList = Table.FromList(Source, Splitter.SplitByNothing()),
    ChangedType = Table.TransformColumnTypes(TableFromList,{{"Column1", type date}}),
    RenamedColumns = Table.RenameColumns(ChangedType,{{"Column1", "Date"}}),
    InsertYear = Table.AddColumn(RenamedColumns, "Year", each Date.Year([Date])),
    InsertQuarter = Table.AddColumn(InsertYear, "QuarterOfYear", each Date.QuarterOfYear([Date])),
    InsertMonth = Table.AddColumn(InsertQuarter, "MonthOfYear", each Date.Month([Date])),
    InsertDay = Table.AddColumn(InsertMonth, "DayOfMonth", each Date.Day([Date])),
    InsertDayInt = Table.AddColumn(InsertDay, "DateInt", each [Year] * 10000 + [MonthOfYear] * 100 + [DayOfMonth]),
    InsertMonthName = Table.AddColumn(InsertDayInt, "MonthName", each Date.ToText([Date], "MMMM", Culture), type text),
    InsertCalendarMonth = Table.AddColumn(InsertMonthName, "MonthInCalendar", each (try(Text.Range([MonthName],0,3)) otherwise [MonthName]) & " " & Number.ToText([Year])),
    InsertCalendarQtr = Table.AddColumn(InsertCalendarMonth, "QuarterInCalendar", each "Q" & Number.ToText([QuarterOfYear]) & " " & Number.ToText([Year])),
    InsertDayWeek = Table.AddColumn(InsertCalendarQtr, "DayInWeek", each Date.DayOfWeek([Date])),
    InsertDayName = Table.AddColumn(InsertDayWeek, "DayOfWeekName", each Date.ToText([Date], "dddd", Culture), type text),
    InsertWeekEnding = Table.AddColumn(InsertDayName, "WeekEnding", each Date.EndOfWeek([Date]), type date)
  in
    InsertWeekEnding
in
  CreateDateTable
2 ACCEPTED SOLUTIONS

Accepted Solutions
Highlighted
Microsoft
Microsoft

Re: Date Dimension Table that Dynamically Pulls Start and End dates from a Column of Dates

As is typical in these types of challenges, I spent a while scouring the internet and trying to get a solution before I posted my question here, only to arrive at one a few minutes later...

 

Anyway, here is the revised code that can be used:

let CreateDateTable = () as table =>
  let
    StartDate = List.Min(Table.Column(Invoices,"OrderDate")),
    EndDate = List.Max(Table.Column(Invoices,"OrderDate")),
    DayCount = Duration.Days(Duration.From(EndDate - StartDate)),
    Source = List.Dates(StartDate,DayCount,#duration(1,0,0,0)),
    TableFromList = Table.FromList(Source, Splitter.SplitByNothing()),
    ChangedType = Table.TransformColumnTypes(TableFromList,{{"Column1", type date}}),
    RenamedColumns = Table.RenameColumns(ChangedType,{{"Column1", "Date"}}),
    InsertYear = Table.AddColumn(RenamedColumns, "Year", each Date.Year([Date])),
    InsertQuarter = Table.AddColumn(InsertYear, "QuarterOfYear", each Date.QuarterOfYear([Date])),
    InsertMonth = Table.AddColumn(InsertQuarter, "MonthOfYear", each Date.Month([Date])),
    InsertDay = Table.AddColumn(InsertMonth, "DayOfMonth", each Date.Day([Date])),
    InsertDayInt = Table.AddColumn(InsertDay, "DateInt", each [Year] * 10000 + [MonthOfYear] * 100 + [DayOfMonth]),
    InsertMonthName = Table.AddColumn(InsertDayInt, "MonthName", each Date.ToText([Date], "MMMM"), type text),
    InsertCalendarMonth = Table.AddColumn(InsertMonthName, "MonthInCalendar", each (try(Text.Range([MonthName],0,3)) otherwise [MonthName]) & " " & Number.ToText([Year])),
    InsertCalendarQtr = Table.AddColumn(InsertCalendarMonth, "QuarterInCalendar", each "Q" & Number.ToText([QuarterOfYear]) & " " & Number.ToText([Year])),
    InsertDayWeek = Table.AddColumn(InsertCalendarQtr, "DayInWeek", each Date.DayOfWeek([Date])),
    InsertDayName = Table.AddColumn(InsertDayWeek, "DayOfWeekName", each Date.ToText([Date], "dddd"), type text),
    InsertWeekEnding = Table.AddColumn(InsertDayName, "WeekEnding", each Date.EndOfWeek([Date]), type date)
  in
    InsertWeekEnding
in
  CreateDateTable

The red text is what you would need to customize, where, in my example, the table name is "Invoices" and the invoice date column is "OrderDate"

View solution in original post

Highlighted
Solution Sage
Solution Sage

Re: Date Dimension Table that Dynamically Pulls Start and End dates from a Column of Dates

This is route I ended up using since I wanted the table updated when I did a refresh

I found this from another post, so I can't take any credit here

 

DateTable =
ADDCOLUMNS (
CALENDAR (MINX(HR_HEADCOUNT,[Date]), NOW()),
"Year", YEAR ( [Date] ),
"QuarterOfYear", FORMAT ( [Date], "Q" ),
"MonthOfYear", FORMAT ( [Date], "MM" ),
"DateInt", FORMAT ( [Date], "YYYYMMDD" ),
"MonthName", FORMAT ( [Date], "mmmm" ),
"MonthInCalendar", FORMAT ( [Date], "mmm YYYY" ),
"QuarterInCalendar", "Q" & FORMAT ( [Date], "Q" ) & " " & FORMAT ( [Date], "YYYY" ),
"DayInWeek", WEEKDAY ( [Date] ),
"DayOfWeekName", FORMAT ( [Date], "dddd" ),
"DayOfWeekShort", FORMAT ( [Date], "ddd" ),
"YearMonthShort", FORMAT ( [Date], "YYYY/mmm" ),
"MonthNameShort", FORMAT ( [Date], "mmm" )

View solution in original post

14 REPLIES 14
Highlighted
Microsoft
Microsoft

Re: Date Dimension Table that Dynamically Pulls Start and End dates from a Column of Dates

As is typical in these types of challenges, I spent a while scouring the internet and trying to get a solution before I posted my question here, only to arrive at one a few minutes later...

 

Anyway, here is the revised code that can be used:

let CreateDateTable = () as table =>
  let
    StartDate = List.Min(Table.Column(Invoices,"OrderDate")),
    EndDate = List.Max(Table.Column(Invoices,"OrderDate")),
    DayCount = Duration.Days(Duration.From(EndDate - StartDate)),
    Source = List.Dates(StartDate,DayCount,#duration(1,0,0,0)),
    TableFromList = Table.FromList(Source, Splitter.SplitByNothing()),
    ChangedType = Table.TransformColumnTypes(TableFromList,{{"Column1", type date}}),
    RenamedColumns = Table.RenameColumns(ChangedType,{{"Column1", "Date"}}),
    InsertYear = Table.AddColumn(RenamedColumns, "Year", each Date.Year([Date])),
    InsertQuarter = Table.AddColumn(InsertYear, "QuarterOfYear", each Date.QuarterOfYear([Date])),
    InsertMonth = Table.AddColumn(InsertQuarter, "MonthOfYear", each Date.Month([Date])),
    InsertDay = Table.AddColumn(InsertMonth, "DayOfMonth", each Date.Day([Date])),
    InsertDayInt = Table.AddColumn(InsertDay, "DateInt", each [Year] * 10000 + [MonthOfYear] * 100 + [DayOfMonth]),
    InsertMonthName = Table.AddColumn(InsertDayInt, "MonthName", each Date.ToText([Date], "MMMM"), type text),
    InsertCalendarMonth = Table.AddColumn(InsertMonthName, "MonthInCalendar", each (try(Text.Range([MonthName],0,3)) otherwise [MonthName]) & " " & Number.ToText([Year])),
    InsertCalendarQtr = Table.AddColumn(InsertCalendarMonth, "QuarterInCalendar", each "Q" & Number.ToText([QuarterOfYear]) & " " & Number.ToText([Year])),
    InsertDayWeek = Table.AddColumn(InsertCalendarQtr, "DayInWeek", each Date.DayOfWeek([Date])),
    InsertDayName = Table.AddColumn(InsertDayWeek, "DayOfWeekName", each Date.ToText([Date], "dddd"), type text),
    InsertWeekEnding = Table.AddColumn(InsertDayName, "WeekEnding", each Date.EndOfWeek([Date]), type date)
  in
    InsertWeekEnding
in
  CreateDateTable

The red text is what you would need to customize, where, in my example, the table name is "Invoices" and the invoice date column is "OrderDate"

View solution in original post

Highlighted
Solution Sage
Solution Sage

Re: Date Dimension Table that Dynamically Pulls Start and End dates from a Column of Dates

Thanks for this post, I have looked for such as well

A couple of questions

 

Does this dynamically update as dates in your Invoices table change?  Meaning, if the max date in your invoice table changes based on data refresh, will the dates in the date table reflect this?  Also, how would this be called in such a scenario

 

Thanks,

Highlighted
Microsoft
Microsoft

Re: Date Dimension Table that Dynamically Pulls Start and End dates from a Column of Dates

Yes this dynamically updates.  Notice near the beginning of the code we have two declarations: 

 

StartDate = List.Min(Table.Column(Invoices,"OrderDate"))

EndDate = List.Max(Table.Column(Invoices,"OrderDate"))

 

To set this up with your own data, after connecting to your data, open the query editor.  Create a new blank table.  Select the table from the list of queries and go to Advanced Editor.  Replace the existing code with the code from this post and it should become a function.  Then, to invoke, simply select the function and look for the button "invoke".

Highlighted
Solution Sage
Solution Sage

Re: Date Dimension Table that Dynamically Pulls Start and End dates from a Column of Dates

Got it, so you have to invoke the function each time you want it updated

Appreciate the response

 

Highlighted
Microsoft
Microsoft

Re: Date Dimension Table that Dynamically Pulls Start and End dates from a Column of Dates

I haven't had a chance to trouble shoot this (i.e. start from scratch to make sure no errors are thrown) but try this as a way to not have to manually invoke this function after refresh (which would produce a new table, lose any data types and formatting, and would require you to re-establish a relationship between your dimDates table and Sales table).

 

After creating the function given in my original post, do the following:

 

  1. Create table from function
    1. Connect to new data source - "Blank Query"
    2. Enter anything (i.e "1", it really doesn't matter)
    3. Convert to table
    4. Add Column -> Invoke Custom Function
    5. Remove the original column from table, leaving only column with function name and value of Table
    6. Expand the column with the double arrow button on header
      1. Uncheck "Use original column headers as prefix"
    7. Rename table as "dimDates"
    8. Configure table (set data types, rename fields if wanted, etc.)
  2. Close and Apply, then create relationship between dimDates table and relevant sales table using date field
  3. You will need to apply some manual sorting rules under "Modeling" tab in order to get text representation of dates (ie.e month and day name) to displayed in correct order when used as axis in charts.  Accomplish this using the appropriate numeric equivalent column

 

You now have a date dimension table and, as your sales database grows over time, these new dates will be added to the dimDates table automatically on refresh.

 

I will also test this for functionality after a publish to PowerBI service and share the results.

Highlighted
Microsoft
Microsoft

Re: Date Dimension Table that Dynamically Pulls Start and End dates from a Column of Dates

Additionally, you can create a calculated table (under "modeling" tab), using the dax expression Calendar(start date, end date), where start and end date are calculated using dax (min and max of sales[dates] while ignoring filters).  From here, you will have to build out the steps the M code above performed, and configure data types and formatting, and create the relationship between this dates table and the sales table.

 

This way seems much easier, not sure why I couldn't find this out earlier in my search.  At the moment, I don't have the specific dax expression to calculate min and max while ignoring applied filters.

Highlighted
Solution Sage
Solution Sage

Re: Date Dimension Table that Dynamically Pulls Start and End dates from a Column of Dates

Something like below?

 

First Invoice Date = CALCULATE(MIN(Invoices[OrderDate]),ALL('Invoices'))
Last Invoice Date = CALCULATE(MAX(Invoices[OrderDate]),ALL('Invoices'))
Highlighted
Solution Sage
Solution Sage

Re: Date Dimension Table that Dynamically Pulls Start and End dates from a Column of Dates

This is route I ended up using since I wanted the table updated when I did a refresh

I found this from another post, so I can't take any credit here

 

DateTable =
ADDCOLUMNS (
CALENDAR (MINX(HR_HEADCOUNT,[Date]), NOW()),
"Year", YEAR ( [Date] ),
"QuarterOfYear", FORMAT ( [Date], "Q" ),
"MonthOfYear", FORMAT ( [Date], "MM" ),
"DateInt", FORMAT ( [Date], "YYYYMMDD" ),
"MonthName", FORMAT ( [Date], "mmmm" ),
"MonthInCalendar", FORMAT ( [Date], "mmm YYYY" ),
"QuarterInCalendar", "Q" & FORMAT ( [Date], "Q" ) & " " & FORMAT ( [Date], "YYYY" ),
"DayInWeek", WEEKDAY ( [Date] ),
"DayOfWeekName", FORMAT ( [Date], "dddd" ),
"DayOfWeekShort", FORMAT ( [Date], "ddd" ),
"YearMonthShort", FORMAT ( [Date], "YYYY/mmm" ),
"MonthNameShort", FORMAT ( [Date], "mmm" )

View solution in original post

Highlighted
Microsoft
Microsoft

Re: Date Dimension Table that Dynamically Pulls Start and End dates from a Column of Dates

This is a much more elegant solution that is also definitely going to work after publish, as all columns are calculated via DAX.  Thanks for finding this.

Helpful resources

Announcements
August 2020 Community Challenge: Can You Solve These?

August 2020 Community Challenge: Can You Solve These?

We're excited to announce our first cross-community 'Can You Solve These?' challenge!

Community Blog

Community Blog

Visit our Community Blog for articles, guides, and information created by fellow community members.

Upcoming Events

Upcoming Events

Wondering what events you could join or have an event to promote yourself? Check out our Upcoming Events.

Get Ready for Power BI Dev Camp

Get Ready for Power BI Dev Camp

We are thrilled to announce we will begin running a monthly webinar series named Power BI Dev Camp.

Top Solution Authors
Top Kudoed Authors