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


Quertion regarding update when there relationship between two tables


Quertion regarding update when there relationship between two tables

Author
Message
Smash125
Smash125
SSC Veteran
SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)SSC Veteran (217 reputation)

Group: General Forum Members
Points: 217 Visits: 1381
Please find the table structures as below

USE Ticket
GO
CREATE TABLE Contact12
(
ContactID INT PRIMARY KEY,
FirstName NVARCHAR(255),
MiddleName NVARCHAR(255),
LastName NVARCHAR(255)
)
GO
CREATE TABLE Contact13
(
ContactID INT,
SalesOrderID INT PRIMARY KEY,
TotalDue MONEY
CONSTRAINT fk_Contact13_Sid FOREIGN KEY(ContactID) REFERENCES Contact12(ContactID)
)

I want to update contactid in contact12 table

want to update contact 1 with 19978

wrote a query it gives following error of course there is conflict

The UPDATE statement conflicted with the REFERENCE constraint "fk_Contact13_Sid". The conflict occurred in database "Ticket", table "dbo.Contact13", column 'ContactID'.

how to go about for such kind of updates.
WolfgangE
WolfgangE
SSC Veteran
SSC Veteran (216 reputation)SSC Veteran (216 reputation)SSC Veteran (216 reputation)SSC Veteran (216 reputation)SSC Veteran (216 reputation)SSC Veteran (216 reputation)SSC Veteran (216 reputation)SSC Veteran (216 reputation)

Group: General Forum Members
Points: 216 Visits: 777
A foreign key helps you keeping your data consistent. In your case the foreign key says that you can only insert ContactIds in table Contact13 if it already exists in column ContactId of table Contact12.

So to make your update you need the ContactId 19978 in table Contact12 first.
Vedran Kesegic
Vedran Kesegic
Old Hand
Old Hand (382 reputation)Old Hand (382 reputation)Old Hand (382 reputation)Old Hand (382 reputation)Old Hand (382 reputation)Old Hand (382 reputation)Old Hand (382 reputation)Old Hand (382 reputation)

Group: General Forum Members
Points: 382 Visits: 1255
Make sure both 1 and 19978 exist in parent table, insert if not.
Update the child table, it will now pass without error.
Delete the old parent row.

I hope it is not your regular procedure, because updating primary key which is by default also a clustered index key, is a very bad idea because of fragmentation and slow operation.
If it is your regular operation, you should create new IDENTITY field and make that a primary key, and reference that with FK constraint.
That will not change and you will not have all sorts of problems you now have.

_____________________________________________________
Microsoft Certified Master: SQL Server 2008
XDetails Addin - for SQL Developers
blog.sqlxdetails.com - Transaction log myths

Bhuvnesh
Bhuvnesh
SSCrazy
SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)SSCrazy (2.9K reputation)

Group: General Forum Members
Points: 2924 Visits: 4076
Vedran Kesegic (1/11/2013)
I hope it is not your regular procedure, because updating primary key which is by default also a clustered index key, is a very bad idea because of fragmentation and slow operation.
i would say , EITHER you are miskenly updating the root column (PK/FK column) OR you have bad business/database design here where you have to make changes in contactid (PK/FK )

-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
Mark Cowne
Mark Cowne
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2090 Visits: 22778
Change

CONSTRAINT fk_Contact13_Sid FOREIGN KEY(ContactID) REFERENCES Contact12(ContactID) 




to

CONSTRAINT fk_Contact13_Sid FOREIGN KEY(ContactID) REFERENCES Contact12(ContactID) ON UPDATE CASCADE



____________________________________________________

Deja View - The strange feeling that somewhere, sometime you've optimised this query before

How to get the best help on a forum

http://www.sqlservercentral.com/articles/Best+Practices/61537




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