Adding a column to a table with a default (NULL vs NOT NULL)

4

October 30, 2013 by Kenneth Fisher

There are lots of ways to learn new things, or be reminded of old things. One of my favorites is the QotD on sql server central. Recently there was an interesting question on defaults. It pointed out that there is a difference between adding a column with a default that allows NULLs and one that does not.

-- Setup
CREATE TABLE DefaultTest (Id INT NOT NULL IDENTITY(1,1))
GO

INSERT INTO DefaultTest DEFAULT VALUES
INSERT INTO DefaultTest DEFAULT VALUES
INSERT INTO DefaultTest DEFAULT VALUES
GO
-- Test adding one NULL column and one NOT NULL column
ALTER TABLE DefaultTest ADD 
	Nullable char(1) NULL 
		CONSTRAINT df_DefaultTest_Nullable DEFAULT 'x',
	NotNull char(1) NOT NULL
		CONSTRAINT df_DefaultTest_NotNull DEFAULT 'x'
GO

With the results:
Adding a column with a default

Note that the nullable column is all NULLs and the other was filled in with x’s. This makes sense when you think about it. If you add a column with a default that allows NULLs it can just have NULL in any existing rows. However when you add a column that doesn’t allow NULLs then you have to have a value to put in it. In fact that brings up the point that you can’t add a NOT NULL column without a default if there are any rows in the table.

This

-- Trying to add a NOT NULL column without a default
ALTER TABLE DefaultTest ADD 
	NotNull2 char(1) NOT NULL 
GO

Returns an error of

Msg 4901, Level 16, State 1, Line 1
ALTER TABLE only allows columns to be added that can contain 
nulls, or have a DEFAULT definition specified, or the column 
being added is an identity or timestamp column, or alternatively 
if none of the previous conditions are satisfied the table must 
be empty to allow addition of this column. Column 'NotNull2' 
cannot be added to non-empty table 'DefaultTest' because it does 
not satisfy these conditions.

This is one of those simple things that can bite you in the ____ occasionally. It certainly catches me every now and again.

Edit

I noticed an interesting set of keywords on the ALTER TABLE command while looking at an answer on dba.stackexchange.

ALTER TABLE DefaultTest ADD 
	Nullable char(1) NULL 
		CONSTRAINT df_DefaultTest_Nullable DEFAULT 'x'
		WITH VALUES; 

The WITH VALUES keywords cause the column to be filled in with the default values even though the column is NULLable. FYI there is no error if you include WITH VALUES and the column is NOT NULL but it doesn’t change the behavior either.

Got to love learning new stuff!

4 thoughts on “Adding a column to a table with a default (NULL vs NOT NULL)

  1. Brian says:

    If I have to do this, there is usually some population-step to fill in values for the new non-null field in the existing records. My steps are:

    1. Alter the table to add the column as NULLable
    2. SQL to update the new column in existing records
    3. Alter the table again to add the NOT NULL constraint.

    • Absolutely. Another possible option is to create the column as NOT NULL but with a default. Then when you are done you can drop the default. This method is somewhat limited though. Your method is better for large batches because you can control the transaction size. You do have to be careful however because it is possible that someone could insert a new row between steps 2 and 3.

  2. […] Add the column NOT NULL with a default […]

  3. Ben says:

    Thanks! This answered my question. I was looking at Stack overflow also, but didn’t find the answer I was looking for. This post answered my question quickly and easily

    –Add new column with a default value
    alter table SalesLt.SalesOrderDetail
    ADD test varchar(20) not null default ‘x’

Leave a comment

This site uses Akismet to reduce spam. Learn how your comment data is processed.

Enter your email address to follow this blog and receive notifications of new posts by email.

Join 6,758 other subscribers

Follow me on Twitter

Archives

ToadWorld Pro of the Month November 2013