Determine ANSI_PADDING status in TSQL

  • 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!

  • SELECTSESSIONPROPERTY('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/

  • Many thanks 🙂

  • 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>)

    ~ Lokesh Vij


    Guidelines for quicker answers on T-SQL question[/url]
    Guidelines for answers on Performance questions

    Link to my Blog Post --> www.SQLPathy.com[/url]

    Follow me @Twitter

  • 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[/url]
    Guidelines for answers on Performance questions

    Link to my Blog Post --> www.SQLPathy.com[/url]

    Follow me @Twitter

  • 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>)

    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>)

  • 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>)

    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>)

    Great Lynn, I missed that.

    Thanks 🙂

    ~ Lokesh Vij


    Guidelines for quicker answers on T-SQL question[/url]
    Guidelines for answers on Performance questions

    Link to my Blog Post --> www.SQLPathy.com[/url]

    Follow me @Twitter

  • 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.

    SELECTt.name as [table_name],

    c.name as [column_name],

    ty.[name] as [column_data_type],

    CASEWHEN 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)

    wheret.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

  • 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) A socialist is someone who will give you the shirt off *someone else's* back.

Viewing 9 posts - 1 through 8 (of 8 total)

You must be logged in to reply to this topic. Login to reply