SET ANSI_NULL_DFLT_ON

Transact-SQL Reference

Transact-SQL Reference

SET ANSI_NULL_DFLT_ON

Alters the session's behavior to override default nullability of new columns when the ANSI null default option for the database is false. For more information about setting the value for ANSI null default, see sp_dboption and Setting Database Options.

Syntax

SET ANSI_NULL_DFLT_ON {ON | OFF}

Remarks

This setting only affects the nullability of new columns when the nullability of the column is not specified in the CREATE TABLE and ALTER TABLE statements. When SET ANSI_NULL_DFLT_ON is ON, new columns created with the ALTER TABLE and CREATE TABLE statements allow null values if the nullability status of the column is not explicitly specified. SET ANSI_NULL_DFLT_ON has no effect on columns created with an explicit NULL or NOT NULL.

Both SET ANSI_NULL_DFLT_OFF and SET ANSI_NULL_DFLT_ON cannot be set ON simultaneously. If one option is set ON, the other option is set OFF. Therefore, either ANSI_NULL_DFLT_OFF or ANSI_NULL_DFLT_ON can be set ON, or both can be set OFF. If either option is ON, that setting (SET ANSI_NULL_DFLT_OFF or SET ANSI_NULL_DFLT_ON) takes effect. If both options are set OFF, Microsoft® SQL Server™ uses the value of the ANSI null default option of sp_dboption.

For the most reliable operation of Transact-SQL scripts used in databases with different nullability settings, it is best to specify NULL or NOT NULL in CREATE TABLE and ALTER TABLE statements.

The SQL Server ODBC driver and Microsoft OLE DB Provider for SQL Server automatically set ANSI_NULL_DFLT_ON to ON when connecting. SET ANSI_NULL_DFLT_ON defaults to OFF for connections from DB-Library applications.

When SET ANSI_DEFAULTS is ON, SET ANSI_NULL_DFLT_ON is enabled.

The setting of SET ANSI_NULL_DFLT_ON is set at execute or run time and not at parse time.

Permissions

SET ANSI_NULL_DFLT_ON permissions default to all users.

Examples

This example shows the effects of SET ANSI_NULL_DFLT_ON with both settings for the ANSI null default database option.

USE pubs
GO
-- The code from this point on demonstrates that SET ANSI_NULL_DFLT_ON
-- has an effect when the 'ANSI null default' for the database is false.
-- Set the 'ANSI null default' database option to false by executing
-- sp_dboption.
EXEC sp_dboption 'pubs','ANSI null default','false'
GO
-- Create table t1.
CREATE TABLE t1 (a tinyint) 
GO 
-- NULL INSERT should fail.
INSERT INTO t1 (a) VALUES (null)
GO
-- SET ANSI_NULL_DFLT_ON to ON and create table t2.
SET ANSI_NULL_DFLT_ON ON
GO
CREATE TABLE t2 (a tinyint)
GO 
-- NULL insert should succeed.
INSERT INTO t2 (a) VALUES (null)
GO
-- SET ANSI_NULL_DFLT_ON to OFF and create table t3.
SET ANSI_NULL_DFLT_ON OFF
GO
CREATE TABLE t3 (a tinyint) 
GO 
-- NULL insert should fail.
INSERT INTO t3 (a) VALUES (null)
GO
-- The code from this point on demonstrates that SET ANSI_NULL_DFLT_ON 
-- has no effect when the 'ANSI null default' for the database is true.
-- Set the 'ANSI null default' database option to true.
EXEC sp_dboption 'pubs','ANSI null default','true'
GO
-- Create table t4.
CREATE TABLE t4 (a tinyint) 
GO 
-- NULL INSERT should succeed.
INSERT INTO t4 (a) VALUES (null)
GO
-- SET ANSI_NULL_DFLT_ON to ON and create table t5.
SET ANSI_NULL_DFLT_ON ON
GO
CREATE TABLE t5 (a tinyint)
GO 
-- NULL INSERT should succeed.
INSERT INTO t5 (a) VALUES (null)
GO
-- SET ANSI_NULL_DFLT_ON to OFF and create table t6.
SET ANSI_NULL_DFLT_ON OFF
GO
CREATE TABLE t6 (a tinyint)
GO 
-- NULL INSERT should succeed.
INSERT INTO t6 (a) VALUES (null)
GO
-- Set the 'ANSI null default' database option to false.
EXEC sp_dboption 'pubs','ANSI null default','false'
GO
-- Drop tables t1 through t6.
DROP TABLE t1
DROP TABLE t2
DROP TABLE t3
DROP TABLE t4
DROP TABLE t5
DROP TABLE t6
GO

See Also

ALTER TABLE

CREATE TABLE

SET

SET ANSI_DEFAULTS

SET ANSI_NULL_DFLT_OFF