Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


FK created WITH NOCHECK, FK validation for SQL update statements which don't update FK column(s)


FK created WITH NOCHECK, FK validation for SQL update statements which don't update FK column(s)

Author
Message
Jay Byoun
Jay Byoun
Grasshopper
Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)

Group: General Forum Members
Points: 12 Visits: 162
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..
Orlando Colamatteo
Orlando Colamatteo
SSCrazy Eights
SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)SSCrazy Eights (8.2K reputation)

Group: General Forum Members
Points: 8235 Visits: 14368
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
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