SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Determine ANSI_PADDING status in TSQL


Determine ANSI_PADDING status in TSQL

Author
Message
Mr. Cursor
Mr. Cursor
SSC Rookie
SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)

Group: General Forum Members
Points: 45 Visits: 68
Hello SQL Gurus.

I have a situation where the production databases have ANSI_PADDING on. This is what I want, as for reasons best know to the users they need to store A [Space][Space] as exactly that.

Yesterday I found that the UAT databases have ANSI_PADDING off. This is producing inconsistent test data, as you can imagine.

I was hoping that A/P might be visible on INFORMATION_SCHEMA.COLUMNS, and I would be able to set it in code. But so far I haven't been able to find how to do this.

Please can someone tell me what level ANSI_PADDING is stored - Column, Table or DB... and furthermore, what is the best way to find this out in code?

Thanks!
Kingston Dhasian
Kingston Dhasian
SSCertifiable
SSCertifiable (6.1K reputation)SSCertifiable (6.1K reputation)SSCertifiable (6.1K reputation)SSCertifiable (6.1K reputation)SSCertifiable (6.1K reputation)SSCertifiable (6.1K reputation)SSCertifiable (6.1K reputation)SSCertifiable (6.1K reputation)

Group: General Forum Members
Points: 6128 Visits: 5285
SELECT   SESSIONPROPERTY('ANSI_PADDING')




Kingston Dhasian

How to post data/code on a forum to get the best help - Jeff Moden
http://www.sqlservercentral.com/articles/Best+Practices/61537/
Mr. Cursor
Mr. Cursor
SSC Rookie
SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)SSC Rookie (45 reputation)

Group: General Forum Members
Points: 45 Visits: 68
Many thanks Smile
Lokesh Vij
Lokesh Vij
Hall of Fame
Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)

Group: General Forum Members
Points: 3370 Visits: 1599
For checking ANSI_PADDING on columns:

SELECT name  column_name,
CASE is_ansi_padded
WHEN 1 THEN 'On'
ELSE 'Off'
AS [ANSI_PADDING]
FROM sys.all_columns
WHERE object_id = object_id(<table name>Wink



~ Lokesh Vij

Guidelines for quicker answers on T-SQL question
Guidelines for answers on Performance questions

Link to my Blog Post --> www.SQLPathy.com

Follow me @Twitter


Lokesh Vij
Lokesh Vij
Hall of Fame
Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)

Group: General Forum Members
Points: 3370 Visits: 1599
To further add (SQL Server 2012 BOL):

In a future version of Microsoft SQL Server ANSI_PADDING will always be ON and any applications that explicitly set the option to OFF will produce an error. Avoid using this feature in new development work, and plan to modify applications that currently use this feature.

Source: http://msdn.microsoft.com/en-us/library/ms187403.aspx

~ Lokesh Vij

Guidelines for quicker answers on T-SQL question
Guidelines for answers on Performance questions

Link to my Blog Post --> www.SQLPathy.com

Follow me @Twitter


Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)SSC Guru (97K reputation)

Group: General Forum Members
Points: 97557 Visits: 38988
Lokesh Vij (7/27/2012)
For checking ANSI_PADDING on columns:

SELECT name  column_name,
CASE is_ansi_padded
WHEN 1 THEN 'On'
ELSE 'Off'
AS [ANSI_PADDING]
FROM sys.all_columns
WHERE object_id = object_id(<table name>Wink



Or:



SELECT
name column_name,
CASE is_ansi_padded
WHEN 1 THEN 'On'
ELSE 'Off'
AS [ANSI_PADDING]
FROM
sys.columns
WHERE
object_id = object_id(<schema.tablename>Wink




Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Lokesh Vij
Lokesh Vij
Hall of Fame
Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)

Group: General Forum Members
Points: 3370 Visits: 1599
Lynn Pettis (7/27/2012)
Lokesh Vij (7/27/2012)
For checking ANSI_PADDING on columns:

SELECT name  column_name,
CASE is_ansi_padded
WHEN 1 THEN 'On'
ELSE 'Off'
AS [ANSI_PADDING]
FROM sys.all_columns
WHERE object_id = object_id(<table name>Wink



Or:



SELECT
name column_name,
CASE is_ansi_padded
WHEN 1 THEN 'On'
ELSE 'Off'
AS [ANSI_PADDING]
FROM
sys.columns
WHERE
object_id = object_id(<schema.tablename>Wink





Great Lynn, I missed that.
Thanks :-)

~ Lokesh Vij

Guidelines for quicker answers on T-SQL question
Guidelines for answers on Performance questions

Link to my Blog Post --> www.SQLPathy.com

Follow me @Twitter


Buck-293246
Buck-293246
SSC Rookie
SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)

Group: General Forum Members
Points: 26 Visits: 70
just FYI that "is_ansi_padded" column in sys.all_columns will show as 0 if the column type is not a char, binary or variant column. If you are trying to find all columns with the ansi_padding where it actually matters you may want to limit it to those columns with something like the below.


SELECT t.name as [table_name],
c.name as [column_name],
ty.[name] as [column_data_type],
CASE WHEN c.is_ansi_padded = 1
THEN 'On'
ELSE 'Off'
END as [ansi_padding]
FROM sys.all_columns c
inner join sys.tables t
on (c.object_id = t.object_id)
inner join sys.types ty
on (c.system_type_id = ty.system_type_id)
where t.name not like 'sys%'
and t.name not like 'MS_%'
and ty.name in ('char','varchar','binary','sql_variant','nvarchar','nchar')
order by t.name



ScottPletcher
ScottPletcher
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20216 Visits: 7419
Fwiw, I prefer the a different way to check the current ansi / connection settings, using:
@@OPTIONS
I actually use a table of config values so the code is more readable, but here's the direct value comparison method:



IF @@OPTIONS & 16 > 0
PRINT 'ANSI_PADDING is ON'
ELSE
PRINT 'ANSI_PADDING is OFF'
IF @@OPTIONS & 16384 > 0
PRINT 'XACT_ABORT is ON'
ELSE
PRINT 'XACT_ABORT is OFF'




SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search