Learn more about SQL Server tools

mssqltips logo
 

Tutorials          DBA          Dev          BI          Career          Categories          Webcasts          Whitepapers          Today's Tip          Join

Tutorials      DBA      Dev      BI      Categories      Webcasts

DBA    Dev    BI    Categories

 
The Trade-off Between SQL Server Security and Performance - Free Webinar
 

Comparison of the VARCHAR(max) and VARCHAR(n) SQL Server Data Types


By:   |   Last Updated: 2016-10-06   |   Comments (5)   |   Related Tips: 1 | 2 | 3 | More > Data Types

Problem

You are developing a SQL Server application and at some point in your code you receive the error "String or binary data would be truncated". After digging into the code you discovered that this error message is caused because a table has a VARCHAR(1000) column and you need to insert more than 1000 characters. Someone on your team suggest using the VARCHAR(max) data type, but you are unsure about the implications of the this data type.  Read this tip to learn what you should know about the SQL Server VARCHAR(Max) vs. VARCHAR(n) data types.

Solution

In order to decide between using VARCHAR(Max) or VARCHAR(n) we have to understand that even when both data types look the same, they have some major differences pertaining to storage, behavior and of course their intended usage.

The VARCHAR(Max) SQL Server Data Type

The VARCHAR(Max) as well as NVARCHAR(max) and VARBINARY(max) data types were first introduced in SQL Server 2005 to replace the large object (LOB) data types TEXT, NTEXT and IMAGE respectively. All of these data types can store up to 2GB of data except NVARCHAR(max) that can store 1GB of Unicode text. As you may guess, the maximum storage for these data types is the same as the ones being replaced. I suggest reading the SQL Server differences of char, nchar, varchar and nvarchar data types tip in case you need a further explanation on the differences between VARCHAR and NVARCHAR data types.

A common question amongst beginners is: if the VARCHAR(max) data type can store up to 2GB why can't we declare a column or variable of type VARCHAR(10000)? Why are we limited to either declare a VARCHAR(8000) or VARCHAR(max)? The reason behind this is that VARCHAR(n) is intended to store the data in the row page. SQL Server stores data in 8KB pages (8,192 bytes), but the page header occupies the first 96 bytes of each data page leaving 8,096 bytes for data, row overhead, and row offsets, that’s why you cannot declare a value greater than VARCHAR(8000).

Advantages

One of the advantages of the VARCHAR(max) data type as a replacement of TEXT data type is that we can declare local variables to manipulate LOBs and even declare VARCHAR(max) parameters on functions and stored procedures. This is something that cannot be done with the TEXT data type. Furthermore the VARCHAR(max) data type can be used inside string functions such as REPLACE, CHARINDEX or LEFT instead of using READTEXT, WRITETEXT, and UPDATETEXT commands to manipulate LOBs.

The following list includes the functions that support the VARCHAR(max) data type:

Updating Data on VARCHAR(max) Columns

Something that not many people know is that the UPDATE statement allows us to append and replace data in VARCHAR(max), NVARCHAR(max) and VARBINARY(max) columns without using string functions. There is an implicit WRITE function in the UPDATE statement for columns of VARCHAR(max), NVARCHAR(max) and VARBINARY(max) data type with the following syntax.

UPDATE MyTable SET
Lob_column_name.WRITE (expression,Offset,Length)

Parameter

Type

Description

expression

VARCHAR(max)
NVARCHAR(max)
VARBINARY(max)

The value that is copied to Lob_column_name. If expression is set to NULL, Length is ignored, and the value in Lob_column_name is truncated at the specified Offset.

Offset

Bigint

The starting position in the value of Lob_column_name at which expression is written. If Offset is NULL, the update operation appends expression at the end of Lob_column_name ignoring the value of Length parameter.

Length

Bigint

The length of the section in the column, starting from Offset, which is replaced by expression. If Length is NULL, the update operation removes all data from Offset to the end of the Lob_column_name value.

Limitations

There is an obvious limitation on VARCHAR(max) columns which is that these columns cannot be indexed.  If you think you need to place an index on a VARCHAR(max) column I suggest that you may need to review the table design.

Sample Usage

Let’s create a new database to do some testing.

USE [Employees];
GO

CREATE TABLE Sellers
    (
      SellerID INT IDENTITY(1, 1)
                   PRIMARY KEY ,
      Name VARCHAR(255) ,
      Percentage NUMERIC(3, 2) ,
      Commissions  MONEY
    )

GO

INSERT INTO dbo.Sellers
SELECT 'John Doe', 0.25, 0
UNION ALL
SELECT 'Linda Smith', 0.1, 0
GO

On the Sales database create a table named Transactions to store sales information.

USE [master]
GO

CREATE DATABASE [TestDB]
 CONTAINMENT = NONE
 ON  PRIMARY 
( NAME = N'TestDB', FILENAME = N'E:\MSSQL\TestDB.mdf' ,
 SIZE = 10MB , MAXSIZE = UNLIMITED, FILEGROWTH = 1024KB )
 LOG ON 
( NAME = N'TestDB_log', FILENAME = N'E:\MSSQL\TestDB_log.ldf',
 SIZE = 10240KB , MAXSIZE = 2048GB , FILEGROWTH = 10%)
GO

The following script will create a test table with one VARCHAR(Max) column and an identity column, and then insert one row with 1,000,000 characters.

USE [TestDB]
GO

CREATE TABLE TestTable
    (
      ID INT IDENTITY(1, 1) ,
      TestData VARCHAR(MAX) ,
      PRIMARY KEY CLUSTERED ( ID )
    )
GO

DECLARE @str VARCHAR(MAX) = 'a'

INSERT  INTO dbo.TestTable
        ( TestData )
        SELECT  REPLICATE(@str, 1000000)
GO

Now we will append the text "0123" at the end of the string.

USE [TestDB]
GO

UPDATE  dbo.TestTable
SET     TestData.WRITE('0123', NULL, NULL)
WHERE   ID = 1;

SELECT  RIGHT(testdata, 10) ,
        LEN(TestData)
FROM    dbo.TestTable;

GO

As you can see on the next image the data was appended and the string length was increased.

Screen capture of appended data.
Next Steps


Last Updated: 2016-10-06


next webcast button


next tip button



About the author





Post a comment or let the author know this tip helped.

All comments are reviewed, so stay on subject or we may delete your comment. Note: your email address is not published. Required fields are marked with an asterisk (*).

*Name    *Email    Email me updates 


Signup for our newsletter
 I agree by submitting my data to receive communications, account updates and/or special offers about SQL Server from MSSQLTips and/or its Sponsors. I have read the privacy statement and understand I may unsubscribe at any time.



    



Wednesday, November 02, 2016 - 6:51:55 PM - JeremyH Back To Top

"except NVARCHAR(max) that can store 1GB of Unicode text" is incorrect. It can also store 2 GB of data, it would just be one half of the number of characters since each character uses 2 bytes of space instead of the 1 byte that VARCHAR(max) characters use.

 


Monday, October 10, 2016 - 9:37:25 PM - Daniel Farina Back To Top

Hi Don!

In the following link you will find what you are looking for. http://rusanu.com/2010/03/22/performance-comparison-of-varcharmax-vs-varcharn/

Thank you for reading!


Monday, October 10, 2016 - 9:36:26 PM - Daniel Farina Back To Top

Hi György!

Yes you are right! VARCHAR(max) allows the usage of full text indexes just like the TEXT data type does.

Thank you for reading!


Monday, October 10, 2016 - 5:34:09 PM - Don Schaeffer Back To Top

 

I would like to see an anlysis of performance considerations, comparing say, varchar(8000) with varchar(max).


Thursday, October 06, 2016 - 2:25:31 AM - György Görög Back To Top

Daniel, thanks for this clarifying paper. Just not to scare potential users, please mention that varchar(max) can be indexed with a full-text index. 

 

 


Learn more about SQL Server tools