Delete Constraint rule Set Default problem

  • I just want to ask if Set Default works with columns that are string related?

    I've tried setting up my a column in the Child table to have a string value default then made a relation with a parent table.

    I set the relationship to have a 'Set Default' on Delete. I succesfuly even saved a diagram of it but when I try to delete a record in the parent table

    a exception occurs :

    Msg 547, Level 16, State 0, Line 1

    The DELETE statement conflicted with the FOREIGN KEY constraint "Member_ChapterBelong_FK". The conflict occurred in database "Student", table "dbo.Chapter", column 'Chapter'.

    The statement has been terminated.

    I am pretty certain that I have followed and turn Set Default in the delete rule thats why I dont know what makes this restricted.

    Just to add few info, I made the relationship and set defaults through GUI in management studio.

    I want to know if this is a limitation or theres a mistake on my approach on doing it.

  • Can you post the ddl for the tables involved, including all constraints and indexes? Take a look at the first link in my signature for best practices when posting questions.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • I apologize for the wrong format anyway I did my best to make my question clear. Pls refer to the items below:

    -- START

    USE student

    -- Create table for food category

    CREATE TABLE FoodCategory

    (

    Category nvarchar(50) PRIMARY KEY NOT NULL

    )

    -- Create table for food name and its category

    CREATE TABLE Food

    (

    [Name] nvarchar(50) PRIMARY KEY Not null,

    Category nvarchar(50) DEFAULT 'Unassigned' NOT NULL CONSTRAINT Food_Category_FK REFERENCES FoodCategory(Category) ON DELETE SET DEFAULT

    )

    -- Add values to foodcategory

    INSERT INTO FoodCategory VALUES('Fruits')

    INSERT INTO FoodCategory VALUES('Vegetables')

    -- Add values to Food

    INSERT INTO Food VALUES ('Apple','Fruits')

    INSERT INTO Food VALUES ('Spinach', 'Vegetables')

    -- Delete 'Fruits' category to test if the default value will be assigned when ON DELETE SET DEFAULT is the settings.

    DELETE FROM FoodCategory WHERE Category = 'Fruits'

    -- END

    After I perform the delete SQL Management studio gives me this message:

    Msg 547, Level 16, State 0, Line 1

    The DELETE statement conflicted with the FOREIGN KEY constraint "Food_Category_FK". The conflict occurred in database "Student", table "dbo.FoodCategory", column 'Category'.

    The statement has been terminated.

    Ive tried doing this with integer,it seems to work but what I need is a string value. I hope this makes my question clear. Thank You.

  • crux1187 (9/17/2012)


    I apologize for the wrong format anyway I did my best to make my question clear. Pls refer to the items below:

    -- START

    USE student

    -- Create table for food category

    CREATE TABLE FoodCategory

    (

    Category nvarchar(50) PRIMARY KEY NOT NULL

    )

    -- Create table for food name and its category

    CREATE TABLE Food

    (

    [Name] nvarchar(50) PRIMARY KEY Not null,

    Category nvarchar(50) DEFAULT 'Unassigned' NOT NULL CONSTRAINT Food_Category_FK REFERENCES FoodCategory(Category) ON DELETE SET DEFAULT

    )

    -- Add values to foodcategory

    INSERT INTO FoodCategory VALUES('Fruits')

    INSERT INTO FoodCategory VALUES('Vegetables')

    -- Add values to Food

    INSERT INTO Food VALUES ('Apple','Fruits')

    INSERT INTO Food VALUES ('Spinach', 'Vegetables')

    -- Delete 'Fruits' category to test if the default value will be assigned when ON DELETE SET DEFAULT is the settings.

    DELETE FROM FoodCategory WHERE Category = 'Fruits'

    -- END

    After I perform the delete SQL Management studio gives me this message:

    Msg 547, Level 16, State 0, Line 1

    The DELETE statement conflicted with the FOREIGN KEY constraint "Food_Category_FK". The conflict occurred in database "Student", table "dbo.FoodCategory", column 'Category'.

    The statement has been terminated.

    Ive tried doing this with integer,it seems to work but what I need is a string value. I hope this makes my question clear. Thank You.

    Thanks for the ddl etc. The reason this isn't working is because you have the foreign key constraint. That means that any value for Category in the Food table MUST exist in the FoodCategory table. Your default value of 'Unassigned' is not in the FoodCategory table. You either need to use ON DELETE SET NULL (which is what I would do in this case) or you need the category 'Unassigned' in the FoodCategory table.

    Try this:

    insert into FoodCategory values('Unassigned')

    Then try your delete, it will now work because your RI is still intact because the new value is a valid category.

    The alternate, which is what I would use in my own system in this type of situation is like this.

    CREATE TABLE FoodCategory

    (

    Category nvarchar(50) PRIMARY KEY NOT NULL

    )

    -- Create table for food name and its category

    CREATE TABLE Food

    (

    [Name] nvarchar(50) PRIMARY KEY Not null,

    Category nvarchar(50) NULL CONSTRAINT Food_Category_FK REFERENCES FoodCategory(Category) ON DELETE SET NULL

    )

    -- Add values to foodcategory

    INSERT INTO FoodCategory VALUES('Fruits')

    INSERT INTO FoodCategory VALUES('Vegetables')

    -- Add values to Food

    INSERT INTO Food VALUES ('Apple','Fruits')

    INSERT INTO Food VALUES ('Spinach', 'Vegetables')

    select * from Food

    DELETE FROM FoodCategory WHERE Category = 'Fruits'

    select * from Food

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Okey before I try it out I have a question regarding your answer. When you set the Delete Rule constraint to Set Default, the default value in the column in the child table should exist somewhere in the parent?Is it the concept of Set Default?

  • crux1187 (9/18/2012)


    Okey before I try it out I have a question regarding your answer. When you set the Delete Rule constraint to Set Default, the default value in the column in the child table should exist somewhere in the parent?Is it the concept of Set Default?

    No that is how foreign keys work. You could make your column have a default but if that default does not exist in the parent table it will not work. I think you understand the concept of how it works but it is important to know that the default will violate the foreign key constraint when the default value does not exist.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • I think what you ought to explain is the same with what I have thought of,anyway I have to try this out first and I'll get back to you. Thanks bro!

Viewing 7 posts - 1 through 6 (of 6 total)

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