DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Please enter at least three characters to search
Refcards Trend Reports
Events Video Library
Refcards
Trend Reports

Events

View Events Video Library

Zones

Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks

Last call! Secure your stack and shape the future! Help dev teams across the globe navigate their software supply chain security challenges.

Modernize your data layer. Learn how to design cloud-native database architectures to meet the evolving demands of AI and GenAI workloads.

Releasing software shouldn't be stressful or risky. Learn how to leverage progressive delivery techniques to ensure safer deployments.

Avoid machine learning mistakes and boost model performance! Discover key ML patterns, anti-patterns, data strategies, and more.

Related

  • Design Patterns for Scalable Test Automation Frameworks
  • Architecture Patterns : Data-Driven Testing
  • Cypress API Testing: A Detailed Guide
  • Exploring Shadow DOM With Examples Using Cypress

Trending

  • Measuring the Impact of AI on Software Engineering Productivity
  • Cookies Revisited: A Networking Solution for Third-Party Cookies
  • Artificial Intelligence, Real Consequences: Balancing Good vs Evil AI [Infographic]
  • Issue and Present Verifiable Credentials With Spring Boot and Android
  1. DZone
  2. Coding
  3. Frameworks
  4. Unit Tests for SPs Using tsqlt Framework

Unit Tests for SPs Using tsqlt Framework

In this article, see how to easily test Stored Procedures by adding unit tests using tsqlt framework.

By 
Gowthamraj Palani user avatar
Gowthamraj Palani
·
Sep. 13, 22 · Tutorial
Likes (1)
Comment
Save
Tweet
Share
4.8K Views

Join the DZone community and get the full member experience.

Join For Free

Writing unit tests to test the code is an inevitable practice in programming. Testing stored procedures are as important as the other code. Often SPs are tested manually, and we avoid adding an automated test. In an agile environment, code without tests are prone to defects at some point. In this article, let's see about tsqlt framework - an open source Database Unit Testing framework for SQL Server.

Pre-Requisites

  •  Code Editor (ex., IntelIj)
  • SQL Database

Attach your Editor to the running database. The database can be running either in the local, cloud or in any VMs. 

Attach your Editor to the running database.


Create Test Objects

Create a new Test class as below.  Running this in the attached session of DB will create a test object in DB. We will be adding all the test scripts (SPs) inside this object.

SQL
 
EXEC  tsqlt.NewTestClass 'EMPLOYEE'
GO


Note the tests inside the newly created object. We will be reading about the tests in detail below. We are all set now to write our tests. 

 the tests inside the newly created object.


Table and SP Details

Below are the table details and SP for the example that we are going to see in this article. 

Table Name: Employee with columns emp_no, emp_name, and salary.

Table Name: Employee with columns emp_no, emp_name and salary


Stored Procedure 1:  To select rows from the table.

SQL
 
CREATE PROCEDURE [dbo].[get_all_employees_v1]
AS
BEGIN
    SET NOCOUNT ON
    SET XACT_ABORT ON
    SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED

    SELECT emp_no
        , emp_name
        , salary
    FROM dbo.employee c
END
GO


Stored Procedure 2: To insert a new record.

SQL
 

CREATE PROCEDURE [dbo].[update_employees_v1]
    @emp_no INT
   ,@emp_name VARCHAR(20)
   ,@salary INT

AS
BEGIN
    SET NOCOUNT ON
    SET XACT_ABORT ON
    SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED

    INSERT INTO dbo.employee (emp_no, emp_name, salary)
    VALUES (@emp_no, @emp_name, @salary)
END
GO


Let's see how to write tests for the above SPs.

Test Patterns

We write tests in different structure for SPs that returns result and updates records. There is no major difference in both but a simple difference in populating expected and actual tables. 

For Select:

  1. Create fake tables.
  2. Insert test data into tables.
  3. Create expected and actual tables.
  4. Run SP and put the result in the "actual" table.
  5. Compare "expected" and "actual" tables. 


SQL
 
CREATE OR ALTER PROCEDURE [EMPLOYEE].[test employee]
AS
BEGIN
    -- ARRANGE (fake synonym table employee is created)
    EXEC tSQLt.FakeSynonymTable 'employee', 'dbo';

-- Test data insertion
    INSERT INTO dbo.employee (emp_no, emp_name, salary) VALUES (2, 'xxx', 1000);

-- Actual table is defined
    SELECT emp_no, emp_name, salary INTO #actual FROM dbo.employee where 1 = 0

-- Create an empty #Expected temp table that has the same structure as the #Actual table
    SELECT TOP (0) *
    INTO #expected
    FROM #actual;

-- Run the SP and store results in actual table
    INSERT INTO #actual
        EXEC dbo.get_all_employees_v1

-- Populate expected table with desired results
    INSERT INTO #expected (emp_no, emp_name, salary) VALUES (2, 'xxx', 1000);

-- Assert expected and actual
    EXEC tSQLt.AssertEqualsTable '#expected', '#actual', 'missing expected row'

END
GO


Run the test using the code below and see the tests pass: 

 
EXEC tSQLT.RUN 'EMPLOYEE.[test employee]'



Insert or Update or Delete:

  1. Create fake tables.
  2. Insert test data into tables.
  3. Create expected and actual tables.
  4. Run the SP.
  5. Copy records that are modified from the original table to actual.
  6. Compare "expected" and "actual" tables.
SQL
 
CREATE OR ALTER PROCEDURE [EMPLOYEE].[test update_employee]
AS
BEGIN
    -- ARRANGE (fake synonym table employee is created)
    EXEC tSQLt.FakeSynonymTable 'employee', 'dbo';

-- Create expected tables
    CREATE TABLE #expected (emp_no int, emp_name VARCHAR(20), salary int)

-- Run the SP
    EXEC dbo.update_employees_v1 @emp_no=1, @emp_name='test', @salary=300

-- Above step had already create a new record in the table. Read it and store it in actual table
    SELECT emp_no, emp_name, salary INTO #actual FROM dbo.employee WHERE emp_no=1

-- Populate expected table with desired results
    INSERT INTO #expected (emp_no, emp_name, salary) VALUES (1, 'test', 300);

-- Assert expected and actual
    EXEC tSQLt.AssertEqualsTable '#expected', '#actual', 'missing expected row'

END
GO


Run the test using:

 
EXEC tSQLT.RUN 'EMPLOYEE.[test employee]'



Conclusion

Writing tests for any piece of code is important to prevent bugs. SPs are no different. Writing automated tests for SPs is a good option to test them very early and efficiently. 

Framework Testing

Opinions expressed by DZone contributors are their own.

Related

  • Design Patterns for Scalable Test Automation Frameworks
  • Architecture Patterns : Data-Driven Testing
  • Cypress API Testing: A Detailed Guide
  • Exploring Shadow DOM With Examples Using Cypress

Partner Resources

×

Comments
Oops! Something Went Wrong

The likes didn't load as expected. Please refresh the page and try again.

ABOUT US

  • About DZone
  • Support and feedback
  • Community research
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Core Program
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 3343 Perimeter Hill Drive
  • Suite 100
  • Nashville, TN 37211
  • support@dzone.com

Let's be friends:

Likes
There are no likes...yet! 👀
Be the first to like this post!
It looks like you're not logged in.
Sign in to see who liked this post!