Create a Dynamic Calendar Table

I know this topic has been covered before, but I’m teaching a course on Power Pivot tomorrow, and it’s something that I’ll probably be brining up.  As we need a calendar table for our Power Pivot solutions, a method to create a dynamic calendar table is pretty important.  If you haven’t seen this before, I think you’ll be surprised at how easy it is to create a complete calendar driven by only a few Excel formulas and Power Query.

Setting up a dynamic source

The first key we need to do is set up a parameter table in order to hold the start and end date.  To do that, I’m creating a basic parameter table as described in this post.  Mine looks like this:

SNAGHTML3f7266cf

  • B3 is simply a hard coded January 1, 2014
  • B4 contains the =TODAY() function, returning today’s date

Once I created this table, I named it “Parameters” (as described in the aforementioned blog post), then created the fnGetParameter function in Power Query (again, as described in the aforementioned blog post.)

With that work done, it was time to move on to creating my calendar.

How to create a dynamic calendar table in Power Query

What I did at this point was create a new blank Power Query:

  • Power Query –> From Other Sources –> Blank Query

In the formula bar, I created a simple list by typing the following:

={1..10}

SNAGHTML3f7892f2

As you’ll see if you try this, it creates a simple list from 1 through 10.  That’s great, but it’s just a temporary placeholder.  Now I need to get my hands a bit dirty… I want to use the fnGetParameter function to load in my start and end dates as date serial numbers (not actual dates.)  To do this, I’ll retrieve them and explicitly force them to be Numbers.

  • Go to View –> Advanced Editor
  • Insert two new lines as follows:

let
    StartDate = Number.From(fnGetParameter("Start Date")),
EndDate = Number.From(fnGetParameter("End Date")),

Source = {1..10}
in
Source

So, as you can see, we’ve used the fnGetParameter function to retrieve the Start Date and End Date values from the Excel table, then converted them to the date serial numbers (values) by using Number.From.

With that in place, we can then sub the StartDate and EndDate variables into the list that we created in the Source step:

let
StartDate = Number.From(fnGetParameter("Start Date")),
EndDate = Number.From(fnGetParameter("End Date")),
Source = {StartDate..EndDate}
in
Source

And when we click OK, we now have a nice list of numbers that spans from the first date serial number to the last from the Excel table:

SNAGHTML3f810c61

“Great,” you’re thinking, “but I really want dates, not the date serial numbers.”  No problem, lets do that.

First we need to convert our list to a table:

  • Go to Transform –> Convert to Table –> Click OK (with the default options)

image

  • Select Column1 –> Transform –> Data Type –> Date
  • Right click Column1 –> Rename –> Date

And look at that!

SNAGHTML3f84f29c

And now it’s just a matter of adding the different date columns we need.  If you select the Date column, you’ll find a great variety of formats available under Add Column –> Date.  Just browse into the subcategory you want (year, month, day, week) and choose the piece you want to add.  In the table below, I added:

  • Date –> Year –> Year
  • Date –> Month –> Month
  • Date –> Month –> End of Month

SNAGHTML3f87a345

There are a lot of transformations for a variety of dates built in… for numeric or date values.  One thing that’s missing though, is text versions.  For those you need to add a custom column.  Here’s 3 formulas that you may find useful if you want to add text dates to your table:

  • Date.ToText([Date],"ddd")
  • Date.ToText([Date],"MMM")
  • Date.ToText([Date],"MMMM dd, yyyy")

To use them, go to Add Column –> Add Custom Column and provide those as the formula.  Their results add a bit more useful data to our query:

SNAGHTML3f907072

As you can see, they work like Excel’s TEXT function, except that the characters are case sensitive.

Conclusion

Overall, it’s super easy to create a dynamic calendar table using Power Query to read the start and end date from Excel cells.  This makes it very easy to scope your calendar to only have the date range you need, and also gives you the ability to quick add columns on the fly for formats that you discover you need, rather than importing a massive calendar with a ton of formats that you will never use.

In addition to being easy, it’s also lightening quick if you’re prepared.  It takes seconds to create the Excel parameter table, a few more seconds to set up the fnGetParameter function (if you have the code stored in a text file/bookmarked), and only a little while longer to create the original list and plumb in the variables once you’re used to it.  I can knock up a calendar like this in less than two minutes, and let it serve my data model every after.  🙂

PowerQuery.Training

I should also mention that this is one of the techniques (amongst MANY others) that we cover in our PowerQuery.Training course.  We’ll be announcing a new intake soon, so don’t forget to sign up for the newsletter in the footer of the site so you’ll know when that happens!

Listing Outstanding Cheques

Power Query is all about transforming and filtering data, and automating the process.  One of the tedious tasks that accountants get to deal with all the time is bank reconciliations, which is essentially the process of filtering and matching items to see what is left over.  It’s been on my list for a while now, but I’ve been thinking that we can use Power Query for listing outstanding cheques (or checks if you’re in the USA).

The completed workbook is available for download by clicking here.

Background

Because I don’t want to run on to 100 pages, I’m going to start with two lists that show just the cheques, in two tables:

SNAGHTML1901ec84

The table on the left is the table of cheques that have been issued, as per the list maintained in the General Ledger. We’re making the assumption that we’ve dumped that list into an Excel worksheet, formatted it as a table, and given the table the name “GLListing”.

The table on the right is the table of the cheques that have cleared the bank.  Again, the assumption is that we’ve been able to download a list of the transactions, and filtered them down to show just the cheques that have cleared.  (Maybe we’d even use Power Query to do this.)  This table has been named “Bank”

Creating the data Staging queries

The first step is to create the staging queries to connect to these two tables.  One of the important things I wanted to ensure is that I can match transactions where both the cheque number and amount are identical.  (If a cheque clears for the wrong amount, I want to list it as outstanding at this point, as I need to review it.)  I’m going to keep that in mind as I create my staging tables.

The GLListing table:

To set this up I:

  • Clicked inside the GLListing table –> Power Query –> From Table
  • Set the data types on each column (Whole Number, Date, Decimal)
  • Selected the Cheque and Amount columns –> Add Column –> Merge
    • Separator:  Custom (I used a dash)
    • Name:  Issued

The end result in Power Query:

image

  • Go to Home –> Close & Load –> Close & Load To… –> Only Create Connection

The Bank table:

It’s virtually the identical process:

  • Click inside the Bank table –> Power Query –> From Table
  • Set the data types on each column (Whole Number, Date, Decimal)
  • Selected the Cheque and Amount columns –> Add Column –> Merge
    • Separator:  Custom (I used a dash)
    • Name:  Cleared

The end result in Power Query:

image

  • Go to Home –> Close & Load –> Close & Load To… –> Only Create Connection

Listing Outstanding Cheques

Now to build the important part.

  • In the Workbook Queries pane, right click the GLListing query—> Reference

At this point you’ll have a pointer to the GLListing table.  We also want a pointer to the Bank table.  To do that, let’s click the fx icon on the formula bar:

image

This will create a new step in your query.  The formula in the formula bar will read =Source (it refers to the previous step), and you’ll see a new step in your Applied Steps area called Custom1.  Let’s update both of those:

  • Change the formula to =Bank
  • Right click and rename the step to “Bank”

image

The key things we now have are a Source step (which contains the output of the GLListing query) and a Bank step (which contains the output of the Bank query).  The Source step has an Issued column, the Bank query a Cleared column, and we’ll like to know which items between those two columns are different.

To work this out we’re going to knock up a little M code.  Here’s how:

  • Click the fx icon on the formula bar
  • Replace the formula (it will read =Bank) with this:

=List.Difference(Source[Issued],Bank[Cleared])

The result will be as follows:

image

So what happened here?  Let’s break this down.

List.Difference generates the items that are different between two provided lists.  And fortunately, when we feed a column to the function, it passes it in as a list.  So that’s what you’re seeing there:

  • Source[Issued] is the Issued column from the Source step of our query
  • Bank[Cleared] is the Cleared column from the Bank step of our query

And the result is the only items that don’t exist in both lists.

Expanding the Details

As great as this is, it is returning a list of values.  We want to convert this back into a table, and get the original data of issue as well.  So let’s do that.

  • Go to Transform –> To Table

image

  • When prompted, select that the list has a Custom Delimiter of a dash and click OK

You should now have a nice table split into two columns:

image

Let’s clean this up:

  • Right click Column1 –> Rename –> Cheque
  • Right click Column2 –> Rename –> Amount

Now, the next tricky part is getting the issue date back in.  I’d like to feed this from the current query – just to keep it self contained – but it’s easier to start by merging it with another query.

  • Go to Home –> Merge Queries –> GLListing
  • Choose to merge based on the Cheque field on both tables
  • Make sure you check to “Only include matching rows”

image

  • Click OK

This works nicely to add our column, but we’ve already pulled this data into this query once, so why reach outside it again?  If you look in the formula bar, you can see that the formula reads as follows:

= Table.NestedJoin(#"Renamed Columns",{"Cheque"},GLListing,{"Cheque"},"NewColumn",JoinKind.Inner)

Highlighted in the middle of the text is the name of the table we merged into this one.  So why not just replace that with the step name from this query that has the same table?  Modify the formula in the formula bar to read:

= Table.NestedJoin(#"Renamed Columns",{"Cheque"},Source,{"Cheque"},"NewColumn",JoinKind.Inner)

It doesn’t look like anything happened, does it?  That’s okay.  Remember that the source step just pulls in the data from the GLListing query.  Since we didn’t do anything to it in that step, it SHOULD look identical.

Now we can continue on and finalize the query:

  • Expand the “NewColumn” column:
    • Only expand the Date column, as we have the others we need
    • Uncheck the “Use original column name as prefix” setting
  • Move the Date column between then Cheque and Amount columns

image

  • Rename the query to “Outstanding”
  • Go to Home –> Close & Load

And the final result:

SNAGHTML1b93e715

Final Thoughts

Figuring out which records match is actually pretty easy.  We simply merge two tables, and choose to only include matching rows.  Working out differences is obviously a bit harder.  (Wouldn’t it be awesome if there was an inverse setting on that merge dialog that let us only include unmatched rows?)

I left my full time controllership job before I ever got the chance to implement this technique for our bank reconciliations.  Currently there is a lot of VBA and manual work needed to clear both the cheques and deposits on a monthly basis.  Given this, however, I know that I could have re-written the bank reconciliation to very quickly eliminate all the records that match, leaving me with only the transactions that I actually needed to focus on.

Taking it even one step further, with another table of adjustments added in to the mix, I’m sure I could build it to actually produce an ever diminishing listing of un-reconciled transactions, and most likely even an output report replicating a full bank reconciliation.  Pretty cool, especially when you consider how much could be refreshed when you start the process next month!

Calculate Hours Worked

Chandoo posted an interesting challenge on his blog last Friday, challenging users to calculated hours worked for an employee name Billy.  This example resonated with me for a couple of reasons.  The first is that I’ve had to do this kind of stuff in the past, the second is because I’ve got a new toy I’d use to do it.  (Yup… that toy would be Power Query.)

It always blows my mind how many people respond on Chandoo’s blog.  As the answers were pouring in, I decided to tackle the issue my own way too.  I thought I’d share a bit more detailed version of that here as I think many users still struggle with time in Excel.

Background and Excel Formula Solution

Chandoo provided a sample file on his blog, so I downloaded it.  The basic table of data looks like this:

SNAGHTMLeb2f08

Now, for anyone who has done this a long time, there a few key pieces to solving this:

  • The recognition that all times are fractions of days,
  • The recognition that if you omit the day it defaults to 1900-01-01, and
  • The data includes End times that are intended to be the day following the Start time

The tricks we use to deal with this are:

  • Test if the End time is less than the start time.  If so, add a day.  (This allows us to subtract the Start from the End and get the difference in hours.
  • Multiply the hours by 24.  (This allows us to convert the fractional time into a number that represents hours instead of fractions of a day.)

Easy enough, and the following submitted formula (copied down from F4:F9 and summed) works:

=(D4+IF(C4>D4,1,0)-C4)*24

SNAGHTMLea6d3e

Also, there was a great comment that Billy shouldn’t get paid for his lunch break.  Where I used to work (before I went out on my own), we had a rule that if you worked any more than 4 hours you MUST take a lunch break.  Plumbing in that logic, we’d would need a different formula.  There’s lots that would work, and this is one:

=((D4+IF(C4>D4,1,0)-C4)*24)-IF(((D4+IF(C4>D4,1,0)-C4)*24)>4,1,0)

SNAGHTMLf008e9

So why Power Query?

If we can do this in Excel, why would we cook up a Power Query solution?  Easy.  Because I’m tired of having to actually write the formula every time Billy sends me his timesheet. Formula work is subject to error, so why not essentially automate the solution?

Using Power Query to Calculate Hours Worked

Okay, first thing I’m going to do is set up a system.  I’m set up a template, email to Billy and get him to fill it out and email it to me every two weeks.  I’ll save the file in a folder, and get to work.

  • Open a blank workbook –> Power Query –> From File –> From Excel
  • Browse and locate the file
  • Select the “Billy” worksheet (Ok, to be fair, it would probably be called Sheet1 in my template)

image

  • Click Edit

And now the fun begins…

  • Home –> Remove Rows –> Remove Top Rows –> 2
  • Transform –> Use First Row as Headers
  • Filter the Day column to remove (null) values
  • Select the Day:End columns –> right click –> Remove Other Columns

And we’ve now got a nice table of data to start with:

SNAGHTMLfb3d71

Not bad, but the data type for the Start and End columns is set to “any”.  That’s bad news to me, as I want to do some Date/Time math.  The secret here is that we need our values to be Date/Times (not just times), so let’s force that format on them, just to be safe:

  • Select Start:End –> Transform –> Date/Time

Next, we need to test if the Start Date occurs after the End Date.  Let’s use one step to test that and add one day if it’s true:

  • Add Column –> Add Custom Column
    • Name:  Custom
    • Formula:  =if [Start]>[End] then Date.AddDays([End],1) else [End]

So basically, we add 1 day to the End data if the Start time is greater than the end time.  Once we’ve done that, we can:

  • Right click the End column –> Remove
  • Right click the Custom column –> Rename –> End

And, as you can see, we’ve got 3 records that have been increased by a day (they are showing 12/31/1899 instead of 12/30/1899

image

Good stuff, let’s figure out the difference between these two. The order of the next 3 steps is important…

  • Select the End column
  • Hold down the CTRL key and select the Start column
  • Go to Add Column –> Time –> Subtract

Because we selected the Start column second, it is subtracted from the End column we selected first:

image

Now we can set the Start and End columns so that only show times, as we don’t need the date portion any more.  In addition, we want to convert the TimeDifference to hours:

  • Select the Start:End columns –> Transform –> Time
  • Select the TimeDifference column –> Transform –> Decimal Number

Hmm… that didn’t work quite as cleanly as we’d like:

image

Ah… but times are fractions of days, right?  Let’s multiply this column by 24 and see what happens:

  • With the TimeDifference column selected:  Transform –> Standard –> Multiply –> 24
  • Right click the TimeDifference column –> Rename –> Hours

Nice!

image

Oh… but what about those breaks?

  • Add Column –> Add Custom Column
    • Name:  Breaks
    • Formula:  =if [Hours]>4 then -1 else 0
  • Add Column –> Add Custom Column
    • Name:  Net Hours
    • Formula:  =[Hours]+[Breaks]

And here we go:

image

At this point I would generally:

  • Change the name of the query to something like:  Timesheet
  • Close and Load to a Table
  • Add a total row to the table

SNAGHTML12fe424

But just in case you only cared about the total of the Net Hours column, we could totally do that in Power Query as well.  Even though it’s not something I would do (I’m sure Billy would trust YOU implicitly and never want to see the support that proved you added things up correctly…), here’s how you’d do it:

  • Go to Transform –> Group By
  • Click the – character next to the Day label to remove that grouping level
  • Set up the Grouping column:
    • Name:  Net Hours
    • Operation:  Sum
    • Column:  Net Hours

Here’s what it looks like if you set the column details up first, indicating where to click to remove the grouping level:

image

And the result after you click OK:

SNAGHTML1344d4b

Holy Cow that’s a LOT of Work!?!

Not really.  Honestly, it took me about a minute to cook it up.  (And a LOT longer to write this post.)  But even better, this work was actually an investment.  Next time I get a timesheet, I just save it over the old one, open this file, right click the table and click Refresh.  Done, dusted, finished and time to move on to more challenging problems.

Even better, if I wanted to get really serious with it, I could implement a parameter function to make the file path relative to the file, and then I could pass it off to someone else to refresh.  Or automate the refresh completely.  After all, why write formulas every month if you don’t have to?

🙂

Excel Text Function Equivalents

For some time it’s bothered me that we don’t have full parity between Excel and Power Query functions.  In this post I’m going to look at four Excel text function equivalents, intended to allow an Excel user to just work with formulas as they’re used to.

=LEFT()

The first function is the LEFT function which, if implemented in M, would be:

(text as text,num_chars as number)=>
let
ReturnValue = Text.Start(text,num_chars)
in
ReturnValue

You’d call it like so:

=LEFT([Word],4)

And it would return the Excel text function equivalent as shown here.  (Excel’s output is in teh LEFT(x,4) column, and the Power Query LEFT function is shown in the pqLeft column.)

image

This one may not be a big deal, as it’s just a new function name, but it now works exactly as an Excel user would expect.  (Except for the fact that you MUST type the function name in uppercase.)

=RIGHT()

We can do the same thing with the RIGHT function:

(text as text,num_chars as number)=>
let
ReturnValue = Text.End(text,num_chars)
in
ReturnValue

And call it with:

=RIGHT([Word],4)

Returning:

image

=LEN()

This is yet another simple one:

(text as text)=>
let
ReturnValue = Text.Length(text)
in
ReturnValue

Called with:

=LEN([Word])

Returning:

image

Why I care about Excel text function equivalents?

Beyond allowing a user to just use the knowledge they’ve been investing in for years, it’s the next function that makes a difference.  With the MID function we have a bunch of things that are different, and to replicate our expectations we need to do some manipulation and conditional testing.

=MID()

This is what it takes to replicate the MID() function in Power Query:

(text as text,start_num as number,num_chars as number)=>
let

tLength = Text.Length(text),
StartCorrected = if start_num>tLength then -1 else start_num-1,
ReturnCorrected = if (StartCorrected+num_chars) > tLength then tLength - start_num + 1 else num_chars,
ReturnValue = if StartCorrected >-1
then Text.Range(text,StartCorrected,ReturnCorrected)
else null
in
ReturnValue

That’s a fairly big pain to just knock up in a couple of seconds!  But once done, it’s easy to use:

=MID([Word],5,4)

And it returns results consistent to Excel as well:

image

Final Thoughts

I really wish these functions were built under and consistent with Excel’s function names to begin with.  While we can replicate their form and function, it takes a lot of work to create/debug and implement them in a power query solution.  In addition, some of the functions are VERY difficult to built.  But regardless, at least we can.

Naming Conflict Fun

Jeff Weir published a post at DDOE last week on global names freaking out when a local name is encountered.  It reminded me that I ran into something similar when I was testing text functions in Power Query a while back; a naming conflict when I created a table from Power Query.

Interestingly, I can replicate this without Power Query at all using just native table functionality.

Set up a Table

To begin with I created a very simple table:

SNAGHTML868f307

Then I gave the table a name.  In this case, for whatever reason, I chose “mid”:

SNAGHTML869e527

Enter Wonkiness (Naming Conflict)…

Okay, it’s a weird table name.  I get that.  But in my original example I was comparing Power Query’s Text.Range function with the MID function, which is why I named my table mid…  anyway…

Add a new column and type in =MID

SNAGHTML86ce5c5

You can see that we’ve plainly chosen the MID that refers to the function, not the table.  I even set the capitalization correctly to make sure I got the right one.  Now complete the formula:

=MID([@Product],3,1]

SNAGHTML86e317f

And press Enter:

SNAGHTML86f7672

Nice!  Apparently Excel is too smart for it’s own good and overrules the interpretation of built in functions with table names, resulting in a #REF! error.

Fixing the issue

The solution to fix this should be pretty obvious… rename the table.  When you do, you’ll see that it also updates the formula:

SNAGHTML8739b0e

Plainly Excel was very confused! So now we just need to fix the formula:

SNAGHTML87501e1

And we’re good.  🙂

End Thoughts

To cause this issue from Power Query, you simply need to give your query a name that conflicts with an Excel function (like MID).  When it's loaded to an Excel table, that table inherits the query name as the table name.

The naming conflict issue has probably existed since tables were implemented in Excel.  It’s not good, but at the same time, it’s taken me a long time to trip on this, as I don’t usually use a table name that conflicts with a built in function name… at least not one that I use.

Long story short:  Avoid naming your tables (or Power Queries) after Excel function names.  😉