This has been painful
Project Online reporting has been a fairly significant limitation of the Online experience for me so far. Besides the complexity in building the oData stream, the fairly fundamental limitations of the data filtering of the URI's has been a major falling down point for me.
To digress for a moment, most reports people want are timephased in some way, either Actual Work by period, planned work by period, or timesheet data by period. All of these reports lead to a "time by day" feed. Now the thing with timephased reports is you are usually looking for a "last three months, next three months" view (or similar). Also the thing with the Time By Day feeds is that they are HUGE!
Add these things together and you really need a way of limiting your data feed to avoid extremely lengthy refresh times.
Easy enough I hear you say. Just put a timebyday ge '2014-01-01T00:00:00' select statement in your URI before adding it into your PowerPivot data model.
Yup, that's sweet. However when you come to change the date parameter, two things will happen
1) the table relationships are broken
2) any links within the sheet (pivots, calculations, custom columns in the model) will have to be recreated
Basically - the report breaks or needs to be maintained by someone "with experience" on a periodic basis.
Enter PowerQuery with PowerPivot
The purpose of this blog
So with the above findings for standard PowerPivot limitations, we look at the requirement for a "missing timesheet" report.
1) It should show the status of timesheets for last week
2) it should highlight where a timehseet hasnt been created
3) it should show the hours currently in the timesheet and the timesheet status (where created)
4) It will be run weekly so shouldn't require maintenance, and should refresh fast
5) It should include resource level custom fields (Department, Team, Employment Type)
To do this we need to grab data from the following feeds
1) Timesheets
2) TimesheetLines
3) TimesheetActualDataSet (the time by day data)
4) Resources
To do this we will use PowerQuery to support the rolling filtering
PowerQuery timephased filtering
There are two really handy functions in PowerQuery that allows you to filter on rolling periods:
( DateTime.FixedLocalNow() ) works as a todays date marker
#duration(n, 0, 0, 0) allows you to stipulate an elapsed number of days (or hours, minutes, seconds) where n is the number of days in question
add these two items together and you can set up a filter on the Time by Day table to show you records that exist where time by day is greater than or equal to for the last 15 days and into the future (in this scenario we're not worried about future hours as there shouldn't be much in timesheets except holiday time, and we will join this data out using the timesheet periods data. We could add an additional filter if we wished)
FilteredRows = Table.SelectRows(TimesheetLineActualDataSet1,
each [TimeByDay] >= (DateTime.FixedLocalNow() - #duration(8, 0, 0, 0))),
The step by step is:
Preparation:
You should see something like this:
let
Source = OData.Feed("https://candc365.sharepoint.com/sites/pwa/_api/projectdata"),
TimesheetLineActualDataSet1 = Source{[Name="TimesheetLineActualDataSet"]}[Data],
FilteredRows = Table.SelectRows(TimesheetLineActualDataSet1, each [TimeByDay] > #datetime(2014, 7, 1, 0, 0, 0))
in
FilteredRows
The date filter you created is seen here:
FilteredRows = Table.SelectRows(TimesheetLineActualDataSet1, each [TimeByDay] > #datetime(2014, 7, 1, 0, 0, 0))
And you want to change this to something like this:
FilteredRows = Table.SelectRows(TimesheetLineActualDataSet1, each [TimeByDay] >= (DateTime.FixedLocalNow() - #duration(15, 0, 0, 0))),
Once done to your satisfaction, select Home tab in query editor and select Apply and Close.
In Excel the data table you've created with your filtered query should be returned. At this point i would double check you are happy wit this.
Now Select your PowerPivot tab and click "Add to Model"
Repeat the above steps for your Timesheet and TimesheetLines data feeds.
Sample TimesheetLines Query
let
Source = OData.Feed("https://candc365.sharepoint.com/sites/pwa/_api/projectdata/"),
TimesheetLines1 = Source{[Name="TimesheetLines"]}[Data],
RemovedColumns = Table.RemoveColumns(TimesheetLines1,{"AssignmentId", "CreatedDate", "LastSavedWork", "LCID", "TimesheetPeriodStatusId"}),
FilteredRows = Table.SelectRows(RemovedColumns, each ([TimesheetPeriodStatus] = "Opened")),
FilteredRows1 = Table.SelectRows(FilteredRows, each [PeriodEndDate] <= (DateTime.FixedLocalNow() ))
in
FilteredRows1
Sample Timesheets Query
let
Source = OData.Feed("https://candc365.sharepoint.com/sites/pwa/_api/projectdata"),
Timesheets1 = Source{[Name="Timesheets"]}[Data],
FilteredRows = Table.SelectRows(Timesheets1, each [EndDate] < (DateTime.FixedLocalNow() )),
FilteredRows1 = Table.SelectRows(FilteredRows, each [Description] <> "Closed")
in
FilteredRows1
Now the important bit....
In order to understand who has not created timesheets, normally in SQL we would use some outer join mechanism to a master list of resources who SHOULD be submitting, so as to know who is NOT IN the master set. This is because until the timesheet is created, the data is not in the database.
We do this by:
Project Online reporting has been a fairly significant limitation of the Online experience for me so far. Besides the complexity in building the oData stream, the fairly fundamental limitations of the data filtering of the URI's has been a major falling down point for me.
To digress for a moment, most reports people want are timephased in some way, either Actual Work by period, planned work by period, or timesheet data by period. All of these reports lead to a "time by day" feed. Now the thing with timephased reports is you are usually looking for a "last three months, next three months" view (or similar). Also the thing with the Time By Day feeds is that they are HUGE!
Add these things together and you really need a way of limiting your data feed to avoid extremely lengthy refresh times.
Easy enough I hear you say. Just put a timebyday ge '2014-01-01T00:00:00' select statement in your URI before adding it into your PowerPivot data model.
Yup, that's sweet. However when you come to change the date parameter, two things will happen
1) the table relationships are broken
2) any links within the sheet (pivots, calculations, custom columns in the model) will have to be recreated
Basically - the report breaks or needs to be maintained by someone "with experience" on a periodic basis.
Enter PowerQuery with PowerPivot
The purpose of this blog
So with the above findings for standard PowerPivot limitations, we look at the requirement for a "missing timesheet" report.
1) It should show the status of timesheets for last week
2) it should highlight where a timehseet hasnt been created
3) it should show the hours currently in the timesheet and the timesheet status (where created)
4) It will be run weekly so shouldn't require maintenance, and should refresh fast
5) It should include resource level custom fields (Department, Team, Employment Type)
To do this we need to grab data from the following feeds
1) Timesheets
2) TimesheetLines
3) TimesheetActualDataSet (the time by day data)
4) Resources
To do this we will use PowerQuery to support the rolling filtering
PowerQuery timephased filtering
There are two really handy functions in PowerQuery that allows you to filter on rolling periods:
( DateTime.FixedLocalNow() ) works as a todays date marker
#duration(n, 0, 0, 0) allows you to stipulate an elapsed number of days (or hours, minutes, seconds) where n is the number of days in question
add these two items together and you can set up a filter on the Time by Day table to show you records that exist where time by day is greater than or equal to for the last 15 days and into the future (in this scenario we're not worried about future hours as there shouldn't be much in timesheets except holiday time, and we will join this data out using the timesheet periods data. We could add an additional filter if we wished)
FilteredRows = Table.SelectRows(TimesheetLineActualDataSet1,
each [TimeByDay] >= (DateTime.FixedLocalNow() - #duration(8, 0, 0, 0))),
Preparation:
- install PowerQuery addin for Excel first :)
- create a PowerQuery connection to your ProjectOnline instance using either Windows or Organisatinoal account
- use the ProjectData URI
- Select the oData stream you want from the list provided in the Navigator panel (lets do the TimesheetLineActualDataset)
- once query editor opens, select the timebyday column and create a date filter on it (something like AFTER dd/mm/yyyyy) to set up the filter structure
- Apply any other data filters required by your report data definition
- now select the VIEW tab, and click Advanced Editor
You should see something like this:
let
Source = OData.Feed("https://candc365.sharepoint.com/sites/pwa/_api/projectdata"),
TimesheetLineActualDataSet1 = Source{[Name="TimesheetLineActualDataSet"]}[Data],
FilteredRows = Table.SelectRows(TimesheetLineActualDataSet1, each [TimeByDay] > #datetime(2014, 7, 1, 0, 0, 0))
in
FilteredRows
The date filter you created is seen here:
FilteredRows = Table.SelectRows(TimesheetLineActualDataSet1, each [TimeByDay] > #datetime(2014, 7, 1, 0, 0, 0))
And you want to change this to something like this:
FilteredRows = Table.SelectRows(TimesheetLineActualDataSet1, each [TimeByDay] >= (DateTime.FixedLocalNow() - #duration(15, 0, 0, 0))),
In Excel the data table you've created with your filtered query should be returned. At this point i would double check you are happy wit this.
Now Select your PowerPivot tab and click "Add to Model"
Repeat the above steps for your Timesheet and TimesheetLines data feeds.
Sample TimesheetLines Query
let
Source = OData.Feed("https://candc365.sharepoint.com/sites/pwa/_api/projectdata/"),
TimesheetLines1 = Source{[Name="TimesheetLines"]}[Data],
RemovedColumns = Table.RemoveColumns(TimesheetLines1,{"AssignmentId", "CreatedDate", "LastSavedWork", "LCID", "TimesheetPeriodStatusId"}),
FilteredRows = Table.SelectRows(RemovedColumns, each ([TimesheetPeriodStatus] = "Opened")),
FilteredRows1 = Table.SelectRows(FilteredRows, each [PeriodEndDate] <= (DateTime.FixedLocalNow() ))
in
FilteredRows1
Sample Timesheets Query
let
Source = OData.Feed("https://candc365.sharepoint.com/sites/pwa/_api/projectdata"),
Timesheets1 = Source{[Name="Timesheets"]}[Data],
FilteredRows = Table.SelectRows(Timesheets1, each [EndDate] < (DateTime.FixedLocalNow() )),
FilteredRows1 = Table.SelectRows(FilteredRows, each [Description] <> "Closed")
in
FilteredRows1
Now the important bit....
In order to understand who has not created timesheets, normally in SQL we would use some outer join mechanism to a master list of resources who SHOULD be submitting, so as to know who is NOT IN the master set. This is because until the timesheet is created, the data is not in the database.
We do this by:
- Creating the Resource datafeed with the appropriate filters to show only those resouorces who SHOULD be submitting a timesheet
- Add this to the datamodel
- Create the relationships in the PowerPivot datamodel (I am going to assume you know how to do this)
- Create a pivot table based on the datamodel to show submitted hours
- Convert this pivot to a flat structure (classic display mode, no totaling)
- now on the tab that has your resource table on it, navigate to the right hand side of the table. You want to create three custom columns, both using vlookup references to the pivot table you just created. One example is here, you can work the rest out!
=IF(ISNA(VLOOKUP([@ResourceName],'Submitted Hours Summary'!B$4:E$200,4,FALSE)),0,VLOOKUP([@ResourceName],'Submitted Hours Summary'!B$4:E$200,4,FALSE))
This looks at the resource name in the table, finds the name in the Pivot Table and returns either the Total Timesheet Hours, or 0 if a record is not found - The three columns you need are
- Sum of Timesheet Hours
- Timesheet Status - your ISNA value should be "Not Created"
- Period ending
- Once done, make a pivot from the Resource table with the extended columns, adding the Resource Name, Status and Hours Total
- here's what you end up with is something like this after some quick conditional formatting
Enjoy!
Comments
Post a Comment