cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
charleshale
Helper V
Helper V

Dax Date Table not going to full range -- Bug or I am losing my mind, or both

Dear community forum - Either I'm losing my mind, there's a bug, or both.

 

Check this out: the simple dax date table generator I often use is the following -- a classic recommended by folks like my heros at SQLBI or many regular super contributors of this board (like @amitchandak or @Greg_Deckler -- if I ever log on and DONT see you, I will be worried 🙂  ).

 

DimDate = 
VAR MINYEAR = 2000 // normally use a dynamic reference like //  YEAR (  MIN( fGL[Date] ) )
VAR MAXYEAR = 2025 // but for QA purposes fixing a value    //    YEAR (  MAX ( fGL[Date]) )
RETURN
ADDCOLUMNS (
    FILTER (
        CALENDARAUTO( ),
        AND ( YEAR ( [DATE] ) >= MINYEAR, YEAR ( [DATE] ) <= MAXYEAR )
    ),
"DateAsInteger", FORMAT ( [Date], "YYYYMMDD" ),
"Year", YEAR ( [Date] ),
"Monthnumber", FORMAT ( [Date], "MM" ),
"YearMonthnumber", FORMAT ( [Date], "YYYY/MM" ),
"YearMonthShort", FORMAT ( [Date], "YYYY/mmm" ),
"MonthNameShort", FORMAT ( [Date], "mmm" ),
"MonthNameLong", FORMAT ( [Date], "mmmm" ),
"DayOfWeekNumber", WEEKDAY ( [Date] ),
"DayOfWeek", FORMAT ( [Date], "dddd" ),
"DayOfWeekShort", FORMAT ( [Date], "ddd" ),
"DayNumber", FORMAT ( [Date], "d" ),
"Quarter", FORMAT ( [Date], "Q" ),
"YearQuarter", FORMAT ( [Date], "YYYY" ) & "/Q" & FORMAT ( [Date], "Q" )
)

 

 

The date table that gets returned should go through the MAXYEAR, or 2025, but instead the date table returns only through 12/31/2021, as below.  What black magic has infected my DAX, my system, my brain, or all of the above?  

 

(I'd meant to post on something more interesting like Treatas with virtual tables, but can't get past this bizarre occurrence.   Would greatly appreciate any help / mental counseling)

 

charleshale_1-1632187709893.png

 

1 ACCEPTED SOLUTION
Greg_Deckler
Super User
Super User

@charleshale I would not use CALENDARAUTO, it analyzes your data model and only returns the min and max date range it finds. I would use CALENDAR instead like:

 

DimDate = 
VAR MINYEAR = 2000 // normally use a dynamic reference like //  YEAR (  MIN( fGL[Date] ) )
VAR MAXYEAR = 2025 // but for QA purposes fixing a value    //    YEAR (  MAX ( fGL[Date]) )
RETURN
ADDCOLUMNS (
    FILTER (
        CALENDAR(DATE(MINYEAR,1,1),DATE(MAXYEAR,12,31)),
        AND ( YEAR ( [DATE] ) >= MINYEAR, YEAR ( [DATE] ) <= MAXYEAR )
    ),
"DateAsInteger", FORMAT ( [Date], "YYYYMMDD" ),
"Year", YEAR ( [Date] ),
"Monthnumber", FORMAT ( [Date], "MM" ),
"YearMonthnumber", FORMAT ( [Date], "YYYY/MM" ),
"YearMonthShort", FORMAT ( [Date], "YYYY/mmm" ),
"MonthNameShort", FORMAT ( [Date], "mmm" ),
"MonthNameLong", FORMAT ( [Date], "mmmm" ),
"DayOfWeekNumber", WEEKDAY ( [Date] ),
"DayOfWeek", FORMAT ( [Date], "dddd" ),
"DayOfWeekShort", FORMAT ( [Date], "ddd" ),
"DayNumber", FORMAT ( [Date], "d" ),
"Quarter", FORMAT ( [Date], "Q" ),
"YearQuarter", FORMAT ( [Date], "YYYY" ) & "/Q" & FORMAT ( [Date], "Q" )

 


@ me in replies or I'll lose your thread!!!
Check out my External Tool for Power BI Desktop!
Microsoft Hates Greg's Quick Measures
Check out my latest book!

View solution in original post

2 REPLIES 2
Greg_Deckler
Super User
Super User

@charleshale I would not use CALENDARAUTO, it analyzes your data model and only returns the min and max date range it finds. I would use CALENDAR instead like:

 

DimDate = 
VAR MINYEAR = 2000 // normally use a dynamic reference like //  YEAR (  MIN( fGL[Date] ) )
VAR MAXYEAR = 2025 // but for QA purposes fixing a value    //    YEAR (  MAX ( fGL[Date]) )
RETURN
ADDCOLUMNS (
    FILTER (
        CALENDAR(DATE(MINYEAR,1,1),DATE(MAXYEAR,12,31)),
        AND ( YEAR ( [DATE] ) >= MINYEAR, YEAR ( [DATE] ) <= MAXYEAR )
    ),
"DateAsInteger", FORMAT ( [Date], "YYYYMMDD" ),
"Year", YEAR ( [Date] ),
"Monthnumber", FORMAT ( [Date], "MM" ),
"YearMonthnumber", FORMAT ( [Date], "YYYY/MM" ),
"YearMonthShort", FORMAT ( [Date], "YYYY/mmm" ),
"MonthNameShort", FORMAT ( [Date], "mmm" ),
"MonthNameLong", FORMAT ( [Date], "mmmm" ),
"DayOfWeekNumber", WEEKDAY ( [Date] ),
"DayOfWeek", FORMAT ( [Date], "dddd" ),
"DayOfWeekShort", FORMAT ( [Date], "ddd" ),
"DayNumber", FORMAT ( [Date], "d" ),
"Quarter", FORMAT ( [Date], "Q" ),
"YearQuarter", FORMAT ( [Date], "YYYY" ) & "/Q" & FORMAT ( [Date], "Q" )

 


@ me in replies or I'll lose your thread!!!
Check out my External Tool for Power BI Desktop!
Microsoft Hates Greg's Quick Measures
Check out my latest book!

View solution in original post

Amazing, @Greg_Decker, you've nailed it.  This eliminates the error.  Thank you.  Nice work as always! 

Helpful resources

Announcements
PBI_User Group Leader_768x460.jpg

Manage your user group events

Check out the News & Announcements to learn more.

Power BI October Update 2021.jpg

Power BI Release

Click here to read more about the October 2021 Release!

Community Connections 768x460.jpg

Community & How To Videos

Check out the new Power Platform Community Connections gallery!

Teds Dev Camp Oct. 2021 768x460.jpg

Power BI Dev Camp - October 28th, 2021

Mark your calendars and join us for our next Power BI Dev Camp!