Tag Archives: SQL

T-SQL Transactions

I do not confess to being a database expert, nor a guru in T-SQL, which is why I have only just found out how crap transactions in T-SQL on SQL Server 2000 can be.  Take a look at the following piece of T-SQL:

CREATE TABLE #Foo
(
PK int NOT NULL
)

CREATE TABLE #Foo2
(
PK int NOT NULL
)

BEGIN TRANSACTION

INSERT INTO #Foo (PK) VALUES (1)
INSERT INTO #Foo2 (PK) VALUES (NULL)

COMMIT TRANSACTION

SELECT * FROM #Foo

DROP TABLE #Foo2
DROP TABLE #Foo

The above script creates two temporary tables, attempts to insert a value in the first, and then a NULL in the second table.  Since #Foo2.PK does not allow NULL values, the second insert fails.  I naively assumed that because I have wrapped the insert statements in a transaction, the commit will only complete if no error occurs.  This is not the case.  The commit statement commits the first insert but not the second – not exactly what I had in mind.  

The problem experienced above, is partially due to bad coding on my part because I did not initially understand the intricacies of how SQL Server 2000 manages transactions – the user is responsible for managing the roll back of a transaction after a statement error. The correct approach would have been to check the @@ERROR value for non-zero after each statement in the transaction block to see if a roll back was required. This can be a real chore if a transaction has many statements, and especially annoying if the error number of any one statement be reported, and the transaction aborted upon an error (typical behavior).  Fortunately, SQL Server 2005 comes to the rescue with try-catch – similar to that of how ADO.NET deals with transactions.  The following code will produce the desired results in SQL Server 2005:

CREATE TABLE #Foo
(
PK int NOT NULL
)

CREATE TABLE #Foo2
(
PK int NOT NULL
)

BEGIN TRANSACTION

BEGIN TRY

INSERT INTO #Foo (PK) VALUES (1)
INSERT INTO #Foo2 (PK) VALUES (NULL)

COMMIT TRANSACTION

END TRY
BEGIN CATCH

ROLLBACK TRANSACTION
PRINT ‘It broke’

END CATCH

SELECT * FROM #Foo

DROP TABLE #Foo2
DROP TABLE #Foo

FOR XML and ADO.NET

My esteemed colleague Sahil Malik has blogged about using FOR XML in SQL server.  The following C# example demonstrates how to retrieve XML data from a SQL Server 2K5 database as XML:

using (SqlConnection conn = new SqlConnection(“…”))
{
using (SqlCommand cmd = new SqlCommand(
“select’Rob’ as [Employee/@EmployeeName],’A cool dude’ as [Employee] FOR XML PATH(‘Staff’)”, conn))
{
conn.Open();
XmlReader reader = cmd.ExecuteXmlReader();
while (reader.Read())
{
switch (reader.NodeType)
{
case XmlNodeType.Element:
if (reader.HasAttributes)
{
Console.Write(“”);
}
else
Console.Write(“”, reader.Name);
break;
case XmlNodeType.Text:
Console.Write(reader.Value);
break;
}
}
}
}

Common Table Expressions

Today I was delighted to learn about common table expressions in SQL Server 2005. Essentially, CTEs replace the need for cursors when executing statements against rows in a result set. Here are some examples…

Let us assume that we have an employee table, and the employee table lists all employees in the company. Each employee has a unique ID – EmployeeID, which is the primary key in the table. Each employee reports to one manager and this is indicated by the managers EmployeeID in the ManagerID column for a given employee. e.g

EmployeeID Name ManagerID
1 Bob (CEO) NULL
2 Sally 1
3 Jim 1
4 Paul 2
5 Simon 4

As shown above, Bob is the CEO and reports to nobody, Sally and Jim report to Bob, Paul reports to Sally, and Simon reports to Paul.

Let’s say that we want to list how many employees report to each manager. We could write a query using the group by clause (assuming we don’t want to join the result set back with the employees table to match the name with EmployeeID), as follows:

SELECT
ManagerID, count(*)
FROM
#employees
WHERE
ManagerID IS NOT NULL
GROUP BY ManagerID

What if we wanted to display those managers that had more than one person reporting to them? This result could be obtained by storing the results of the previous query in a temporary table and then running a separate query, or using a cursor. However, using a CTE it is possible to gain the same result with one statement, as follows:

WITH my_CTE (ManagerID, Employees) AS
(
SELECT
e.ManagerID, count(*) AS Employees
FROM
#employees e
WHERE e.ManagerID IS NOT NULL
GROUP BY e.ManagerID
)
SELECT e.[Name], cte.*
FROM
my_CTE cte
INNER JOIN #employees e ON e.EmployeeID = cte.ManagerID
WHERE
Employees > 1

How about listing the company hierarchy in as a tabular list, indicating rank, starting with the CEO, and following with the direct reports at each level throughout the company? A CTE is great for this problem:

WITH my_CTE (ManagerID, EmployeeID, Rank) AS
(
SELECT
e.ManagerID, e.EmployeeID, 0 AS Rank
FROM
#employees e
WHERE
e.ManagerID IS NULL
UNION ALL
SELECT
e.ManagerID, e.EmployeeID, cte.Rank + 1
FROM
#employees e
INNER JOIN my_CTE cte ON e.ManagerID = cte.EmployeeID
)
SELECT
e.[Name], cte.*
FROM
my_CTE cte
INNER JOIN #employees e ON e.EmployeeID = cte.EmployeeID

The last example uses recursion to produce the ranking. This query will work no matter how many employees work for the company and no matter how many levels of management. Prior to CTEs, obtaining the same result would have involved some sophisticated SQL.