Test driven database development links

2012/08/27

A couple of interesting articles about test driven database development and the database testing framework tsqlt – worth taking a look at.

Test-driven Database Development – Why Bother?

Test-driven Database Development – Why tSQLt?


Unit testing update sprocs where more that one table is updated

2011/08/03

Introduction
The previous blog showed how to unit test an update sproc. The sample sproc used was relatively straight forward and it only updated one base table.

This blog will look at a slightly more complex scenario to testing an update that affects 2 base tables.

Background
AdventureWorks does not contain any samples sprocs that can be used. Therefore, a new sproc – HumanResources.uspUpdateEmployeeDetails – will be created and used as an example.

The purpose of the new sproc is to allow some basic details – FirstName, MiddleName, LastName, JobTitle – to be updated in one ‘busienss transaction. Two base tables – Person.Person (FirstName, MiddleName, LastName) and HumanResources.Employee(JobTitle) will be updated.

Testing that the sproc exists and that the schema is as expected
See the previous blog on how to do this,

The example tests in this series of blogs will be included as samples in future versions of the DBTestUnit download.

Creating the expected initial state test XML file
A similar approach to the previous blog will be used. But, data will be exported from both the HumanResources.Employee and Person.Person tables using the ExportDBDataAsXML tool.

The Person.Person table contains approx 20K rows. Ideally when unit testing, the size of test datasets should be much smaller than this. But, as the performance is not unduly affected (approx 10 secs to run) for the purposes of this blog it is easier to use the full dataset provided.

To export the data the following is added to the ExportDBDataAsXML tool config.

<!--********************-->
<!--SECTION FOR SPROCS-->
<!--********************-->
<Sprocs>

  <SQLObject>
    <FileName>TestData_uspUpdateEmployeeDetails_EmployeeInitialState</FileName>
    <Execute>YES</Execute>
    <SQLStatement>
      SELECT BusinessEntityID, NationalIDNumber, LoginID, OrganizationLevel, JobTitle, BirthDate, MaritalStatus, Gender, HireDate, SalariedFlag, VacationHours, SickLeaveHours, CurrentFlag, rowguid, ModifiedDate
      FROM HumanResources.Employee ORDER BY BusinessEntityID
    </SQLStatement>
  </SQLObject>

  <SQLObject>
    <FileName>TestData_uspUpdateEmployeeDetails_PersonInitialState</FileName>
    <Execute>YES</Execute>
    <SQLStatement>
      SELECT BusinessEntityID, PersonType, NameStyle, Title, FirstName, MiddleName, LastName, Suffix, EmailPromotion, AdditionalContactInfo, Demographics, rowguid, ModifiedDate
      FROM Person.Person ORDER BY BusinessEntityID
    </SQLStatement>
  </SQLObject>
 

The names of the XML/XSD files that will be created are:

TestData_uspUpdateEmployeeDetails_EmployeeInitialState and TestData_uspUpdateEmployeeDetails_PersonInitialState

When the tool is run it will output all the data in these tables as per the ‘SQLStatement’ in the config file.

The first record – where BusinessEntityID=1 – for each exported XML file is shown below:

<?xml version="1.0" standalone="yes"?>
<NewDataSet>
  <Table>
    <BusinessEntityID>1</BusinessEntityID>
    <NationalIDNumber>295847285</NationalIDNumber>
    <LoginID>adventure-works\ken0</LoginID>
    <OrganizationLevel>0</OrganizationLevel>
    <JobTitle>Chief Executive Officer</JobTitle>
    <BirthDate>1963-03-01T00:00:00+00:00</BirthDate>
    <MaritalStatus>M</MaritalStatus>
    <Gender>F</Gender>
    <HireDate>2003-02-15T00:00:00+00:00</HireDate>
    <SalariedFlag>true</SalariedFlag>
    <VacationHours>99</VacationHours>
    <SickLeaveHours>69</SickLeaveHours>
    <CurrentFlag>true</CurrentFlag>
    <rowguid>f01251e5-96a3-448d-981e-0f99d789110d</rowguid>
    <ModifiedDate>2008-07-31T00:00:00+01:00</ModifiedDate>
  </Table>
 
<?xml version="1.0" standalone="yes"?>
<NewDataSet>
  <Table>
    <BusinessEntityID>1</BusinessEntityID>
    <PersonType>EM</PersonType>
    <NameStyle>false</NameStyle>
    <FirstName>Ken</FirstName>
    <MiddleName>J</MiddleName>
    <LastName>Sánchez</LastName>
    <EmailPromotion>0</EmailPromotion>
    <Demographics>&lt;IndividualSurvey xmlns="http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/IndividualSurvey"&gt;&lt;TotalPurchaseYTD&gt;0&lt;/TotalPurchaseYTD&gt;&lt;/IndividualSurvey&gt;</Demographics>
    <rowguid>92c4279f-1207-48a3-8448-4636514eb7e2</rowguid>
    <ModifiedDate>2003-02-08T00:00:00+00:00</ModifiedDate>
  </Table>

Creating the expected post state test XML file
A copy of the files created above are taken and renamed as:
TestData_uspUpdateEmployeeDetails_EmployeePostState and TestData_uspUpdateEmployeeDetails_PersonPostState

The record with BusinessEntityID=1 will be updated as part of this test.

The following SQL statement will return the data that is expected to be updated by the new sproc:

SELECT FirstName, MiddleName, LastName, JobTitle
FROM HumanResources.Employee AS e
INNER JOIN Person.Person AS p on e.BusinessEntityID = p.BusinessEntityID
WHERE p.BusinessEntityID = 1

The data returned is:

Ken,J,Sánchez,Chief Executive Officer

It should be updated to:

Kenneth,John,Sanchez,CEO

The following EXEC statement and update values will be run in the test:

EXEC EXEC HumanResources.uspUpdateEmployeeDetails
@BusinessEntityID=1
, @FirstName='Kenneth'
, @MiddleName='John'
, @Lastname='Sanchez'
, @JobTitle='CEO'
 

Both XML files are amended to include these ‘post update’ expected values to as follows (note only showing the first record and the rest of the file remains the same):

<?xml version="1.0" standalone="yes"?>
<NewDataSet>
  <Table>
    <BusinessEntityID>1</BusinessEntityID>
    <NationalIDNumber>295847285</NationalIDNumber>
    <LoginID>adventure-works\ken0</LoginID>
    <OrganizationLevel>0</OrganizationLevel>
    <JobTitle>CEO</JobTitle>
    <BirthDate>1963-03-01T00:00:00+00:00</BirthDate>
    <MaritalStatus>M</MaritalStatus>
    <Gender>F</Gender>
    <HireDate>2003-02-15T00:00:00+00:00</HireDate>
    <SalariedFlag>true</SalariedFlag>
    <VacationHours>99</VacationHours>
    <SickLeaveHours>69</SickLeaveHours>
    <CurrentFlag>true</CurrentFlag>
    <rowguid>f01251e5-96a3-448d-981e-0f99d789110d</rowguid>
    <ModifiedDate>2008-07-31T00:00:00+01:00</ModifiedDate>
  </Table>
 
<?xml version="1.0" standalone="yes"?>
<NewDataSet>
  <Table>
    <BusinessEntityID>1</BusinessEntityID>
    <PersonType>EM</PersonType>
    <NameStyle>false</NameStyle>
    <FirstName>Kenneth</FirstName>
    <MiddleName>John</MiddleName>
    <LastName>Sanchez</LastName>
    <EmailPromotion>0</EmailPromotion>
    <Demographics>&lt;IndividualSurvey xmlns="http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/IndividualSurvey"&gt;&lt;TotalPurchaseYTD&gt;0&lt;/TotalPurchaseYTD&gt;&lt;/IndividualSurvey&gt;</Demographics>
    <rowguid>92c4279f-1207-48a3-8448-4636514eb7e2</rowguid>
    <ModifiedDate>2003-02-08T00:00:00+00:00</ModifiedDate>
  </Table>

Writing the unit test that defines the requirement
Once the expected initial and post states have been defined the next step is to write the unit test.

The sample code below shows a data comparison test for this update sproc:

using System;
using MbUnit.Framework;
using DBTestUnit.Util;
using System.Data;

namespace AdventureWorks.DatabaseTest.Tests.Sprocs.Functional
{
    [TestFixture]
    public class uspUpdateEmployeeDetails
    {
        string dbInstance = "AdventureWorks";
        string sprocTestFileDir = AppSettings.DirSprocExpectedResults();

        public uspUpdateEmployeeDetails() { }

        [RollBack]
        [Test]
        public void TestSprocUpdatesCorrectly()
        {
            //Expected data XML file names 
            string initialStateExpectedEmployeeDataFile = "TestData_uspUpdateEmployeeDetails_EmployeeInitialState";
            string initialStateExpectedPersonDataFile = "TestData_uspUpdateEmployeeDetails_PersonInitialState";
            string postStateExpectedEmployeeDataFile = "TestData_uspUpdateEmployeeDetails_EmployeePostState";
            string postStateExpectedPersonDataFile = "TestData_uspUpdateEmployeeDetails_PersonPostState";

            //SQL statement to return all data from the Employee table
            string sqlText_EmployeeData = "SELECT BusinessEntityID, NationalIDNumber, LoginID, OrganizationLevel, JobTitle,BirthDate,";
            sqlText_EmployeeData += " MaritalStatus, Gender,HireDate, SalariedFlag, VacationHours, SickLeaveHours, CurrentFlag, rowguid, ModifiedDate";
            sqlText_EmployeeData += " FROM HumanResources.Employee order by BusinessEntityID";

            //SQL statement to return all data from the Person table
            string sqlText_PersonData = "SELECT BusinessEntityID, PersonType, NameStyle, Title, FirstName, MiddleName, LastName, Suffix,";
            sqlText_PersonData += " EmailPromotion, AdditionalContactInfo, Demographics, rowguid, ModifiedDate";
            sqlText_PersonData += " FROM Person.Person ORDER BY BusinessEntityID";

            //Update sproc exec SQL
            string sqlText_ExecSproc = "EXEC HumanResources.uspUpdateEmployeeDetails";
            sqlText_ExecSproc += " @BusinessEntityID=1";
            sqlText_ExecSproc += ", @FirstName='Kenneth'";
            sqlText_ExecSproc += ", @MiddleName='John'";
            sqlText_ExecSproc += ", @Lastname='Sanchez'";
            sqlText_ExecSproc += ", @JobTitle='CEO'";

            //BEFORE UPDATE TESTS - compare actual from table and expected initial states before running update
            bool areTheSame = DataSetComparer.Compare(sprocTestFileDir, initialStateExpectedEmployeeDataFile, dbInstance, sqlText_EmployeeData);
            Assert.IsTrue(areTheSame, "Data in Employee table is not as expected BEFORE running update");

            areTheSame = DataSetComparer.Compare(sprocTestFileDir, initialStateExpectedPersonDataFile, dbInstance, sqlText_PersonData);
            Assert.IsTrue(areTheSame, "Data in Person table is not as expected BEFORE running update");

            //RUN UPDATE SPROC
            DALHelper.Execute(dbInstance, sqlText_ExecSproc);

            //AFTER UPDATE TESTS - compare actual from table and expected post states after running update
            areTheSame = DataSetComparer.Compare(sprocTestFileDir, postStateExpectedEmployeeDataFile, dbInstance, sqlText_EmployeeData);
            Assert.IsTrue(areTheSame, "Data in Employee table is not as expected AFTER running update");

            areTheSame = DataSetComparer.Compare(sprocTestFileDir, postStateExpectedPersonDataFile, dbInstance, sqlText_PersonData);
            Assert.IsTrue(areTheSame, "Data in Person table is not as expected AFTER running update");
        }
    }
}

 

The test is very similar to that outlined in the previous blog. But, it has to test two tables both before and after running the update.

When this test is run, it will fail as the sproc does not currently do anything. After running the ‘test EXEC statement’ the actual data in the tables have not changed and when compared to the expected post state XML files, they are different and therefore the test fails.

Making the test pass
A SQL script – as shown below – is created and run against the database.

At this point, only the ‘update’ functionality of the sproc is being tested. Note for simplicity no error or transaction handling is included (I hope to cover this in a future blog).

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID('HumanResources.uspUpdateEmployeeDetails') AND type in (N'P', N'PC'))
DROP PROCEDURE [HumanResources].[uspUpdateEmployeeDetails]
GO

CREATE PROCEDURE HumanResources.uspUpdateEmployeeDetails
@BusinessEntityID int, 
@FirstName dbo.Name,
@MiddleName  dbo.Name,
@LastName  dbo.Name,
@JobTitle nvarchar (50)
AS

BEGIN

SET NOCOUNT ON

UPDATE Person.Person
SET FirstName = @FirstName
,MiddleName = @MiddleName
,LastName = @Lastname
WHERE BusinessEntityID =@BusinessEntityID

UPDATE HumanResources.Employee
SET JobTitle = @JobTitle
WHERE BusinessEntityID = @BusinessEntityID

END 

If the test is run again it should now pass as the sproc correctly updates both tables – changing the rows where BusinessEntityID=1 with the expected values.

Trouble shooting failing tests
Similar techniques can be used as per the previous blog.

What next
This blog has shown a way to test the functionality of a sproc that updates more than one base table.

So far, the tests have relied on comparing expected data – created as XML files – and actual data. The next blog will look at a different technique – running SQL statements – to unit test update sprocs.


Unit testing the functionality of an update stored procedures – part 2

2011/07/13

Introduction
The previous blog in this series looked at how to test that an update sproc existed and that its parameters and properties are as expected.

This blog will look at testing the functionality – how to ensure that it updates the underlying base table correctly.

It is assumed that you have read the previous blogs in this series:

Overview of the overall process
1. Ensure appropriate test data has been set up and that the expected initial state of the row to be updated is different to what it should be after the update sproc has run.
2. Use ExportDBDataAsXML tool to create an XML file of the ‘expected initial state’ (the data that should be present BEFORE running the update sproc).
3. Modify a copy of this file. Update the row which should be changed as part of the test with the expected values the sproc should update it with to create the ‘expected post state’ (the data that should be present AFTER running the update sproc).
4. Write the unit test. When first run it will fail as the sproc will not update the row.
5. Write the SQL script so that the sproc correctly updates the table.
6. Run the test again. It will pass if the ‘actual’ data in the table is the same when compared to the ‘expected’ data.

Creating the expected initial state test XML file
All the data in the HumanResources.Employee table – including the row that is going to be updated as part of the test – is exported as XML/XSD files using the ExportDBDataAsXML tool.

There are approx 290 rows in the table so the size of the table should not be an issue. Ideally, the size of test datasets should be smaller than this. But, this is used as this is the data provided in the sample database.

Add the following to the ExportDBDataAsXML tool config.

<!--********************-->
<!--SECTION FOR SPROCS-->
<!--********************-->
<Sprocs>

  <SQLObject>
    <FileName>TestData_uspUpdateEmployeePersonalInfo_InitialState</FileName>
    <Execute>YES</Execute>
    <SQLStatement>
      SELECT BusinessEntityID, NationalIDNumber, LoginID, OrganizationLevel, JobTitle, BirthDate, MaritalStatus, Gender, HireDate, SalariedFlag, VacationHours, SickLeaveHours, CurrentFlag, rowguid, ModifiedDate
      FROM HumanResources.Employee ORDER BY BusinessEntityID
    </SQLStatement>
  </SQLObject>

Note the name of the XML/XSD files that will be created – TestData_uspUpdateEmployeePersonalInfo_InitialState
and the SELECT ’SQLStatement’* used to export the data.

When the tool is run it will output all the data in the table as per the ‘SQLStatement’ into an XML file.

The first two ‘records’ of this file are shown below:

<?xml version="1.0" standalone="yes"?>
<NewDataSet>
  <Table>
    <BusinessEntityID>1</BusinessEntityID>
    <NationalIDNumber>295847285</NationalIDNumber>
    <LoginID>adventure-works\ken0</LoginID>
    <OrganizationLevel>0</OrganizationLevel>
    <JobTitle>Chief Executive Officer</JobTitle>
    <BirthDate>1963-03-01T00:00:00+00:00</BirthDate>
    <MaritalStatus>M</MaritalStatus>
    <Gender>F</Gender>
    <HireDate>2003-02-15T00:00:00+00:00</HireDate>
    <SalariedFlag>true</SalariedFlag>
    <VacationHours>99</VacationHours>
    <SickLeaveHours>69</SickLeaveHours>
    <CurrentFlag>true</CurrentFlag>
    <rowguid>f01251e5-96a3-448d-981e-0f99d789110d</rowguid>
    <ModifiedDate>2008-07-31T00:00:00+01:00</ModifiedDate>
  </Table>
  <Table>
    <BusinessEntityID>2</BusinessEntityID>
    <NationalIDNumber>245797967</NationalIDNumber>
    <LoginID>adventure-works\terri0</LoginID>
    <OrganizationLevel>1</OrganizationLevel>
    <JobTitle>Vice President of Engineering</JobTitle>
    <BirthDate>1965-09-01T00:00:00+01:00</BirthDate>
    <MaritalStatus>S</MaritalStatus>
    <Gender>F</Gender>
    <HireDate>2002-03-03T00:00:00+00:00</HireDate>
    <SalariedFlag>true</SalariedFlag>
    <VacationHours>1</VacationHours>
    <SickLeaveHours>20</SickLeaveHours>
    <CurrentFlag>true</CurrentFlag>
    <rowguid>45e8f437-670d-4409-93cb-f9424a40d6ee</rowguid>
    <ModifiedDate>2008-07-31T00:00:00+01:00</ModifiedDate>
  </Table>

The initial state of the table is recorded and tested as it is very easy to forget to ‘rollback’ the changes of an update, insert or delete unit test. If rollback is not carried out then tests will potentially pass even if the sproc is not updating correctly. This is a relatively quick way to check that the pre-conditions are as expected.

*The SELECT statement does not include the column ‘OrganizationNode’ as it uses a new data type (as per SQL 2K8) ‘hierarchyid’. This data type is currently excluded as it causes issues with DBTestUnit comparison tests.

Creating the expected post state test XML file
A copy of the XML file created above is taken and renamed as:

TestData_uspUpdateEmployeePersonalInfo_PostState.xml

The first record with – BusinessEntityID=1 – will be updated as part of the test.

The following EXEC statement and ‘update’ values will be run in the test:

EXEC HumanResources.uspUpdateEmployeePersonalInfo 
@ BusinessEntityID=1
, @NationalIDNumber =11111111
, @BirthDate='1960-01-01'
, @MaritalStatus='M'
, @Gender='F'

Each parameter has a different value to the original initial state of the record. This is to ensure that each parameter correctly updates its associated base table column.

‘TestData_uspUpdateEmployeePersonalInfo_PostState.xml’ needs to be amended to include these post update expected values. So, the first record is manually updated, changing it to the values expected as per the ‘EXEC’ above (note ALL the other ‘records’ should remain unchanged).

The modified record is shown below:

<Table>
    <BusinessEntityID>1</BusinessEntityID>
    <NationalIDNumber>11111111</NationalIDNumber>
    <LoginID>adventure-works\ken0</LoginID>
    <OrganizationLevel>0</OrganizationLevel>
    <JobTitle>Chief Executive Officer</JobTitle>
    <BirthDate>1960-01-01T00:00:00+00:00</BirthDate>
    <MaritalStatus>M</MaritalStatus>
    <Gender>F</Gender>
    <HireDate>2003-02-15T00:00:00+00:00</HireDate>
    <SalariedFlag>true</SalariedFlag>
    <VacationHours>99</VacationHours>
    <SickLeaveHours>69</SickLeaveHours>
    <CurrentFlag>true</CurrentFlag>
    <rowguid>f01251e5-96a3-448d-981e-0f99d789110d</rowguid>
    <ModifiedDate>2008-07-31T00:00:00+01:00</ModifiedDate>
  </Table>

Writing the unit test that defines the requirement
Once the expected initial and post states have been defined the next step is to write the unit test.

The sample code below shows a data comparison test for this update sproc:

using System;
using MbUnit.Framework;
using DBTestUnit.Util;
using System.Data;

namespace AdventureWorks.DatabaseTest.Tests.Sprocs.Functional
{
    [TestFixture]
    public class uspUpdateEmployeePersonalInfo
    {
        string dbInstance = "AdventureWorks";
        string sprocTestFileDir = AppSettings.DirSprocExpectedResults();

        public uspUpdateEmployeePersonalInfo() { }

        [RollBack]
        [Test]
        public void TestSprocUpdatesCorrectly()
        {
            //Expected data XML file names 
            string initialStateExpectedDataFile = "TestData_uspUpdateEmployeePersonalInfo_InitialState";
            string postStateExpectedDataFile = "TestData_uspUpdateEmployeePersonalInfo_PostState";

            //SQL statement to return all data from the table
            string sqlText_TestData = "SELECT BusinessEntityID, NationalIDNumber, LoginID, OrganizationLevel, JobTitle, BirthDate, MaritalStatus, Gender,";
            sqlText_TestData += "HireDate, SalariedFlag, VacationHours, SickLeaveHours, CurrentFlag, rowguid, ModifiedDate";
            sqlText_TestData += " FROM HumanResources.Employee order by BusinessEntityID";

            //Update sproc exec
            string sqlText_ExecSproc = "EXEC HumanResources.uspUpdateEmployeePersonalInfo 1,11111111,'1960-01-01','M','F'";

            //Compare actual from table and expected initial states BEFORE update
            bool areTheSame = DataSetComparer.Compare(sprocTestFileDir, initialStateExpectedDataFile, dbInstance, sqlText_TestData);
            Assert.IsTrue(areTheSame, "Data in table is not as expected BEFORE running update");

            //Run update sproc
            DALHelper.Execute(dbInstance, sqlText_ExecSproc);

            //Compare actual from table and expected post states AFTER update
            areTheSame = DataSetComparer.Compare(sprocTestFileDir, postStateExpectedDataFile, dbInstance, sqlText_TestData);
            Assert.IsTrue(areTheSame, "Data in table is not as expected AFTER running update");
        }
    }
}

 

A number of things to note from the sample test:

1. It follows the steps outlined in the intro to this series:

  • Test the initial state
  • Run the sproc
  • Test the post state

2. It uses the MBUnit ‘[RollBack]’ attribute. This will run the test under a transaction and will roll it back once it has completed. This allows the test to be run multiple times.

3. The SQL SELECT set in the variable ‘sqlText_TestData’ is the same as that used in the ExportDBDataAsXML tool config to create the test XML file.

4. As seen in previous blogs, the DBTestUnit method ‘DataSetComparer.Compare’ is used.

When this test is run it will fail as the sproc does not currently do anything. After running the ‘test EXEC statement’ the actual data in the table has not changed and when compared to the expected post state XML file, it is different and so the test fails.

Making the test pass
A script – as shown below – is created and run against the database.

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[HumanResources].[uspUpdateEmployeePersonalInfo]') AND type in (N'P', N'PC'))
DROP PROCEDURE [HumanResources].[uspUpdateEmployeePersonalInfo]
GO

CREATE PROCEDURE [HumanResources].[uspUpdateEmployeePersonalInfo]
@BusinessEntityID [int], 
@NationalIDNumber [nvarchar](15), 
@BirthDate [date], 
@MaritalStatus [nchar](1), 
@Gender [nchar](1)
AS

BEGIN

SET NOCOUNT ON;

UPDATE [HumanResources].[Employee] 
SET [NationalIDNumber] = @NationalIDNumber 
,[BirthDate] = @BirthDate 
,[MaritalStatus] = @MaritalStatus 
,[Gender] = @Gender 
WHERE [BusinessEntityID] = @BusinessEntityID;

END

If the test is run again – it should now pass as the sproc correctly updates the table – changing the row where BusinessEntityID=1 with the expected values.

Trouble shooting failing tests
These types of tests can help identify a number of errors that are easily made when carrying out initial design or when refactoring a sproc. It is very easy to update a column with the wrong parameter or to update incorrect rows by making a mistake with the ‘WHERE’ clause.

For example, say a mistake is made with the parameters as shown below:

UPDATE [HumanResources].[Employee] 
SET [NationalIDNumber] = @MaritalStatus 
,[BirthDate] = @BirthDate 
,[MaritalStatus] = @MaritalStatus 
,[Gender] =  @Gender
WHERE [BusinessEntityID] = @BusinessEntityID;

The column ‘NationalIDNumber’ will be incorrectly updated with the value set in the parameter ‘@MaritalStatus’

If the unit test is run again it will fail with an error as shown below.

In a simple case like this, trouble shooting might be as straight forward as visually inspecting the sproc creation script. But, in cases where the sproc is more complex identifying the issue via inspection might be difficult. ‘Seeing’ the difference between the actual and expected data can be useful.

In the unit test above the actual data is not persisted. If required, it can be persisted by adding the following code (under comment ‘//Persist actual data in table after doing update’’) as shown below:


            //Run update sproc
            DALHelper.Execute(dbInstance, sqlText_ExecSproc);

            //Persist actual data in table after doing update
            DataSet ds = DALHelper.ExecuteDataSet(dbInstance, sqlText_TestData);
            string postStateActualDataFile = sprocTestFileDir + postStateExpectedDataFile + "ActualData.xml";
            ds.WriteXml(postStateActualDataFile);

            //Compare actual from table and expected post states AFTER update
            areTheSame = DataSetComparer.Compare(sprocTestFileDir, postStateExpectedDataFile, dbInstance, sqlText_TestData);
            Assert.IsTrue(areTheSame, "Data in table is not as expected AFTER running update");
        }

When this test is run – the inserted code will create an XML file ‘TestData_uspUpdateEmployeePersonalInfo_PostUpdate_ActualData.xml’ in the same directory as the other XML files.

It will persist the actual data in the table after running the update sproc.

This file can then be compared to the expected XML file – ‘TestData_uspUpdateEmployeePersonalInfo_PostUpdate.xml’ – using a diff tool.

The result of this comparison is shown below:

This highlights the fact that the ‘NationalIDNumber’ element is different. Knowing this should make it easier to resolve issues with the sproc implementation.

Why not persist the actual data all the time as part of the ‘standard’ unit test?

As reviewing/troubleshooting the output of the diff process is a manual step and the overhead of adding this code on an ‘ad hoc’ basis is not too great, I treat it as an exception so I don’t include it as standard into the unit test. If required, just include it as part of the test.

What next
This blog has shown a way to test the functionality of an update sproc.

The example sproc is only updating one base table and is relatively simple. The next blog in this series will look at testing more complex scenarios – for example – where two or more tables are updated by a sproc.


Unit testing update stored procedures – part 1

2011/06/29

Introduction
This is the first in a series of blogs that will look at unit testing an ‘update’ sproc using taking a TDD approach.

Testing that the sproc exists and that it has it’s expected properties will be covered – following steps 1 and 2 as per the Database unit testing patterns.

What are the requirements of the sproc
HumanResources.uspUpdateEmployeePersonalInfo from the AdventureWorks2008R2 database will be used as an example.

It updates the HumanResources.Employee table with the values specified in the input parameters for a specified Employee – using the primary key BusinessEntityID.

The SQL script to create it is shown below:


CREATE PROCEDURE [HumanResources].[uspUpdateEmployeePersonalInfo]
@BusinessEntityID [int], 
@NationalIDNumber [nvarchar](15), 
@BirthDate [datetime], 
@MaritalStatus [nchar](1), 
@Gender [nchar](1)
WITH EXECUTE AS CALLER
AS
BEGIN
SET NOCOUNT ON;
BEGIN TRY
UPDATE [HumanResources].[Employee] 
SET [NationalIDNumber] = @NationalIDNumber 
,[BirthDate] = @BirthDate 
,[MaritalStatus] = @MaritalStatus 
,[Gender] = @Gender 
WHERE [BusinessEntityID] = @BusinessEntityID;
END TRY
BEGIN CATCH
EXECUTE [dbo].[uspLogError];
END CATCH;
END;

This sproc will be dropped from the database and recreated from scratch – but taking a TDD type approach.

The ‘end game’ is to recreate the sproc as above (with a couple of minor changes that I will mention along the way).

The first thing is to run the following script to delete it from the test database:

DROP PROCEDURE HumanResources.uspUpdateEmployeePersonalInfo

Step 1 Testing that the sproc exists
A similar approach to that in Unit testing ‘Select’ stored procedures – part 1 is used.

The unit test class – ..\Tests\DatabaseTest.cs – tests for the existence of all expected SQL objects that should be in the database.

As the sproc was previously present its name is already in the list of expected sprocs (‘expectedSprocList’ and the ‘expectedSprocCount’ is already 11).

When this tests are run those related to sproc counts fail as the sproc was deleted so the count is down to 10.

To get the test to pass the following script is run:

CREATE PROCEDURE HumanResources.uspUpdateEmployeePersonalInfo
AS
BEGIN
SET NOCOUNT ON;
END
 

The tests now pass.

Step 2 Testing it’s properties
A similar approach to that in Unit testing ‘Select’ stored procedures – part 2 is be used.

Take a copy of one of the sample unit test classes included in the DBTestUnit download and rename it to uspUpdateEmployeePersonalInfo_Schema.

Update it appropriately so that the unit test class looks like the following:


using System;
using MbUnit.Framework;
using DBTestUnit.InfoSchema;
using DBTestUnit.UnitTestBaseClass.MSSQL;

namespace AdventureWorks.DatabaseTest.Tests.Sprocs.Schema
{
    [TestFixture]
    public class uspUpdateEmployeePersonalInfo : SprocTestBase
    {
        public uspUpdateEmployeePersonalInfo()
        {
            dbInstance = "AdventureWorks";
            schema = "HumanResources";
            sprocName = "uspUpdateEmployeePersonalInfo";
            sproc = new Sproc(dbInstance, schema, sprocName);
            expectedInputCount = 5;
            expectedInputList = "@BusinessEntityID,@NationalIDNumber,@BirthDate,@MaritalStatus,@Gender";
            expectedOutputCount = 0;
            expectedOutputList = "";
        }
        [RowTest]
        [Row("@BusinessEntityID ", "1,IN,int,N/A")]
        [Row("@NationalIDNumber ", "2,IN,nvarchar,15")]
        [Row("@BirthDate", "3,IN,date,N/A")]
        [Row("@MaritalStatus", "4,IN,nchar,1")]
        [Row("@Gender", "5,IN,nchar,1")]
        public void T05_ParameterProperties(string paramName, string expectedParameterProperties)
        {
            string parameterProperties = sproc.ParameterProperties(paramName);
            Assert.AreEqual(expectedParameterProperties, parameterProperties, "Param properties are not as expected");
        }

        [RowTest]
        [Row("@BusinessEntityID", "HumanResources.Employee", "BusinessEntityID")]
        [Row("@NationalIDNumber", "HumanResources.Employee", "NationalIDNumber")]
        [Row("@BirthDate", "HumanResources.Employee", "BirthDate")]
        [Row("@MaritalStatus", "HumanResources.Employee", "MaritalStatus")]
        [Row("@Gender", "HumanResources.Employee", "Gender")]
        public void T06_ParameterIsTheSameDataTypeAndLength(string paramName, string tableName, string columnName)
        {
            bool areTheSame = sproc.ParameterIsSameAsColumn(paramName, tableName, columnName);
            Assert.IsTrue(areTheSame, "Parameter and column are not the same");
        }
    }
}

This will test that the sproc’s parameters are as expected – correct number of parameters and properties.

It will also check that the parameters have the same data types as the base table columns that they will update. It is very easy to make a mistake and not have the parameters exactly match the columns (see this blog for more detail).

* The paramater ‘@BirthDate’ in the original sproc – see SQL script above – has a data type of ‘datetime’ whereas the underlying base table column HumanResources.Employee has a type of ‘date’. The sproc created in this series of blogs will have ‘@BirthDate’ as ‘date’.

Compile and run the tests. They will fail as the sproc does not currently have any parameters.

To make it pass the tests the following script is run:


IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'HumanResources.uspUpdateEmployeePersonalInfo') AND type in (N'P', N'PC'))
DROP PROCEDURE HumanResources.uspUpdateEmployeePersonalInfo
GO

CREATE PROCEDURE HumanResources.uspUpdateEmployeePersonalInfo
@BusinessEntityID [int], 
@NationalIDNumber [nvarchar](15), 
@BirthDate [date], 
@MaritalStatus [nchar](1), 
@Gender [nchar](1)
AS

BEGIN

SET NOCOUNT ON;


END
 

Run the test again and they now pass as the sproc meets the expectations/requirements as per the tests.

What next
Steps 1 and 2 as per the Database unit testing patterns have been carried out and an initial sproc has been created.

The next blog in this series will look at Step 3 – testing the functionality of the sproc – ensuring that it updates the base table as expected.


Unit testing insert, delete and update stored procedures – intro

2011/06/27

Up to now the previous blogs on unit testing sprocs have focused on those that output data – ‘Select’ sprocs. Over the next few weeks I intend to write a series of blogs that will look at testing sprocs that carry out other types of data manipulation.

The steps outlined in Database unit testing patterns will be followed for testing delete, insert and update sprocs. But as steps 1,2 and 4 are effectively the same as outlined previously, the focus will be on Step 3 – testing the functionality of the sproc.

Does the sproc delete/insert/update as expected?

Over the series a functional test pattern will emerge for testing all three types of sprocs.

This can be outlined as:

1. Test initial state is as expected
For example, if testing an update sproc ensure that the row(s) to be updated has the expected initial values (ie it hasn’t already been updated by a previous test and not ‘rolled back’).

2. Run the sproc

3. Test post state is as expected
For example, after running an update sproc ensure that the row(s) has been updated correctly AND it hasn’t inadvertantly effected any other rows.

I will give examples of two different approaches that can be used to do the steps outlined above:

A. Using the ExportDBDataAsXML tool to create expected pre and post state XML files that can that can be compared to ‘actuals’.

B. Using ‘ad hoc’ SQL commands to test checksums, row counts and values in rows for both pre and post states.

The series will start with a relatively straight forward example of an update sproc – taken from Microsoft’s AdventureWorks2008R2 – which updates a single table. This will then be extended to look at how to handle more complex scenarios, such as where 2 or more base tables are involved.


Using ad hoc SQL commands in DBTestUnit tests

2011/06/20

When writing database tests you will find that you need to excute a SQL statement as part of the test.

For example, you might want to check the number of rows in a table before and after running an ‘insert’ sproc or to execute the sproc from your C# tests.

The DBTestUnit.Util.DALHelper class provides three methods that allow SQL commands to be run against your database.

These are:

  • ExecuteScalar
  • ExecuteDataSet
  • Execute

All take two strings as parameters – the dbInstance (defines which db to run the SQL command against) and the SQL text to run.

Which one to use depends on the expected output:

  • No value to be returned.

    For example to carry out an insert of a test record into a table:

    string sqlText = "INSERT INTO HumanResources.Department (Name, GroupName) VALUES ('TestDeptName', 'TestGroupName')";
    DBTestUnit.Util.DALHelper.Execute(dbInstance, sqlText);
    
  • Scalar value to be returned.

    For example, to get the row count of a table:

    string sqlText = "SELECT COUNT(*) FROM HumanResources.Department";
    int rowCount = System.Convert.ToInt32(DALHelper.ExecuteScalar(dbInstance, sqlText));
    
  • Dataset to be returned
    sqlText = "SELECT * FROM  HumanResources.Department";
    DataSet ds =DBTestUnit.Util.DALHelper.ExecuteDataSet(dbInstance, sqlText);
    


Configuring your DBTestUnit test project

2011/06/14

There are two places that need to be configured to allow tests to run:

1. The test dll config file.
2. The ‘dbInstance’ property set in the test classes.

This blog will explain how to config each of these.

Test dll config file
If you have downloaded DBTestUnit and followed the instructions outlined here – you will find the test dll config file – AdventureWorks.DatabaseTest.dll.config – in the following dir:

C:\Projects\AdventureWorksBlog\src\AdventureWorksDatabaseTest\bin\Debug\

This contains the connections settings for the database(s) that will be tested.

The following text shows a sample database connection for a MS SQL server from this file.

<connectionStrings>
<add name="AdventureWorks" connectionString="Data Source=serverName;Initial Catalog=AdventureWorks;Integrated Security=True;Application Name=AdventureWorksUnitTesting" providerName="System.Data.SqlClient"/>
</connectionStrings>

There are two parts to configuring a MS SQL server database

A) The element ‘name’ shown above as – name=”AdventureWorks”. This is referenced within the test classes.
B) The element ‘connectionString’. This is a standard SQL server connection string – consisting of:

  • ‘Data Source=serverName’ – the SQL server to connect to.
  • ‘Initial Catalog=AdventureWorks’ – the database to test.
  • ‘Integrated Security=True’ – use trusted security ie uses the account that the tests are being run under.

Note DBTestUnit requires read access to information_schema and system views. Therefore, the account being used will need appropriate access.

Test class
The sample code, shown below, is for testing a sproc in the AdventureWorks db.

using System;
using MbUnit.Framework;
using DBTestUnit.InfoSchema;
using DBTestUnit.UnitTestBaseClass.MSSQL;

namespace AdventureWorks.DatabaseTest.Tests.Sprocs.Schema
{
    [TestFixture]
    public class uspGetManagerEmployees : SprocTestBase
    {
        public uspGetManagerEmployees()
        {
            dbInstance = "AdventureWorks";

As can be seen the ‘dbInstance’ property is set to ‘AdventureWorks’. This test class would use the connection settings in the config file set by the element ‘name’ which has a value of ‘AdventureWorks’.

Example
Imagine the scenario where you want to carry out both unit and deployment tests using the same Visual Studio project ie only having one test dll and config file. But, you want to use different SQL servers/databases for each type of test – with settings as outlined below:

Type SQL server Database dbInstance
Unit test SQLServer01 TestDb MyUnitTests
Deployment test SQLServer02 DeploymentDb MyDeploymentTests

To do this the following would be added to the test dll config file.

<connectionStrings>
<add name="MyUnitTests" connectionString="Data Source=SQLServer01;Initial Catalog=TestDb;Integrated Security=True;Application Name=UnitTesting" providerName="System.Data.SqlClient"/>

<add name="MyDeploymentTests" connectionString="Data Source=SQLServer02;Initial Catalog=DeploymentDb;Integrated Security=True;Application Name=DeploymentTesting" providerName="System.Data.SqlClient"/>
</connectionStrings>

Each type of test class would also need to reference the appropriate configuration settings – ‘dbInstance’ would be set as follows in each type of test class.

Unit test

    [TestFixture]
    public class someUnitTest
    {
        public someUnitTest()
        {
            dbInstance = "MyUnitTests";

Deployment test

    [TestFixture]
    public class someDeploymentTest
    {
        public someDeploymentTest()
        {
            dbInstance = "MyDeploymentTests";


Follow

Get every new post delivered to your Inbox.