Sequence Numbers A table of sequence numbers consists of N rows with each row containing a unique integer value from 1 through N. In some cases it may be more convenient to have the values X through Y where Y-X equals N-1. A table of sequence numbers can be very useful for a variety of purposes. See Listing 1 for a short user-defined function that returns such a table. Of course, similar code can be included within a stored procedure for SQL Server 7 which does not have user-defined functions. A table of sequence numbers is often involved in a CROSS JOIN with a table of working data. The result set contains a row for every combination of working data and sequence number. This method can be used to replicate the rows of the working data. All rows are replicated N times by default, but a WHERE clause can selectively replicate specific rows in different quantities. For example, if table Address contains addresses for mailing labels the following query would produce three labels for addresses in Nebraska/Kansas/Oklahoma and six labels for all other addresses. SELECT * FROM Address CROSS JOIN dbo.udfGetSequence(1,6) WHERE Number < CASE State WHEN 'NE' THEN 4 WHEN 'KS' THEN 4 WHEN 'OK' THEN 4 ELSE 7 END Here's another way to get the same result. SELECT * FROM Address, dbo.udfGetSequence(1,6) WHERE State NOT IN ('NE','KS','OK') OR Number < 4 A table of sequence numbers can also be used as an index into a string value to provide a set-based approach to some common string manipulations. Listing 2 is a user-defined function that counts the number of times one string is found within another string. Listing 3 is a user-defined function that parses a delimited string into individual elements. Both of these functions use the earlier function to generate a table of sequence numbers. Here are some example uses of the two functions. DECLARE @S varchar(2000) SET @S = 'football basketball baseball hockey soccer volleyball golf tennis' SELECT dbo.udfCountString(@S,'ball') This returns the value 4. DECLARE @S varchar(2000) SET @S = 'This fine line is a baseline for the incline of the main line.' SELECT dbo.udfCountString(@S,'[ ]line[;,.!? ]') This returns the value 2. DECLARE @S varchar(2000) SET @S = '1,12,123,1234,ABCD,ABC,AB,A,*' SELECT * FROM dbo.udfParseString(@S,',') This returns a table of nine rows with each one containing an index, an offset, and a string. 1 1 1 2 3 12 3 6 123 4 10 1234 5 15 ABCD 6 20 ABC 7 24 AB 8 27 A 9 29 * I hope these functions are useful for you and/or help you come up with creative ways to use a table of sequence numbers. Listing 1: CREATE FUNCTION dbo.udfGetSequence (@A int, @Z int) RETURNS @T TABLE (Number int) AS BEGIN DECLARE @I int SET @I = 1 INSERT @T VALUES (@A) WHILE @I < @Z - @A + 1 BEGIN INSERT @T SELECT @I + Number FROM @T WHERE @I + Number <= @Z SET @I = @I + @@ROWCOUNT END RETURN END Listing 2: CREATE FUNCTION dbo.udfCountString (@S varchar(8000), @E varchar( 80)) RETURNS smallint AS BEGIN DECLARE @Result smallint DECLARE @I smallint SET @I = DATALENGTH(@S) SELECT @Result = COUNT(*) FROM udfGetSequence(1,@I) AS T WHERE SUBSTRING(@S,T.Number,@I) LIKE @E + '%' RETURN (@Result) END Listing 3: CREATE FUNCTION dbo.udfParseString (@S varchar(7998), @E char( 1)) RETURNS @T TABLE (Number smallint IDENTITY(1,1), Offset smallint, String varchar(2000)) AS BEGIN DECLARE @N smallint DECLARE @Z varchar(8000) SET @N = LEN(@S) + 1 SET @Z = @E + @S + @E INSERT @T (Offset, String) SELECT Number , SUBSTRING(@S,Number,CHARINDEX(@E,@Z,Number+1)-Number-1) FROM dbo.udfGetSequence(1,@N) WHERE SUBSTRING(@Z,Number,1) = @E ORDER BY Number RETURN END