Login or Sign Up to become a member!
LessThanDot Site Logo

LessThanDot

A Technical Community for IT Professionals

Less Than Dot is a community of passionate IT professionals and enthusiasts dedicated to sharing technical knowledge, experience, and assistance. Inside you will find reference materials, interesting technical discussions, and expert tips and commentary. Once you register for an account you will have immediate access to the forums and all past articles and commentaries.

LTD Social Sitings

Lessthandot twitter Lessthandot Linkedin Lessthandot facebook Lessthandot rss

Note: Watch for social icons on posts by your favorite authors to follow their postings on these and other social sites.

Highly Rated Users

Forum
No Posts Rated

Top 50
Given
Received

Forum Statistics

Users
Members:
1875
Members Online:
3
Guests Online:
79

Total Post History
Posts:
81446
Topics:
18714

7-Day Post History
New Posts:
0
New Topics:
0
Active Topics:
0

Our newest member
konam534As

Other

FAQ
All times are UTC [ DST ]

Google Ads

Suggestion: Check for Not Trustred or Disabled check constra

Please wait...

Suggestion: Check for Not Trustred or Disabled check constra

Postby PhilFactor on Tue Jan 31, 2012 7:52 pm

Why not just alert the user to either foreign key or check constraints that have been disabled or are flagged as 'not trusted'? You know it makes sense, since the query analyser ignores constraints with either.
SELECT [Table Name], [Constraint], [Type], is_not_trusted, is_disabled
FROM
(SELECT sys.objects.name AS [Table Name],
sys.check_constraints.name AS [Constraint],
'check' AS [Type],
is_not_trusted,
is_disabled
FROM sys.objects
INNER JOIN sys.check_constraints
ON sys.check_constraints.parent_object_ID = sys.objects.object_ID
UNION ALL
SELECT sys.objects.name AS [Table Name],
sys.foreign_keys.name AS [Constraint],
'foreign key',
is_not_trusted,
is_disabled
FROM sys.objects
INNER JOIN sys.foreign_keys
ON sys.foreign_keys.parent_object_ID = sys.objects.object_ID) Constraints

WHERE is_not_trusted = 1
OR is_disabled = 1
ORDER BY [Table name], [constraint]
PhilFactor
Apprentice
Apprentice
LTD Bronze - Rating: 4
 
Posts: 5
Joined: Thu Jan 15, 2009 10:28 am

Re: Suggestion: Check for Not Trustred or Disabled check constra

Postby gmmastros on Tue Jan 31, 2012 8:12 pm

I like this idea. Do you have a blog or wiki article that explains the problem?
-George
User avatar
gmmastros
LTD Admin
LTD Admin
LTD Gold - Rating: 1630LTD Gold - Rating: 1630LTD Gold - Rating: 1630LTD Gold - Rating: 1630LTD Gold - Rating: 1630
LTD Gold - Rating: 1630LTD Gold - Rating: 1630LTD Gold - Rating: 1630LTD Gold - Rating: 1630LTD Gold - Rating: 1630
LTD Gold - Rating: 1630LTD Gold - Rating: 1630
 
Posts: 2367
Joined: Tue Oct 09, 2007 5:19 pm
Unrated

Re: Suggestion: Check for Not Trustred or Disabled check constra

Postby PhilFactor on Thu Feb 02, 2012 5:57 pm

It is in the pipeline to be published. The problem happens usually when you use BULK INSERT with certain options set. Once the tables are inserted, you're supposed to test that the data conforms with the relationships and checks, and then set the NOT TRUSTED flag to false by adding WITH CHECK to the constraint. If you don't, your queries start running slow because the optimizer cannot use the constraints to optimize the execution plan!
PhilFactor
Apprentice
Apprentice
LTD Bronze - Rating: 4
 
Posts: 5
Joined: Thu Jan 15, 2009 10:28 am
Unrated