Archive
Posts Tagged ‘NOCHECK CONSTRAINT’
SQL Error – UPDATE statement conflicted with the FOREIGN KEY/REFERENCE constraint
December 21, 2010
11 comments
Just replied on MSDN forum’s following post: http://social.msdn.microsoft.com/Forums/en-US/transactsql/thread/289c4ca5-6ab2-4ed6-b446-0300f5c7dc88
When tables are referenced by Foreign Key constraints it gets difficult to UPDATE the key columns.
An example shows this issue and how one can perform UPDATE on FK columns.
USE [tempdb] GO -- CREATE test tables CREATE TABLE dept (d_id INT PRIMARY KEY, dept VARCHAR(50)) CREATE TABLE emp (sn INT PRIMARY KEY, ename VARCHAR(50), d_fk INT CONSTRAINT fk_dept_d_fk FOREIGN KEY (d_fk) REFERENCES dept(d_id)) -- INSERT test data INSERT INTO dept SELECT 1, 'finance' UNION SELECT 2, 'hr' INSERT INTO emp SELECT 1, 'Manoj', 1 UNION SELECT 2, 'Saurabh', 2 UNION SELECT 3, 'Kanchan', 1 UNION SELECT 4, 'Pooja', 2 -- SELECT the INSERTed data SELECT * from dept
d_id dept
1 finance
2 hr -- DeptID needs to be updated to 3
SELECT * from emp
sn ename d_fk
1 Manoj 1
2 Saurabh 2 -- DeptID should also be updated here to 3
3 Kanchan 1
4 Pooja 2 -- DeptID should also be updated here to 3
-- Now lets UPDATE the FK column values UPDATE dept SET d_id=3 WHERE d_id=2
Error Message:
Msg 547, Level 16, State 0, Line 1
The UPDATE statement conflicted with the REFERENCE constraint "fk_dept_d_fk".
The conflict occurred in database "tempdb", table "dbo.emp", column 'd_fk'.
The statement has been terminated.
UPDATE emp SET d_fk=3 WHERE d_fk=2
Error Message:
Msg 547, Level 16, State 0, Line 1
The UPDATE statement conflicted with the FOREIGN KEY constraint "fk_dept_d_fk".
The conflict occurred in database "tempdb", table "dbo.dept", column 'd_id'.
The statement has been terminated.
We can disable the FK constraints by ALTER statement before the UPDATE and enable them after the UPDATE, like:
-- Disable FK Constraint ALTER TABLE emp NOCHECK CONSTRAINT fk_dept_d_fk -- Perform UPDATE UPDATE dept SET d_id=3 WHERE d_id=2 UPDATE emp SET d_fk=3 WHERE d_fk=2 -- Enable FK Constraint ALTER TABLE emp WITH CHECK CHECK CONSTRAINT fk_dept_d_fk -- Following SELECTS will show the new values in updated records: SELECT * from dept
d_id dept
1 finance
3 hr -- Updated record
SELECT * from emp
sn ename d_fk
1 Manoj 1
2 Saurabh 3 -- Updated record
3 Kanchan 1
4 Pooja 3 -- Updated record
-- Final Cleanup, DROP the tables. DROP TABLE emp DROP TABLE dept
MSDN BOL: http://msdn.microsoft.com/en-us/library/10cetyt6(v=VS.80).aspx
Categories: SQL Errors, SQL Tips
NOCHECK CONSTRAINT, WITH CHECK