Deleting from Parent and all its child tables with FK (no DELETE ON CASCADE)

  • Hi Experts,

    I have a database with many tables. I would like to Delete all rows with practiceID=55 from all Parents tables and all corresponding rows from its child tables. Tables are linked with foreign key constraints (but there is no ON DELETE CASCADE).

    Can any one tell how to write a generalized code for removing rows from both parent and child tables.

    Query should pick parent table one by one and delete rows with practiceID=55 and all corresponding rows from its child tables

    Thanks,

    Naveen J V

  • Reverse that order logically and you should have your answer. You need to delete all the child table rows, then delete the parent.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • Put another way, work from the lowest-level children up to the parent. Start with the great-grandchildren, then up to the grandchildren, then to the children, then to the parent table. You can't violate referential integrity at any point along the way.

  • I think the following will walk through FK relationships starting with a parent down through the affected tables.

    DECLARE @Parent_Table SYSNAME = 'YourParentTable';

    WITH TraverseTableHierarchy AS

    (

    -- Using the starting object's ID, identify all foreign keys to it

    SELECT Lvl=0

    ,ReferencedTableName=OBJECT_NAME(a.referenced_object_id)

    ,ReferencingTableName=OBJECT_NAME(a.parent_object_id)

    ,FKName=a.name, a.object_id, a.parent_object_id, a.referenced_object_id

    ,Relationship=CAST(OBJECT_NAME(a.referenced_object_id) + '<' + OBJECT_NAME(a.parent_object_id) AS VARCHAR(8000))

    FROM sys.foreign_keys a

    JOIN sys.all_objects b ON a.parent_object_id = b.object_id

    WHERE a.referenced_object_id =

    OBJECT_ID(

    @Parent_Table

    , 'U')

    UNION ALL

    -- Traverse the hiearchy through the foreign keys and identify the children

    SELECT Lvl+1

    ,ReferencedTableName=OBJECT_NAME(b.referenced_object_id)

    ,ReferencingTableName=OBJECT_NAME(b.parent_object_id)

    ,FKName=b.name, b.object_id, b.parent_object_id, b.referenced_object_id

    ,Relationship=a.Relationship + '<' + CAST(OBJECT_NAME(b.parent_object_id) AS VARCHAR(8000))

    FROM TraverseTableHierarchy a

    JOIN sys.foreign_keys b ON a.parent_object_id = b.referenced_object_id

    JOIN sys.all_objects c ON b.parent_object_id = c.object_id

    )

    SELECT *

    FROM TraverseTableHierarchy

    ORDER BY Lvl DESC, Relationship;

    Just in case you're afraid you might miss one. Tables should be returned in the order you need to delete the FKs.

    Hope this helps.

    Edit: Fixed comments.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

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

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