cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
NatWinckler
Regular Visitor

Convert date ranges e.g. 2021/22, 2022/23 etc

I receive budget and actual amounts with assigned date ranges e.g. 2021/22, 2022/23 etc in their own "Financial Year" column, I am very new to Power Query and BI and would love to know how to these assigned dates to an actual fiscal year range. My financial year runs April to March 

1 ACCEPTED SOLUTION
v-cgao-msft
Community Support
Community Support

Hi @NatWinckler ,

Please new a blank query in Power Query Editor:

let
    startDate = #date(2020, 1, 1),                                      //start date. update the date if you need it
    endDate = Date.From(DateTime.LocalNow()),                           //Today date
    numMonths = Duration.Days(endDate - startDate),                     //get number of months
    dateList = List.Dates(startDate, numMonths, #duration(1,0,0,0)),    //generate a list of dates
    generateCalendar = List.Transform(
                            dateList, 
                            each 
                            {                                           
                                    _,                                  //date
                                    Date.Day(_),                        //get day
                                    Date.Month(_),                      //get month
                                    Date.Year(_),                       //get year
                                    Date.DayOfWeekName(_),              //get day of week name
                                    Date.MonthName(_),                  //get month name    
                                    (                                   //get financial period
                                        if Date.Month(_)-3 < 1 
                                        then Date.Month(_)+9 
                                        else Date.Month(_)-3
                                    ), 
                                    (                                   //get financial year
                                        if _ > #date(Date.Year(_),3,31) 
                                        then Date.ToText(_,"yyyy")&"/"&Date.ToText(Date.AddYears(_,1),"yy") 
                                        else Date.ToText(Date.AddYears(_,-1),"yyyy")&"/"&Date.ToText(_,"yy")
                                    )
                                }
                        ),
    output = Table.FromRows(
                    generateCalendar, 
                    {                                                   //column name: same order as above
                        "Date",                                         
                        "Day", 
                        "Month", 
                        "Year", 
                        "Day Of Week", 
                        "Month Name", 
                        "Financial Period", 
                        "Financial Year"
                    }
                )
in
    output

vcgaomsft_0-1669259978152.png

Refer:

Re: Fiscal Year / Calendar Year - Power Platform Community (microsoft.com)

 

Best Regards,
Gao

Community Support Team

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly -- How to provide sample data

View solution in original post

1 REPLY 1
v-cgao-msft
Community Support
Community Support

Hi @NatWinckler ,

Please new a blank query in Power Query Editor:

let
    startDate = #date(2020, 1, 1),                                      //start date. update the date if you need it
    endDate = Date.From(DateTime.LocalNow()),                           //Today date
    numMonths = Duration.Days(endDate - startDate),                     //get number of months
    dateList = List.Dates(startDate, numMonths, #duration(1,0,0,0)),    //generate a list of dates
    generateCalendar = List.Transform(
                            dateList, 
                            each 
                            {                                           
                                    _,                                  //date
                                    Date.Day(_),                        //get day
                                    Date.Month(_),                      //get month
                                    Date.Year(_),                       //get year
                                    Date.DayOfWeekName(_),              //get day of week name
                                    Date.MonthName(_),                  //get month name    
                                    (                                   //get financial period
                                        if Date.Month(_)-3 < 1 
                                        then Date.Month(_)+9 
                                        else Date.Month(_)-3
                                    ), 
                                    (                                   //get financial year
                                        if _ > #date(Date.Year(_),3,31) 
                                        then Date.ToText(_,"yyyy")&"/"&Date.ToText(Date.AddYears(_,1),"yy") 
                                        else Date.ToText(Date.AddYears(_,-1),"yyyy")&"/"&Date.ToText(_,"yy")
                                    )
                                }
                        ),
    output = Table.FromRows(
                    generateCalendar, 
                    {                                                   //column name: same order as above
                        "Date",                                         
                        "Day", 
                        "Month", 
                        "Year", 
                        "Day Of Week", 
                        "Month Name", 
                        "Financial Period", 
                        "Financial Year"
                    }
                )
in
    output

vcgaomsft_0-1669259978152.png

Refer:

Re: Fiscal Year / Calendar Year - Power Platform Community (microsoft.com)

 

Best Regards,
Gao

Community Support Team

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly -- How to provide sample data

Helpful resources

Announcements
Carousel_PBI_Wave1

2023 Release Wave 1 Plans

Power BI release plans for 2023 release wave 1 describes all new features releasing from April 2023 through September 2023.

Power BI Summit Carousel 2

Global Power BI Training

Make sure you register today for the Power BI Summit 2023. Don't miss all of the great sessions and speakers!

Thank you 2022 Review

2022 Monthly Feature Releases

We had a great 2022 with a ton of feature releases to help you drive a data culture.

Top Solution Authors
Top Kudoed Authors