Home > Differences, SQL DB Engine > SET ANSI_NULLS, QUOTED_IDENTIFIER, ANSI_PADDING – SQL Server

SET ANSI_NULLS, QUOTED_IDENTIFIER, ANSI_PADDING – SQL Server

December 10, 2010 Leave a comment Go to comments

You have to create a Stored-Procedure and you need a template. You expand the Object Explorer go to Database -> Programmability -> “Stored Procedure” -> (right click) -> select “New Stored Procedure”.
A new editor opens up with lot of commented & flawless code. There you see some predefined statements.

Sometimes while working with Stored Procedures and other SQL Scripts a those few statements makes you confusing and clueless. Most of the time people remove them or just ignore them, but one should know why are they placed there. The 2 mains SET statements that are placed by default are described below with examples:

–// SET ANSI_NULLS (http://msdn.microsoft.com/en-us/library/ms188048.aspx)
Specifies ISO compliant behavior of the Equals (=) and Not Equal To (<>) comparison operators when they are used with null values.

Syntax: SET ANSI_NULLS { ON | OFF }

create table #tempTable (sn int, ename varchar(50))

insert into #tempTable
select 1, 'Manoj'
UNION ALL
select 2, 'Pankaj'
UNION ALL
select 3, NULL
UNION ALL
select 4, 'Lokesh'
UNION ALL
select 5, 'Gopal'

SET ANSI_NULLS ON
select * from #tempTable where ename is NULL -- (1 row(s) affected)
sn	ename
3	NULL
select * from #tempTable where ename = NULL -- (0 row(s) affected)
select * from #tempTable where ename <> NULL -- (0 row(s) affected)

SET ANSI_NULLS OFF
select * from #tempTable where ename is NULL -- (1 row(s) affected)
select * from #tempTable where ename = NULL -- (1 row(s) affected)
sn	ename
3	NULL
select * from #tempTable where ename is not NULL -- (4 row(s) affected)
select * from #tempTable where ename <> NULL -- (4 row(s) affected)
sn	ename
1	Manoj
2	Pankaj
4	Lokesh
5	Gopal
drop table #tempTable

–// SET QUOTED_IDENTIFIER (http://msdn.microsoft.com/en-us/library/ms174393.aspx)
Causes SQL Server to follow the ISO rules regarding quotation mark delimiting identifiers and literal strings. Identifiers delimited by double quotation marks can be either Transact-SQL reserved keywords or can contain characters not generally allowed by the Transact-SQL syntax rules for identifiers.
When SET QUOTED_IDENTIFIER is ON, identifiers can be delimited by double quotation marks, and literals must be delimited by single quotation marks.
When SET QUOTED_IDENTIFIER is OFF, identifiers cannot be quoted and must follow all Transact-SQL rules for identifiers.

Syntax: SET QUOTED_IDENTIFIER { ON | OFF }

-- Example 1
SET QUOTED_IDENTIFIER ON
create table "#tempTable" (sn int, ename varchar(50)) -- Command(s) completed successfully.

SET QUOTED_IDENTIFIER OFF
create table "#tempTable" (sn int, ename varchar(50)) -- Incorrect syntax near '#tempTable'.

drop table #tempTable

-- Example 2
SET QUOTED_IDENTIFIER ON
select "'My Name is Manoj'" as Col1, "Let's play" as Col2 -- Invalid column name ''My Name is Manoj''. Invalid column name 'Let's play'.

SET QUOTED_IDENTIFIER OFF
select "'My Name is Manoj'" as Col1, "Let's play" as Col2 -- (1 row(s) affected)
Col1			Col2
'My Name is Manoj'	Let's play
-- Example 3
SET QUOTED_IDENTIFIER ON
select '''My Name is Manoj''' as Col1, 'Let''s play' as Col2 -- (1 row(s) affected)
Col1			Col2
'My Name is Manoj'	Let's play
SET QUOTED_IDENTIFIER OFF
select '''My Name is Manoj''' as Col1, 'Let''s play' as Col2 -- (1 row(s) affected)
Col1			Col2
'My Name is Manoj'	Let's play

–// SET ANSI_PADDING (http://msdn.microsoft.com/en-us/library/ms187403.aspx)
Controls the way the column stores values shorter than the defined size of the column, and the way the column stores values that have trailing blanks in char, varchar, binary, and varbinary data.

Syntax: SET ANSI_PADDING { ON | OFF }

-- Example 1
SET ANSI_PADDING ON
create table #tempTable1 (charcol char(20), varcharcol varchar(20))

insert into #tempTable1
select 'Manoj', 'Manoj'
UNION ALL
select 'Pandey', 'Pandey'

select '['+charcol+']' as charcol, '['+varcharcol+']' as varcharcol from #tempTable1
charcol			varcharcol
[Manoj               ]	[Manoj]
[Pandey              ]	[Pandey]
-- Example 2
SET ANSI_PADDING OFF
create table #tempTable2 (charcol char(20), varcharcol varchar(20))

insert into #tempTable2
select 'Manoj', 'Manoj'
UNION ALL
select 'Pandey', 'Pandey'
select '['+charcol+']' as charcol, '['+varcharcol+']' as varcharcol from #tempTable2
charcol		varcharcol
[Manoj]		[Manoj]
[Pandey]	[Pandey]
drop table #tempTable1
drop table #tempTable2

Other SET statements MSDN BOL: http://msdn.microsoft.com/en-us/library/ms190356.aspx

Advertisement

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out /  Change )

Facebook photo

You are commenting using your Facebook account. Log Out /  Change )

Connecting to %s

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

%d bloggers like this: