SQL SERVER – CREATE TABLE Failed Because Column ‘C1024’ in Table ‘myTable’ Exceeds the Maximum of 1024 Columns

Sometimes the best way to learn is by taking some of the capabilities to the extreme. This blog post is one of those explorations which I would like to share. A very long time ago I wrote a blog on this feature which was introduced in SQL Server 2008 called “Sparse Columns”. You can read below blogs to read about the fundamentals of SPARSE columns:

One of the thing which people have misunderstood is the number of sparse column we can have with a table. As per documentation we can go beyond 1024 column limit by using sparse columns. One of my blog reader has done some test and said that the statement is not true. Here is the script which we was using:

CREATE TABLE SomeTable (Id INT SPARSE NULL)
DECLARE @SN INT
SET
@SN = 1
WHILE (@SN <= 1030)
BEGIN
DECLARE
@CLN VARCHAR(100)
SET @CLN = 'C' + CONVERT(VARCHAR(100), @SN)
DECLARE @Query VARCHAR(MAX)
SET @Query = 'ALTER TABLE SomeTable ADD ' + @CLN + ' nvarchar(100) SPARSE'
SET @SN = @SN + 1
EXEC (@query)
END
GO

Above script is having a logic where it would create a table called SomeTable as below

CREATE TABLE SomeTable (Id INT SPARSE NULL)

And then it would keep adding columns using dynamic SQL

ALTER TABLE SomeTable ADD C1 NVARCHAR(100) SPARSE
ALTER TABLE SomeTable ADD C2 NVARCHAR(100) SPARSE
..
..
ALTER TABLE SomeTable ADD C1023 NVARCHAR(100) SPARSE
ALTER TABLE SomeTable ADD C1024 NVARCHAR(100) SPARSE

It fails with below error

Msg 1702, Level 16, State 2, Line 1
CREATE TABLE failed because column ‘C1024’ in table ‘SomeTable’ exceeds the maximum of 1024 columns.

As per https://msdn.microsoft.com/en-us/library/ms143432.aspx (Maximum Capacity Specifications for SQL Server) we should not have received the error because our table is a wide table.

Columns per non-wide table1024
Columns per wide table30,000

Here is the answer from Qingsong Yao (Microsoft)

In order to create more than 1024 columns, you have to have a columnset column defined in the table. Once the table has columnset defined, the select * will hide all sparse columns, and only see the column set. Meanwhile, people can still select individual sparse columns in their query.

So, the test done by my blog reader was having little problem. He forgot to define columnset column. Here is the sample of columnset with sparse column.

AllDetails XML COLUMN_SET FOR ALL_SPARSE_COLUMNS

Let me give you a quick example.

SET NOCOUNT ON
GO
USE tempdb
GO
CREATE TABLE MySparseTable (
i INT
,Detail XML COLUMN_SET FOR ALL_SPARSE_COLUMNS
,Height DECIMAL(10, 2) Sparse
,Width DECIMAL(10, 2) Sparse
,Length DECIMAL(10, 2) Sparse
,Color VARCHAR(10) Sparse
,Volume DECIMAL(10, 2) Sparse
)
GO
INSERT INTO MySparseTable (i,Height,Width)
VALUES (1,11.9,12.0);
INSERT INTO MySparseTable (i,Height,Length)
VALUES (2,2.8,9.3);
INSERT INTO MySparseTable (i,Color)
VALUES (3,'Red')
GO
SELECT *
FROM MySparseTable
GO
SELECT i
,Height
,Width
,Color
FROM [MySparseTable] GO
/* Clean up time
drop table MySparseTable
go
*/

Here is the output.

SQL SERVER - CREATE TABLE Failed Because Column 'C1024' in Table 'myTable' Exceeds the Maximum of 1024 Columns Sparse-01

Have you ever use this feature in your environments? What has been your experience in using and what scenarios have you been using these capabilities? Let me know via your comments.

Reference: Pinal Dave (https://blog.sqlauthority.com)

SPARSE Columns
Previous Post
Interview Question of the Week #021 – Difference Between Index Seek and Index Scan (Table Scan)
Next Post
SQL SERVER – Identify Disk Latency on SQL Server Box Using PowerShell

Related Posts

8 Comments. Leave new

Leave a Reply