Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

FK created WITH NOCHECK, FK validation for SQL update statements which don't update FK column(s) Expand / Collapse
Author
Message
Posted Tuesday, March 26, 2013 9:05 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, September 12, 2013 2:28 PM
Points: 12, Visits: 159
Does SQL server validate FK constraint(s) on SQL update statements which don't update any columns of FK?

This question came up when I updated non-key columns for a very large table (150 mil rows) CPU usage jumped 96%, which I did not see any reason for high CPU..

Here's what MS doc shows, it says "in ALL later data updates"

If you do not want to verify new CHECK or FOREIGN KEY constraints against existing data, use WITH NOCHECK. We do not recommend doing this, except in rare cases. The new constraint will be evaluated in all later data updates. Any constraint violations that are suppressed by WITH NOCHECK when the constraint is added may cause future updates to fail if they update rows with data that does not comply with the constraint

Any input will be appreciated..
Post #1435563
Posted Tuesday, March 26, 2013 11:19 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Wednesday, April 16, 2014 9:25 AM
Points: 7,070, Visits: 12,523
Not sure if there was a misconception but to clarify the WITH NOCHECK option only applies to the initial creation of the FK, not later updates. If the column with the FK constraint is later updated, the FK is checked. As to whether "later updates" also mean when the table us updated but the column with the constraint is not updated, no. If you're not updating the column with the FK constraint then the constraint is not checked again.

use tempdb;
go

create table dbo.test
(
test_id int identity(1,1) not null primary key,
name varchar(100)
);

create table dbo.test_child
(
test_child_id int identity(1,1) not null primary key,
test_id int null,
name varchar(100)
);

insert into dbo.test_child (test_id, name) values (1,'John');

alter table dbo.test_child with nocheck add constraint [fk_dbo.test_child_dbo.test.test_id] foreign key (test_id)
references dbo.test (test_id) ;

-- would not succeed if FK were checked
update dbo.test_child
set name = 'Dave'
where name = 'John';

Chances are your CPU is issue is related to something else. It could be a lot of things but if you post the actual execution plan from the update it may give us some things to look into further.


__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato

Believe you can and you're halfway there. --Theodore Roosevelt

Everything Should Be Made as Simple as Possible, But Not Simpler --Albert Einstein

The significant problems we face cannot be solved at the same level of thinking we were at when we created them. --Albert Einstein

1 apple is not exactly 1/8 of 8 apples. Because there are no absolutely identical apples. --Giordy
Post #1435631
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse