Recently I needed to create a date dimension for a Power BI model as there was not one in the source database. There are two different ways that I could do this, using DAX from the Modeling Tab within the Data View or using M via the Query Editor window. As a general rule, when it is possible data manipulation should be done in M as it offers a greater level of compression. In this case though I am using a function in DAX, which is not the same as creating a calculated column.
Create a Date Table in DAX
To create a date table in DAX, in Power BI go to the Data View->Modeling Table. Click on the New Table button on the ribbon. For those who are wondering how you would go about writing either one, here is the source code for the DAX version.
DimDate = ADDCOLUMNS( CALENDAR(DATE(2017,1,1), DATE(2020,12,31)) ,
"Date Key", FORMAT ( [Date], "YYYYMMDD" ), //NumericDate
"Year", YEAR([Date]),
"Qtr Number", "Qtr " & FORMAT( [Date], "Q"),
"Q Number", "Q " & FORMAT( [Date], "Q"),
"Month Name" , FORMAT ( [Date], "mmmm" ) ,
"Month Short Name" , FORMAT ( [Date], "mmm" ) ,
"Month Number", MONTH([Date]),
"Month Year", FORMAT ( [Date], "mmm " ) & YEAR([Date]),
"Day Name", FORMAT ( [Date], "dddd" ), //Name for Each day of the week
"Day Short Name", FORMAT ( [Date], "ddd" ),
"Day Number" , WEEKDAY ( [Date] ) //Sunday is 1
)
This code uses the DAX CALENDAR function to create a contiguous set of dates between January 1, 2017 and December 31, 2020 with a field is named “Date”. The remaining fields need field names and comments were added for clarity
Create a Date Table in M
In the Power BI Query Editor, click on the New Source button and select Blank Query. Select the View tab and click on the Advanced Editor button. The Advanced Editor is where the M query is stored. Paste the following code in to create a new table called Query1, which of course you can rename.
let
Source = List.Dates( #date(2017,1,1), Number.From( #date(2020, 12,31) - Date.From( #date(2017,1,1) ))+1, #duration(1,0,0,0)),
#"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
#"Changed Type" = Table.TransformColumnTypes(#"Converted to Table",{{"Column1", type date}}),
#"Renamed Columns" = Table.RenameColumns(#"Changed Type",{{"Column1", "Date"}}),
#"AddYear" = Table.AddColumn(#"Renamed Columns", "Year", each Text.End(Text.From([#"Date"], "en-US"), 4), type text),
#"AddMonth" = Table.AddColumn(AddYear, "Month Number", each Date.ToText([Date], "MM")),
#"AddQuarter" = Table.AddColumn(AddMonth, "Quarter Number", each "Qtr " & Number.ToText(Date.QuarterOfYear([Date]))),
#"AddMonthName" = Table.AddColumn(#"AddQuarter", "Month Name", each Date.ToText([Date], "MMMM")),
#"AddMonthShortName" = Table.AddColumn(#"AddMonthName", "Month Short Name", each Date.ToText([Date], "MMM")),
#"AddShortMonthYear" = Table.AddColumn(#"AddMonthShortName", "Short Month Year", each [Month Short Name] &" " & [Year]),
#"AddDayOfWeek" = Table.AddColumn(#"AddShortMonthYear", "Day of Week", each Date.ToText([Date], "dddd")),
#"AddDay" = Table.AddColumn(#"AddDayOfWeek", "Day", each Date.ToText([Date], "dd")),
#"AddDateKey" = Table.AddColumn(AddDay, "DateKey", each ([Year]&[Month Number]&[Day]))
in
#"AddDateKey"
To Create A Date Table Use Either M or DAX
Now the question is which one should you use? To be honest it doesn’t matter. I couldn’t see any difference when I tested it. To validate this answer I consulted twitter, which sparked some very interesting comments and analysis. Marco Russo b | t is planning on writing a blog on the details of it, but Jason Thomas b | t gave me this summary. “[The] Dictionary expands as needed as values are inserted–designed to reduce cost of re-alloc and re-org of hash buckets (at cost of memory waste).” The full explanation needs a post of it’s own to be sure, which I am looking forward to reading when Marco writes it. I’ll quote Kasper De Jonge b | t who summed it up best “I don’t believe it will matter much, the date table will be so small regardless”. Whichever way you chose to add a date table, DAX or M, which are needed for time intelligence, you now have the code to do either one.
Yours Always
Ginger Grant
Data aficionado et SQL Raconteur
Great post thanks. I tend to use DAX for performance reasons if I am creating a dynamic calendar that depends on the first and last dates in the fact tables. Especially if M performance is bad because of it causing loading the fact table multiple times. You can get around the issue in M by formulating a separate compact query to just retrieved the first and last dates from the data source, sometimes that isn’t possible.
Brian —
Thanks for your nice comment on my post. Your comment intrigued me. I have not created a dynamic calendar. I am looking to create a date table to add to my model so that I can perform time based calculations. What use case do you find requires the use of a dynamic calendar?
Regards,
Ginger
Brian —
Thanks for your nice comment on my post. Your comment intrigued me. I have not created a dynamic calendar. I am looking to create a date table to add to my model so that I can perform time based calculations. What use case do you find requires the use of a dynamic calendar?
Regards,
Ginger
Pingback: Dynamic Date Dimensions In Power BI – Curated SQL