Create a Custom Period Calendar in Power Query

In this post, I am going to show you how I created a custom period calendar table using Power Query.

Why did I need this?

I work for California State University, Chico. Enough said. Seriously though, our organization uses what we call the Faculty / Staff Calendar for payroll. You can find them @ https://www.csuchico.edu/hr/calendars.shtml. Anyone notice anything odd?

July thru September; Faculty / Staff Calendar 2018-2019

The August period is defined as August 1st – August 30th and August 31st is actually in the September period. I have been told the purpose of this is have the same number of working days in each period. I don’t believe them.

Our custom period(s)

  1. Fiscal Year defined as:
    • July 1 through June 30
  2. Monthly Periods are defined by the Chancellor’s Office
    • Officially we get an announcement saying the “calendar has been approved” generally, a couple of months before July
    • It is literally a .pdf file!

Creating a Table in Power Query

The fundamentals are discussed in Chris Webb’s BI Blog @ https://blog.crossjoin.co.uk/2016/06/03/creating-tables-in-power-bipower-query-m-code-using-table/.

This is where we are explicitly defining our Start of the Period and the End of the Period. Yes, unfortunately this is a manual process.

#table(
	type table
		[
			#"PeriodStart" = date,
			#"PeriodEnd" = date
		],
	{
		// Faculty/Staff Calendar 2018-2019
		{ #date ( 2018, 07, 01 ), #date ( 2018, 07, 31 ) },
		{ #date ( 2018, 08, 01 ), #date ( 2018, 08, 30 ) },
		{ #date ( 2018, 08, 31 ), #date ( 2018, 09, 30 ) },
		{ #date ( 2018, 10, 01 ), #date ( 2018, 10, 30 ) },
		{ #date ( 2018, 10, 31 ), #date ( 2018, 11, 29 ) },
		{ #date ( 2018, 11, 30 ), #date ( 2018, 12, 31 ) },
		{ #date ( 2019, 01, 01 ), #date ( 2019, 01, 30 ) },
		{ #date ( 2019, 01, 31 ), #date ( 2019, 02, 28 ) },
		{ #date ( 2019, 03, 01 ), #date ( 2019, 03, 31 ) },
		{ #date ( 2019, 04, 01 ), #date ( 2019, 04, 30 ) },
		{ #date ( 2019, 05, 01 ), #date ( 2019, 05, 30 ) },
		{ #date ( 2019, 05, 31 ), #date ( 2019, 06, 30 ) }
	}
)
12 custom periods for Faculty / Staff Calendar 2018-2019

Creating a Period Index

Add Column > Index Column > From 1.

Adding an Index Column

Expanding the dates between

Add Column > Custom Column

Custom Column Formula dialog window
List.Transform( { Number.From ( [PeriodStart] ) ..Number.From ( [PeriodEnd] ) }, each Date.From (_) )
Each row returns a list of values

Expand to New Rows

Expanding the list values into new rows

A list of all dates between

As you can see, now we have a list of all the calendar dates like a typical ‘Calendar’ table would have. The difference is we also have an Index number as well. Take a look at Rows 61 & 62.

The change of the Index value

Leveraging the Index

To really see how we leverage the Index values I’ll need to add additional custom periods. Since I already have the Faculty / Staff Calendar for 2017-2018, I’ll just add that too Advanced Editor.

We now have 24 Index values

We now have 24 unique custom periods; {1, 2, 3, … ,22, 23, 24} over 730 rows.

Getting Fiscal Year Period Numbers {1, 2, … , 11, 12}

The solution to this actually eluded me for a long time. My friend and co-worker, provided the answer to this.

Why don’t you use the MOD function?

Elbert Chan

You can read about MOD ( ) @ https://docs.microsoft.com/en-us/powerquery-m/number-mod.

Add Column > Custom Column


Custom Column Formula dialog window
if Number.Mod([Index], 12) = 0 then 12 else Number.Mod([Index], 12)

Now we have period numbers {1, 2, … , 11, 12}.

You can see how this works at the change to the new fiscal year.

Shows the Fiscal Year change; Period 12 to Period 1

Getting the Period Name

In Excel, you can get the Month Name by using TEXT(MONTH([Serial Number]). We can not really do something like this here. Remember some dates are allocated to a different month/period. I’ll use the example from above to demonstrate this.

Input of 8/31/2018

TEXT(MONTH(8/31/2018),"mmm")

Returns ‘Aug’

The correct Period Name should be ‘Sep’ since 8/31/2018 belongs to that period in our custom calendar.

A custom function to SWITCH ( )

The fundamentals are discussed @ https://www.powerquery.training/portfolio/replicate-power-pivots-switch-function/

  (input) =>

  let

  values = {

    {1, "Jul"},
    {2, "Aug"},
    {3, "Sep"},
    {4, "Oct"},
    {5, "Nov"},
    {6, "Dec"},
    {7, "Jan"},
    {8, "Feb"},
    {9, "Mar"},
    {10, "Apr"},
    {11, "May"},
    {12, "Jun"},
    {input, "Undefined"}

  },

  Result = List.First(List.Select(values, each _{0}=input)){1}

  in

  Result

Add Column > Custom Column

Custom Column Formula dialog window
8/31/2018 is in Period Name ‘Sep’

Combine ‘PeriodNum’ & ‘PeriodName’

The campus reporting system report that I use shows the Period as ‘##-mmm’.

Add Column > Custom Column

Custom Column Formula dialog window
Text.Combine({Text.PadStart(Number.ToText([PeriodNum]), 2, "0"),[PeriodName]}, "-")
Formatted Periods

The Fiscal Year Name/Number

Our fiscal year name for the periods July 2018 through June 2019 is 2018.

Add Column > Custom Column

Custom Column Formula dialog window
if [PeriodNum] >= 7 then Date.Year([Date]) - 1 else Date.Year([Date])
Shows the Fiscal Year change at PeriodNum >= 7

The result

If you are savvy, you probably noticed that I have been using Power BI for all of my screen captures; this could have also been done in Power Query for Excel then visualized through Power Pivot. Same exact Query Editor, same language.

After formatting and ensuring data types, like [Date] is actually of type Date, I present the final Matrix visualization in Power BI

Download the .txt file(s) and insert into the Advanced Editor

4 thoughts on “Create a Custom Period Calendar in Power Query”

  1. Any chance the PBIX file is available? I am trying to figure out how to handle a company that wants the ability to use 12 different fiscal calendars. I am not sure if I put all 12 in one calendar table and then go through a bridge table to use unique values to connect to the fact table, or 12 separate calendars and use a slicer table to choose the calendar, or some sort of dynamic setup that calculates the calendar based off… that just sounds ugly.
    Any thoughts?
    Thanks, Phil

    1. I’ve added the .txt files with the M-code so you can insert into your .pbix Advanced Editor.

      I think you could use one ‘Calendar’ table, albeit you might need to really think about the logic for the different start and end of period.

      In my final production solution I had the custom Fiscal Period Calendar as a hierarchy, a normal calendar as a hierarchy, and an ‘aid year’ hierarchy. The ‘aid year’ was just a different year number however, periods followed the normal calendar (e.g. currently FY 2021; AY 2022).

      I haven’t seen a great solution to your need though. I presume you’ve already looked at the Microsoft Power BI Community. If not, you should try looking there as well.

  2. Hello, we use Power Query to look Outlook calendar in Excel(it is quite practical to have a quick look on the events of the day without going into Outlook calendar). I would like to be able to get the categories of the events of the calendar, but it seems power Query does not deal with categories. Would you know a method please?
    Thank you in advance for your help.
    Regards,
    Yohann

    1. @Yohann – It looks like the [Categories] are contained in a ‘List’ within the Exchange Connector in Power Query. You’ll just need to extract the values from the list.

Leave a Reply to Yohann Cancel reply

Your email address will not be published. Required fields are marked *

css.php