22

I'm trying to perform a cascading delete on 15+ tables but I'm not certain that all of the requisite foreign keys have been configured properly. I would like to check for missing constraints without manually reviewing each constraint.

Is there a way to obtain a list of tables that will be affected by a cascading delete query?

klin
  • 112,967
  • 15
  • 204
  • 232
Peter Hanneman
  • 523
  • 1
  • 5
  • 18

3 Answers3

30

Use pg_depend. Example:

create table master (id int primary key);
create table detail_1 (id int, master_id int references master(id) on delete restrict);
create table detail_2 (id int, master_id int references master(id) on delete cascade);

select pg_describe_object(classid, objid, objsubid)
from pg_depend 
where refobjid = 'master'::regclass and deptype = 'n';

                  pg_describe_object
------------------------------------------------------
 constraint detail_1_master_id_fkey on table detail_1
 constraint detail_2_master_id_fkey on table detail_2
(2 rows)

deptype = 'n' means:

DEPENDENCY NORMAL - A normal relationship between separately-created objects. The dependent object can be dropped without affecting the referenced object. The referenced object can only be dropped by specifying CASCADE, in which case the dependent object is dropped, too.

Use pg_get_constraintdef() to get constraint definitions:

select 
    pg_describe_object(classid, objid, objsubid), 
    pg_get_constraintdef(objid)
from pg_depend 
where refobjid = 'master'::regclass and deptype = 'n';


                  pg_describe_object                  |                       pg_get_constraintdef
------------------------------------------------------+------------------------------------------------------------------
 constraint detail_1_master_id_fkey on table detail_1 | FOREIGN KEY (master_id) REFERENCES master(id) ON DELETE RESTRICT
 constraint detail_2_master_id_fkey on table detail_2 | FOREIGN KEY (master_id) REFERENCES master(id) ON DELETE CASCADE
(2 rows)

To find the full chain of cascading dependencies we should use recursion and look into the catalog pg_constraint to get id of a dependent table.

with recursive chain as (
    select classid, objid, objsubid, conrelid
    from pg_depend d
    join pg_constraint c on c.oid = objid
    where refobjid = 'the_table'::regclass and deptype = 'n'
union all
    select d.classid, d.objid, d.objsubid, c.conrelid
    from pg_depend d
    join pg_constraint c on c.oid = objid
    join chain on d.refobjid = chain.conrelid and d.deptype = 'n'
    )
select pg_describe_object(classid, objid, objsubid), pg_get_constraintdef(objid)
from chain;
klin
  • 112,967
  • 15
  • 204
  • 232
  • Thanks this was a huge help! However these queries only show the direct child FKs not the full chain of cascading deletes. So to find all of the tables affected by a delete I have to run this query again on every distinct table name returned for each execution. This is time consuming for databases with complex table relationships. – Peter Hanneman Jun 27 '16 at 21:40
  • 2
    Try the recursive version of the query. – klin Jun 27 '16 at 23:06
  • 1
    This is awesome. – ThomasH Mar 03 '18 at 16:04
  • Thank you, this was the only thing that worked to show me what dependencies a table had! – displacedtexan Dec 08 '20 at 15:40
8

Using transitive closure, one can determine the referencing and referenced tables. A caveat is that this query/view depends on the existence of Foreign Keys to determine the dependencies, and will not find tables if the FK's are missing (and the latter seems to be what the OP is asking for).

Table dependencies via Foreign Keys

CREATE OR REPLACE VIEW table_dependencies AS (
WITH RECURSIVE t AS (
    SELECT
        c.oid AS origin_id,
        c.oid::regclass::text AS origin_table,
        c.oid AS referencing_id,
        c.oid::regclass::text AS referencing_table,
        c2.oid AS referenced_id,
        c2.oid::regclass::text AS referenced_table,
        ARRAY[c.oid::regclass,c2.oid::regclass] AS chain
    FROM pg_catalog.pg_constraint AS co
    INNER JOIN pg_catalog.pg_class AS c ON c.oid = co.conrelid
    INNER JOIN pg_catalog.pg_class AS c2 ON c2.oid = co.confrelid
--     Add this line as an input parameter if you want to make a one-off query
--     WHERE c.oid::regclass::text = 'YOUR TABLE'
    UNION ALL
    SELECT
        t.origin_id,
        t.origin_table,
        t.referenced_id AS referencing_id,
        t.referenced_table AS referencing_table,
        c3.oid AS referenced_id,
        c3.oid::regclass::text AS referenced_table,
        t.chain || c3.oid::regclass AS chain
    FROM pg_catalog.pg_constraint AS co
    INNER JOIN pg_catalog.pg_class AS c3 ON c3.oid = co.confrelid
    INNER JOIN t ON t.referenced_id = co.conrelid
    WHERE
        -- prevent infinite recursion by pruning paths where the last entry in
        -- the path already appears somewhere else in the path
        NOT (
            ARRAY[ t.chain[array_upper(t.chain, 1)] ] -- an array containing the last element
            <@                                        -- "is contained by"
            t.chain[1:array_upper(t.chain, 1) - 1]    -- a slice of the chain,
                                                      -- from element 1 to n-1
        )
)
SELECT  origin_table,
        referenced_table,
        array_upper(chain,1) AS "depth",
        array_to_string(chain,',') as chain
FROM t
);

Tables referencing a specific table

SELECT * FROM table_dependencies WHERE origin_table = 'clients';

Tables directly related to the "clients" table

SELECT *
FROM table_dependencies
WHERE referenced_table = 'clients'
AND depth = 2
ORDER BY origin_table;
bma
  • 9,424
  • 2
  • 33
  • 22
6

Yes. you can truncate cascade in transaction and rollback. Note ROLLBACK is a key to save the data. postgres will NOTICE you what other referencing tables will be affected.

postgres=# begin;
BEGIN
postgres=# truncate table a cascade;
NOTICE:  truncate cascades to table "b"
TRUNCATE TABLE
postgres=# rollback;
ROLLBACK
Vao Tsun
  • 47,234
  • 13
  • 100
  • 132
  • 1
    In the case the OP is asking about, you can see the plan that actually gets executed by the delete via `begin; explain analyze ; rollback;`. Note that you are executing the actual query, then rolling back the results. – bma Aug 08 '17 at 22:05