Featured image of post Overcoming Date Range Hurdles (Power BI/DAX)

Overcoming Date Range Hurdles (Power BI/DAX)

The single biggest challenge when developing a reporting solution is data. Invariably, you won’t always have one database that contains all the information you need; often, you will need to bring across disparate and unrelated data sources into a common model. This problem can be exasperated if your organisation has a number of application or database systems from different vendors. Finding a tool that can overcome some of these hurdles is a real challenge. For example, whilst I am a huge fan of SQL Server Reporting Services, the out of the box data connection options are generally limited to common vendor products or ODBC/OLE DB data sources. Case in point: Finding or even developing a Data Source that can support a JSON stream can be troublesome and complicated to configure. With the landscape as such, the reporting tool that can offer the most streamlined method of overcoming these challenges is the tool that is going to win the day.

Following on from my deep-dive with the product last year, I have been working more and more with Power BI in recent weeks. What I like most about the tool is that a lot of the hassle is taken out of configuring your data sources. Power BI does this by leveraging the existing Power Query language and equipping itself with a large number of Data Source Connectors. The most surprising aspect of this? Microsoft products form only a subset of the options available, with connectors in place for many of competitor products from the likes SAP, SalesForce and Oracle. In my limited experience with the product to date, I have yet to find a data source that it does not support, either as part of a data connector or a manual Power Query.

A recent work example can best illustrate the above, as well as showcasing some of the built-in functionality (and learning curves!) that come to working with data via Power Query and writing Data Analysis Expressions (DAXs). There was a requirement to generate an internal department dashboard for an IT service desk. The dashboard had to meet the following key requirements:

  • Display a summary of each team members movements for the current week, including the location of each person on that current day. Each member of the team was already recording their weekly movements within their Exchange calendar as all day appointments, configuring the Subject field for each appointment accordingly. For example, In OfficeWorking at Home etc. No other all day appointments were booked in the calendars.
  • Query Dynamics CRM and return data relating to Active/Inactive Case records.
  • To be displayable on a TV/Screen, refresh automatically and be exportable as a .pdf document or similar.

A CRM Dashboard can achieve about 50-60% of the above, but the key requirements of querying Exchange and exporting the dashboard are much more tricky; whilst it is certainly possible to perform web service requests from within CRM to Exchange, the process would be so convoluted to implement that is arguably not worth the effort. Likewise, CRM is not particularly friendly when it comes to printing out Dashboards, as you often left to the mercy of the web browser in question. With all this in mind, we decided that Power BI was the best option and proceeded to bring all the data together using PowerQuery.

We first used the out of the box Exchange connector to query each person’s mailbox for all Calendar items, performing two transformations on the data. First, we filtered the result to return Calendar items from the current week and, second, we added a column to identify which Calendar the record derives from (as there is no field on each record to determine this). We’ll see why this is required in a few moments:

let
    Source = Exchange.Contents("john.smith@domain.com"),
    Calendar1 = Source{[Name="Calendar"]}[Data],
    #"Filtered Rows" = Table.SelectRows(Calendar1, each Date.IsInCurrentWeek([Start])),
    #"Added Custom" = Table.AddColumn(#"Filtered Rows", "Owner", each "John Smith")
in
    #"Added Custom"

Next, we combined all Calendars together into one table - again using Power Query. Table.Combine is a comma-separated list of all tables you want to merge together, so you can add/remove accordingly to suit your requirements. We also take this opportunity to remove unnecessary fields and convert our Start and End field values to their correct type:

let
    Source = Table.Combine({Calendar1, Calendar2, Calendar3}),
    #"Removed Columns" = Table.RemoveColumns(Source,{"Folder Path", "Location", "DisplayTo", "DisplayCc", "RequiredAttendees", "OptionalAttendees", "LegacyFreeBusyStatus", "IsReminderSet", "ReminderMinutesBeforeStart", "Importance", "Categories", "HasAttachments", "Attachments", "Preview", "Attributes", "Body"}),
    #"Changed Type" = Table.TransformColumnTypes(#"Removed Columns",{{"Start", type date}, {"End", type date}})
in
    #"Changed Type"

Our CRM data is returned via an adapted version of the query used previously on the blog, taking into account the benefits of using a Saved Query as opposed to FetchXML. No further work is required to manipulate the data once in Power BI, so this won’t be covered any further. Our issue is now with the Exchange Calendars. Because the appointments in the Calendars to indicate each person’s movement are set as All Day appointments spanning multiple days, we have no way of extrapolating the days in between to determine whether it is the current day. So for example, if the all-day Appointment starts on Monday and ends on Wednesday, we have Monday and Wednesday’s date, but not Tuesday’s. We, therefore, need to find a solution that determines whether the appointment falls on a specific day of the week - Monday, Tuesday, Wednesday, Thursday or Friday.

Our first step is to generate a date table covering the entire period we are concerned with. Using this very handy query, we can set up a Power BI function that will allow us to generate just that - in this case, for the whole of 2017:

Why do we need this? Because we need to determine for each date in 2017 what day it falls on. For this reason, we now take off our Power Query hat and jam on our DAX one instead 🙂 Close & Apply your queries in Power BI and then navigate to your new date table. Add a new Column, using the following DAX formula to populate it:

Day of Week (Number) = WEEKDAY('2017'[Date], 2)

The WEEKDAY function is an incredibly handy function in this regard, enabling us to determine the day of the week for any date value. Nice! We can now go back to our “unified” calendar, and perform the following modifications to it:

  • Add on a column that returns a TRUE/FALSE value for each row on our calendar, which tells us if the Start, End or any date between these values falls on a specific day. So, for our IsMondayAllDay field, our DAX formula is below. This will need to be modified accordingly for each subsequent column, by incrementing 1 on the ‘2017’[Day of Week (Number)], 1 bit by 1 for Tuesday, 2 for Wednesday etc.:
IsMondayAllDay = IF(AND(CONTAINS(CALENDAR([Start], IF([End] = [Start], [End], [End] - 1)), [Date], DATEVALUE(LOOKUPVALUE('2017'[Date], '2017'[Week Number], FORMAT(WEEKNUM(AllCalendars[Start], 2), "General Number"), '2017'[Day of Week (Number)], 1))), AllCalendars[IsAllDayEvent] = TRUE()), "TRUE", "FALSE")
  • A calculated column that tells us whether the current row is today, by referencing each of our fields created in the subsequent step. Similar to above, a TRUE/FALSE is returned for this:
IsToday = IF(([IsMondayAllDay] = "TRUE" && WEEKDAY(TODAY(), 2) = 1) || ([IsTuesdayAllDay] = "TRUE" && WEEKDAY(TODAY(), 2) = 2) || ([IsWednesdayAllDay] = "TRUE" && WEEKDAY(TODAY(), 2) = 3) || ([IsThursdayAllDay] = "TRUE" && WEEKDAY(TODAY(), 2) = 4) || ([IsFridayAllDay] = "True" && WEEKDAY(TODAY(), 2) = 5), "TRUE", "FALSE")

We now have everything we need to configure a Measure that can be used on our Dashboard - the Subject of the calendar appointment and a way of indicating that the appointment is today. So our final DAX formula would be as follows for John Smith:

John's Location (Today) = LOOKUPVALUE(AllCalendars[Subject], AllCalendars[IsToday], "TRUE", AllCalendars[Owner], "John Smith")

Now, it is worth noting, that the above solution is not fool-proof. For example, if a person has multiple All Day Appointments configured in their Calendar, then it is likely that the Measure used above will fall over. Giving that this is unlikely to happen in the above scenario, no proactive steps have been taken to mitigate this, although you can certainly implement a solution to address this (e.g. use the MAX function, only return records which contains “Working”, “Office” or “Home” in the Subject etc.). Nevertheless, I feel the above solution provided an effective “crash course” in a number of fundamental Power BI concepts, including:

  • Power Query data retrieval and manipulation
  • Power BI Functions
  • DAX Formulas and the difference between Measures and Calculated Columns

As a colleague recently said to me, “I think we will be using PowerBI a lot more in the future”. This is something that I would certainly agree with based on my experience with it so far. 😁

comments powered by Disqus
Built with Hugo
Theme Stack designed by Jimmy