Finding Table Constraints With Column Level Detail

  • Hi All,

    Could anyone please advise how to go about finding table constraints down to the column level, to show which columns are involved? I'm in the process of working on a script to drop/recreate a table, but need to make sure that all constraints are restored, and to do so on the correct columns. I've already found these statements:

    Select *

    From INFORMATION_SCHEMA.TABLE_CONSTRAINTS

    Where TABLE_NAME = 'TableName'

    AND TABLE_SCHEMA = 'SchemaName'


    and


    select s1.name as from_schema,
    o1.Name as from_table , 
    s2.name as to_schema,
    o2.Name as to_table
    from sys.foreign_keys fk
    inner join sys.objects o1 on fk.parent_object_id = o1.object_id
    inner join sys.schemas s1 on o1.schema_id = s1.schema_id
    inner join sys.objects o2 on fk.referenced_object_id = o2.object_id
    inner join sys.schemas s2 on o2.schema_id = s2.schema_id
    WHERE o1.name = 'TableName'
    OR o2.name = 'TableName'

    but it doesn't looke like they include column level detail.
    Thanks in advance for your advice!

  • Hopefully you'll get some informative answers as this is a good question!

    When I've done this sort of thing, I used ssms script objects functionality, and in details I check box the stuff I want to generate create scripts for and just really really hoped I didn't miss anything. Doing it yourself could be an interesting project and it would be interesting if this thread generates a complete set of queries. My google foo isn't very good, I'm just glomming onto hopefully a good thread!

    These are pretty good:

    sp_help <tablename>

    sp_helpconstraint <tablename>

    here's a possibility for some check constraints:


    select chk.definition, *
    from sys.check_constraints chk
    inner join sys.columns col
     on chk.parent_object_id = col.object_id
    inner join sys.tables st
     on chk.parent_object_id = st.object_id

    I got that and other info from:

    https://stackoverflow.com/questions/14229277/sql-server-2008-get-table-constraints

    Sorry for the junky post, I can delete it when the inevitable superior posts start piling in.

    (edited for formatting)

  • Not a superior post but wanted to mention that I think you need more than just columns if you want to recreate the constraints. What about the definitions for check constraints and default constraints?

    Sue

  • patrickmcginnis59 10839 - Thursday, December 28, 2017 2:13 PM

    sp_helpconstraint <tablename>

    That is the most complete one out of the lists as it includes definitions but doesn't have the columns.
    For the foreign key columns, sys.foreign_key_columns
    For primary key and unique constraint columns, sys.indexes and sys.indexes_columns I think is what I used before. I'm just too lazy to find what I used before right now so I'll wait for that superior post as well. 🙂
    All I can find now is what I use to lists all the constraints by table - no columns or definitions:

    SELECT
        o.[name] as ConstraintName,
        OBJECT_NAME(parent_object_id) AS TableName,
        schema_name(o.[schema_id]) as SchemaName,
        o.type_desc as ConstraintType
    FROM sys.objects AS o
    WHERE o.[type] IN ('D','C','F','PK','UQ')
        and OBJECT_NAME(parent_object_id) like 'Your Table Name'
    ORDER BY o.[type];

    Sue

  • This will give you a list of the system views that have information on check, default, and other constraints > 


    select * from sys.all_views
    where [name] like '%constraint%'

    From here I would focus on the constraint name and check against it against source control. 

    If you dont have or cannot access source countrol.. you have to get a little creative.
    As a catalyst, I like to refer to my trusty adventureWorks database.

    Something akin to > 

    select
        distinct OBJECT_NAME(parent_object_id) as tableWithConstraint
    from sys.default_constraints
    union 
    /* get from check constraints, etc... */

    and put those names in a temp table. 
    You can then employ a cursor to to run the sp_helpconstraint command on each of those tables. 

    Try one case on your own

    sp_helpconstraint  'sales.salesTerritory'

    As I said, this is to get you started with a creative approach to the solution. You can always output the results to a text file. Play around with it and the solution unfolds.

    ----------------------------------------------------

  • Here's how I get Foreign Key info:

    SELECT
      FK.name,
      SCHEMA_NAME(FK.schema_id) AS schemaName,
      OBJECT_NAME(FK.parent_object_id) AS parentTableName,
      parentCols.name AS parentColumnName,
      OBJECT_NAME(FK.referenced_object_id) AS referencedTableName,
      referencedCols.name AS referencedColumnName
    FROM
      sys.foreign_keys AS FK
      JOIN sys.foreign_key_columns AS FKCols
       ON FK.parent_object_id = FKCols.parent_object_id AND
        FK.object_id = FKCols.constraint_object_id AND
        FK.referenced_object_id = FKCols.referenced_object_id
      JOIN sys.columns AS parentCols
       ON FKCols.parent_object_id = parentCols.object_id AND
        FKCols.parent_column_id = parentCols.column_id
      JOIN sys.columns AS referencedCols
       ON FKCols.referenced_object_id = referencedCols.object_id AND
        FKCols.referenced_column_id = referencedCols.column_id;

    Here's how I'd get other constraints:


    SELECT
      DC.name AS ConstraintName,
      DC.type_desc AS ConstraintType,
      DC.definition AS ConstraintDefinition,
      OBJECT_SCHEMA_NAME(DC.schema_id) AS SchemaName,
      OBJECT_NAME(DC.parent_object_id) AS TableName,
      C.name AS ColumnName
    FROM
      sys.default_constraints AS DC
      JOIN sys.columns AS C
       ON DC.parent_object_id = C.object_id AND
        DC.parent_column_id = C.column_id
    UNION ALL
    SELECT
      CC.name,
      CC.type_desc,
      CC.definition,
      CC.schema_id,
      OBJECT_SCHEMA_NAME(CC.schema_id) AS SchemaName,
      OBJECT_NAME(CC.parent_object_id),
      C.name AS ColumnName
    FROM
      sys.check_constraints AS CC
      JOIN sys.columns AS C
       ON CC.parent_object_id = C.object_id AND
        CC.parent_column_id = C.column_id
    UNION ALL
    SELECT
      KC.name,
      KC.type_desc,
      NULL AS Defintion,
      OBJECT_SCHEMA_NAME(KC.schema_id) AS SchemaName,
      OBJECT_NAME(KC.parent_object_id),
      C.name
    FROM
      sys.key_constraints AS KC
      JOIN sys.indexes AS I
       ON KC.unique_index_id = I.index_id AND
        KC.parent_object_id = I.object_id
      JOIN sys.index_columns AS IC
       ON I.index_id = IC.index_id AND
        I.object_id = IC.object_id
      JOIN sys.columns AS C
       ON IC.column_id = C.column_id AND
        IC.object_id = C.object_id

  • I uploaded some pictures to help illustrate what was mentioned in a prior post. You can right click the database, select the tables you want to script out and what level of details through the advanced scripting options. You can save the results to a file or to a new editor window.

    ----------------------------------------------------

  • Jack Corbett - Thursday, December 28, 2017 4:03 PM

    Here's how I get Foreign Key info:

    SELECT
      FK.name,
      SCHEMA_NAME(FK.schema_id) AS schemaName,
      OBJECT_NAME(FK.parent_object_id) AS parentTableName,
      parentCols.name AS parentColumnName,
      OBJECT_NAME(FK.referenced_object_id) AS referencedTableName,
      referencedCols.name AS referencedColumnName
    FROM
      sys.foreign_keys AS FK
      JOIN sys.foreign_key_columns AS FKCols
       ON FK.parent_object_id = FKCols.parent_object_id AND
        FK.object_id = FKCols.constraint_object_id AND
        FK.referenced_object_id = FKCols.referenced_object_id
      JOIN sys.columns AS parentCols
       ON FKCols.parent_object_id = parentCols.object_id AND
        FKCols.parent_column_id = parentCols.column_id
      JOIN sys.columns AS referencedCols
       ON FKCols.referenced_object_id = referencedCols.object_id AND
        FKCols.referenced_column_id = referencedCols.column_id;

    Here's how I'd get other constraints:


    SELECT
      DC.name AS ConstraintName,
      DC.type_desc AS ConstraintType,
      DC.definition AS ConstraintDefinition,
      OBJECT_SCHEMA_NAME(DC.schema_id) AS SchemaName,
      OBJECT_NAME(DC.parent_object_id) AS TableName,
      C.name AS ColumnName
    FROM
      sys.default_constraints AS DC
      JOIN sys.columns AS C
       ON DC.parent_object_id = C.object_id AND
        DC.parent_column_id = C.column_id
    UNION ALL
    SELECT
      CC.name,
      CC.type_desc,
      CC.definition,
      CC.schema_id,
      OBJECT_SCHEMA_NAME(CC.schema_id) AS SchemaName,
      OBJECT_NAME(CC.parent_object_id),
      C.name AS ColumnName
    FROM
      sys.check_constraints AS CC
      JOIN sys.columns AS C
       ON CC.parent_object_id = C.object_id AND
        CC.parent_column_id = C.column_id
    UNION ALL
    SELECT
      KC.name,
      KC.type_desc,
      NULL AS Defintion,
      OBJECT_SCHEMA_NAME(KC.schema_id) AS SchemaName,
      OBJECT_NAME(KC.parent_object_id),
      C.name
    FROM
      sys.key_constraints AS KC
      JOIN sys.indexes AS I
       ON KC.unique_index_id = I.index_id AND
        KC.parent_object_id = I.object_id
      JOIN sys.index_columns AS IC
       ON I.index_id = IC.index_id AND
        I.object_id = IC.object_id
      JOIN sys.columns AS C
       ON IC.column_id = C.column_id AND
        IC.object_id = C.object_id

    By the way, thanks Jack...this was brilliant...your 1st query returned exactly what I was looking for. 🙂

  • Great glad I could help and thanks for letting me know that it helped you out.

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

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