This is a description of how to put together a report that tracks change to some data over time. This example will be a basic Product Backlog report.
For this work we will use Report Builder 3.0 and use the query editor in MS SQL Management Studio to write the SQL.
You need to have a way of writing, running, tuning, and testing the SQL for your reports. One way to do this is with SQL Management Studio; it provides good visibility of the structure of TFS databases and provides good tools for creating the SQL that will ultimately be used in the report.
You could use the graphical UI or SQL text editor found in Report Builder; but to tweak and develop the SQL you will most likely discover that you need to get more control and feedback than the Report Builder editor provides. The editor in SQL Server Management Studio has Intellisense which is useful. Another good alternative would be to use Visual Studio.
For this example report we will need to read data from a couple of tables in the TFS Warehouse; specifically DimWorkitem and FactWorkitemHistory.
So we need to set up SQL Management Studio to connect to TFS SQL server; which when connected looks like the image on the right.
We can then select DimWorkItem and click ‘New Query’.
We’ll write some SQL that will generate an array of dates for the X axis and for each of those dates sum up the effort outstanding on that date. The full SQL is appended at the end of this article.
We need a start date and end date for the array of dates. We’ll simply get the minimum and maximum dates from the workitem data; so selecting from DimWorkitem we’ll set @vDataSetStartDate and @vDataSetEndDate as below. Also we’ll limit this example to the ‘Product Backlog Item’ workitem type. No effort is made here to restrict the data to a particular Project Collection or Team Project; so be aware that the volume of data returned could be quite large.
With the start and end date handy we can then populate an array of dates. We’ll put the dates into a temporary table called @tblDates. You could use select * from @tblDates to see the dates in this table (see the inset to the right); remember to remove the select * before using the SQL in a report.
For each of those dates in @tblDates we’ll get all the latest revisions of workitems up to and including the DayDate. For each date we store the data that will be used for filtering in the last step where we will sum up remaining effort based on workitems that are in the ‘not done’ state. We will need the WorkItemSK (which is the unique id for a revision) to join into the FactWorkitemHistory. The ID and the Rev columns are for reference and debug. Use select * from @tblDatesWithWorkitems to see the dates and data in this table; remember to remove it before using the SQL in the report.
The data we want requires joining DimWorkitem with FactWorkitemHistory; INNER JOIN on the WorkitemSK. There are rows in FactWorkitemHistory that are irrelevant; so filter them out using fwih.RecordCount > -1.
Finally filter by system state for the ‘not done’ workitems from the temporary table @tblDatesWithWorkitems and SUM up Effort for each day by grouping on DayDate. So for example on 2012-10-02 join each row that matches our state criteria to FactWorkitemHistory and sum up.
So that’s the data ready to go.
Importantly it is in the exact shape and format that we need for our report. An array of Dates with associated backlog of effort.
We could enhance this data with additional information about sprints, teams and velocity.
We could add filtering for Project Collection, Team Project, Iteration, Areas and the like.
That will be a subject for another article!
Open up MS SQL Server Report Builder. Close the wizard and go straight into the application. Create a Data Source pointing at the TFS SQL Server.
Add a data source that points at the TFS warehouse. Here I use the ‘Use a connection embedded in my report’ option with connection type ‘Microsoft SQL Server’ and name the connection TFS2012.
Create a dataset using the previously created data source.
In the Dataset Properties dialog open the Query Designer, select ‘Edit as Text’ and paste in the SQL that was previously created in SQL Server Management Studio. Run the SQL to check that it works ok. Although of course if you are using SQL Server Management Studio to develop this type of report SQL you will have already seen that it works; so you would not normally need to do this.
Add a table to the report so that you can view the data that is going to be charted. This is a useful way to verify that the data looks shipshape! The table can be deleted later. Lift click and drag DayDate and Effort into the table.
Add a chart.
Select the first Line type chart.
Then left Click drag DayDate onto the chart as a category group.
Then left Click drag Effort as a value.
Use the expression editor and edit ‘Effort’ to remove the Sum() and then OK to save the modified expression.
Run the chart.
That’s it. You have day by day data in a SQL Report.
SET ANSI_WARNINGS ON -- Specifies SQL-92 standard behaviour for several error conditions
SET XACT_ABORT ON -- If error, the entire transaction is terminated
SET NOCOUNT ON -- Stops the message count of the number of rows affected SQL statement
SET DATEFIRST 7 -- Sunday is first day of week -- this is actually the default
-------------------------------------------------------------------------------------------
-- Some basic Product Backlog Report Data
-- Demonstrates array of dates and attaching data into that array
-- Version March 2013 - RippleRock
-- Get the minimum date and maximum date from the data
DECLARE @vDataSetStartDate AS DATE
DECLARE @vDataSetEndDate AS DATE
SELECT @vDataSetStartDate = CONVERT(DATE, MIN(dwi.System_ChangedDate), 112)
,@vDataSetEndDate = CONVERT(DATE, MAX(dwi.System_ChangedDate), 112)
FROM dbo.DimWorkItem dwi
WHERE dwi.System_WorkItemType = 'Product Backlog Item'
-- Create an array of dates; this will be the basis of the report x axis
-- into @tblDates
DECLARE @tblDates AS TABLE (DayDate DATE NOT NULL);
WITH ReleaseDates (ReleaseDate)
AS (
SELECT ISNULL(@vDataSetStartDate, GETDATE()) AS ReleaseDate
UNION ALL
SELECT DATEADD(d, 1, ReleaseDate) AS ReleaseDate
FROM ReleaseDates
WHERE DATEADD(d, 1, ReleaseDate) <= ISNULL(@vDataSetEndDate, GETDATE())
)
INSERT INTO @tblDates (DayDate)
SELECT CONVERT(DATE, rd.[ReleaseDate], 112)
FROM ReleaseDates rd
OPTION (MAXRECURSION 0)
-----------------------------------------------------------------------------------------
-- Join the last revision of each workitem under the DayDate into the dates
DECLARE @tblDatesWithWorkitems AS TABLE (
DayDate DATE NOT NULL
,System_ID INT
,System_Rev INT
,WorkitemSK INT
,System_State NVARCHAR(256)
INSERT INTO @tblDatesWithWorkitems (
DayDate
,System_ID
,System_Rev
,WorkItemSK
,System_State
SELECT datesArray.DayDate
,dwi.System_ID
,dwi.System_Rev
,dwi.WorkItemSK
,dwi.System_State
FROM @tblDates datesArray
,dbo.DimWorkItem dwi
WHERE dwi.System_Rev IN (
SELECT MAX(System_Rev) -- we want the last revision of each workitem under the DayDate
FROM dbo.DimWorkItem wil
WHERE wil.System_Id = dwi.System_Id
AND (CONVERT(DATE, wil.System_ChangedDate, 112) <= datesArray.DayDate)
-- capture max rev
-- so the last change up to that day for each of those Product Backlog Items
-- keep any data that we will be filtering by in the next stage; so in this case System_State
AND dwi.System_WorkItemType = 'Product Backlog Item'
ORDER BY DayDate
-- Return the data we are interested in back to the report
-- Summed effort of Product Backlog Items for each day (which we filtered out previously)
-- that are in a 'not done state'
,ISNULL(SUM(fwih.Microsoft_VSTS_Scheduling_Effort), 0) AS Effort
FROM @tblDatesWithWorkitems datesArray
INNER JOIN dbo.FactWorkItemHistory fwih ON datesArray.WorkitemSK = fwih.WorkItemSK
AND fwih.RecordCount > - 1
WHERE
-- filter by system state to get the 'not done' effort for that date
(
datesArray.System_State <> 'Done'
AND datesArray.System_State <> 'Removed'
AND datesArray.System_State <> 'Resolved'
GROUP BY DayDate -- we sum up the filtered effort for each day
RSS
Email RippleRock
© Copyright 2023 RippleRock