Database Research & Development

  • Home
  • NoSQL
    • NoSQL
    • Cassandra
  • Databases
    • Database Theory
    • Database Designing
    • SQL Server Coding Standards
    • SQL Server
    • PostgreSQL
    • MySQL
    • Greenplum
    • Linux
  • Interviews
    • SQL Server Interviews
    • MySQL Interviews
    • SQL Puzzles
  • DBA Scripts
    • SQL Server DBA Scripts
    • PostgreSQL DBA Scripts
    • MySQL DBA Scripts
    • Greenplum DBA Scripts
  • Home
  • Blog Archives !
  • (: Laugh@dbrnd :)
  • Contact Me !
sqlserverinterviews
Home 2017 January SQL Server: Avoid the use of Indexes on VARCHAR columns

SQL Server: Avoid the use of Indexes on VARCHAR columns

This article is half-done without your Comment! *** Please share your thoughts via Comment ***

I am also adding a Database Design category for this post, because what I am feeling that you guys must know about this before designing tables or indexes.

You can create Indexes on VARCHAR columns, but you should not create indexes on big size of VARCHAR Columns.

Indexes also require storing data as key for accessing associated records. There is a size limitation of index key values.

Before SQL Server 2016, Index key size limitation was 900 bytes for Clustered and Non-Clustered index column.
SQL Server 2016 increased this limitation for Non-Clustered Index and now it is up to 1700 bytes, but for Clustered Index column it is still 900 bytes.

Let me demonstrate this.

Create a sample table with Nonclustered Index:

1
2
3
4
5
6
7
8
9
CREATE TABLE tbl_TestVarcharNonClustered
(
ID INT
,Name VARCHAR(2000)
)
GO
 
CREATE NONCLUSTERED INDEX idx_tbl_TestVarcharNonClustered_Name ON tbl_TestVarcharNonClustered(Name)
GO

You will get a below warning:
Because we have set Name VARCHAR(2000).

1
Warning! The maximum key length for a nonclustered index is 1700 bytes. The index 'idx_tbl_TestVarcharNonClustered_Name' has maximum length of 2000 bytes. For some combination of large values, the insert/update operation will fail.

Try to insert 1701 bytes data:

1
2
3
INSERT INTO tbl_TestVarcharNonClustered
VALUES (1,REPLICATE('a',1701))
GO

You will get a below error:

1
2
Msg 1946, Level 16, State 3, Line 1
Operation failed. The index entry of length 1701 bytes for the index 'idx_tbl_TestVarcharNonClustered_Name' exceeds the maximum length of 1700 bytes for nonclustered indexes.

You can successfully run below INSERT, because it inserts only 1700 bytes:

1
2
3
INSERT INTO tbl_TestVarcharNonClustered
VALUES (1,REPLICATE('a',1700))
GO

Now, create a sample table with Clustered Index:

1
2
3
4
5
6
7
8
9
CREATE TABLE tbl_TestVarcharClustered
(
ID INT
,Name VARCHAR(2000)
)
GO
 
CREATE CLUSTERED INDEX idx_tbl_TestVarcharClustered_Name ON tbl_TestVarcharClustered(Name)
GO

You will get a below warning:
Because we have set Name VARCHAR(2000) on cluster index column.

1
Warning! The maximum key length for a clustered index is 900 bytes. The index 'idx_tbl_TestVarcharClustered_Name' has maximum length of 2000 bytes. For some combination of large values, the insert/update operation will fail.

Try to insert a over size data like more than 900 bytes:

1
2
3
INSERT INTO tbl_TestVarcharClustered
VALUES (1,REPLICATE('a',1001))
GO

You will get a below error:

1
2
Msg 1946, Level 16, State 3, Line 1
Operation failed. The index entry of length 1001 bytes for the index 'idx_tbl_TestVarcharClustered_Name' exceeds the maximum length of 900 bytes for clustered indexes.

You can successfully run below INSERT, because it inserts only 900 bytes:

1
2
3
INSERT INTO tbl_TestVarcharClustered
VALUES (1,REPLICATE('a',900))
GO

Jan 12, 2017Anvesh Patel
SQL Server Interview: Where does DMVs store its data?SQL Server: DBCC INPUTBUFFER to find the last statement executed by a SPID
Anvesh Patel
Anvesh Patel

Database Engineer

January 12, 2017 Database Designing, SQL ServerAnvesh Patel, clustered index, database, Database Design, database research and development, dbrnd, index, Index key size, non clustered index, SQL Query, SQL Server, SQL Server Administrator, SQL Server Monitoring, SQL Server Performance Tunning, SQL Server Tips and Tricks, TSQL
About Me!

I'm Anvesh Patel, a Database Engineer certified by Oracle and IBM. I'm working as a Database Architect, Database Optimizer, Database Administrator, Database Developer. Providing the best articles and solutions for different problems in the best manner through my blogs is my passion. I have more than six years of experience with various RDBMS products like MSSQL Server, PostgreSQL, MySQL, Greenplum and currently learning and doing research on BIGData and NoSQL technology. -- Hyderabad, India.

About DBRND !

dbrnd

This is a personal blog (www.dbrnd.com).

Any views or opinions represented in this blog are personal and belong solely to the blog owner and do not represent those of people, institutions or organizations that the owner may or may not be associated with in professional or personal capacity, unless explicitly stated.

Feel free to challenge me, disagree with me, or tell me I’m completely nuts in the comments section of each blog entry, but I reserve the right to delete any comment for any reason whatsoever (abusive, profane, rude, or anonymous comments) - so keep it polite.

The content of this website is protected by copyright. No portion of this website may be copied or replicated in any form without the written consent of the website owner.

Recent Comments !
  • Anvesh Patel { Sure will do... } – May 27, 12:43 PM
  • Anvesh Patel { Great... } – May 27, 12:41 PM
  • Anvesh Patel { Great... } – May 27, 12:39 PM
  • Anvesh Patel { Great... } – May 27, 12:36 PM
  • Anvesh Patel { Great... } – May 27, 12:28 PM
  • Anvesh Patel { Great... } – May 27, 12:27 PM
  • Anvesh Patel { Great... } – May 27, 12:16 PM
  • Older »
Follow Me !
  • facebook
  • linkedin
  • twitter
  • youtube
  • google
  • flickr
© 2015 – 2019 All rights reserved. Database Research & Development (dbrnd.com)
Posting....