1
0
mirror of https://github.com/postgres/postgres.git synced 2025-06-27 23:21:58 +03:00

doc: Explain more thoroughly when a table rewrite is needed

Author: Masahiro Ikeda <ikedamsh@oss.nttdata.com>
Reviewed-by: Robert Treat <rob@xzilla.net>
Discussion: https://postgr.es/m/00e6eb5f5c793b8ef722252c7a519c9a@oss.nttdata.com
This commit is contained in:
Álvaro Herrera
2025-03-14 20:44:59 +01:00
parent 1c9242b2cd
commit 11bd831860
2 changed files with 29 additions and 25 deletions

View File

@ -1650,17 +1650,15 @@ ALTER TABLE products ADD COLUMN description text;
<tip>
<para>
From <productname>PostgreSQL</productname> 11, adding a column with
a constant default value no longer means that each row of the table
needs to be updated when the <command>ALTER TABLE</command> statement
Adding a column with a constant default value does not require each row of
the table to be updated when the <command>ALTER TABLE</command> statement
is executed. Instead, the default value will be returned the next time
the row is accessed, and applied when the table is rewritten, making
the <command>ALTER TABLE</command> very fast even on large tables.
</para>
<para>
However, if the default value is volatile (e.g.,
<function>clock_timestamp()</function>)
If the default value is volatile (e.g., <function>clock_timestamp()</function>)
each row will need to be updated with the value calculated at the time
<command>ALTER TABLE</command> is executed. To avoid a potentially
lengthy update operation, particularly if you intend to fill the column

View File

@ -1421,30 +1421,36 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<para>
When a column is added with <literal>ADD COLUMN</literal> and a
non-volatile <literal>DEFAULT</literal> is specified, the default is
non-volatile <literal>DEFAULT</literal> is specified, the default value is
evaluated at the time of the statement and the result stored in the
table's metadata. That value will be used for the column for all existing
rows. If no <literal>DEFAULT</literal> is specified, NULL is used. In
neither case is a rewrite of the table required.
table's metadata, where it will be returned when any existing rows are
accessed. The value will be only applied when the table is rewritten,
making the <command>ALTER TABLE</command> very fast even on large tables.
If no column constraints are specified, NULL is used as the
<literal>DEFAULT</literal>. In neither case is a rewrite of the table
required.
</para>
<para>
Adding a column with a volatile <literal>DEFAULT</literal> or
changing the type of an existing column will require the entire table and
its indexes to be rewritten. As an exception, when changing the type of an
existing column, if the <literal>USING</literal> clause does not change
the column contents and the old type is either binary coercible to the new
type or an unconstrained domain over the new type, a table rewrite is not
needed. However, indexes must always be rebuilt unless the system can
verify that the new index would be logically equivalent to the existing
one. For example, if the collation for a column has been changed, an index
rebuild is always required because the new sort order might be different.
However, in the absence of a collation change, a column can be changed
from <type>text</type> to <type>varchar</type> (or vice versa) without
rebuilding the indexes because these data types sort identically.
Table and/or index rebuilds may take a
significant amount of time for a large table; and will temporarily require
as much as double the disk space.
Adding a column with a volatile <literal>DEFAULT</literal>
(e.g., <function>clock_timestamp()</function>), a generated column
(e.g., <literal>GENERATED BY DEFAULT AS IDENTITY</literal>), a domain
data type with constraints will require the entire table and its
indexes to be rewritten, as will changing the type of an existing
column. As an exception, when changing the type of an existing column,
if the <literal>USING</literal> clause does not change the column
contents and the old type is either binary coercible to the new type
or an unconstrained domain over the new type, a table rewrite is not
needed. However, indexes must always be rebuilt unless the system
can verify that the new index would be logically equivalent to the
existing one. For example, if the collation for a column has been
changed, an index rebuild is required because the new sort
order might be different. However, in the absence of a collation
change, a column can be changed from <type>text</type> to
<type>varchar</type> (or vice versa) without rebuilding the indexes
because these data types sort identically. Table and/or index
rebuilds may take a significant amount of time for a large table,
and will temporarily require as much as double the disk space.
</para>
<para>