March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
How can I build a calendar with dates of each month at working day 7 ??
E.g.
I know that I can use CalendarAuto or Calendar
But I just need dates within the DateDimension, which are falling on WorkDay (WeekDay) 7 (of a particular month)
Solved! Go to Solution.
@Sachy123
I am not sure if I understood your question correctly. If you need to create a date table with only the 7th Working day for each month considering Saturday and Sunday as weekends, then the following code in DAX for a new table should get you what you are after:
Table =
var __Calendar =
ADDCOLUMNS(
CALENDAR("01/01/2020","31/12/2020"),
"Year" , YEAR([Date]),
"Month", MONTH([Date]),
"Week", FORMAT([Date],"ddd"),
"7th Working Day", IF( WEEKDAY([Date],2) in {6,7}, 0 , 1)
)
return
FILTER(
ADDCOLUMNS(
__Calendar,
"DateAdded" ,
SUMX(
FILTER(__Calendar, [Year] = EARLIER([Year]) && [Month]=EARLIER([Month]) && [Date] <= EARLIER([Date])),
[7th Working Day]
)
),
[DateAdded] = 7
)
________________________
If my answer was helpful, please click Accept it as the solution to help other members find it useful
Click on the Thumbs-Up icon if you like this reply 🙂
⭕ Subscribe and learn Power BI from these videos
⚪ Website ⚪ LinkedIn ⚪ PBI User Group
@Sachy123
I am not sure if I understood your question correctly. If you need to create a date table with only the 7th Working day for each month considering Saturday and Sunday as weekends, then the following code in DAX for a new table should get you what you are after:
Table =
var __Calendar =
ADDCOLUMNS(
CALENDAR("01/01/2020","31/12/2020"),
"Year" , YEAR([Date]),
"Month", MONTH([Date]),
"Week", FORMAT([Date],"ddd"),
"7th Working Day", IF( WEEKDAY([Date],2) in {6,7}, 0 , 1)
)
return
FILTER(
ADDCOLUMNS(
__Calendar,
"DateAdded" ,
SUMX(
FILTER(__Calendar, [Year] = EARLIER([Year]) && [Month]=EARLIER([Month]) && [Date] <= EARLIER([Date])),
[7th Working Day]
)
),
[DateAdded] = 7
)
________________________
If my answer was helpful, please click Accept it as the solution to help other members find it useful
Click on the Thumbs-Up icon if you like this reply 🙂
⭕ Subscribe and learn Power BI from these videos
⚪ Website ⚪ LinkedIn ⚪ PBI User Group
@Fowmy !
this is one of the best solutions!
Thanks I can even change the number to get the 7th or 8th working day.
What if I have to include Holidays? E.g. I have an excel with list of holidays that I want to exclude in the calculation of nth "working" day from example about?
Hi, @Sachy123 , the solution provided by @BA_Pete is simple and straightforward enough; if you insists on weekday-style calendar, you might try using the following code to create such a calendar,
let
StartingYr = 2021,
Months = 3, // must be whole number greater than 0
days = Duration.Days(Date.AddMonths(#date(StartingYr,1,1),Months)-#date(StartingYr,1,1)),
//Weekday calendar starts from January 1 of assigned StartingYr and lasts for assigned Month(s)
Weekdays = Table.FromList(
List.Accumulate({0..days-1}, {}, (s,c) => [dt=Date.AddDays(#date(StartingYr,1,1),c), res=if Date.DayOfWeek(dt,Day.Monday)<5 then s&{dt} else s][res]),
Splitter.SplitByNothing(),
{"Date"}
)
in
Weekdays
Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension! |
DAX is simple, but NOT EASY! |
Hi @Sachy123 ,
If you use CALENDAR or CALENDARAUTO you can add a calculated flag column, something like this:
isDaySeven =
IF(
WEEKDAY([Date], 2) = 7,
1,
0
)
The second argument here (2) denotes that the week starts on Monday. This can be changed to suit your particular week-start day.
You would then use this flag column in measures to identify the dates you want.
Possibly the preferable option would be to do this in Power Query. You would start with a list of dates then, similar to above, create a calculated flag column, something like this:
= if Date.DayOfWeek(Calendar[Date], Day.Monday) = 6 then 1 else 0
Again, the second argument here denotes your week-start day.
Note in this instance that day of week 6 is actually 7, as Power Query is base-zero.
The advantage(?) with this method is that you can then filter the calendar table on this flag column and thus only pass your required dates to the model, so no need to write the flag column into measures etc.
Pete
Proud to be a Datanaut!
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
129 | |
90 | |
75 | |
58 | |
53 |
User | Count |
---|---|
200 | |
104 | |
101 | |
67 | |
55 |