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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

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!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

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!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

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

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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