SQLServerCentral Article

Uses For Derived Tables

,

Introduction

A derived table is a select statement inside parenthesis, with an alias, used as a table in a join.

A simple example is:

SELECT a.LastName, b.State
FROM UserTable a INNER JOIN
(SELECT UserID, State FROM AddressTable)
b
ON a.UserID = b.UserID

The table with the alias b is the derived table.  Of course, in the above example you could just as easily do the join without the derived table.  All code in this article was tested on SQL Server 7.0 and SQL Server 2000.

Derived Table Example 1

I have found two cases where a derived table can be useful.

First we need to set up a few test tables.  You can copy and paste the following code into Query Analyzer:

CREATE TABLE #Components (UserID
int, ComponentName varchar(20),
SerialNumber varchar(10))
CREATE TABLE #Users (UserID int, LocationID int, UserName varchar(20))
CREATE TABLE #Locations (LocationID
int, State char(2))
INSERT INTO #Locations (LocationID,
State)
SELECT 1, 'VA'
UNION
SELECT 2, 'MD'
INSERT INTO #Users (UserID, LocationID, UserName)
SELECT 1, 1, 'Robert Marda'
UNION
SELECT 2, 1, 'Arthur Landers'
UNION
SELECT 3, 2, 'Flecha Ardiente'
UNION
SELECT 4, 2, 'Lia Bakker'
INSERT INTO #Components (UserID, ComponentName, SerialNumber)
SELECT 1, 'Computer', 'A003B2'
UNION
SELECT 1, 'Computer', 'A003B5'
UNION
SELECT 2, 'Computer', 'A003B7'
UNION
SELECT 2, 'Laptop', 'CG15R4D'
UNION
SELECT 3, 'Computer', 'A003B10'
UNION
SELECT 3, 'Laptop', 'CG15R1Z'
UNION
SELECT 3, 'Computer', 'A003B0'
UNION
SELECT 4, 'Laptop', 'CG15R4W'
UNION
SELECT 4, 'Computer', 'A003B6'
UNION
SELECT 4, 'Laptop', 'CG15R3E'

Now for our first result set lets suppose we need to know how many users are at each location and how many components are at each location.  Here is a query I have seen developers use to try and get the desired results:

SELECT DISTINCT l.State, COUNT(u.LocationID) AS UserCount, COUNT(c.UserID) AS ComponentCount
FROM #Locations l
INNER JOIN #Users u ON l.LocationID
= u.LocationID
INNER JOIN #Components c ON c.UserID
= u.UserID
GROUP BY l.State
This query will return the following results:
State UserCount   ComponentCount
----- ----------- --------------
MD    6           6
VA    4           4
(2 row(s) affected)

The query returns the correct number of components but not the correct number of users.  One way to get the desired results without changing the database structure is to use a derived table like this:

SELECT DISTINCT l.State, COUNT(u.LocationID) AS UserCount, c.ComponentCount
FROM #Locations l
INNER JOIN #Users u ON l.LocationID
= u.LocationID
INNER JOIN (SELECT u.LocationID, COUNT(c.ComponentName) AS ComponentCount
                FROM #Components c
                INNER JOIN #Users u ON c.UserID
= u.UserID
                GROUP
BY u.LocationID) c ON c.LocationID
= l.LocationID
GROUP BY l.State,c.ComponentCount
ORDER BY l.State
Executing this query returns the following results:
State UserCount   ComponentCount
----- ----------- --------------
MD    2           6
VA    2           4
(2 row(s) affected)

The derived table is everything in the parenthesis and has the alias name c.  To get the desired results we simply moved one of the count functions into the derived table and the results came back as needed.

Derived Table Example 2

This next example shows a case where a simple join will not work. This occurs when you need to use the key word distinct and you are using the case statement in the order by clause. Using the same tables and test data previously created lets say we need to know what components are at each location. We want to be able to sort by the state or the component name by setting a variable.  The following query could be used:

DECLARE @orderby int
SET @orderby = 1
SELECT
l.State, ComponentName
FROM #Locations l
INNER JOIN #Users u ON l.LocationID
= u.LocationID
INNER JOIN #Components c ON c.UserID
= u.UserID
ORDER BY CASE @orderby
             WHEN 1 THEN l.State
             WHEN 2 THEN ComponentName
             END

Here are the results:

State ComponentName        
----- --------------------
MD    Laptop
MD    Laptop
MD    Computer
MD    Computer
MD    Laptop
MD    Computer
VA    Computer
VA    Computer
VA    Computer
VA    Laptop
(10 row(s) affected)

Now we need to eliminate the duplicates and so we add the distinct key word to the query:

DECLARE @orderby int
SET @orderby = 1
SELECT DISTINCT
l.State, ComponentName
FROM #Locations l
INNER JOIN #Users u ON l.LocationID
= u.LocationID
INNER JOIN #Components c ON c.UserID
= u.UserID
ORDER BY CASE @orderby
             WHEN 1 THEN l.State
             WHEN 2 THEN ComponentName
             END

However, when we execute the modified query we get the following error:

Server: Msg 145, Level 15, State
1, Line 5

ORDER BY items must appear in the select list if SELECT DISTINCT is specified.

I will not claim to understand why the error is given since as far as I can see I have specified both columns in the order by and the select list.  Just adding the keyword distinct breaks the query. The way I found to get around this problem is to use a derived table and put the SELECT DISTINCT in the derived table.  The modified query looks like this:

DECLARE @orderby int
SET @orderby = 1
SELECT --DISTINCT
l.State, ComponentName
FROM #Locations l
INNER JOIN
(SELECT DISTINCT LocationID, ComponentName FROM #Users u
INNER JOIN #Components c ON c.UserID
= u.UserID) derived ON l.LocationID
= derived.LocationID
ORDER BY CASE @orderby
             WHEN 1 THEN l.State
             WHEN 2 THEN ComponentName
             END

This query gives us the following result set:

State ComponentName        
----- --------------------
MD    Computer
MD    Laptop
VA    Computer
VA    Laptop
(4 row(s) affected)

In the above query we converted a join between the table #Users and #Components into the derived table and moved the distinct keyword to the derived table and were able to get the desired results.

Conclusions

I use derived tables whenever convenient. It is often easier than creating a temp table and usually works better. The above two examples show cases when it can be useful, perhaps required to use something other than a simple join and derived tables work well in both the examples I have given.

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating