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
Anonymous
Not applicable

Get Remaining Working days for each day in month

Hi,

 

I am trying to calculate the Working days remaining for each month,

 

I have created a column to calculate if each day is Working day or not, But my requirement is if it is weekend or a non working day then it should show the previous days remaining working days

I have created the Rank for Working Day in Month by using the following DAX

Rank For Working Day in Month =
// Calculates the Working Day Rank by YearMonth
VAR AllDates = Dates[Date]
VAR YearMon = Dates[YearMon]
RETURN
CALCULATE (
RANK.EQ ( AllDates, Dates[Date], DESC ),
FILTER ( ALL( Dates ), AND(Dates[WorkingDay] = "Y", Dates[YearMon] = YearMon)
))

 

DateWorkingDayRank For Working Day in Month
Thursday, 1 August 2019Y21
Friday, 2 August 2019Y20
Saturday, 3 August 2019N 
Sunday, 4 August 2019N 
Monday, 5 August 2019Y19
Tuesday, 6 August 2019Y18
Wednesday, 7 August 2019Y17
Thursday, 8 August 2019Y16
Friday, 9 August 2019Y15
Saturday, 10 August 2019N 
Sunday, 11 August 2019N 
Monday, 12 August 2019Y14
Tuesday, 13 August 2019Y13
Wednesday, 14 August 2019Y12
Thursday, 15 August 2019Y11
Friday, 16 August 2019Y10
Saturday, 17 August 2019N 
Sunday, 18 August 2019N 
Monday, 19 August 2019Y9
Tuesday, 20 August 2019Y8
Wednesday, 21 August 2019Y7
Thursday, 22 August 2019Y6
Friday, 23 August 2019Y5
Saturday, 24 August 2019N 
Sunday, 25 August 2019N 
Monday, 26 August 2019N 
Tuesday, 27 August 2019Y4
Wednesday, 28 August 2019Y3
Thursday, 29 August 2019Y2
Friday, 30 August 2019Y1
Saturday, 31 August 2019N 

 

This is what I have achieved so for but, as you can see there are blanks for example on the 3rd and 4th I need to get 20.

 

Could anybody please help me in this regard.

 

Thanks,

Prime

1 ACCEPTED SOLUTION
Anonymous
Not applicable

I have created 2 Calculated columns in Date table

Rank For Working Day in Month =
// Calculates the Working Day Rank by YearMonth
VAR AllDates = Dates[Date]
VAR YearMon = Dates[YearMon]
RETURN
CALCULATE (
RANK.EQ ( AllDates, Dates[Date], DESC ),
FILTER ( ALL( Dates ), AND(Dates[WorkingDay] = "Y", Dates[YearMon] = YearMon)
))
 
and
 
Rank For NON Working Day in Month =
// Calculates the Working Day Rank by YearMonth
VAR AllDates = Dates[Date]
VAR YearMon = Dates[YearMon]
RETURN
CALCULATE (
RANK.EQ ( AllDates, Dates[Date], DESC ),
FILTER ( ALL( Dates ), AND(Dates[WorkingDay] = "N", Dates[YearMon] = YearMon)
))
 
which gives the raking for working days and NON working days in a month in 2 column. Note YearMon is the concatination of Year and Month
 
Now the finale Measure is
 
No Of Working Days Reamining =

VAR NoOfDaysInMonth = DAY(
IF(
MONTH(MAX(Dates[Date])) = 12,
DATE(YEAR(MAX(Dates[Date])) + 1,1,1),
DATE(YEAR(MAX(Dates[Date])), MONTH(MAX(Dates[Date])) + 1, 1)
) - 1
)

VAR CalculationForNonWorkingDays = NoOfDaysInMonth- MAX(Dates[Rank For NON Working Day in Month]) - MAX(Dates[DayNo]) + 1

Return

IF(MAX(Dates[Rank For Working Day in Month]) = BLANK(),CalculationForNonWorkingDays,MAX(Dates[Rank For Working Day in Month]))

 

 

Regards,

Prime

View solution in original post

6 REPLIES 6
Anonymous
Not applicable

DAX is not a tool for this. Use Power Query for this since it's where such calculations belong.

Best
D.
Anonymous
Not applicable

Thanks for your suggestion.

But unfortunately this is a date table and created using the CALENDERAUTO() as shown in below syntax

Dates =
ADDCOLUMNS (
CALENDARAUTO(),
"DateAsInteger", FORMAT ( [Date], "YYYYMMDD" ),
"Date 2", FORMAT([Date], "ddd dd/mm/yyyy"),
"Year", YEAR ( [Date] ),
"Monthnumber", MONTH([Date]),
"YearMonthnumber", FORMAT ( [Date], "YYYY/MM" ),
"YearMonthShort", FORMAT ( [Date], "YYYY/mmm" ),
"MonthNameShort", FORMAT ( [Date], "mmm" ),
"MonthNameLong", FORMAT ( [Date], "mmmm" ),
"DayOfWeekNumber", WEEKDAY ( [Date] ),
"Month", MONTH([DATE]),
"DayOfWeek", FORMAT ( [Date], "dddd" ),
"DayOfWeekShort", FORMAT ( [Date], "ddd" ),
"Quarter", "Q" & FORMAT ( [Date], "Q" ),
"YearQuarter", FORMAT ( [Date], "YYYY" ) & "/Q" & FORMAT ( [Date], "Q" ),
"YearMon", FORMAT ( [Date], "YYYY" ) & FORMAT ( [Date], "mmm" ),
"WeekNo", FORMAT([Date], "ww"),
"DayNo", FORMAT([Date], "d"),
"MonthLongYear", FORMAT ( [Date], "mmmm" ) & " " & FORMAT([Date], "YYYY"),
"DayNoMonthShort", FORMAT([Date], "ddd") & " " & FORMAT([Date], "d"),
"DayNoINT", DAY([Date]),
"DDMMYYYY", FORMAT([Date], "DD/MM/YYYY")
)
Anonymous
Not applicable

Then create a proper Date table in PQ. If you don't know how, you'll find it via Google.

That's really easier than you think.

Best
D.
Anonymous
Not applicable

I have created a date table in PQ, just wondering how do I account bank holidays into PQ?

Anonymous
Not applicable

Create a table of bank holidays using data found on the web and then left outer join the Date table to the Bank Holidays table. This is also easy.

Best
D.
Anonymous
Not applicable

I have created 2 Calculated columns in Date table

Rank For Working Day in Month =
// Calculates the Working Day Rank by YearMonth
VAR AllDates = Dates[Date]
VAR YearMon = Dates[YearMon]
RETURN
CALCULATE (
RANK.EQ ( AllDates, Dates[Date], DESC ),
FILTER ( ALL( Dates ), AND(Dates[WorkingDay] = "Y", Dates[YearMon] = YearMon)
))
 
and
 
Rank For NON Working Day in Month =
// Calculates the Working Day Rank by YearMonth
VAR AllDates = Dates[Date]
VAR YearMon = Dates[YearMon]
RETURN
CALCULATE (
RANK.EQ ( AllDates, Dates[Date], DESC ),
FILTER ( ALL( Dates ), AND(Dates[WorkingDay] = "N", Dates[YearMon] = YearMon)
))
 
which gives the raking for working days and NON working days in a month in 2 column. Note YearMon is the concatination of Year and Month
 
Now the finale Measure is
 
No Of Working Days Reamining =

VAR NoOfDaysInMonth = DAY(
IF(
MONTH(MAX(Dates[Date])) = 12,
DATE(YEAR(MAX(Dates[Date])) + 1,1,1),
DATE(YEAR(MAX(Dates[Date])), MONTH(MAX(Dates[Date])) + 1, 1)
) - 1
)

VAR CalculationForNonWorkingDays = NoOfDaysInMonth- MAX(Dates[Rank For NON Working Day in Month]) - MAX(Dates[DayNo]) + 1

Return

IF(MAX(Dates[Rank For Working Day in Month]) = BLANK(),CalculationForNonWorkingDays,MAX(Dates[Rank For Working Day in Month]))

 

 

Regards,

Prime

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.

Top Solution Authors