cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
charleshale
Responsive Resident
Responsive Resident

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!!!
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Learn Power BI 2nd Edition

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!!!
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Learn Power BI 2nd Edition

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

Helpful resources

Announcements
Microsoft Build 768x460.png

Microsoft Build is May 24-26. Have you registered yet?

Come together to explore latest innovations in code and application development—and gain insights from experts from around the world.

charticulator_carousel_with_text (1).png

Charticulator Design Challenge

Put your data visualization and design skills to the test! This exciting challenge is happening now through May 31st!

May UG Leader Call Carousel 768x460.png

What difference can a User Group make for you?

At the monthly call, connect with other leaders and find out how community makes your experience even better.

Power BI Release May 2022 768x460.png

Check it out!

Click here to read more about the May 2022 updates!