# Tuesday, 12 March 2013
Technorati Tags:
Technorati Tags:

 

I don’t want to get into the whys and wherefores just yet; I’d like to start with the assumption that branches exist in your TFS ALM implementation.

You may not be comfortable with those branches though.

You may feel that too much cost is involved in ‘using’ those branches! The cost of merging, the cost of creating new branches, the cost of updating build definitions and the cost of increased complexity.

Any two branches have a relationship and this relationship has a cost.

The simple reason is that branches split up code. Code that represents a single product. Code that is the product.

Your live service and website is at any point in time derived from a particular singular unique set of code. Same goes for the DVD that has your latest product on it or the product download site.

However, no two ways about this; split code is a copy of code that can then be changed and will then be different from where it was copied from. That difference should only exist for a particular clearly defined purpose. So a purposeful change would be to check in code related to a Task. Hopefully that Task would be related to a Product Backlog Item which has been added to a Sprint. These workitems are in the MS Scrum 2.0/2.1 which is is the default process template in TFS 2012.

Branches serve a purpose; but they need to be thought about very carefully.

A set of code will exist that represents a live product and this live code is usually separated from any changes that will be taking place; such as a piece of development work or a spike of R&D. It seems sensible to keep a copy of that live code safe so that it can be used for any patches that need to be made to the live product to keep it going before the next release.

We could get into the detail of what a main branch is and if a live branch exists or not. But rather than dwell on that too much I’d rather have us say for the moment that there are branches involved and you are merging code between them.

I’m going to list a few topics as points that I think can improve branch quality and throughput efficiency, in future editions of this blog I’ll try take these topics a step further.

Not sure yet which would be a good topic to start on, but I’m open to suggestions!

Some topics are related and so will get bundled together.

Branching topics (In no particular order):

1 Reduce the amount of merging required to the minimum possible; have fewer branches.
It’s all about speed to market; less steps to get you there will help…
However of course this will depend on the quality of the code that goes to market.
Do less branches impact that quality?
2 Reduce or eliminate complexity of merging; merge often.
Be ready and prepared to merge, know the branch quality all the time; auto builds, auto deployment, auto testing.
No excuses here.
3 Understand what is being merged. I’ve seen some really good custom approaches to this topic.
4 Validate the code quality on all branches; aim to use Integration builds. Some sort of buddy or manual build and Nightly is the very minimum.  Continuous is best if you can achieve it.
Use the same builds and same tests on all the branches for the same product. So that the same files, the same binaries, the same installer and the testing is consistent.  There can be an issue here around configuration and database environment specific data.
Builds and tests are part of the product code and get  merged around with the product.
5 Speed up the builds. Good to know sooner rather than later that a change does not build.
So look at ways of doing incremental builds. That is incremental Continuous Integration builds.
The ‘Clean Workspace’ option can be set to none via the basic section in a build definition’s process parameters; no code change no build.
Consider using a NUGet enterprise repository to store built versions of components; so that they can be pulled into an integration build and do not have to be rebuilt. http://inedo.com/proget/overview
I know of an organisation that has a very clever bespoke way of understanding what needs to be built via changeset and a component dependency tree. The thing is; if you build solution files you need a way of calculating dependency.
I suspect that NUGet would be a reasonable alternative.
6 Understand what is waiting to be merged and how long that list is.
Report on this. Heads up of the release.
7 Communicate the ‘purpose’ of a branch; update this all the time.
Communicate and document any test environments that may be specific to the branch.
Understand, manage and ensure that the correct work is undertaken on branches with a view to reducing  or eliminating conflict.
Take work from the Product Backlog.
Check in work against Tasks.
Make use of Sprints.
Iterations. Releases. Teams.
Areas.
Make sure that development teams are fully aware of the purpose of the existing branches.
8 Divide up the product into components to help scope the merge.
Components will simplify build definition workspace mapping; reduce the build process get latest overhead. Faster builds.
Have build definitions that are scoped to build the individual component parts of the product.
Product sliced up into components will reduce the likelihood for teams to be working on the same code.
Have a folder structure that is clear and unambiguous about which component lies under a folder.
Contain all code and artefacts that relate to building a particular component under that folder.
Consider putting build definitions into version control.
9 Having the product divided up into components does not mean that you stop feature based development.
Features involve creating new components or updating and changing existing components.
10 Facilitate visibility of work on a particular component that is taking place on different branches.
Clarify the merge overhead by helping provide a component based view of the merge prior to release and merge of updated product.
11 Refactoring branches.
Do this actively all the time.
Prune and cut back irrelevant branches.
Update the branching documentation.
12 Keep development branches absolutely up to date with live product code as it is delivered.
So using the familiar RI and FI paradigm in whatever guise that takes.
Prevent development branches merging into main if they are out of sync with the latest RIs into main.
13 If development takes place on child of main; merge into the main branch should overwrite.
The resolution of conflict should be dealt with on the child branch first by integrating changes from the main branch; through FI.
The result is no conflict when merging into the parent main branch; through RI.
14 Do not allow branches to exist for too long.
Once they have achieved their purpose get rid of them.
Re- branch for new work.
Main is an exception and will exist for the lifetime of the product. This would be the same for development taking place on main.
15 Consider using main branch only for development work; rather than development work on children of main branch.
This may sound rather extreme but it is a very agile way of working.
Release branches would be taken from main; the hope would be to avoid having to make any significant changes on that branch.
e.g.image
16 Consider Team Projects as a way of encapsulating build definitions for a particular branch.
Do you have a very long rather messy list of build definitions?
That long list incidentally may not be version controlled; unless you have put together some custom code to handle it.
Yes, Team Projects can sit over the branch structure!
Useful way of controlling access to a branch; per team. So Team Project contributors only.
17 Speeding up the availability of code for testing by way of automated deployment  should be an objective.
To achieve this there needs to be a way of defining which server types components are installed onto.
There needs to be a definition of test environments and what server types exist in those environments.
Contained in these definitions in combination with an understanding of dependency, services and app pools can be automatically stopped and started.
Quite often organisations write there own deployment processes and systems.
There are products available to help out with automated deployment such as Nolio: http://www.noliosoft.com/ and InRelease : http://www.incyclesoftware.com/inrelease/
18 It should be an objective to build once and install that same packaged build all the way to the live deployment; be that a website or DVD. NUGet could help here too.
19 Automatically version stamp assembly.info and installer packages where used so that version and build info can be  seen in the file info properties and add remove programs. It’s great to be able to look in add remove programs to see what is installed. This is a simple and well documented modification to the TFS Build workflow.
20 Last; but has the clear honour of being number 20 are database deployments.
Yes the database schema needs to be versioned and it needs to be automatically deployed.
Some write custom code and scripts to do this; others use tools in combination with scripts.
It is often a very complex area; but will be a showstopper unless fully addressed.
This has to work seamlessly with code component deployments. There needs to be an understanding of dependency of code component on database ‘components’.
Changes to schema and objects such as stored procedures need to be incorporated into a live database baseline  that can then be used to build a fully functioning version of live. Changes that are not yet live are then ‘appended’ onto the baseline for testing.


.
Tags:

Tuesday, 12 March 2013 22:52:18 (GMT Standard Time, UTC+00:00)  #    Comments [0]


# Monday, 11 March 2013

 

Introduction

In many organisations a TFS installation will comprise of more than one project collection. The data from all project collections is stored in the same TFS warehouse.

This is useful in that it means cross organisation reports can be written; Views of whole organisation products and backlogs are feasible.

The data from multiple project collections sits in the same tables; so keys such as WorkItemSK, System_ID and System_Rev are not unique across collections.

When multiple collections were introduced for TFS 2010, GUIDs were introduced into the TFS tables. Where SQL is not scoped to a particular collection, GUIDs must be used in joins. We need to use these GUID keys in joins; rather than integer keys such as WorkItemSK.

Updating SQL to use the GUID key; WorkItemBK

So looking back at the ‘How to create a Day by Day based SQL Report’ example from my previous blog; ReportsHowToCreateADayByDayBasedSQLReport the following steps can be followed to update that SQL query for a multi collection installation.

The WorkItemBK must be used in the join between DimWorkItem and FactWorkitemHistory.

A couple of changes need to be made for this to happen. This change would need to be made to any SQL that makes joins using WorkItemSK; where the join is not scoped to the project collection.

Basically we replace WorkItemSK with WorkItemBK.

WorkItemBK is a GUID; so provides the uniqueness that is needed to make joins between tables in the multiple collection scenario.image

 

Here is the original SQL that we used to get the last revision of workitems for each day date; collecting WorkitemSK as a key to be used later in the join to FactWorkItemHistory.

 

image

Here is the same SQL updated to collect the GUID; replacing the WorkItemSK with WorkitemBK.

Note that we still need to use the System_ID and System_Rev to get the latest revision; so to ensure that this is unique we scope the sub query to the project collection by adding  the TeamProjectCollectionSK into the sub query join criteria.

 

Lastly the SQL that sums up the Effort for Product Backlog must be updated to use the collected GUID WorkItemBK in the join to FactWorkItemHistory.

There is an interesting trick involved in using the GUID as can be seen below.

Notice that previously I used fwih.RecordCount > –1 in the join.

This is no longer required as the record count has SNAGHTML492e9aabeen incorporated into the key WorkItemHistoryBK.

The GUID fwih.WorkItemHistoryBK appends the RecordCount column onto the end of the GUID.

 

 

image

 

Here is the original SQL using WorkItemSK.

 

 

 

 

 

image

 

Here is the SQL updated to use WorkItemBK.

Note how ‘|1’ has been appended onto WorkItemBK in the join.

 

 

 

Summary

Use the GUID keys (e.g. WorkItemBK) in joins rather than the integer keys (e.g. WorkItemSK).

You may want to review existing reports where WorkItemSK is used.

The example SQL will now list an organisation product backlog (for Product Backlog Items) where multiple project collections are used.

Product Backlog SQL updated to use GUIDs

SET ANSI_WARNINGS ON -- Specifies SQL-92 standard behaviour for several error conditions
SET XACT_ABORT ON -- If a Transact-SQL statement raises a run-time error, the entire transaction is terminated
SET NOCOUNT ON -- Stops the message that shows the count of the number of rows affected by a Transact-SQL statement
SET DATEFIRST 7 -- Sunday is first day of week -- this is actually the default

-------------------------------------------------------------------------------------------
-- Some basic Burndown Report Data
-- Demonstrates array of dates and attaching data into that array
-- Version March 2013 - RippleRock
-- Updated to use GUID keys in joins
-------------------------------------------------------------------------------------------
-------------------------------------------------------------------------------------------
-- 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
    ,WorkItemBK NVARCHAR(128)
    ,System_State NVARCHAR(256)
    )

INSERT INTO @tblDatesWithWorkitems (
    DayDate
    ,System_ID
    ,System_Rev
    ,WorkItemBK
    ,System_State
    )
SELECT datesArray.DayDate
    ,dwi.System_ID
    ,dwi.System_Rev
    ,dwi.WorkItemBK
    ,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 wil.TeamProjectCollectionSK = dwi.TeamProjectCollectionSK
            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.WorkItemBK + '|1' = fwih.WorkItemHistoryBK
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



.
Tags:

Monday, 11 March 2013 10:38:36 (GMT Standard Time, UTC+00:00)  #    Comments [0]


# Friday, 08 March 2013

 

Introduction

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.

image

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. 

clip_image025clip_image002

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.

Writing the SQL for the report.

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.

imageimage

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.

image

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.

imageimage

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.imageimage

image

 

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!

Getting the data into a report. Creating a DataSet.

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.

image

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.

imageimageimage

Create a dataset using the previously created data source.

SNAGHTML62b04c1

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.

imageimage

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.

imageimage

Add a chart.

imageimage

Select the first Line type chart.

Then left Click drag DayDate onto the chart as a category group.

image

Then left Click drag Effort as a value.

image

Use the expression editor and edit ‘Effort’ to remove the Sum() and then OK to save the modified expression.

image

Run the chart.

That’s it. You have day by day data in a SQL Report.

image

 

  • Summary.

  • The approach taken here is a pattern used in many SQL Reports that require data to be charted against days.
  • Use SQL to generate an array of dates into a temporary table. These dates should be limited by the date range of the data being charted. For each Date get the maximum revision for the workitems with change date falling before or on the Date. Use additional filters where appropriate to define the workitems; but remember the aim is to get the latest revision of each workitem for the Date. So for that date we can look at things as they were on the day; as we were looking at them through a Query run on that day. The latest revision may not have taken place that day; it most likely will be an earlier day. Finally SUM up by grouping the data by Date.

 

The complete SQL.

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



.
Tags:

Friday, 08 March 2013 22:33:32 (GMT Standard Time, UTC+00:00)  #    Comments [0]