Skip to content
Projects
Groups
Snippets
Help
Loading...
Help
Support
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in
Toggle navigation
P
Postgres FD Implementation
Project overview
Project overview
Details
Activity
Releases
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Issues
0
Issues
0
List
Boards
Labels
Milestones
Merge Requests
0
Merge Requests
0
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Analytics
Analytics
CI / CD
Repository
Value Stream
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
Abuhujair Javed
Postgres FD Implementation
Commits
984a6ced
Commit
984a6ced
authored
Mar 03, 2006
by
Tom Lane
Browse files
Options
Browse Files
Download
Email Patches
Plain Diff
Add CASCADE option to TRUNCATE. Joachim Wieland
parent
2a0ba3f8
Changes
12
Hide whitespace changes
Inline
Side-by-side
Showing
12 changed files
with
252 additions
and
47 deletions
+252
-47
doc/src/sgml/ref/truncate.sgml
doc/src/sgml/ref/truncate.sgml
+38
-4
src/backend/catalog/heap.c
src/backend/catalog/heap.c
+59
-3
src/backend/commands/tablecmds.c
src/backend/commands/tablecmds.c
+74
-16
src/backend/nodes/copyfuncs.c
src/backend/nodes/copyfuncs.c
+2
-1
src/backend/nodes/equalfuncs.c
src/backend/nodes/equalfuncs.c
+2
-1
src/backend/parser/gram.y
src/backend/parser/gram.y
+3
-2
src/backend/tcop/utility.c
src/backend/tcop/utility.c
+2
-6
src/include/catalog/heap.h
src/include/catalog/heap.h
+3
-1
src/include/commands/tablecmds.h
src/include/commands/tablecmds.h
+2
-2
src/include/nodes/parsenodes.h
src/include/nodes/parsenodes.h
+2
-1
src/test/regress/expected/truncate.out
src/test/regress/expected/truncate.out
+44
-10
src/test/regress/sql/truncate.sql
src/test/regress/sql/truncate.sql
+21
-0
No files found.
doc/src/sgml/ref/truncate.sgml
View file @
984a6ced
<!--
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/truncate.sgml,v 1.
19 2005/02/22 19:06:18
tgl Exp $
$PostgreSQL: pgsql/doc/src/sgml/ref/truncate.sgml,v 1.
20 2006/03/03 03:30:52
tgl Exp $
PostgreSQL documentation
PostgreSQL documentation
-->
-->
...
@@ -20,7 +20,7 @@ PostgreSQL documentation
...
@@ -20,7 +20,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<refsynopsisdiv>
<synopsis>
<synopsis>
TRUNCATE [ TABLE ] <replaceable class="PARAMETER">name</replaceable> [, ...]
TRUNCATE [ TABLE ] <replaceable class="PARAMETER">name</replaceable> [, ...]
[ CASCADE | RESTRICT ]
</synopsis>
</synopsis>
</refsynopsisdiv>
</refsynopsisdiv>
...
@@ -47,6 +47,27 @@ TRUNCATE [ TABLE ] <replaceable class="PARAMETER">name</replaceable> [, ...]
...
@@ -47,6 +47,27 @@ TRUNCATE [ TABLE ] <replaceable class="PARAMETER">name</replaceable> [, ...]
</para>
</para>
</listitem>
</listitem>
</varlistentry>
</varlistentry>
<varlistentry>
<term><literal>CASCADE</literal></term>
<listitem>
<para>
Automatically truncate all tables that have foreign-key references
to any of the named tables, or to any tables added to the group
due to <literal>CASCADE</literal>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>RESTRICT</literal></term>
<listitem>
<para>
Refuse to truncate if any of the tables have foreign-key references
from tables that are not to be truncated. This is the default.
</para>
</listitem>
</varlistentry>
</variablelist>
</variablelist>
</refsect1>
</refsect1>
...
@@ -61,7 +82,10 @@ TRUNCATE [ TABLE ] <replaceable class="PARAMETER">name</replaceable> [, ...]
...
@@ -61,7 +82,10 @@ TRUNCATE [ TABLE ] <replaceable class="PARAMETER">name</replaceable> [, ...]
<command>TRUNCATE</> cannot be used on a table that has foreign-key
<command>TRUNCATE</> cannot be used on a table that has foreign-key
references from other tables, unless all such tables are also truncated
references from other tables, unless all such tables are also truncated
in the same command. Checking validity in such cases would require table
in the same command. Checking validity in such cases would require table
scans, and the whole point is not to do one.
scans, and the whole point is not to do one. The <literal>CASCADE</>
option can be used to automatically include all dependent tables —
but be very careful when using this option, else you might lose data you
did not intend to!
</para>
</para>
<para>
<para>
...
@@ -78,10 +102,20 @@ TRUNCATE [ TABLE ] <replaceable class="PARAMETER">name</replaceable> [, ...]
...
@@ -78,10 +102,20 @@ TRUNCATE [ TABLE ] <replaceable class="PARAMETER">name</replaceable> [, ...]
<programlisting>
<programlisting>
TRUNCATE TABLE bigtable, fattable;
TRUNCATE TABLE bigtable, fattable;
</programlisting>
</para>
<para>
Truncate the table <literal>othertable</literal>, and cascade to any tables
that are referencing <literal>othertable</literal> via foreign-key
constraints:
<programlisting>
TRUNCATE othertable CASCADE;
</programlisting>
</programlisting>
</para>
</para>
</refsect1>
</refsect1>
<refsect1>
<refsect1>
<title>Compatibility</title>
<title>Compatibility</title>
...
...
src/backend/catalog/heap.c
View file @
984a6ced
...
@@ -8,7 +8,7 @@
...
@@ -8,7 +8,7 @@
*
*
*
*
* IDENTIFICATION
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/catalog/heap.c,v 1.29
3 2005/11/22 18:17:08 momjian
Exp $
* $PostgreSQL: pgsql/src/backend/catalog/heap.c,v 1.29
4 2006/03/03 03:30:52 tgl
Exp $
*
*
*
*
* INTERFACE ROUTINES
* INTERFACE ROUTINES
...
@@ -2043,7 +2043,7 @@ heap_truncate_check_FKs(List *relations, bool tempTables)
...
@@ -2043,7 +2043,7 @@ heap_truncate_check_FKs(List *relations, bool tempTables)
if
(
con
->
contype
!=
CONSTRAINT_FOREIGN
)
if
(
con
->
contype
!=
CONSTRAINT_FOREIGN
)
continue
;
continue
;
/* Not
for
one of our list of tables */
/* Not
referencing
one of our list of tables */
if
(
!
list_member_oid
(
oids
,
con
->
confrelid
))
if
(
!
list_member_oid
(
oids
,
con
->
confrelid
))
continue
;
continue
;
...
@@ -2066,7 +2066,8 @@ heap_truncate_check_FKs(List *relations, bool tempTables)
...
@@ -2066,7 +2066,8 @@ heap_truncate_check_FKs(List *relations, bool tempTables)
get_rel_name
(
con
->
conrelid
),
get_rel_name
(
con
->
conrelid
),
get_rel_name
(
con
->
confrelid
),
get_rel_name
(
con
->
confrelid
),
NameStr
(
con
->
conname
)),
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
))));
get_rel_name
(
con
->
conrelid
))));
}
}
}
}
...
@@ -2074,3 +2075,58 @@ heap_truncate_check_FKs(List *relations, bool tempTables)
...
@@ -2074,3 +2075,58 @@ heap_truncate_check_FKs(List *relations, bool tempTables)
systable_endscan
(
fkeyScan
);
systable_endscan
(
fkeyScan
);
heap_close
(
fkeyRel
,
AccessShareLock
);
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
;
}
src/backend/commands/tablecmds.c
View file @
984a6ced
...
@@ -8,7 +8,7 @@
...
@@ -8,7 +8,7 @@
*
*
*
*
* IDENTIFICATION
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/commands/tablecmds.c,v 1.17
7 2006/01/30 16:18:58
tgl Exp $
* $PostgreSQL: pgsql/src/backend/commands/tablecmds.c,v 1.17
8 2006/03/03 03:30:52
tgl Exp $
*
*
*-------------------------------------------------------------------------
*-------------------------------------------------------------------------
*/
*/
...
@@ -527,26 +527,79 @@ RemoveRelation(const RangeVar *relation, DropBehavior behavior)
...
@@ -527,26 +527,79 @@ RemoveRelation(const RangeVar *relation, DropBehavior behavior)
* ExecuteTruncate
* ExecuteTruncate
* Executes a TRUNCATE command.
* Executes a TRUNCATE command.
*
*
* This is a multi-relation truncate. It first opens and grabs exclusive
* This is a multi-relation truncate. We first open and grab exclusive
* locks on all relations involved, checking permissions and otherwise
* lock on all relations involved, checking permissions and otherwise
* verifying that the relation is OK for truncation. When they are all
* verifying that the relation is OK for truncation. In CASCADE mode,
* open, it checks foreign key references on them, namely that FK references
* relations having FK references to the targeted relations are automatically
* are all internal to the group that's being truncated. Finally all
* added to the group; in RESTRICT mode, we check that all FK references are
* relations are truncated and reindexed.
* internal to the group that's being truncated. Finally all the relations
* are truncated and reindexed.
*/
*/
void
void
ExecuteTruncate
(
List
*
relations
)
ExecuteTruncate
(
TruncateStmt
*
stmt
)
{
{
List
*
rels
=
NIL
;
List
*
rels
=
NIL
;
List
*
directRelids
=
NIL
;
ListCell
*
cell
;
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
);
RangeVar
*
rv
=
lfirst
(
cell
);
Relation
rel
;
/* Grab exclusive lock in preparation for truncate */
rel
=
heap_openrv
(
rv
,
AccessExclusiveLock
);
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 */
/* Only allow truncate on regular tables */
if
(
rel
->
rd_rel
->
relkind
!=
RELKIND_RELATION
)
if
(
rel
->
rd_rel
->
relkind
!=
RELKIND_RELATION
)
...
@@ -585,25 +638,30 @@ ExecuteTruncate(List *relations)
...
@@ -585,25 +638,30 @@ ExecuteTruncate(List *relations)
ereport
(
ERROR
,
ereport
(
ERROR
,
(
errcode
(
ERRCODE_FEATURE_NOT_SUPPORTED
),
(
errcode
(
ERRCODE_FEATURE_NOT_SUPPORTED
),
errmsg
(
"cannot truncate temporary tables of other sessions"
)));
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
);
heap_truncate_check_FKs
(
rels
,
false
);
#else
if
(
stmt
->
behavior
==
DROP_RESTRICT
)
heap_truncate_check_FKs
(
rels
,
false
);
#endif
/*
/*
* OK, truncate each table.
* OK, truncate each table.
*/
*/
foreach
(
cell
,
rels
)
foreach
(
cell
,
rels
)
{
{
Relation
rel
=
lfirst
(
cell
);
Oid
heap_relid
;
Oid
heap_relid
;
Oid
toast_relid
;
Oid
toast_relid
;
rel
=
(
Relation
)
lfirst
(
cell
);
/*
/*
* Create a new empty storage file for the relation, and assign it as
* Create a new empty storage file for the relation, and assign it as
* the relfilenode value. The old storage file is scheduled for
* the relfilenode value. The old storage file is scheduled for
...
...
src/backend/nodes/copyfuncs.c
View file @
984a6ced
...
@@ -15,7 +15,7 @@
...
@@ -15,7 +15,7 @@
* Portions Copyright (c) 1994, Regents of the University of California
* Portions Copyright (c) 1994, Regents of the University of California
*
*
* IDENTIFICATION
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.32
7 2006/02/19 00:04:26 neilc
Exp $
* $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.32
8 2006/03/03 03:30:52 tgl
Exp $
*
*
*-------------------------------------------------------------------------
*-------------------------------------------------------------------------
*/
*/
...
@@ -1961,6 +1961,7 @@ _copyTruncateStmt(TruncateStmt *from)
...
@@ -1961,6 +1961,7 @@ _copyTruncateStmt(TruncateStmt *from)
TruncateStmt
*
newnode
=
makeNode
(
TruncateStmt
);
TruncateStmt
*
newnode
=
makeNode
(
TruncateStmt
);
COPY_NODE_FIELD
(
relations
);
COPY_NODE_FIELD
(
relations
);
COPY_SCALAR_FIELD
(
behavior
);
return
newnode
;
return
newnode
;
}
}
...
...
src/backend/nodes/equalfuncs.c
View file @
984a6ced
...
@@ -18,7 +18,7 @@
...
@@ -18,7 +18,7 @@
* Portions Copyright (c) 1994, Regents of the University of California
* Portions Copyright (c) 1994, Regents of the University of California
*
*
* IDENTIFICATION
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/equalfuncs.c,v 1.26
3 2006/02/19 00:04:26 neilc
Exp $
* $PostgreSQL: pgsql/src/backend/nodes/equalfuncs.c,v 1.26
4 2006/03/03 03:30:52 tgl
Exp $
*
*
*-------------------------------------------------------------------------
*-------------------------------------------------------------------------
*/
*/
...
@@ -930,6 +930,7 @@ static bool
...
@@ -930,6 +930,7 @@ static bool
_equalTruncateStmt
(
TruncateStmt
*
a
,
TruncateStmt
*
b
)
_equalTruncateStmt
(
TruncateStmt
*
a
,
TruncateStmt
*
b
)
{
{
COMPARE_NODE_FIELD
(
relations
);
COMPARE_NODE_FIELD
(
relations
);
COMPARE_SCALAR_FIELD
(
behavior
);
return
true
;
return
true
;
}
}
...
...
src/backend/parser/gram.y
View file @
984a6ced
...
@@ -11,7 +11,7 @@
...
@@ -11,7 +11,7 @@
*
*
*
*
* IDENTIFICATION
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.53
1 2006/02/28 22:37:26
tgl Exp $
* $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.53
2 2006/03/03 03:30:53
tgl Exp $
*
*
* HISTORY
* HISTORY
* AUTHOR DATE MAJOR EVENT
* AUTHOR DATE MAJOR EVENT
...
@@ -2938,10 +2938,11 @@ attrs: '.' attr_name
...
@@ -2938,10 +2938,11 @@ attrs: '.' attr_name
*****************************************************************************/
*****************************************************************************/
TruncateStmt:
TruncateStmt:
TRUNCATE opt_table qualified_name_list
TRUNCATE opt_table qualified_name_list
opt_drop_behavior
{
{
TruncateStmt *n = makeNode(TruncateStmt);
TruncateStmt *n = makeNode(TruncateStmt);
n->relations = $3;
n->relations = $3;
n->behavior = $4;
$$ = (Node *)n;
$$ = (Node *)n;
}
}
;
;
...
...
src/backend/tcop/utility.c
View file @
984a6ced
...
@@ -10,7 +10,7 @@
...
@@ -10,7 +10,7 @@
*
*
*
*
* IDENTIFICATION
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/tcop/utility.c,v 1.25
2 2006/02/12 19:11:01 momjian
Exp $
* $PostgreSQL: pgsql/src/backend/tcop/utility.c,v 1.25
3 2006/03/03 03:30:53 tgl
Exp $
*
*
*-------------------------------------------------------------------------
*-------------------------------------------------------------------------
*/
*/
...
@@ -628,11 +628,7 @@ ProcessUtility(Node *parsetree,
...
@@ -628,11 +628,7 @@ ProcessUtility(Node *parsetree,
break
;
break
;
case
T_TruncateStmt
:
case
T_TruncateStmt
:
{
ExecuteTruncate
((
TruncateStmt
*
)
parsetree
);
TruncateStmt
*
stmt
=
(
TruncateStmt
*
)
parsetree
;
ExecuteTruncate
(
stmt
->
relations
);
}
break
;
break
;
case
T_CommentStmt
:
case
T_CommentStmt
:
...
...
src/include/catalog/heap.h
View file @
984a6ced
...
@@ -7,7 +7,7 @@
...
@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
* Portions Copyright (c) 1994, Regents of the University of California
*
*
* $PostgreSQL: pgsql/src/include/catalog/heap.h,v 1.7
6 2005/10/15 02:49:42 momjian
Exp $
* $PostgreSQL: pgsql/src/include/catalog/heap.h,v 1.7
7 2006/03/03 03:30:53 tgl
Exp $
*
*
*-------------------------------------------------------------------------
*-------------------------------------------------------------------------
*/
*/
...
@@ -62,6 +62,8 @@ extern void heap_truncate(List *relids);
...
@@ -62,6 +62,8 @@ extern void heap_truncate(List *relids);
extern
void
heap_truncate_check_FKs
(
List
*
relations
,
bool
tempTables
);
extern
void
heap_truncate_check_FKs
(
List
*
relations
,
bool
tempTables
);
extern
List
*
heap_truncate_find_FKs
(
List
*
relationIds
);
extern
List
*
AddRelationRawConstraints
(
Relation
rel
,
extern
List
*
AddRelationRawConstraints
(
Relation
rel
,
List
*
rawColDefaults
,
List
*
rawColDefaults
,
List
*
rawConstraints
);
List
*
rawConstraints
);
...
...
src/include/commands/tablecmds.h
View file @
984a6ced
...
@@ -7,7 +7,7 @@
...
@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
* Portions Copyright (c) 1994, Regents of the University of California
*
*
* $PostgreSQL: pgsql/src/include/commands/tablecmds.h,v 1.2
5 2005/11/21 12:49:32 alvherre
Exp $
* $PostgreSQL: pgsql/src/include/commands/tablecmds.h,v 1.2
6 2006/03/03 03:30:53 tgl
Exp $
*
*
*-------------------------------------------------------------------------
*-------------------------------------------------------------------------
*/
*/
...
@@ -36,7 +36,7 @@ extern void AlterRelationNamespaceInternal(Relation classRel, Oid relOid,
...
@@ -36,7 +36,7 @@ extern void AlterRelationNamespaceInternal(Relation classRel, Oid relOid,
Oid
oldNspOid
,
Oid
newNspOid
,
Oid
oldNspOid
,
Oid
newNspOid
,
bool
hasDependEntry
);
bool
hasDependEntry
);
extern
void
ExecuteTruncate
(
List
*
relations
);
extern
void
ExecuteTruncate
(
TruncateStmt
*
stmt
);
extern
void
renameatt
(
Oid
myrelid
,
extern
void
renameatt
(
Oid
myrelid
,
const
char
*
oldattname
,
const
char
*
oldattname
,
...
...
src/include/nodes/parsenodes.h
View file @
984a6ced
...
@@ -7,7 +7,7 @@
...
@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
* Portions Copyright (c) 1994, Regents of the University of California
*
*
* $PostgreSQL: pgsql/src/include/nodes/parsenodes.h,v 1.30
1 2006/02/19 00:04:27 neilc
Exp $
* $PostgreSQL: pgsql/src/include/nodes/parsenodes.h,v 1.30
2 2006/03/03 03:30:53 tgl
Exp $
*
*
*-------------------------------------------------------------------------
*-------------------------------------------------------------------------
*/
*/
...
@@ -1314,6 +1314,7 @@ typedef struct TruncateStmt
...
@@ -1314,6 +1314,7 @@ typedef struct TruncateStmt
{
{
NodeTag
type
;
NodeTag
type
;
List
*
relations
;
/* relations (RangeVars) to be truncated */
List
*
relations
;
/* relations (RangeVars) to be truncated */
DropBehavior
behavior
;
/* RESTRICT or CASCADE behavior */
}
TruncateStmt
;
}
TruncateStmt
;
/* ----------------------
/* ----------------------
...
...
src/test/regress/expected/truncate.out
View file @
984a6ced
...
@@ -40,30 +40,37 @@ CREATE TABLE trunc_e (a int REFERENCES truncate_a, b int REFERENCES trunc_c);
...
@@ -40,30 +40,37 @@ CREATE TABLE trunc_e (a int REFERENCES truncate_a, b int REFERENCES trunc_c);
TRUNCATE TABLE truncate_a; -- fail
TRUNCATE TABLE truncate_a; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
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".
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
TRUNCATE TABLE truncate_a,trunc_b; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
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".
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_b,trunc_e; -- ok
TRUNCATE TABLE truncate_a,trunc_e; -- fail
TRUNCATE TABLE truncate_a,trunc_e; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
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".
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
TRUNCATE TABLE trunc_c; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
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".
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
TRUNCATE TABLE trunc_c,trunc_d; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
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".
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; -- ok
TRUNCATE TABLE trunc_c,trunc_d,trunc_e,truncate_a; -- fail
TRUNCATE TABLE trunc_c,trunc_d,trunc_e,truncate_a; -- fail
ERROR: cannot truncate a table referenced in a foreign key constraint
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".
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 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
-- circular references
ALTER TABLE truncate_a ADD FOREIGN KEY (col1) REFERENCES trunc_c;
ALTER TABLE truncate_a ADD FOREIGN KEY (col1) REFERENCES trunc_c;
-- Add some data to verify that truncating actually works ...
-- Add some data to verify that truncating actually works ...
...
@@ -75,19 +82,19 @@ INSERT INTO trunc_e VALUES (1,1);
...
@@ -75,19 +82,19 @@ INSERT INTO trunc_e VALUES (1,1);
TRUNCATE TABLE trunc_c;
TRUNCATE TABLE trunc_c;
ERROR: cannot truncate a table referenced in a foreign key constraint
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".
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;
TRUNCATE TABLE trunc_c,trunc_d;
ERROR: cannot truncate a table referenced in a foreign key constraint
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".
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;
TRUNCATE TABLE trunc_c,trunc_d,trunc_e;
ERROR: cannot truncate a table referenced in a foreign key constraint
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".
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;
TRUNCATE TABLE trunc_c,trunc_d,trunc_e,truncate_a;
ERROR: cannot truncate a table referenced in a foreign key constraint
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".
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;
TRUNCATE TABLE trunc_c,trunc_d,trunc_e,truncate_a,trunc_b;
-- Verify that truncating did actually work
-- Verify that truncating did actually work
SELECT * FROM truncate_a
SELECT * FROM truncate_a
...
@@ -106,6 +113,33 @@ SELECT * FROM trunc_e;
...
@@ -106,6 +113,33 @@ SELECT * FROM trunc_e;
---+---
---+---
(0 rows)
(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;
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_e_a_fkey on table trunc_e
NOTICE: drop cascades to constraint trunc_b_a_fkey on table trunc_b
NOTICE: drop cascades to constraint trunc_b_a_fkey on table trunc_b
...
...
src/test/regress/sql/truncate.sql
View file @
984a6ced
...
@@ -30,6 +30,9 @@ TRUNCATE TABLE trunc_c,trunc_d,trunc_e; -- ok
...
@@ -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
;
-- fail
TRUNCATE
TABLE
trunc_c
,
trunc_d
,
trunc_e
,
truncate_a
,
trunc_b
;
-- ok
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
-- circular references
ALTER
TABLE
truncate_a
ADD
FOREIGN
KEY
(
col1
)
REFERENCES
trunc_c
;
ALTER
TABLE
truncate_a
ADD
FOREIGN
KEY
(
col1
)
REFERENCES
trunc_c
;
...
@@ -55,4 +58,22 @@ SELECT * FROM truncate_a
...
@@ -55,4 +58,22 @@ SELECT * FROM truncate_a
SELECT
*
FROM
trunc_d
;
SELECT
*
FROM
trunc_d
;
SELECT
*
FROM
trunc_e
;
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
;
DROP
TABLE
truncate_a
,
trunc_c
,
trunc_b
,
trunc_d
,
trunc_e
CASCADE
;
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment