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.

ChrisMendoza

Create a Custom Period Calendar in Power Query

Why did I need this?

My 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?

snip-faculty-staff-calendar-2018-2019-1024x319

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 ) }
	}
)

 

 

custom-power-query-table

Creating a Period Index

Add Column > Index Column > From 1.

step-1-period-index-1

Expanding the dates between

Add Column > Custom Column

step-2-dates-between

 

 

List.Transform( { Number.From ( [PeriodStart] ) ..Number.From ( [PeriodEnd] ) }, each Date.From (_) )

 

 

step-2_1-dates-between

Expand to New Rows

step-2_2-dates-between

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.

step-2_2-index-action

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.

step-3-twentyfour-index-periods

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

step-3-mod-function

 

 

if Number.Mod([Index], 12) = 0 then 12 else Number.Mod([Index], 12)

 

 

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

step-3-fy-period-nums

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

step-3-fy-period-change

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 were originally found @ 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

step-4-switch-function

step-4_1-switch-function

Combine 'PeriodNum' & 'PeriodName'

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

Add Column > Custom Column

step-5-combine-period

 

 

Text.Combine({Text.PadStart(Number.ToText([PeriodNum]), 2, "0"),[PeriodName]}, "-")

 

 

step-5_1-combine-period

The Fiscal Year Name/Number

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

Add Column > Custom Column

step-6-fiscal-year

 

 

if [PeriodNum] >= 7 then Date.Year([Date]) - 1 else Date.Year([Date])

 

 

step-6_1-fiscal-year-768x203

The result

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

step-final

Comments

Absolutely genius, thank you!

Thank you, Chris. This is a really helpful tutorial. Please can you also show me how to create an offset month, Quarter Year based on your calendar?

 

Below is the screenshot of my advanced editor. 

 

Thanks

 

let
Source = #table(
type table
[
#"PeriodStart" = date,
#"PeriodEnd" = date
],
{
//Calendar 2021-2023
{ #date ( 2021, 01, 01 ), #date ( 2021, 01, 30 ) },
{ #date ( 2021, 01, 31 ), #date ( 2021, 02, 27 ) },
{ #date ( 2021, 02, 28 ), #date ( 2021, 04, 03 ) },
{ #date ( 2021, 04, 04 ), #date ( 2021, 05, 01 ) },
{ #date ( 2021, 05, 02 ), #date ( 2021, 05, 29 ) },
{ #date ( 2021, 05, 30 ), #date ( 2021, 06, 30 ) },
{ #date ( 2021, 07, 01 ), #date ( 2021, 07, 31 ) },
{ #date ( 2021, 08, 01 ), #date ( 2021, 08, 28 ) },
{ #date ( 2021, 08, 29 ), #date ( 2021, 10, 02 ) },
{ #date ( 2021, 10, 03 ), #date ( 2021, 10, 30 ) },
{ #date ( 2021, 10, 31 ), #date ( 2021, 11, 27) },
{ #date ( 2021, 11, 28 ), #date ( 2021, 12, 31 ) },
{ #date ( 2022, 01, 01 ), #date ( 2022, 01, 29 ) },
{ #date ( 2022, 01, 30 ), #date ( 2022, 02, 26 ) },
{ #date ( 2022, 02, 27 ), #date ( 2022, 04, 02 ) },
{ #date ( 2022, 04, 03 ), #date ( 2022, 04, 30 ) },
{ #date ( 2022, 05, 01 ), #date ( 2022, 05, 28 ) },
{ #date ( 2022, 05, 29 ), #date ( 2022, 06, 30 ) },
{ #date ( 2022, 07, 01 ), #date ( 2022, 07, 30 ) },
{ #date ( 2022, 07, 31 ), #date ( 2022, 08, 27 ) },
{ #date ( 2022, 08, 28 ), #date ( 2022, 10, 01 ) },
{ #date ( 2022, 10, 02 ), #date ( 2022, 10, 29 ) },
{ #date ( 2022, 10, 30 ), #date ( 2022, 11, 26) },
{ #date ( 2022, 11, 27 ), #date ( 2022, 12, 31 ) }
}
),
#"Added Index" = Table.AddIndexColumn(Source, "Index", 1, 1, Int64.Type),
#"Added Custom" = Table.AddColumn(#"Added Index", "Custom", each List.Transform( { Number.From ( [PeriodStart] ) ..Number.From ( [PeriodEnd] ) }, each Date.From (_) )),
#"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),
#"Added Custom1" = Table.AddColumn(#"Expanded Custom", "Period Number", each if Number.Mod([Index], 12) = 0 then 12 else Number.Mod([Index], 12)),
#"Added Custom2" = Table.AddColumn(#"Added Custom1", "CurrentDate", each DateTime.Date(DateTime.FixedLocalNow())),
#"Duplicated Column" = Table.DuplicateColumn(#"Added Custom2", "CurrentDate", "CurrentDate - Copy"),
#"Extracted Year" = Table.TransformColumns(#"Duplicated Column",{{"CurrentDate - Copy", Date.Year, Int64.Type}}),
#"Duplicated Column1" = Table.DuplicateColumn(#"Extracted Year", "PeriodEnd", "PeriodEnd - Copy"),
#"Calculated Start of Month" = Table.TransformColumns(#"Duplicated Column1",{{"PeriodEnd - Copy", Date.StartOfMonth, type date}}),
#"Renamed Columns" = Table.RenameColumns(#"Calculated Start of Month",{{"PeriodEnd - Copy", "StartofMonth"}}),
#"Added Conditional Column" = Table.AddColumn(#"Renamed Columns", "Month", each if [Period Number] = 1 then "January" else if [Period Number] = 2 then "February" else if [Period Number] = 3 then "March" else if [Period Number] = 4 then "April" else if [Period Number] = 5 then "May" else if [Period Number] = 6 then "June" else if [Period Number] = 7 then "July" else if [Period Number] = 8 then "August" else if [Period Number] = 9 then "September" else if [Period Number] = 10 then "October" else if [Period Number] = 11 then "November" else if [Period Number] = 12 then "December" else "Undefined"),
#"Duplicated Column2" = Table.DuplicateColumn(#"Added Conditional Column", "Month", "Month - Copy"),
#"Split Column by Position" = Table.SplitColumn(#"Duplicated Column2", "Month - Copy", Splitter.SplitTextByRepeatedLengths(3), {"Month - Copy.1", "Month - Copy.2", "Month - Copy.3"}),
#"Changed Type" = Table.TransformColumnTypes(#"Split Column by Position",{{"Month - Copy.1", type text}, {"Month - Copy.2", type text}, {"Month - Copy.3", type text}}),
#"Renamed Columns1" = Table.RenameColumns(#"Changed Type",{{"Month - Copy.1", "MON"}}),
#"Removed Columns" = Table.RemoveColumns(#"Renamed Columns1",{"Month - Copy.2", "Month - Copy.3"}),
#"Renamed Columns2" = Table.RenameColumns(#"Removed Columns",{{"Custom", "Date"}}),
#"Changed Type1" = Table.TransformColumnTypes(#"Renamed Columns2",{{"Date", type date}}),
#"Added Custom3" = Table.AddColumn(#"Changed Type1", "Custom", each if [Period Number]>= 1 then Date.Year([Date]) - 1 else Date.Year([Date]))
in
#"Added Custom3"

@drgrd13 - I don't know if I fully understand your question.

 

...show me how to create an offset month, Quarter Year based on your calendar?

 

You can create [QuarterNum] as:

= Table.AddColumn(#"Added Custom", "QuarterNum", each if [PeriodNum] <= 3 then 1 else if [PeriodNum] <= 6 then 2 else if [PeriodNum] <= 9 then 3 else 4, Int64.Type)

to get:

image.png

In my actual .pbix, I use yyyymm as an integer, [...PeriodID] to fix granularity of an annual budget to daily transactions.

image.png

Possibly you can implement the idea of using an integer to do math operations to 'offset' periods to your criteria since you can not use Built-in DateTime Functions when using custom periods?