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

Be 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

Reply
tacobannas
Regular Visitor

Return the 2nd Tuesday of every Month

I am trying to return the 2nd Tuesday of every month. My table has a date for everyday. How can I return this based on the that field. 

1 ACCEPTED SOLUTION

Please try this as a caluculated column

 

Is 2nd Tuesday = 
VAR a = 'Dates'[Date]
VAR y = FILTER(
        ALL(Dates[Date]),
        YEAR('Dates'[Date]) = YEAR(a) && 
        MONTH('Dates'[Date]) = MONTH(a) && 
        DAY([Date]) > 7 && 
        DAY([Date]) < 15 && 
        WEEKDAY([Date],3) = 1)
RETURN MAXX(y,[Date])

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

Proud to be a Datanaut!

View solution in original post

15 REPLIES 15
MFelix
Super User
Super User

Hi @tacobannas,

 

Create these two column:

 

MonthWeekday = MONTH('Calendar'[Date]) & WEEKDAY('Calendar'[Date]) 

weekday_Number = WEEKDAY('Calendar'[Date])

 

Then create this measure:

 

2nd Tuesday =
VAR Date_Max =
    MAX ( 'Calendar'[Date] )
VAR Month_week_Max =
    MAX ( 'Calendar'[MonthWeekday] )
RETURN
    IF (
        CALCULATE (
            COUNT ( 'Calendar'[MonthWeekday] ),
            'Calendar'[Date] <= Date_Max,
            'Calendar'[MonthWeekday] = Month_week_Max
        )
            = 2
            && MAX ( 'Calendar'[weekday_Number] ) = 3,
        "2nd",
        ""
    )

 

Add the measure as a filter on your visuals and you should get the result you need:

dates.png

 

Regards,

MFelix


Regards

Miguel Félix


Did I answer your question? Mark my post as a solution!

Proud to be a Super User!

Check out my blog: Power BI em Português



Thanks, that works as a measure, but I was hoping to return the 2nd Tuesday each month as a date in a column. So for everday of the month in my calendar table I would have a corresponding column with the 2nd Tuesday date. 

Please try this as a calculated column

 

Is 2nd Tuesday = 
VAR x =  IF(WEEKDAY([Date],1) = 3 , DAY([Date]) , 0)
RETURN IF(x > 7 && x < 15 , 1 , 0)

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

Proud to be a Datanaut!

That appears to work returning true or false, however I want to return the actual date of the 2nd Tuesday. 

2017-12-05_12-25-54.png

 

 

Hi

 

Please try this

 

Is 2nd Tuesday = 
VAR x =  IF(WEEKDAY([Date],1) = 3 , DAY([Date]) , 0)
RETURN IF(x > 7 && x < 15 , [Date] , blank())

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

Proud to be a Datanaut!

Anonymous
Not applicable

Hi,

How to get the last tuesday of a month? I want to add a calculated coloumn in my table which should return the current month of the date of that row. But current is from Last wednesday of the previous month to last tuesday of the current month rather than just month(date).

This appears to be working, but I need that to be filled into every row value pair, not blank in the instance it is not the 2nd Tuesday. 

So do you mean every row for the month will carry the date that happens to be the 2nd tuesday of each month?


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

Proud to be a Datanaut!

Please try this as a caluculated column

 

Is 2nd Tuesday = 
VAR a = 'Dates'[Date]
VAR y = FILTER(
        ALL(Dates[Date]),
        YEAR('Dates'[Date]) = YEAR(a) && 
        MONTH('Dates'[Date]) = MONTH(a) && 
        DAY([Date]) > 7 && 
        DAY([Date]) < 15 && 
        WEEKDAY([Date],3) = 1)
RETURN MAXX(y,[Date])

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

Proud to be a Datanaut!

@tacobannas my Power Query solution also fits your requirements.

Specializing in Power Query Formula Language (M)

 

@MarcelBeug I am not sure how to convert that power query statement into the correct power bi syntax. 

Power BI encompasses 2 languages: Power Query (M) and DAX.

 

If you're not comfortable with Power Query, you can use a DAX solution.

 

Also Power Query is correct Power BI syntax.

As I already explained, in the Query Editor you can add a custom column.

 

A screen shot of adding a custom column (taken from another topic, so with another formula):

Adding a custom column in the Query Editor.png

 

 

Specializing in Power Query Formula Language (M)

@MarcelBeug thanks for the further clarification. My date table is not a table that shows up in query editor, so I am guessing I can't use your Power Query solution.... I created the date table by creating a new caculated column. I am probably a bit more confused as well since I am new to PowerBI 🙂

 

However @Phil_Seamark solution is working so I think I will just stick with that. 

 

2ndTuesday = VAR a = 'Date'[Date]
VAR y = FILTER(
        ALL('Date'[Date]),
        YEAR('Date'[Date]) = YEAR(a) && 
        MONTH('Date'[Date]) = MONTH(a) && 
        DAY('Date'[Date]) > 7 && 
        DAY('Date'[Date]) < 15 && 
        WEEKDAY('Date'[Date],3) = 1)
RETURN MAXX(y,'Date'[Date])

 

Thanks everyone for the help and quick response

A power Query solution: add a column with formula:

 

= Date.StartOfWeek(#date(Date.Year([Date]),Date.Month([Date]),14),Day.Tuesday)

 

This wil take the 14th of the year/month of the date, and from that date: the start of the week, with Tuesday as the first day of the week. So that must be the 2nd Tuesday in the month.

Specializing in Power Query Formula Language (M)

@MarcelBeug: I found this method super helpful in getting Daylight Savings Time for a local refresh time function

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.