9 Jul 2014

Integrating tsqlt with SQL Server Data Tools

As mentioned in a previous post I've recently been working with a SQL Server unit test framework: tsqlt. I would like to share how I managed to integrate the framework and unit test into my project life-cycle.

Unit tests should be treated the same as application code, meaning they should be contained within a project under source control. Being under source control will allow the tests to be maintained and changes tracked when multiple people are helping to write tests.  Also having the unit test in a project means there is a deployment mechanism out-of-the-box.

The tsqlt framework has a few requirement which are as follows
  • CLR is enabled on the SQL Server
  • The framework and the unit test are contained within the same database of the objects which are being tested
  • The database instance is trustworthy
As unit test are required to be contained within the same database as the objects being tested, also due to the way SQL Server Data Tools (SSDT) project validation works, the easiest solution would be to add the unit test and the framework objects into the same project of your application database.

However one question would be raised which is how do you stop the unit test framework and the unit tests getting into the production deployment? The tsqlt framework does offer an approach to this problem by supplying an uninstall store procedure which could be called after deployment to remove the unit tests and the framework. This is more of a workaround rather than solving the problem of not deploying tests and the framework into production.

There is an alternative solution, which is the method I used, to integrate the unit tests into the project life cycle.  The solution is to use SSDT project setup method of composite database project.  The composite database project method, which has been around since visual studio database professionals, is basically having 2 (or more) database projects, where one references the other(s), which both gets deployed into the same database on the same server.

My method to implement composite SSDT database project was as follows:
  • Created an application database project as normal. Which contained all the objects for the application requirements.
  • Create a unit tests database project to contain all my unit tests and supporting objects. This project could also be where tsqlt unit framework code could be stored.  I decided created a separate tsqlt dacpak file by using the following steps:
    • Create an empty database.
    • Execute the tsqlt install script within the empty database.
    • Use SQLPackage with the extract action.
    UnitTestSolutionExplorer
  • Before starting to create my unit test code within my unit to project I had to set up the references.  I created references to the application project and the tsqlt dacpack file but setting database location to be “same database”, which is the same as removing the generated database name and variable.
Adding Database Reference To Application Project From Unit Test ProjectAdd Database References to tsqlt dacpac file From Unit Test Project
Setting up the projects in this method means I can deploy my application project without the unit tests and the framework to all the environments. Then add the unit test to any one of my  environments: development, test or separate unit test server.

The reason for creating a dacpack file was to have a single reusable file for my next projects. And if the unit framework is updated I only have to update a single file.  Also hopefully at some point the SSDTS project will support the use of NuGet. This would mean that I can upload my dacpack to a NuGet server and add the package reference.  Then if I ever updated the server package the project would automatically pick up the new version. (There is a fork within the NuGet project which already allows this: https://nuget.codeplex.com/workitem/2439.)

Here is a link to find out more about composite projects: http://blogs.msdn.com/b/ssdt/archive/2012/06/26/composite-projects-and-schema-compare.aspx.

SQLpackage has a setting which will allow a composite project to deploy its composite references objects at the same time. This allow the unit test project to deploy the unit tests including the application database and the tsqlt framework database objects. However be aware that only one Pre/Post deployment file is executed which is one that is attached to the dacpack listed in the SQL package source file parameter. So the composite references project have post/pre-deployment requirements are not executed.  This can be a problem if your application database has a post-deployment script to load reference data.

A couple of closing notes:

To create a unit test class within SSDTS for tsqlt add the following extended property on the schema which is to become a tsqlt test class: tSQLt.TestClass with a value of 1
e.g:
   1:  EXECUTE sp_addextendedproperty
   2:  @name = N'tSQLt.TestClass'
   3:  , @value = 1
   4:  , @level0type = N'SCHEMA'
   5:  , @level0name = N'MyUnitSchema';

And creating unit test the store procedure must start with "test "

further reading:

Automated Unit Testing SQL Server Code

I have never been a fan of automated unit testing of SQL code mainly because previous frameworks / tools, which I came across, all seem to miss the point of SQL code which is either retrieving or manipulating data.

Some of the frameworks would only test SQL scalar functions which limited code coverage. Others would test stored procedures but only the output parameter not the data being returned which limited the usefulness of the test.  The methods used to determine if a test pass or fail were also limited. As some would only check the return value; the correct number of rows were returned; a single row of data appeared in the dataset or within a row and column a value is returned. This meant that you could write code that would satisfy the test and could still be functionally incorrect as the rest of the data not checked could be inaccurate.

Another problem that some of the previous frameworks forced upon you to solve was how to make the test repeatable. As data has state which is maintained through the code that you are testing. If you rerun a test it may not be against the same data state as the previous test run.  This could cause test to fail because the expected results were out of date or due to constraints violations as previous run weren’t removed.  Also getting the data into a starting state could be time-consuming and error prone because of identity properties; referential integrity and table constraints.

However I recently came across a unit test framework called tsqlt which has changed my mind about automating unit testing against my SQL code.  The framework supports the testing of any executable SQL code and offers approaches to isolate embedded stored procedures; triggers and functions. There are a range of asserts the test to use to make sure that the code is functionally correct ranging from data compare, structure compare, the existence of objects and calls were made to embedded code.

The framework helps with repeatable unit tests by wrapping the execution of tests within database transactions and then rolling back once the execution has completed. Also the framework offers tools for getting the database into a particular test state by faking the database tables and applying selective constraints, this is similar to .net mocking objects, which makes inserting data easier.  More details of how to use and get the tsqlt framework can be found at the following URL: http://tsqlt.org/.

I would like to share some of my methods I use to make using the framework a little bit easier.

Creating the set up stored procedure within each test class helps reduce the amount of repeatable code that each unit test would have to contain. The set up stored procedure is automatically called before each unit test, within the test class, is executed. The code I put in my Setup procedures was the faking of the required tables and inserting of any initial data required.

To create a set up stored procedure just create a stored procedure call SetUp e.g.


   1:  CREATE Procedure [MyTestClass].[Setup]
   2:  AS 
   3:  EXECUTE [tSQLt].[FakeTable]
   4:  @TableName = N'[MyAppSchema].[MyAppTable]'
   5:  , @Identity = 1
   6:  , @ComputedColumns = 0
   7:  , @Defaults = 1
   8:  Retutn 0

I found by grouping my unit tests based upon C.R.U.D operations help to get the most out of the setup stored procedure. As I found my insert operations needed the tables to retain their identity columns and defaults to ensure that the insert stored procedures worked. Whereas the updates only required the defaults and the reads only required a fake table.

I found putting my test data into table value functions / views reduced repeating code. Also this helped me in creating my actual data as I was able to apply filters and case statements to get the required results for the particular tests.

For timestamp column you can emit them from the expected results so they are not compared with the actual table. However my method for dealing with my timestamp columns was within my setup stored procedures / unit tests and application code. 

Within the setup stored procedures I would alter the defaults to a static date and time, which was completely different to the initial data, before faking the table. Then use the same static value in my expected table within the unit test. Within my application code I change my approach to updating my timestamp columns. Instead of directly updating the column by using a call to the SYSDATETIME() function I would update the column by using the DEFAULT keyword e.g.

   1:  UPDATE [AppSchema].[AppTable]
   2:  SET [AppColumn1] = @pValue1
   3:  , [AppColumn2] = @pValue2
   4:  , [AppColumn3] = @pValue3
   5:  , [LastUpdated] = DEFAULT
   6:  WHERE [KeyColumnId] = @pKeyColumnId

further reading: