cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
mb0307
Post Patron
Post Patron

First friday of every month - Power Query

Hi,

 

Need below in Power Query only please:

 

Using Current Month as reference, I want to create 12 blank queries which will be used as parameters -- which shows Date of First Friday of every month.  12 queries will be for last 12 months.

 

Friday.jpg

 

Thanks in advance

2 ACCEPTED SOLUTIONS

@mb0307 my bad, I didnt understand your question correctly! You can either add a custom column based on your Date column and fetch the first friday of each month for your calendar table:

 

 

Date.StartOfWeek(#date(Date.Year([Date_Key]),Date.Month([Date_Key]),7),Day.Friday)

 

 

goncalogeraldes_0-1635419400441.png

 

 

or, you can create a table with the last 12 months and add a custom column to fetch the correspondent first friday of the month:

 

 

let
    Dates = Table.FromList(    
        List.Generate(
            ()=> [Month Start = Date.StartOfMonth(Date.AddMonths(DateTime.LocalNow(),-12)), idx = 11],
            each [idx] >= 0,
            each [Month Start = Date.StartOfMonth(Date.AddMonths(DateTime.LocalNow(),-[idx])), idx = [idx]-1],
            each [Month Start]), 

            Splitter.SplitByNothing(),{"Month Start"}),
    dateType = Table.TransformColumnTypes(Dates,{"Month Start", Date.Type}),
    #"Added Custom" = Table.AddColumn(dateType, "First Friday", each Date.StartOfWeek(#date(Date.Year([Month Start]),Date.Month([Month Start]),7),Day.Friday))
in
    #"Added Custom"

 

 

goncalogeraldes_1-1635419425551.png

 

 

Hope this answer solves your problem!
If you need any additional help please @ me in your reply.
If my reply provided you with a solution, please consider marking it as a solution ✔️ or giving it a kudoe 👍
Thanks!

You can also check out my LinkedIn!

Best regards,
Gonçalo Geraldes

View solution in original post

@mb0307 hey there! No problem at all! The code is pretty similar actually:

let
    Dates = Table.FromList(    
        List.Generate(
            ()=> [Month End = Date.EndOfMonth(Date.AddMonths(DateTime.LocalNow(),-12)), idx = 11],
            each [idx] >= 0,
            each [Month End = Date.EndOfMonth(Date.AddMonths(DateTime.LocalNow(),-[idx])), idx = [idx]-1],
            each [Month End]), 

            Splitter.SplitByNothing(),{"Month End"}),
    dateType = Table.TransformColumnTypes(Dates,{"Month End", Date.Type}),
    #"Added Custom" = Table.AddColumn(dateType, "Last Friday", each Date.AddDays([Month End], -Date.DayOfWeek([Month End],Day.Friday)))
in
    #"Added Custom"

For additional help, please @ me in your reply!

You can also check out my LinkedIn!

Best regards,
Gonçalo Geraldes

View solution in original post

8 REPLIES 8
goncalogeraldes
Solution Supplier
Solution Supplier

Hello there @mb0307 ! You can achieve that with the following:

 

let
    Dates = Table.FromList(    
        List.Generate(
            ()=> [Month Start = Date.StartOfMonth(Date.AddMonths(DateTime.LocalNow(),-12)), idx = 11],
            each [idx] >= 0,
            each [Month Start = Date.StartOfMonth(Date.AddMonths(DateTime.LocalNow(),-[idx])), idx = [idx]-1],
            each [Month Start]), 

            Splitter.SplitByNothing(),{"Month Start"}),
    dateType = Table.TransformColumnTypes(Dates,{"Month Start", Date.Type})
in
    dateType

 

Hope this answer solves your problem!
If you need any additional help please @ me in your reply.
If my reply provided you with a solution, please consider marking it as a solution ✔️ or giving it a kudoe 👍
Thanks!

You can also check out my LinkedIn!

Best regards,
Gonçalo Geraldes

@goncalogeraldes  thanks for the response, but this is not giving me First Friday of the month as shown the in image of my post.  

 

Your query just return Start of Month.

@mb0307 my bad, I didnt understand your question correctly! You can either add a custom column based on your Date column and fetch the first friday of each month for your calendar table:

 

 

Date.StartOfWeek(#date(Date.Year([Date_Key]),Date.Month([Date_Key]),7),Day.Friday)

 

 

goncalogeraldes_0-1635419400441.png

 

 

or, you can create a table with the last 12 months and add a custom column to fetch the correspondent first friday of the month:

 

 

let
    Dates = Table.FromList(    
        List.Generate(
            ()=> [Month Start = Date.StartOfMonth(Date.AddMonths(DateTime.LocalNow(),-12)), idx = 11],
            each [idx] >= 0,
            each [Month Start = Date.StartOfMonth(Date.AddMonths(DateTime.LocalNow(),-[idx])), idx = [idx]-1],
            each [Month Start]), 

            Splitter.SplitByNothing(),{"Month Start"}),
    dateType = Table.TransformColumnTypes(Dates,{"Month Start", Date.Type}),
    #"Added Custom" = Table.AddColumn(dateType, "First Friday", each Date.StartOfWeek(#date(Date.Year([Month Start]),Date.Month([Month Start]),7),Day.Friday))
in
    #"Added Custom"

 

 

goncalogeraldes_1-1635419425551.png

 

 

Hope this answer solves your problem!
If you need any additional help please @ me in your reply.
If my reply provided you with a solution, please consider marking it as a solution ✔️ or giving it a kudoe 👍
Thanks!

You can also check out my LinkedIn!

Best regards,
Gonçalo Geraldes

View solution in original post

@goncalogeraldes 

 

worked perfectly.  

 

I hope you won't mind me tagging you for my future queries? 

 

Thanks again!

@mb0307 Of course not! I'll help in whatever I can 🙂

@goncalogeraldes  sorry to ask agian, what if I want to extract the LAST friday data of month please?   my requirement changed to Last friday on month.  thanks in advance if you can help.

@mb0307 hey there! No problem at all! The code is pretty similar actually:

let
    Dates = Table.FromList(    
        List.Generate(
            ()=> [Month End = Date.EndOfMonth(Date.AddMonths(DateTime.LocalNow(),-12)), idx = 11],
            each [idx] >= 0,
            each [Month End = Date.EndOfMonth(Date.AddMonths(DateTime.LocalNow(),-[idx])), idx = [idx]-1],
            each [Month End]), 

            Splitter.SplitByNothing(),{"Month End"}),
    dateType = Table.TransformColumnTypes(Dates,{"Month End", Date.Type}),
    #"Added Custom" = Table.AddColumn(dateType, "Last Friday", each Date.AddDays([Month End], -Date.DayOfWeek([Month End],Day.Friday)))
in
    #"Added Custom"

For additional help, please @ me in your reply!

You can also check out my LinkedIn!

Best regards,
Gonçalo Geraldes

View solution in original post

@goncalogeraldes  superb!  perfect result.  THANKS A LOT 🙂

Helpful resources

Announcements
UG GA Amplification 768x460.png

Launching new user group features

Learn how to create your own user groups today!

November Power BI Update 768x460.png

Check it Out!

Click here to read more about the November 2021 Updates!

M365 768x460.jpg

Microsoft 365 Collaboration Conference | December 7–9, 2021

Join us, in-person, December 7–9 in Las Vegas, for the largest gathering of the Microsoft community in the world.