mirror of
https://github.com/postgres/postgres.git
synced 2025-12-19 17:02:53 +03:00
Foreign tables can now be inheritance children, or parents. Much of the system was already ready for this, but we had to fix a few things of course, mostly in the area of planner and executor handling of row locks. As side effects of this, allow foreign tables to have NOT VALID CHECK constraints (and hence to accept ALTER ... VALIDATE CONSTRAINT), and to accept ALTER SET STORAGE and ALTER SET WITH/WITHOUT OIDS. Continuing to disallow these things would've required bizarre and inconsistent special cases in inheritance behavior. Since foreign tables don't enforce CHECK constraints anyway, a NOT VALID one is a complete no-op, but that doesn't mean we shouldn't allow it. And it's possible that some FDWs might have use for SET STORAGE or SET WITH OIDS, though doubtless they will be no-ops for most. An additional change in support of this is that when a ModifyTable node has multiple target tables, they will all now be explicitly identified in EXPLAIN output, for example: Update on pt1 (cost=0.00..321.05 rows=3541 width=46) Update on pt1 Foreign Update on ft1 Foreign Update on ft2 Update on child3 -> Seq Scan on pt1 (cost=0.00..0.00 rows=1 width=46) -> Foreign Scan on ft1 (cost=100.00..148.03 rows=1170 width=46) -> Foreign Scan on ft2 (cost=100.00..148.03 rows=1170 width=46) -> Seq Scan on child3 (cost=0.00..25.00 rows=1200 width=46) This was done mainly to provide an unambiguous place to attach "Remote SQL" fields, but it is useful for inherited updates even when no foreign tables are involved. Shigeru Hanada and Etsuro Fujita, reviewed by Ashutosh Bapat and Kyotaro Horiguchi, some additional hacking by me
235 lines
7.9 KiB
Plaintext
235 lines
7.9 KiB
Plaintext
<!--
|
|
doc/src/sgml/ref/truncate.sgml
|
|
PostgreSQL documentation
|
|
-->
|
|
|
|
<refentry id="SQL-TRUNCATE">
|
|
<indexterm zone="sql-truncate">
|
|
<primary>TRUNCATE</primary>
|
|
</indexterm>
|
|
|
|
<refmeta>
|
|
<refentrytitle>TRUNCATE</refentrytitle>
|
|
<manvolnum>7</manvolnum>
|
|
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
|
</refmeta>
|
|
|
|
<refnamediv>
|
|
<refname>TRUNCATE</refname>
|
|
<refpurpose>empty a table or set of tables</refpurpose>
|
|
</refnamediv>
|
|
|
|
<refsynopsisdiv>
|
|
<synopsis>
|
|
TRUNCATE [ TABLE ] [ ONLY ] <replaceable class="PARAMETER">name</replaceable> [ * ] [, ... ]
|
|
[ RESTART IDENTITY | CONTINUE IDENTITY ] [ CASCADE | RESTRICT ]
|
|
</synopsis>
|
|
</refsynopsisdiv>
|
|
|
|
<refsect1>
|
|
<title>Description</title>
|
|
|
|
<para>
|
|
<command>TRUNCATE</command> quickly removes all rows from a set of
|
|
tables. It has the same effect as an unqualified
|
|
<command>DELETE</command> on each table, but since it does not actually
|
|
scan the tables it is faster. Furthermore, it reclaims disk space
|
|
immediately, rather than requiring a subsequent <command>VACUUM</command>
|
|
operation. This is most useful on large tables.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Parameters</title>
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name (optionally schema-qualified) of a table to truncate.
|
|
If <literal>ONLY</> is specified before the table name, only that table
|
|
is truncated. If <literal>ONLY</> is not specified, the table and all
|
|
its descendant tables (if any) are truncated. Optionally, <literal>*</>
|
|
can be specified after the table name to explicitly indicate that
|
|
descendant tables are included.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>RESTART IDENTITY</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Automatically restart sequences owned by columns of
|
|
the truncated table(s).
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>CONTINUE IDENTITY</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Do not change the values of sequences. This is the default.
|
|
</para>
|
|
</listitem>
|
|
</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 listed in the command. This is the default.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Notes</title>
|
|
|
|
<para>
|
|
You must have the <literal>TRUNCATE</literal> privilege on a table
|
|
to truncate it.
|
|
</para>
|
|
|
|
<para>
|
|
<command>TRUNCATE</> acquires an <literal>ACCESS EXCLUSIVE</> lock on each
|
|
table it operates on, which blocks all other concurrent operations
|
|
on the table. When <literal>RESTART IDENTITY</> is specified, any
|
|
sequences that are to be restarted are likewise locked exclusively.
|
|
If concurrent access to a table is required, then
|
|
the <command>DELETE</> command should be used instead.
|
|
</para>
|
|
|
|
<para>
|
|
<command>TRUNCATE</> cannot be used on a table that has foreign-key
|
|
references from other tables, unless all such tables are also truncated
|
|
in the same command. Checking validity in such cases would require table
|
|
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, or else you might lose data you
|
|
did not intend to!
|
|
</para>
|
|
|
|
<para>
|
|
<command>TRUNCATE</> will not fire any <literal>ON DELETE</literal>
|
|
triggers that might exist for the tables. But it will fire
|
|
<literal>ON TRUNCATE</literal> triggers.
|
|
If <literal>ON TRUNCATE</> triggers are defined for any of
|
|
the tables, then all <literal>BEFORE TRUNCATE</literal> triggers are
|
|
fired before any truncation happens, and all <literal>AFTER
|
|
TRUNCATE</literal> triggers are fired after the last truncation is
|
|
performed and any sequences are reset.
|
|
The triggers will fire in the order that the tables are
|
|
to be processed (first those listed in the command, and then any
|
|
that were added due to cascading).
|
|
</para>
|
|
|
|
<warning>
|
|
<para>
|
|
<command>TRUNCATE</> is not MVCC-safe (see <xref linkend="mvcc">
|
|
for general information about MVCC). After truncation, the table
|
|
will appear empty to all concurrent transactions, even if they
|
|
are using a snapshot taken before the truncation occurred. This
|
|
will only be an issue for a transaction that did not access the
|
|
truncated table before the truncation happened — any
|
|
transaction that has done so would hold at least an
|
|
<literal>ACCESS SHARE</literal> lock, which would block
|
|
<command>TRUNCATE</> until that transaction completes. So
|
|
truncation will not cause any apparent inconsistency in the table
|
|
contents for successive queries on the same table, but it could
|
|
cause visible inconsistency between the contents of the truncated
|
|
table and other tables in the database.
|
|
</para>
|
|
</warning>
|
|
|
|
<para>
|
|
<command>TRUNCATE</> is transaction-safe with respect to the data
|
|
in the tables: the truncation will be safely rolled back if the surrounding
|
|
transaction does not commit.
|
|
</para>
|
|
|
|
<para>
|
|
When <literal>RESTART IDENTITY</> is specified, the implied
|
|
<command>ALTER SEQUENCE RESTART</> operations are also done
|
|
transactionally; that is, they will be rolled back if the surrounding
|
|
transaction does not commit. This is unlike the normal behavior of
|
|
<command>ALTER SEQUENCE RESTART</>. Be aware that if any additional
|
|
sequence operations are done on the restarted sequences before the
|
|
transaction rolls back, the effects of these operations on the sequences
|
|
will be rolled back, but not their effects on <function>currval()</>;
|
|
that is, after the transaction <function>currval()</> will continue to
|
|
reflect the last sequence value obtained inside the failed transaction,
|
|
even though the sequence itself may no longer be consistent with that.
|
|
This is similar to the usual behavior of <function>currval()</> after
|
|
a failed transaction.
|
|
</para>
|
|
|
|
<para>
|
|
<command>TRUNCATE</> is not currently supported for foreign tables.
|
|
This implies that if a specified table has any descendant tables that are
|
|
foreign, the command will fail.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Examples</title>
|
|
|
|
<para>
|
|
Truncate the tables <literal>bigtable</literal> and
|
|
<literal>fattable</literal>:
|
|
|
|
<programlisting>
|
|
TRUNCATE bigtable, fattable;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The same, and also reset any associated sequence generators:
|
|
|
|
<programlisting>
|
|
TRUNCATE bigtable, fattable RESTART IDENTITY;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Truncate the table <literal>othertable</literal>, and cascade to any tables
|
|
that reference <literal>othertable</literal> via foreign-key
|
|
constraints:
|
|
|
|
<programlisting>
|
|
TRUNCATE othertable CASCADE;
|
|
</programlisting></para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Compatibility</title>
|
|
|
|
<para>
|
|
The SQL:2008 standard includes a <command>TRUNCATE</command> command
|
|
with the syntax <literal>TRUNCATE TABLE
|
|
<replaceable>tablename</replaceable></literal>. The clauses
|
|
<literal>CONTINUE IDENTITY</literal>/<literal>RESTART IDENTITY</literal>
|
|
also appear in that standard, but have slightly different though related
|
|
meanings. Some of the concurrency behavior of this command is left
|
|
implementation-defined by the standard, so the above notes should be
|
|
considered and compared with other implementations if necessary.
|
|
</para>
|
|
</refsect1>
|
|
</refentry>
|