Methods to prevent SQL Server table modification

  • Hello,

    My database model is like this: a master table and two referenced tables, which can be acessed independently. Any of the tables can be updated, or new rows can be added. Master table contains dates.

    The request is to prevent table modifications, based on a date, meaning that records from any of the tables must not be altered if the date in the master table falls within specified range. Also, new records in the master table cannot be inserted if the date is not valid.

    I got an idea to do this with a trigger. So, trigger on each table will check if the date in the master table is valid for table modification.

    This should work, but I don't like it much because all these triggers on table could impact performance. And bring some other obscure problems, not yet foreseen 🙂

    I thought about CHECK constraint, is this possible? I mean, can I put a CHECK constraint on a table so that it checks new inserted or updated values ONLY? And not be concerned about some old data that existed.

    Thanks for any suggestions 🙂

  • You can do it with a trigger or with a CHECK constraint WITH NOCHECK.

    Be aware that:

    1) CHECK constraints can't read data from another table directly, but have to use a scalar function. From a performance standpoint, I see this even worse than triggers

    2) If a CHECK constraint is attached to a column, it is not invoked if you update another column. Moreover, I just discovered a weird thing: if the column you update is not explicitly used in the CHECK constraint, you can bypass the check.

    Example:

    USE tempdb;

    GO

    -- Create master table

    CREATE TABLE masterTable (

    id int identity(1,1) PRIMARY KEY,

    dateField datetime

    )

    GO

    -- Create referenced table

    CREATE TABLE referencedTable (

    id int identity(1,1) PRIMARY KEY,

    master_id int FOREIGN KEY REFERENCES masterTable(id),

    valueField varchar(50)

    )

    GO

    -- Insert sample data

    INSERT INTO masterTable(dateField) VALUES(GETDATE())

    INSERT INTO masterTable(dateField) VALUES(DATEADD(day,-1,GETDATE()))

    INSERT INTO masterTable(dateField) VALUES(DATEADD(day,-2,GETDATE()))

    SELECT * FROM masterTable

    -- Insert sample data in referenced table

    INSERT INTO referencedTable(master_id, valueField) VALUES (1,'Value for id 1')

    INSERT INTO referencedTable(master_id, valueField) VALUES (2,'Value for id 2')

    INSERT INTO referencedTable(master_id, valueField) VALUES (3,'Value for id 3')

    SELECT * FROM referencedTable

    GO

    -- Create a scalar UDF: you will need this in the CHECK constraint

    CREATE FUNCTION getMasterDate(@id int)

    RETURNS datetime

    AS

    BEGIN

    RETURN ISNULL((SELECT dateField FROM masterTable WHERE id = @id),'30110101')

    END

    GO

    -- Add the constraint WITH NOCHECK: existing rows are not affected

    ALTER TABLE referencedTable WITH NOCHECK ADD CONSTRAINT chk_date

    CHECK (DATEADD(day,-1,GETDATE()) > dbo.getMasterDate(master_id))

    -- Update referenced table. Some rows conflict with the CHECK constraint, but it works

    -- because the constraint is attached to a single column

    UPDATE referencedTable

    SET valueField = 'New ' + valueField

    -- If you try to update master_id it fails

    UPDATE referencedTable

    SET master_id = master_id + 1 - 1

    --Msg 547, Level 16, State 0, Line 2

    --The UPDATE statement conflicted with the CHECK constraint "chk_date". The conflict occurred in database "tempdb", table "dbo.referencedTable", column 'master_id'.

    --The statement has been terminated.

    -- Drop the constraint

    ALTER TABLE referencedTable DROP CONSTRAINT chk_date

    GO

    -- Create the constraint referencing multiple columns

    ALTER TABLE referencedTable WITH NOCHECK ADD CONSTRAINT chk_date

    CHECK (

    DATEADD(day,-1,GETDATE()) > dbo.getMasterDate(master_id)

    AND

    ISNULL(valueField,'') = ISNULL(valueField,SPACE(0))

    )

    GO

    -- DOESN'T WORK ANY MORE:

    UPDATE referencedTable

    SET valueField = 'New ' + valueField

    --Msg 547, Level 16, State 0, Line 1

    --The UPDATE statement conflicted with the CHECK constraint "chk_date". The conflict occurred in database "tempdb", table "dbo.referencedTable".

    --The statement has been terminated.

    You can check the column/table scope of the constraint querying sys.check_constraints:

    SELECT parent_column_id, definition, is_not_trusted

    FROM sys.check_constraints

    WHERE parent_object_id = OBJECT_ID('referencedTable')

    parent_column_id = 0 means table scoped constraint, parent_column_id > 0 means a single column.

    Hope this helps

    Gianluca

    -- Gianluca Sartori

  • More details on my blog: http://wp.me/p1gueM-4c

    -- Gianluca Sartori

  • Nice tests Gianluca !

    However, regarding the performance impact for this quest compared to a trigger should be the same.

    (b)locking will be part of the game with either solution, so support it with the needed indexes !

    Test the different solutions and pick the one that serves you best keeping KISS in mind.

    Johan

    Learn to play, play to learn !

    Dont drive faster than your guardian angel can fly ...
    but keeping both feet on the ground wont get you anywhere :w00t:

    - How to post Performance Problems
    - How to post data/code to get the best help[/url]

    - How to prevent a sore throat after hours of presenting ppt

    press F1 for solution, press shift+F1 for urgent solution 😀

    Need a bit of Powershell? How about this

    Who am I ? Sometimes this is me but most of the time this is me

Viewing 4 posts - 1 through 3 (of 3 total)

You must be logged in to reply to this topic. Login to reply