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


Check Constraint Works on Inserts, but Not on Updates


Check Constraint Works on Inserts, but Not on Updates

Author
Message
mmallkc
mmallkc
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 4
I created a UDF to check for more than one instances of a value 1 in a bit column corresponding to a given ID in a table.

CREATE function [dbo].[udfDefault4Scheduling] (@intNPIID int)
returns bit
as
begin

declare @bit bit

set @bit = (select case when count(NPIID) <= 1 then 1 else 0 end from NPIOrgAddressAvailability where NPIID = @intNPIID and Default4Scheduling = 1)

return @bit

end

I added a check constraint on the table in question (NPIOrgAddressAvailability) requiring the function to return a value of 1 for a given ID. In other words, the table can have multiple repeated values for NPIID; but, for a given NPIID, only one row can have a value of 1 for Default4Scheduling.

ALTER TABLE [dbo].[NPIOrgAddressAvailability] WITH CHECK ADD CONSTRAINT [CK_NPIOrgAddressAvailability] CHECK (([dbo].[udfDefault4Scheduling]([NPIID])=(1)))
GO

ALTER TABLE [dbo].[NPIOrgAddressAvailability] CHECK CONSTRAINT [CK_NPIOrgAddressAvailability]
GO

Whenever I try to insert a new record in violation of this constraint, I get an error as expected. However, when I update the table in violation of this constraint, it allows me to do so as if the constraint doesn't even exist.

I checked in SSMS and "Enforce for Inserts and Updates" is set to "Yes".

A Google search suggests several others have had this issue; but, I haven't seen a resolution. Any ideas?

Thanks,

Mike
GSquared
GSquared
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14385 Visits: 9729
How about skipping the check constraint and using a Unique, Filtered index?

CREATE UNIQUE INDEX UFI_NPIOrgAddressAvailability_NPIID_Default4Scheduling ON dbo.NPIOrgAddressAvailability (NPIID)
WHERE Default4Scheduling = 1;



Name the index per your local policy, of course. I just gave it a sort of default name.

Assuming you're using SQL 2008 (as per the forum you posted in), that should be an option. Try it and see if it does what you need.

- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread

"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
mmallkc
mmallkc
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 4
Thanks G^2.

I forgot that I could use filtered indexes in SQL 08. Still. I'm puzzled as to why the constraint behaves this way.

Thanks again,

Mike.
GSquared
GSquared
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14385 Visits: 9729
Probably because, at the time the constraint is fired, the updated value hasn't been committed yet, so there's only one row with the live data, committed, and thus it doesn't violate the constraint.

But I'm kind of guessing on that. I avoid UDFs in constraints if I can help it. I've found they create more complexity than they solve. Plus, if they have to access row data, I've seen them do all kinds of nasty things to lock escalation.

- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread

"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
mmallkc
mmallkc
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 4
Thanks.

I went down this same road about 8 weeks ago - trying to create a check constraint using a UDF, finding it works for inserts but not updates, then finding that SQL 08 allows for filtered indexes and using that instead. Somehow, I forgot all about that when the same situation arose again.

I'll keep in mind your advise regarding avoidance of UDFs for constraints.

One more thing - do you know if MySQL allows for filtered indexes? I don't think it does based on my searching.

Thanks again.
GSquared
GSquared
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14385 Visits: 9729
No clue on MySQL. I installed a copy of it once, in 2002, played around with it for about an hour, and haven't touched it since. Not against it in any way, just haven't had the need.

- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread

"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
ScottPletcher
ScottPletcher
Hall of Fame
Hall of Fame (4K reputation)Hall of Fame (4K reputation)Hall of Fame (4K reputation)Hall of Fame (4K reputation)Hall of Fame (4K reputation)Hall of Fame (4K reputation)Hall of Fame (4K reputation)Hall of Fame (4K reputation)

Group: General Forum Members
Points: 3950 Visits: 6686
mmallkc (10/30/2012)
Whenever I try to insert a new record in violation of this constraint, I get an error as expected. However, when I update the table in violation of this constraint, it allows me to do so as if the constraint doesn't even exist.

I checked in SSMS and "Enforce for Inserts and Updates" is set to "Yes".

A Google search suggests several others have had this issue; but, I haven't seen a resolution. Any ideas?

Mike



Without testing it yet, I agree with GSquared that the CHECK occurs before the row is actually UPDATEd. In fact, I'm not sure why then the INSERT CHECK is catching the dup (is it possibly something else causing the INSERT to fail??).

I'm taking it that NPIID is not a unique id itself right? If it were, the check would always pass, right?

SQL DBA,SQL Server MVP('07, '08, '09)

Prosecutor James Blackburn, in closing argument in the "Fatal Vision" murders trial: "If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them."
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