Check constraint that calls function does not work on update
Asked Answered
Z

1

14

I created a constraint that prevents allocations in one table to exceed inventory in another table (see the details in my previous question). But for some reason the constraint works as expected only when I insert new allocations, but on update it does not prevent violating.

Here is my constraint:

([dbo].[fn_AllocationIsValid]([Itemid]) = 1)

And here is the function:

CREATE FUNCTION [dbo].[fn_AllocationIsValid] (@itemId as int)  
RETURNS int  AS  
BEGIN 
DECLARE @isValid bit;

SELECT @isValid = CASE WHEN ISNULL(SUM(Allocation), 0) <= MAX(Inventory) THEN 1 ELSE 0 END
FROM Allocations A 
JOIN Items I ON I.Id = A.ItemId
WHERE I.Id = @itemId
GROUP BY I.Id;

RETURN @isValid;
END

Updated

Here are my tables:

CREATE TABLE [allocations] (
[userID] [bigint] NOT NULL ,
[itemID] [int] NOT NULL ,
[allocation] [bigint] NOT NULL ,
CONSTRAINT [PK_allocations] PRIMARY KEY  CLUSTERED 
(
    [userID],
    [itemID]
)  ON [PRIMARY] ,
CONSTRAINT [FK_allocations_items] FOREIGN KEY 
(
    [itemID]
) REFERENCES [items] (
    [id]
) ON DELETE CASCADE  ON UPDATE CASCADE ,
CONSTRAINT [CK_allocations] CHECK ([dbo].[fn_AllocationIsValid]([Itemid], [Allocation]) = 1)
) ON [PRIMARY]

CREATE TABLE [dbo].[Items](
[Id] [int] NOT NULL,
[Inventory] [int] NOT NULL
) ON [PRIMARY]
GO

INSERT INTO Items (Id, Inventory) VALUES (2692, 336)

INSERT INTO Allocations (UserId, ItemId, Allocation) VALUES(4340, 2692, 336)
INSERT INTO Allocations (UserId, ItemId, Allocation) VALUES(5895, 2692, 0)

The following statement execution should fail, but it does not:

update allocations set allocation = 5
where userid = 5895 and itemid = 2692
Zitazitah answered 7/6, 2018 at 15:42 Comment(6)
As I posted in comments in your previous question, I have verified that CHECK constraints affect INSERTs and UPDATEs the same way. What is the data in your tables, and what is the UPDATE you perform, and what result do you see that makes you think the constraint isn't working?Coon
I have in my Allocations table several records for a particular ItemId. SUM(Allocation) is 336. And in the related table Items, the inventory for that Id is also 336. I can update a record in the Allocations table increasing the Allocation. So now SUM(Allocations.Allocation) is greater than Items.Inventory for the same ItemId, which should not be allowed.Zitazitah
Much like your post yesterday this is lacking the ddl and sample data for others to be able to help you. We can't recreate your issue since you haven't posted those details.Gunnar
I just added scripts with the data. I tested it on a brand new database with the same result.Zitazitah
Ok, I have verified that I can reproduce the issue with your DDL and function. Off the top of my head, I can't explain it. The problem doesn't occur if the Constraint does simple logic. Must be something about calling a function. I'll see if I can find anything about it.Coon
This appears to lead to an answer: social.msdn.microsoft.com/Forums/sqlserver/en-US/… In fact, I just tested and verified. I'll type it up in an answer. Could be useful to future readers on this site.Coon
C
24

Well well, I just learned something.

So it turns out that with CHECK CONSTRAINTS and UPDATES, the CONSTRAINT only gets checked if one of the columns referenced in the CONSTRAINT changed.

In your case, your CONSTRAINT is checking a UDF that you pass ItemID to.

In your UPDATE, presumably you are only changing the value of Allocation, and not ItemID, so the optimizer thinks "If ItemID didn't change, then there's no need to check the constraint", and it doesn't, and the UPDATE succeeds even though the CONSTRAINT should have failed it.

I tested this by rebuilding your function and Constraint and adding Allocation to it:

ALTER FUNCTION [dbo].[fn_AllocationIsValid] (@itemId as int, @Allocation int)  
RETURNS int  AS  
BEGIN 
DECLARE @isValid bit;

SELECT @isValid = CASE WHEN ISNULL(SUM(Allocation), 0) <= MAX(Inventory) THEN 1 ELSE 0 END
FROM Allocations A 
JOIN Items I ON I.Id = A.ItemId
WHERE I.Id = @itemId
GROUP BY I.Id;

RETURN @isValid;
END

And:

ALTER TABLE [dbo].[Allocations]  WITH CHECK ADD  CONSTRAINT [CK_Allocations] 
CHECK  (([dbo].[fn_AllocationIsValid]([Itemid], Allocation)=(1)))
GO

Note that I had to DROP the original constraint first and truncate/repopulate the table, but that's nothing that you need me to show you how to do.

Also note that Allocation isn't involved in any of the logic of the function. I didn't change the logic at all, I just added a parameter for @Allocation. The parameter never gets used.

Then when I did an UPDATE that raised the SUM of Allocation to above the MAX, I got the expected error:

The UPDATE statement conflicted with the CHECK constraint "CK_Allocations". The conflict occurred in database "Tab_Test", table "dbo.Allocations".

Why? Because even though @Allocation isn't used in the logic of the function, the Allocation column is referenced in the CONSTRAINT, so the optimizer does check the constraint when the value of Allocation changes.

Some have argued that because of things like this, it's always preferable to use a TRIGGER instead of a CHECK CONSTRAINT that calls a UDF. I'm not convinced, and I haven't seen any reproducible experiments that prove it. But I leave it up to you which way you want to go with this.

Hopefully this information will prove useful to some future readers.

PS: Ascribing proper credit, I learned all this with some help from the forum post in my comment on the question, which led to this blog on the subject.

Coon answered 7/6, 2018 at 18:6 Comment(9)
Excellent write up. I too was thinking about just adding a placebo parameter to trick sql into checking the constraint. I am not a big fan of using a UDF for a check constraint. There are several loop holes in the logic but this is a new for me.Gunnar
hah.. "placebo parameter".. nice. I've always been a fan of CHECK .. UDF.. but from now on I'm going to be a bit more judicious! BTW, technically in OP's case, the function could be avoided by putting the whole query in the constraint itself, I suppose?Coon
@Tab Alleman A strange thing is happening. I tried to apply your change on our server (2000), and it let me increase allocations... but does not let me decrease it back: "UPDATE statement conflicted with TABLE CHECK constraint 'CK_allocations'" !!Zitazitah
I just applied your changes: ([dbo].[fn_AllocationIsValid]([Itemid], [Allocation]) = 1) and CREATE FUNCTION dbo.fn_AllocationIsValid (@itemId as int, @allocation as int)Zitazitah
The same update statement I showed in my question. It used to be 0 originally, then I was able to set it to 5, but was not able to make it 0 again.Zitazitah
Thank you anyway. This problem does not exist in SQL Server 2016. Only 2000. Hopefully, it will be over when we migrate.Zitazitah
@TabAlleman So my original answer was correct by design. :) On serious notes, this a pretty good thing to know about constraints. Wish I could give more than one voteMonte
@Monte : ) I had the exact same thought about your original answer.. I guess I shouldn't have corrected it.Coon
Seems like Azure Sql Server is still affected by this issue. I ran the repro from that blog.Orellana

© 2022 - 2024 — McMap. All rights reserved.