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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
esterdid
Frequent Visitor

Date calendar dax code

Hello,

 

I am completly new to Dax and will appreciate any assistance here. I have come across this dynamic calendar based on DAX and Ifound it very simple to use. the issue is that I need to expand it to inlcude other columns such as Quarters financial YearQuarter etc..

What is the syntax for including the list below in the current code?

YearNumber
DayWeek
WeekNumber
WeekEnding
DayName
CalendarQtr
FinancialQtr
FinancialYr (FY)
MonthName
CalendarMonth

 

Here is the working script at the moment.

 

Dates =
VAR BaseCalendar =
CALENDARAUTO (6)
RETURN
GENERATE (
BASECALENDAR,
VAR BASEDATE = [DATE] VAR DayDate = DAY([DATE])
VAR YEARDATE = YEAR ( BASEDATE )
VAR MONTHNUMBER = MONTH ( BASEDATE )
VAR YEARMONTHNUMBER = YEARDATE * 12 + MONTHNUMBER -1
RETURN ROW (
"DAY", DayDate,
"YEAR", YEARDATE,
"MONTH NUMBER", MONTHNUMBER,
"MONTH", FORMAT ( BASEDATE, "MMMM" ),
"YEAR MONTH NUMBER", YEARMONTHNUMBER,
"YEAR MONTH", FORMAT ( BASEDATE, "MMM YY" )
)
)

 

 

Thanks

D.

1 ACCEPTED SOLUTION

Hi @esterdid

 

I think this might be close 

 

Dates = 
VAR BaseCalendar =
CALENDAR(date(2016,1,1),today())
RETURN
GENERATE (
BASECALENDAR,
VAR BASEDATE = [DATE] VAR DayDate = DAY([DATE])
VAR YEARDATE = YEAR ( BASEDATE )
VAR MONTHNUMBER = MONTH ( BASEDATE )
VAR YEARMONTHNUMBER = YEARDATE * 12 + MONTHNUMBER -1
VAR FINANCIALQTR = SWITCH(
                        TRUE(),
                        MONTH([Date]) IN {7,8,9} , 1 ,
                        MONTH([Date]) IN {10,11,12} , 2 ,
                        MONTH([Date]) IN {1,2,3} , 3 ,  
                        4)
VAR FINANCIALYR = IF( MONTH([Date]) >=7 , YEARDATE , YEARDATE - 1)
RETURN ROW (
"DAY", DayDate,
"YEAR", YEARDATE,
"MONTH NUMBER", MONTHNUMBER,
"MONTH", FORMAT ( BASEDATE, "MMMM" ),
"YEAR MONTH NUMBER", YEARMONTHNUMBER,
"YEAR MONTH", FORMAT ( BASEDATE, "MMM YY" ),
------------------------------
"Week Number",WEEKNUM([Date]),
"Week Ending",[Date] + (6-(WEEKDAY([Date],3))),
"Day Name" , FORMAT([Date],"DDDD"),
"CalendarQtr" , INT(MONTH([Date]) / 4) + 1 ,       
--
"FinancialQtr" , "FYQ" & FINANCIALQTR ,
"FinancialYr" ,"FY" & FINANCIALYR,
"FinancialYrQtr" ,  FINANCIALQTR &  FINANCIALYR             

)
)

To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

View solution in original post

7 REPLIES 7
Phil_Seamark
Employee
Employee

Here are some suggestions for a starters,

 

"Week Number",WEEKNUM([Date]),
"Week Ending",[Date] + (6-(WEEKDAY([Date],3))),
"Day Name" , FORMAT([Date],"DDDD"),
"CalendarQtr" , INT(MONTH([Date]) / 4) + 1    

Just add these to your  RETURN ROW function.


To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

Thanks Phil,

 

those worked, the remaining straight forward as well? expecially working out the financial year (e.g. FY17) and financial year qarters?


FinancialQtr (e.g. FYQ1)

FinancialQtr (e.g. FYQ12017)
FinancialYr (FY17)

 

Thanks 

When does your financial year start?


To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

It starts in July (07). Thanks

Hi @esterdid

 

I think this might be close 

 

Dates = 
VAR BaseCalendar =
CALENDAR(date(2016,1,1),today())
RETURN
GENERATE (
BASECALENDAR,
VAR BASEDATE = [DATE] VAR DayDate = DAY([DATE])
VAR YEARDATE = YEAR ( BASEDATE )
VAR MONTHNUMBER = MONTH ( BASEDATE )
VAR YEARMONTHNUMBER = YEARDATE * 12 + MONTHNUMBER -1
VAR FINANCIALQTR = SWITCH(
                        TRUE(),
                        MONTH([Date]) IN {7,8,9} , 1 ,
                        MONTH([Date]) IN {10,11,12} , 2 ,
                        MONTH([Date]) IN {1,2,3} , 3 ,  
                        4)
VAR FINANCIALYR = IF( MONTH([Date]) >=7 , YEARDATE , YEARDATE - 1)
RETURN ROW (
"DAY", DayDate,
"YEAR", YEARDATE,
"MONTH NUMBER", MONTHNUMBER,
"MONTH", FORMAT ( BASEDATE, "MMMM" ),
"YEAR MONTH NUMBER", YEARMONTHNUMBER,
"YEAR MONTH", FORMAT ( BASEDATE, "MMM YY" ),
------------------------------
"Week Number",WEEKNUM([Date]),
"Week Ending",[Date] + (6-(WEEKDAY([Date],3))),
"Day Name" , FORMAT([Date],"DDDD"),
"CalendarQtr" , INT(MONTH([Date]) / 4) + 1 ,       
--
"FinancialQtr" , "FYQ" & FINANCIALQTR ,
"FinancialYr" ,"FY" & FINANCIALYR,
"FinancialYrQtr" ,  FINANCIALQTR &  FINANCIALYR             

)
)

To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

Hi Phil - Could you give syntax for calculating fiscal month number, if my fiscal month is starting in April?

Thanks Phil.

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.