Blog Post

The Tally Table and Expanding Rows

,

Suppose you had some data like this:

Class           Limit
————— ———–
Calculus        5
History         4
Physics         2

But what you really want is this:

Class           Student
————— ———–
Calculus       
Calculus       
Calculus       
Calculus       
Calculus       
History        
History        
History        
History        
Physics        

Physics        

Where you have a placeholder for each student. This is a little contrived, but for the sake of the scenario, how do you actually expand the data in the first set to the second?

An easy way is a cursor, but suppose you had a large school environment and you were doing this regularly, you might not want the performance hit of a cursor. Suppose you have some similar scenario, like slotting inventory or holding places for some large report? You would want a better solution.

Setup

Let’s first get a table ready for this.

declare @Table table (
  Class varchar(15)
, Limit int
)
;
insert into @Table 
  values ('Calculas',5)
       , ('History', 6)
       , ('Physics', 2)
;       

A Tally Table

I first saw this when Jeff Moden talked about this in his “The Numbers or Tally Table” article. It seemed like a neartidea, and he improved upon is in his next piece, finding a more efficient way to generate the data. An even more flexible idea that I like came from his Test Data Generator article, where he uses sys.columns to build a list as large as he would like. I found it to be a great idea, and this problem is a great way to apply it.

Here’s a short look at the code that makes this work.

SELECT TOP (4) RowNum = ROW_NUMBER() OVER(ORDER BY a.[Name])
 FROM sys.columns a, sys.columns b

In this code, a cross join occurs between sys.columns and itself. With the addition of the ROW_NUMBER() function, and an order by, you can easily get a list of numbers. If I run this. I get:

RowNum

——————–

1

2

3

4

If I change my TOP value, I can get different rows:

SELECT TOP (6) RowNum = ROW_NUMBER() OVER(ORDER BY a.[Name])
 FROM sys.columns a, sys.columns b

RowNum

——————–

1

2

3

4

5

6

To make this work for me in the original problem, I will use the limit value for my TOP in a subquery. However I can’t do a straight join, I need a CROSS APPLY, that will execute the right side of the CROSS apply for each input row from the left table.. It’s intended to be for table valued functions, but in this case, we’ll just return a table from the right side.

The code looks like this:

SELECT
  c.Class
, 'Student' = ' '
FROM (
SELECT Class,Limit
FROM @Table
) c
CROSS APPLY (
SELECT TOP (Limit) RowNum = ROW_NUMBER() OVER(ORDER BY a.[name])
FROM sys.columns a, sys.columns b
) n

What happens is that for each row, the derived table on the right side of the CROSS APPLY, returns a set of numbers which are then linked to the row on the left side of the CROSS APPLY.

For the first row in @table, we have “Calculus” and “5”. When we apply this row to the subquery on the right side (SELECT TOP()…), we get these results:

1

2

3

4

5

When this is joined with the row and the c.Class returned, we end up with the same value being returned 5 times. That results in

Calculus

Calculus

Calculus

Calculus

Calculus

If this is repeated for each of the other rows, we get 4 and 2 rows from the right side of the CROSS APPLY returned, respectively.

The final results are what we get at the top of this post.

Filed under: Blog Tagged: syndicated, T-SQL

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating