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


Finding Table Constraints With Column Level Detail


Finding Table Constraints With Column Level Detail

Author
Message
daniness
daniness
Mr or Mrs. 500
Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)

Group: General Forum Members
Points: 556 Visits: 264
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!

patrickmcginnis59 10839
patrickmcginnis59 10839
SSCrazy Eights
SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)SSCrazy Eights (9.7K reputation)

Group: General Forum Members
Points: 9656 Visits: 6693
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)

to properly post on a forum:
http://www.sqlservercentral.com/articles/61537/
Sue_H
Sue_H
SSC-Dedicated
SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)

Group: General Forum Members
Points: 33235 Visits: 9497


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



Sue_H
Sue_H
SSC-Dedicated
SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)

Group: General Forum Members
Points: 33235 Visits: 9497
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. Smile
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




MMartin1
MMartin1
SSCoach
SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)

Group: General Forum Members
Points: 15922 Visits: 2079
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.

----------------------------------------------------
How to post forum questions to get the best help
Jack Corbett
  Jack Corbett
SSC Guru
SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)SSC Guru (103K reputation)

Group: General Forum Members
Points: 103118 Visits: 15045
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




Jack Corbett
Consultant Straight Path Solutions
Dont let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work
Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a QuestionHow to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
MMartin1
MMartin1
SSCoach
SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)

Group: General Forum Members
Points: 15922 Visits: 2079
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.

----------------------------------------------------
How to post forum questions to get the best help
Attachments
SSMS script function.gif (4 views, 183.00 KB)
SSMS script function_tables.gif (4 views, 107.00 KB)
SSMS script function_adv.gif (4 views, 140.00 KB)
SSMS script function_options.gif (4 views, 79.00 KB)
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