
Inline adoc files when they are included exactly once. Also fix language tags because this inlining gives us better information on what language the code is written in.
90 lines
2.7 KiB
Plaintext
90 lines
2.7 KiB
Plaintext
== Why is this an issue?
|
|
|
|
When you add a new constraint to a table, (``++ALTER TABLE ... ADD CONSTRAINT ...++``), ``++WITH CHECK++`` is assumed by default, and existing data are automatically validated.
|
|
|
|
|
|
But when you disable/enable an existing constraint, ``++WITH NOCHECK++`` is assumed by default, and existing data are no longer trusted. In this case you will face an integrity issue that prevents some rows from being updated, and a performance issue because the query optimizer cannot trust this constraint anymore.
|
|
|
|
|
|
Of course, ``++WITH CHECK++`` is obviously preferred, but if ``++NOCHECK++`` behavior is desired, it should not be selected by omission, but specified explicitly because ``++WITH NOCHECK++`` has such a significant impact. By making ``++NOCHECK++`` explicit, the developer documents that this behavior has been selected on purpose.
|
|
|
|
|
|
Note: You can list the existing constraints that are in an untrusted state using:
|
|
|
|
``++SELECT * FROM sys.foreign_keys WHERE is_not_trusted = 1;++``
|
|
|
|
``++SELECT * FROM sys.check_constraints WHERE is_not_trusted = 1;++``
|
|
|
|
|
|
=== Noncompliant code example
|
|
|
|
[source,sql]
|
|
----
|
|
-- Create a trusted constraint
|
|
ALTER TABLE users ADD CONSTRAINT max_age CHECK (age < 200) ;
|
|
|
|
-- Disable the constraint
|
|
ALTER TABLE users NOCHECK CONSTRAINT max_age;
|
|
|
|
-- Enable the constraint
|
|
ALTER TABLE users CHECK CONSTRAINT max_age; -- Noncompliant, 'WITH NOCHECK' is the default mode, but is it really intentional?
|
|
----
|
|
|
|
|
|
=== Compliant solution
|
|
|
|
[source,sql]
|
|
----
|
|
-- Create a trusted constraint
|
|
ALTER TABLE users ADD CONSTRAINT max_age CHECK (age < 200) ;
|
|
|
|
-- Disable the constraint
|
|
ALTER TABLE users NOCHECK CONSTRAINT max_age;
|
|
|
|
-- Enable the constraint
|
|
ALTER TABLE users WITH CHECK CHECK CONSTRAINT max_age;
|
|
-- OR
|
|
ALTER TABLE users WITH NOCHECK CHECK CONSTRAINT max_age;
|
|
----
|
|
|
|
|
|
|
|
ifdef::env-github,rspecator-view[]
|
|
|
|
'''
|
|
== Implementation Specification
|
|
(visible only on this page)
|
|
|
|
=== Message
|
|
|
|
Specify explicitly "WITH CHECK" or "WITH NOCHECK".
|
|
|
|
|
|
=== Highlighting
|
|
|
|
CHECK CONSTRAINT keyword of the ALTER TABLE ... CHECK CONSTRAINT ...
|
|
|
|
|
|
'''
|
|
== Comments And Links
|
|
(visible only on this page)
|
|
|
|
=== on 21 Jul 2017, 07:17:42 Alban Auzeill wrote:
|
|
Note, in existing code we mainly found issues on the following (redundant) pattern generated by SQL Management Studio:
|
|
|
|
ALTER TABLE ... ADD CONSTRAINT ...
|
|
|
|
ALTER TABLE ... CHECK CONSTRAINT ...
|
|
|
|
I found a discussion related to it here:
|
|
|
|
https://stackoverflow.com/questions/529941/with-check-add-constraint-followed-by-check-constraint-vs-add-constraint
|
|
|
|
=== on 21 Jul 2017, 14:04:17 Ann Campbell wrote:
|
|
So perhaps this should be removed from the default profile [~alban.auzeill]?
|
|
|
|
=== on 24 Jul 2017, 16:51:19 Ann Campbell wrote:
|
|
I've made a couple edits [~alban.auzeill]. Double-check me, please.
|
|
|
|
endif::env-github,rspecator-view[]
|