1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-03 20:02:46 +03:00

Add CASCADE option to TRUNCATE. Joachim Wieland

This commit is contained in:
Tom Lane
2006-03-03 03:30:54 +00:00
parent 2a0ba3f8dd
commit 984a6ced3e
12 changed files with 252 additions and 47 deletions

View File

@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/catalog/heap.c,v 1.293 2005/11/22 18:17:08 momjian Exp $
* $PostgreSQL: pgsql/src/backend/catalog/heap.c,v 1.294 2006/03/03 03:30:52 tgl Exp $
*
*
* INTERFACE ROUTINES
@ -2043,7 +2043,7 @@ heap_truncate_check_FKs(List *relations, bool tempTables)
if (con->contype != CONSTRAINT_FOREIGN)
continue;
/* Not for one of our list of tables */
/* Not referencing one of our list of tables */
if (!list_member_oid(oids, con->confrelid))
continue;
@ -2066,7 +2066,8 @@ heap_truncate_check_FKs(List *relations, bool tempTables)
get_rel_name(con->conrelid),
get_rel_name(con->confrelid),
NameStr(con->conname)),
errhint("Truncate table \"%s\" at the same time.",
errhint("Truncate table \"%s\" at the same time, "
"or use TRUNCATE ... CASCADE.",
get_rel_name(con->conrelid))));
}
}
@ -2074,3 +2075,58 @@ heap_truncate_check_FKs(List *relations, bool tempTables)
systable_endscan(fkeyScan);
heap_close(fkeyRel, AccessShareLock);
}
/*
* heap_truncate_find_FKs
* Find relations having foreign keys referencing any relations that
* are to be truncated
*
* This is almost the same code as heap_truncate_check_FKs, but we don't
* raise an error if we find such relations; instead we return a list of
* their OIDs. Also note that the input is a list of OIDs not a list
* of Relations. The result list does *not* include any rels that are
* already in the input list.
*
* Note: caller should already have exclusive lock on all rels mentioned
* in relationIds. Since adding or dropping an FK requires exclusive lock
* on both rels, this ensures that the answer will be stable.
*/
List *
heap_truncate_find_FKs(List *relationIds)
{
List *result = NIL;
Relation fkeyRel;
SysScanDesc fkeyScan;
HeapTuple tuple;
/*
* Must scan pg_constraint. Right now, it is a seqscan because
* there is no available index on confrelid.
*/
fkeyRel = heap_open(ConstraintRelationId, AccessShareLock);
fkeyScan = systable_beginscan(fkeyRel, InvalidOid, false,
SnapshotNow, 0, NULL);
while (HeapTupleIsValid(tuple = systable_getnext(fkeyScan)))
{
Form_pg_constraint con = (Form_pg_constraint) GETSTRUCT(tuple);
/* Not a foreign key */
if (con->contype != CONSTRAINT_FOREIGN)
continue;
/* Not referencing one of our list of tables */
if (!list_member_oid(relationIds, con->confrelid))
continue;
/* Add referencer unless already in input or result list */
if (!list_member_oid(relationIds, con->conrelid))
result = list_append_unique_oid(result, con->conrelid);
}
systable_endscan(fkeyScan);
heap_close(fkeyRel, AccessShareLock);
return result;
}

View File

@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/commands/tablecmds.c,v 1.177 2006/01/30 16:18:58 tgl Exp $
* $PostgreSQL: pgsql/src/backend/commands/tablecmds.c,v 1.178 2006/03/03 03:30:52 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@ -527,26 +527,79 @@ RemoveRelation(const RangeVar *relation, DropBehavior behavior)
* ExecuteTruncate
* Executes a TRUNCATE command.
*
* This is a multi-relation truncate. It first opens and grabs exclusive
* locks on all relations involved, checking permissions and otherwise
* verifying that the relation is OK for truncation. When they are all
* open, it checks foreign key references on them, namely that FK references
* are all internal to the group that's being truncated. Finally all
* relations are truncated and reindexed.
* This is a multi-relation truncate. We first open and grab exclusive
* lock on all relations involved, checking permissions and otherwise
* verifying that the relation is OK for truncation. In CASCADE mode,
* relations having FK references to the targeted relations are automatically
* added to the group; in RESTRICT mode, we check that all FK references are
* internal to the group that's being truncated. Finally all the relations
* are truncated and reindexed.
*/
void
ExecuteTruncate(List *relations)
ExecuteTruncate(TruncateStmt *stmt)
{
List *rels = NIL;
List *directRelids = NIL;
ListCell *cell;
Oid relid;
Relation rel;
foreach(cell, relations)
/*
* Open and exclusive-lock all the explicitly-specified relations
*/
foreach(cell, stmt->relations)
{
RangeVar *rv = lfirst(cell);
Relation rel;
/* Grab exclusive lock in preparation for truncate */
rel = heap_openrv(rv, AccessExclusiveLock);
rels = lappend(rels, rel);
directRelids = lappend_oid(directRelids, RelationGetRelid(rel));
}
/*
* In CASCADE mode, suck in all referencing relations as well. This
* requires multiple iterations to find indirectly-dependent relations.
* At each phase, we need to exclusive-lock new rels before looking
* for their dependencies, else we might miss something.
*/
if (stmt->behavior == DROP_CASCADE)
{
List *relids = list_copy(directRelids);
for (;;)
{
List *newrelids;
newrelids = heap_truncate_find_FKs(relids);
if (newrelids == NIL)
break; /* nothing else to add */
foreach(cell, newrelids)
{
relid = lfirst_oid(cell);
rel = heap_open(relid, AccessExclusiveLock);
rels = lappend(rels, rel);
relids = lappend_oid(relids, relid);
}
}
}
/* now check all involved relations */
foreach(cell, rels)
{
rel = (Relation) lfirst(cell);
relid = RelationGetRelid(rel);
/*
* If this table was added to the command by CASCADE, report it.
* We don't do this earlier because if we error out on one of the
* tables, it'd be confusing to list subsequently-added tables.
*/
if (stmt->behavior == DROP_CASCADE &&
!list_member_oid(directRelids, relid))
ereport(NOTICE,
(errmsg("truncate cascades to table \"%s\"",
RelationGetRelationName(rel))));
/* Only allow truncate on regular tables */
if (rel->rd_rel->relkind != RELKIND_RELATION)
@ -585,25 +638,30 @@ ExecuteTruncate(List *relations)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("cannot truncate temporary tables of other sessions")));
/* Save it into the list of rels to truncate */
rels = lappend(rels, rel);
}
/*
* Check foreign key references.
* Check foreign key references. In CASCADE mode, this should be
* unnecessary since we just pulled in all the references; but as
* a cross-check, do it anyway if in an Assert-enabled build.
*/
#ifdef USE_ASSERT_CHECKING
heap_truncate_check_FKs(rels, false);
#else
if (stmt->behavior == DROP_RESTRICT)
heap_truncate_check_FKs(rels, false);
#endif
/*
* OK, truncate each table.
*/
foreach(cell, rels)
{
Relation rel = lfirst(cell);
Oid heap_relid;
Oid toast_relid;
rel = (Relation) lfirst(cell);
/*
* Create a new empty storage file for the relation, and assign it as
* the relfilenode value. The old storage file is scheduled for

View File

@ -15,7 +15,7 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.327 2006/02/19 00:04:26 neilc Exp $
* $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.328 2006/03/03 03:30:52 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@ -1961,6 +1961,7 @@ _copyTruncateStmt(TruncateStmt *from)
TruncateStmt *newnode = makeNode(TruncateStmt);
COPY_NODE_FIELD(relations);
COPY_SCALAR_FIELD(behavior);
return newnode;
}

View File

@ -18,7 +18,7 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/equalfuncs.c,v 1.263 2006/02/19 00:04:26 neilc Exp $
* $PostgreSQL: pgsql/src/backend/nodes/equalfuncs.c,v 1.264 2006/03/03 03:30:52 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@ -930,6 +930,7 @@ static bool
_equalTruncateStmt(TruncateStmt *a, TruncateStmt *b)
{
COMPARE_NODE_FIELD(relations);
COMPARE_SCALAR_FIELD(behavior);
return true;
}

View File

@ -11,7 +11,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.531 2006/02/28 22:37:26 tgl Exp $
* $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.532 2006/03/03 03:30:53 tgl Exp $
*
* HISTORY
* AUTHOR DATE MAJOR EVENT
@ -2938,10 +2938,11 @@ attrs: '.' attr_name
*****************************************************************************/
TruncateStmt:
TRUNCATE opt_table qualified_name_list
TRUNCATE opt_table qualified_name_list opt_drop_behavior
{
TruncateStmt *n = makeNode(TruncateStmt);
n->relations = $3;
n->behavior = $4;
$$ = (Node *)n;
}
;

View File

@ -10,7 +10,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/tcop/utility.c,v 1.252 2006/02/12 19:11:01 momjian Exp $
* $PostgreSQL: pgsql/src/backend/tcop/utility.c,v 1.253 2006/03/03 03:30:53 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@ -628,11 +628,7 @@ ProcessUtility(Node *parsetree,
break;
case T_TruncateStmt:
{
TruncateStmt *stmt = (TruncateStmt *) parsetree;
ExecuteTruncate(stmt->relations);
}
ExecuteTruncate((TruncateStmt *) parsetree);
break;
case T_CommentStmt:

View File

@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/catalog/heap.h,v 1.76 2005/10/15 02:49:42 momjian Exp $
* $PostgreSQL: pgsql/src/include/catalog/heap.h,v 1.77 2006/03/03 03:30:53 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@ -62,6 +62,8 @@ extern void heap_truncate(List *relids);
extern void heap_truncate_check_FKs(List *relations, bool tempTables);
extern List *heap_truncate_find_FKs(List *relationIds);
extern List *AddRelationRawConstraints(Relation rel,
List *rawColDefaults,
List *rawConstraints);

View File

@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/commands/tablecmds.h,v 1.25 2005/11/21 12:49:32 alvherre Exp $
* $PostgreSQL: pgsql/src/include/commands/tablecmds.h,v 1.26 2006/03/03 03:30:53 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@ -36,7 +36,7 @@ extern void AlterRelationNamespaceInternal(Relation classRel, Oid relOid,
Oid oldNspOid, Oid newNspOid,
bool hasDependEntry);
extern void ExecuteTruncate(List *relations);
extern void ExecuteTruncate(TruncateStmt *stmt);
extern void renameatt(Oid myrelid,
const char *oldattname,

View File

@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/nodes/parsenodes.h,v 1.301 2006/02/19 00:04:27 neilc Exp $
* $PostgreSQL: pgsql/src/include/nodes/parsenodes.h,v 1.302 2006/03/03 03:30:53 tgl Exp $
*
*-------------------------------------------------------------------------
*/
@ -1314,6 +1314,7 @@ typedef struct TruncateStmt
{
NodeTag type;
List *relations; /* relations (RangeVars) to be truncated */
DropBehavior behavior; /* RESTRICT or CASCADE behavior */
} TruncateStmt;
/* ----------------------

View File

@ -40,30 +40,37 @@ CREATE TABLE trunc_e (a int REFERENCES truncate_a, b int REFERENCES trunc_c);
TRUNCATE TABLE truncate_a; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
DETAIL: Table "trunc_b" references "truncate_a" via foreign key constraint "trunc_b_a_fkey".
HINT: Truncate table "trunc_b" at the same time.
HINT: Truncate table "trunc_b" at the same time, or use TRUNCATE ... CASCADE.
TRUNCATE TABLE truncate_a,trunc_b; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
DETAIL: Table "trunc_e" references "truncate_a" via foreign key constraint "trunc_e_a_fkey".
HINT: Truncate table "trunc_e" at the same time.
HINT: Truncate table "trunc_e" at the same time, or use TRUNCATE ... CASCADE.
TRUNCATE TABLE truncate_a,trunc_b,trunc_e; -- ok
TRUNCATE TABLE truncate_a,trunc_e; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
DETAIL: Table "trunc_b" references "truncate_a" via foreign key constraint "trunc_b_a_fkey".
HINT: Truncate table "trunc_b" at the same time.
HINT: Truncate table "trunc_b" at the same time, or use TRUNCATE ... CASCADE.
TRUNCATE TABLE trunc_c; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
DETAIL: Table "trunc_d" references "trunc_c" via foreign key constraint "trunc_d_a_fkey".
HINT: Truncate table "trunc_d" at the same time.
HINT: Truncate table "trunc_d" at the same time, or use TRUNCATE ... CASCADE.
TRUNCATE TABLE trunc_c,trunc_d; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
DETAIL: Table "trunc_e" references "trunc_c" via foreign key constraint "trunc_e_b_fkey".
HINT: Truncate table "trunc_e" at the same time.
HINT: Truncate table "trunc_e" at the same time, or use TRUNCATE ... CASCADE.
TRUNCATE TABLE trunc_c,trunc_d,trunc_e; -- ok
TRUNCATE TABLE trunc_c,trunc_d,trunc_e,truncate_a; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
DETAIL: Table "trunc_b" references "truncate_a" via foreign key constraint "trunc_b_a_fkey".
HINT: Truncate table "trunc_b" at the same time.
HINT: Truncate table "trunc_b" at the same time, or use TRUNCATE ... CASCADE.
TRUNCATE TABLE trunc_c,trunc_d,trunc_e,truncate_a,trunc_b; -- ok
TRUNCATE TABLE truncate_a RESTRICT; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
DETAIL: Table "trunc_b" references "truncate_a" via foreign key constraint "trunc_b_a_fkey".
HINT: Truncate table "trunc_b" at the same time, or use TRUNCATE ... CASCADE.
TRUNCATE TABLE truncate_a CASCADE; -- ok
NOTICE: truncate cascades to table "trunc_b"
NOTICE: truncate cascades to table "trunc_e"
-- circular references
ALTER TABLE truncate_a ADD FOREIGN KEY (col1) REFERENCES trunc_c;
-- Add some data to verify that truncating actually works ...
@ -75,19 +82,19 @@ INSERT INTO trunc_e VALUES (1,1);
TRUNCATE TABLE trunc_c;
ERROR: cannot truncate a table referenced in a foreign key constraint
DETAIL: Table "trunc_d" references "trunc_c" via foreign key constraint "trunc_d_a_fkey".
HINT: Truncate table "trunc_d" at the same time.
HINT: Truncate table "trunc_d" at the same time, or use TRUNCATE ... CASCADE.
TRUNCATE TABLE trunc_c,trunc_d;
ERROR: cannot truncate a table referenced in a foreign key constraint
DETAIL: Table "trunc_e" references "trunc_c" via foreign key constraint "trunc_e_b_fkey".
HINT: Truncate table "trunc_e" at the same time.
HINT: Truncate table "trunc_e" at the same time, or use TRUNCATE ... CASCADE.
TRUNCATE TABLE trunc_c,trunc_d,trunc_e;
ERROR: cannot truncate a table referenced in a foreign key constraint
DETAIL: Table "truncate_a" references "trunc_c" via foreign key constraint "truncate_a_col1_fkey".
HINT: Truncate table "truncate_a" at the same time.
HINT: Truncate table "truncate_a" at the same time, or use TRUNCATE ... CASCADE.
TRUNCATE TABLE trunc_c,trunc_d,trunc_e,truncate_a;
ERROR: cannot truncate a table referenced in a foreign key constraint
DETAIL: Table "trunc_b" references "truncate_a" via foreign key constraint "trunc_b_a_fkey".
HINT: Truncate table "trunc_b" at the same time.
HINT: Truncate table "trunc_b" at the same time, or use TRUNCATE ... CASCADE.
TRUNCATE TABLE trunc_c,trunc_d,trunc_e,truncate_a,trunc_b;
-- Verify that truncating did actually work
SELECT * FROM truncate_a
@ -106,6 +113,33 @@ SELECT * FROM trunc_e;
---+---
(0 rows)
-- Add data again to test TRUNCATE ... CASCADE
INSERT INTO trunc_c VALUES (1);
INSERT INTO truncate_a VALUES (1);
INSERT INTO trunc_b VALUES (1);
INSERT INTO trunc_d VALUES (1);
INSERT INTO trunc_e VALUES (1,1);
TRUNCATE TABLE trunc_c CASCADE; -- ok
NOTICE: truncate cascades to table "trunc_d"
NOTICE: truncate cascades to table "trunc_e"
NOTICE: truncate cascades to table "truncate_a"
NOTICE: truncate cascades to table "trunc_b"
SELECT * FROM truncate_a
UNION ALL
SELECT * FROM trunc_c
UNION ALL
SELECT * FROM trunc_b
UNION ALL
SELECT * FROM trunc_d;
col1
------
(0 rows)
SELECT * FROM trunc_e;
a | b
---+---
(0 rows)
DROP TABLE truncate_a,trunc_c,trunc_b,trunc_d,trunc_e CASCADE;
NOTICE: drop cascades to constraint trunc_e_a_fkey on table trunc_e
NOTICE: drop cascades to constraint trunc_b_a_fkey on table trunc_b

View File

@ -30,6 +30,9 @@ TRUNCATE TABLE trunc_c,trunc_d,trunc_e; -- ok
TRUNCATE TABLE trunc_c,trunc_d,trunc_e,truncate_a; -- fail
TRUNCATE TABLE trunc_c,trunc_d,trunc_e,truncate_a,trunc_b; -- ok
TRUNCATE TABLE truncate_a RESTRICT; -- fail
TRUNCATE TABLE truncate_a CASCADE; -- ok
-- circular references
ALTER TABLE truncate_a ADD FOREIGN KEY (col1) REFERENCES trunc_c;
@ -55,4 +58,22 @@ SELECT * FROM truncate_a
SELECT * FROM trunc_d;
SELECT * FROM trunc_e;
-- Add data again to test TRUNCATE ... CASCADE
INSERT INTO trunc_c VALUES (1);
INSERT INTO truncate_a VALUES (1);
INSERT INTO trunc_b VALUES (1);
INSERT INTO trunc_d VALUES (1);
INSERT INTO trunc_e VALUES (1,1);
TRUNCATE TABLE trunc_c CASCADE; -- ok
SELECT * FROM truncate_a
UNION ALL
SELECT * FROM trunc_c
UNION ALL
SELECT * FROM trunc_b
UNION ALL
SELECT * FROM trunc_d;
SELECT * FROM trunc_e;
DROP TABLE truncate_a,trunc_c,trunc_b,trunc_d,trunc_e CASCADE;