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' ------------------------------------------------------------------------------------------- SELECT datesArray.DayDate ,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 ORDER BY DayDate |