mirror of
https://git.postgresql.org/git/postgresql.git
synced 2025-01-12 18:34:36 +08:00
Documentation fixes for FILLFACTOR patch. Minor other editorialization.
This commit is contained in:
parent
655787bfaf
commit
2d0c1d3102
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/alter_index.sgml,v 1.9 2006/07/02 02:23:17 momjian Exp $
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/alter_index.sgml,v 1.10 2006/07/04 18:07:24 tgl Exp $
|
||||
PostgreSQL documentation
|
||||
-->
|
||||
|
||||
@ -22,8 +22,8 @@ PostgreSQL documentation
|
||||
<synopsis>
|
||||
ALTER INDEX <replaceable class="PARAMETER">name</replaceable> RENAME TO <replaceable class="PARAMETER">new_name</replaceable>
|
||||
ALTER INDEX <replaceable class="PARAMETER">name</replaceable> SET TABLESPACE <replaceable class="PARAMETER">tablespace_name</replaceable>
|
||||
ALTER INDEX <replaceable class="PARAMETER">name</replaceable> SET (FILLFACTOR = <replaceable class="PARAMETER">fillfactor</replaceable>)
|
||||
ALTER INDEX <replaceable class="PARAMETER">name</replaceable> RESET (FILLFACTOR)
|
||||
ALTER INDEX <replaceable class="PARAMETER">name</replaceable> SET ( <replaceable class="PARAMETER">storage_parameter</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )
|
||||
ALTER INDEX <replaceable class="PARAMETER">name</replaceable> RESET ( <replaceable class="PARAMETER">storage_parameter</replaceable> [, ... ] )
|
||||
</synopsis>
|
||||
</refsynopsisdiv>
|
||||
|
||||
@ -59,21 +59,28 @@ ALTER INDEX <replaceable class="PARAMETER">name</replaceable> RESET (FILLFACTOR)
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>SET (FILLFACTOR)</literal></term>
|
||||
<term><literal>SET ( <replaceable class="PARAMETER">storage_parameter</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This form changes the index's fillfactor to the specified percentage.
|
||||
Index structure is not modified immediately; use <literal>REINDEX</literal>
|
||||
to ensure reflection of the change.
|
||||
This form changes one or more index-method-specific storage parameters
|
||||
for the index. See
|
||||
<xref linkend="SQL-CREATEINDEX" endterm="sql-createindex-title">
|
||||
for details on the available parameters. Note that the index contents
|
||||
will not be modified immediately by this command; depending on the
|
||||
parameter you may need to rebuild the index with
|
||||
<xref linkend="SQL-REINDEX" endterm="sql-reindex-title">
|
||||
to get the desired effects.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>RESET (FILLFACTOR)</literal></term>
|
||||
<term><literal>RESET ( <replaceable class="PARAMETER">storage_parameter</replaceable> [, ... ] )</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This form changes the index's fillfactor to the default value.
|
||||
This form resets one or more index-method-specific storage parameters to
|
||||
their defaults. As with <literal>SET</>, a <literal>REINDEX</literal>
|
||||
may be needed to update the index entirely.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
@ -116,6 +123,25 @@ ALTER INDEX <replaceable class="PARAMETER">name</replaceable> RESET (FILLFACTOR)
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="PARAMETER">storage_parameter</replaceable></term>
|
||||
<listitem>
|
||||
<para>
|
||||
The name of an index-method-specific storage parameter.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="PARAMETER">value</replaceable></term>
|
||||
<listitem>
|
||||
<para>
|
||||
The new value for an index-method-specific storage parameter.
|
||||
This might be a number or a word depending on the parameter.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
</variablelist>
|
||||
</refsect1>
|
||||
|
||||
@ -154,6 +180,15 @@ ALTER INDEX distributors RENAME TO suppliers;
|
||||
To move an index to a different tablespace:
|
||||
<programlisting>
|
||||
ALTER INDEX distributors SET TABLESPACE fasttablespace;
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To change an index's fill factor (assuming that the index method
|
||||
supports it):
|
||||
<programlisting>
|
||||
ALTER INDEX distributors SET (fillfactor = 75);
|
||||
REINDEX INDEX distributors;
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
@ -167,6 +202,16 @@ ALTER INDEX distributors SET TABLESPACE fasttablespace;
|
||||
extension.
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
|
||||
<refsect1>
|
||||
<title>See Also</title>
|
||||
|
||||
<simplelist type="inline">
|
||||
<member><xref linkend="sql-createindex" endterm="sql-createindex-title"></member>
|
||||
<member><xref linkend="sql-reindex" endterm="sql-reindex-title"></member>
|
||||
</simplelist>
|
||||
</refsect1>
|
||||
</refentry>
|
||||
|
||||
<!-- Keep this comment at the end of the file
|
||||
|
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/alter_table.sgml,v 1.86 2006/07/02 02:23:17 momjian Exp $
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/alter_table.sgml,v 1.87 2006/07/04 18:07:24 tgl Exp $
|
||||
PostgreSQL documentation
|
||||
-->
|
||||
|
||||
@ -46,8 +46,8 @@ where <replaceable class="PARAMETER">action</replaceable> is one of:
|
||||
CLUSTER ON <replaceable class="PARAMETER">index_name</replaceable>
|
||||
SET WITHOUT CLUSTER
|
||||
SET WITHOUT OIDS
|
||||
SET (FILLFACTOR = <replaceable class="PARAMETER">fillfactor</replaceable>)
|
||||
RESET (FILLFACTOR)
|
||||
SET ( <replaceable class="PARAMETER">storage_parameter</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )
|
||||
RESET ( <replaceable class="PARAMETER">storage_parameter</replaceable> [, ... ] )
|
||||
INHERIT <replaceable class="PARAMETER">parent_table</replaceable>
|
||||
NO INHERIT <replaceable class="PARAMETER">parent_table</replaceable>
|
||||
OWNER TO <replaceable class="PARAMETER">new_owner</replaceable>
|
||||
@ -253,38 +253,70 @@ where <replaceable class="PARAMETER">action</replaceable> is one of:
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>SET ( <replaceable class="PARAMETER">storage_parameter</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This form changes one or more storage parameters for the table. See
|
||||
<xref linkend="SQL-CREATETABLE" endterm="sql-createtable-title">
|
||||
for details on the available parameters. Note that the table contents
|
||||
will not be modified immediately by this command; depending on the
|
||||
parameter you may need to rewrite the table to get the desired effects.
|
||||
That can be done with <xref linkend="SQL-CLUSTER"
|
||||
endterm="sql-cluster-title"> or one of the forms of <command>ALTER
|
||||
TABLE</> that forces a table rewrite.
|
||||
</para>
|
||||
|
||||
<note>
|
||||
<para>
|
||||
While <command>CREATE TABLE</> allows <literal>OIDS</> to be specified
|
||||
in the <literal>WITH (<replaceable
|
||||
class="PARAMETER">storage_parameter</>)</literal> syntax,
|
||||
<command>ALTER TABLE</> does not treat <literal>OIDS</> as a
|
||||
storage parameter.
|
||||
</para>
|
||||
</note>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>RESET ( <replaceable class="PARAMETER">storage_parameter</replaceable> [, ... ] )</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This form resets one or more storage parameters to their
|
||||
defaults. As with <literal>SET</>, a table rewrite may be
|
||||
needed to update the table entirely.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>INHERIT <replaceable class="PARAMETER">parent_table</replaceable></literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
|
||||
This form adds a new parent table to the table. This won't add new
|
||||
columns to the child table, instead all columns of the parent table must
|
||||
already exist in the child table. They must have matching data types,
|
||||
and if they have <literal>NOT NULL</literal> constraints in the parent
|
||||
then they must also have <literal>NOT NULL</literal> constraints in the
|
||||
child.
|
||||
</para>
|
||||
|
||||
</para>
|
||||
<para>
|
||||
|
||||
<para>
|
||||
There must also be matching table constraints for all
|
||||
<literal>CHECK</literal> table constraints of the parent. Currently
|
||||
<literal>UNIQUE</literal>, <literal>PRIMARY KEY</literal>, and
|
||||
<literal>FOREIGN KEY</literal> constraints are ignored however this may
|
||||
change in the future.
|
||||
</para>
|
||||
|
||||
</para>
|
||||
<para>
|
||||
|
||||
<para>
|
||||
The easiest way to create a suitable table is to create a table using
|
||||
<literal>INHERITS</literal> and then remove it via <literal>NO
|
||||
INHERIT</literal>. Alternatively create a table using
|
||||
<literal>LIKE</literal> however note that <literal>LIKE</literal> does
|
||||
not create the necessary constraints.
|
||||
|
||||
</para>
|
||||
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
@ -292,9 +324,9 @@ where <replaceable class="PARAMETER">action</replaceable> is one of:
|
||||
<term><literal>NO INHERIT <replaceable class="PARAMETER">parent_table</replaceable></literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This form removes a parent table from the list of parents of the table.
|
||||
Queries against the parent table will no longer include records drawn
|
||||
from the target table.
|
||||
This form removes a parent table from the list of parents of the table.
|
||||
Queries against the parent table will no longer include records drawn
|
||||
from the target table.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
@ -323,26 +355,6 @@ where <replaceable class="PARAMETER">action</replaceable> is one of:
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>SET (FILLFACTOR)</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This form changes the table's fillfactor to the specified percentage.
|
||||
Table structure is not modified immediately; use <literal>CLUSTER</literal>
|
||||
to ensure reflection of the change.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>RESET</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This form changes the table's fillfactor to the default value.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>RENAME</literal></term>
|
||||
<listitem>
|
||||
@ -524,6 +536,34 @@ where <replaceable class="PARAMETER">action</replaceable> is one of:
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="PARAMETER">storage_parameter</replaceable></term>
|
||||
<listitem>
|
||||
<para>
|
||||
The name of a table storage parameter.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="PARAMETER">value</replaceable></term>
|
||||
<listitem>
|
||||
<para>
|
||||
The new value for a table storage parameter.
|
||||
This might be a number or a word depending on the parameter.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="PARAMETER">parent_table</replaceable></term>
|
||||
<listitem>
|
||||
<para>
|
||||
A parent table to associate or de-associate with this table.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="PARAMETER">new_owner</replaceable></term>
|
||||
<listitem>
|
||||
|
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/create_index.sgml,v 1.53 2006/07/02 02:23:17 momjian Exp $
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/create_index.sgml,v 1.54 2006/07/04 18:07:24 tgl Exp $
|
||||
PostgreSQL documentation
|
||||
-->
|
||||
|
||||
@ -22,7 +22,7 @@ PostgreSQL documentation
|
||||
<synopsis>
|
||||
CREATE [ UNIQUE ] INDEX <replaceable class="parameter">name</replaceable> ON <replaceable class="parameter">table</replaceable> [ USING <replaceable class="parameter">method</replaceable> ]
|
||||
( { <replaceable class="parameter">column</replaceable> | ( <replaceable class="parameter">expression</replaceable> ) } [ <replaceable class="parameter">opclass</replaceable> ] [, ...] )
|
||||
[ WITH (FILLFACTOR = <replaceable>fillfactor</replaceable>) ]
|
||||
[ WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] ) ]
|
||||
[ TABLESPACE <replaceable class="parameter">tablespace</replaceable> ]
|
||||
[ WHERE <replaceable class="parameter">predicate</replaceable> ]
|
||||
</synopsis>
|
||||
@ -56,7 +56,7 @@ CREATE [ UNIQUE ] INDEX <replaceable class="parameter">name</replaceable> ON <re
|
||||
|
||||
<para>
|
||||
<productname>PostgreSQL</productname> provides the index methods
|
||||
B-tree, hash, and GiST. Users can also define their own index
|
||||
B-tree, hash, GiST, and GIN. Users can also define their own index
|
||||
methods, but that is fairly complicated.
|
||||
</para>
|
||||
|
||||
@ -136,7 +136,7 @@ CREATE [ UNIQUE ] INDEX <replaceable class="parameter">name</replaceable> ON <re
|
||||
<para>
|
||||
The name of the index method to be used. Choices are
|
||||
<literal>btree</literal>, <literal>hash</literal>,
|
||||
and <literal>gist</literal>. The
|
||||
<literal>gist</literal>, and <literal>gin</>. The
|
||||
default method is <literal>btree</literal>.
|
||||
</para>
|
||||
</listitem>
|
||||
@ -173,10 +173,11 @@ CREATE [ UNIQUE ] INDEX <replaceable class="parameter">name</replaceable> ON <re
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="parameter">fillfactor</replaceable></term>
|
||||
<term><replaceable class="parameter">storage_parameter</replaceable></term>
|
||||
<listitem>
|
||||
<para>
|
||||
The index's fillfactor in percentage.
|
||||
The name of an index-method-specific storage parameter. See
|
||||
below for details.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
@ -203,6 +204,41 @@ CREATE [ UNIQUE ] INDEX <replaceable class="parameter">name</replaceable> ON <re
|
||||
</varlistentry>
|
||||
|
||||
</variablelist>
|
||||
|
||||
<refsect2 id="SQL-CREATEINDEX-storage-parameters">
|
||||
<title id="SQL-CREATEINDEX-storage-parameters-title">Index Storage Parameters</title>
|
||||
|
||||
<para>
|
||||
The <literal>WITH</> clause can specify <firstterm>storage parameters</>
|
||||
for indexes. Each index method can have its own set of allowed storage
|
||||
parameters. The built-in index methods all accept a single parameter:
|
||||
</para>
|
||||
|
||||
<variablelist>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>FILLFACTOR</></term>
|
||||
<listitem>
|
||||
<para>
|
||||
The fillfactor for an index is a percentage that determines how full
|
||||
the index method will try to pack index pages. For B-trees, pages
|
||||
are filled to this percentage during initial index build, and also
|
||||
when extending the index at the right (largest key values). If pages
|
||||
subsequently become completely full, they will be split, leading to
|
||||
gradual degradation in the index's efficiency. B-trees use a default
|
||||
fillfactor of 90, but any value from 70 to 100 can be selected.
|
||||
If the table is static then fillfactor 100 is best to minimize the
|
||||
index's physical size, but for heavily updated tables a smaller
|
||||
fillfactor is better to minimize the need for page splits. The
|
||||
other index methods use fillfactor in different but roughly analogous
|
||||
ways; the default fillfactor and allowed range varies.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
</variablelist>
|
||||
|
||||
</refsect2>
|
||||
</refsect1>
|
||||
|
||||
<refsect1>
|
||||
@ -271,6 +307,21 @@ CREATE UNIQUE INDEX title_idx ON films (title);
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To create an index on the expression <literal>lower(title)</>,
|
||||
allowing efficient case-insensitive searches:
|
||||
<programlisting>
|
||||
CREATE INDEX lower_title_idx ON films ((lower(title)));
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To create an index with non-default fill factor:
|
||||
<programlisting>
|
||||
CREATE UNIQUE INDEX title_idx ON films (title) WITH (fillfactor = 70);
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To create an index on the column <literal>code</> in the table
|
||||
<literal>films</> and have the index reside in the tablespace
|
||||
|
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/create_table.sgml,v 1.103 2006/07/02 02:23:17 momjian Exp $
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/create_table.sgml,v 1.104 2006/07/04 18:07:24 tgl Exp $
|
||||
PostgreSQL documentation
|
||||
-->
|
||||
|
||||
@ -27,8 +27,7 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE <replaceable class="PAR
|
||||
[, ... ]
|
||||
] )
|
||||
[ INHERITS ( <replaceable>parent_table</replaceable> [, ... ] ) ]
|
||||
[ WITH OIDS | WITHOUT OIDS ]
|
||||
[ WITH (FILLFACTOR = <replaceable>fillfactor</replaceable>) ]
|
||||
[ WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] ) | WITH OIDS | WITHOUT OIDS ]
|
||||
[ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
|
||||
[ TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable> ]
|
||||
|
||||
@ -37,9 +36,9 @@ where <replaceable class="PARAMETER">column_constraint</replaceable> is:
|
||||
[ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ]
|
||||
{ NOT NULL |
|
||||
NULL |
|
||||
UNIQUE [ USING INDEX TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable> ] |
|
||||
PRIMARY KEY [ USING INDEX TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable> ] |
|
||||
CHECK (<replaceable class="PARAMETER">expression</replaceable>) |
|
||||
UNIQUE <replaceable class="PARAMETER">index_parameters</replaceable> |
|
||||
PRIMARY KEY <replaceable class="PARAMETER">index_parameters</replaceable> |
|
||||
CHECK ( <replaceable class="PARAMETER">expression</replaceable> ) |
|
||||
REFERENCES <replaceable class="PARAMETER">reftable</replaceable> [ ( <replaceable class="PARAMETER">refcolumn</replaceable> ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ]
|
||||
[ ON DELETE <replaceable class="parameter">action</replaceable> ] [ ON UPDATE <replaceable class="parameter">action</replaceable> ] }
|
||||
[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
|
||||
@ -47,12 +46,17 @@ where <replaceable class="PARAMETER">column_constraint</replaceable> is:
|
||||
and <replaceable class="PARAMETER">table_constraint</replaceable> is:
|
||||
|
||||
[ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ]
|
||||
{ UNIQUE ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) [ USING INDEX TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable> ] |
|
||||
PRIMARY KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) [ USING INDEX TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable> ] |
|
||||
{ UNIQUE ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) <replaceable class="PARAMETER">index_parameters</replaceable> |
|
||||
PRIMARY KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) <replaceable class="PARAMETER">index_parameters</replaceable> |
|
||||
CHECK ( <replaceable class="PARAMETER">expression</replaceable> ) |
|
||||
FOREIGN KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) REFERENCES <replaceable class="PARAMETER">reftable</replaceable> [ ( <replaceable class="PARAMETER">refcolumn</replaceable> [, ... ] ) ]
|
||||
[ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE <replaceable class="parameter">action</replaceable> ] [ ON UPDATE <replaceable class="parameter">action</replaceable> ] }
|
||||
[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
|
||||
|
||||
<replaceable class="PARAMETER">index_parameters</replaceable> in <literal>UNIQUE</> and <literal>PRIMARY KEY</> constraints are:
|
||||
|
||||
[ WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] ) ]
|
||||
[ USING INDEX TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable> ]
|
||||
</synopsis>
|
||||
|
||||
</refsynopsisdiv>
|
||||
@ -270,49 +274,6 @@ and <replaceable class="PARAMETER">table_constraint</replaceable> is:
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>WITH OIDS</></term>
|
||||
<term><literal>WITHOUT OIDS</></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This optional clause specifies whether rows of the new table
|
||||
should have OIDs (object identifiers) assigned to them. If
|
||||
neither <literal>WITH OIDS</literal> nor <literal>WITHOUT
|
||||
OIDS</literal> is specified, the default value depends upon the
|
||||
<xref linkend="guc-default-with-oids"> configuration parameter. (If
|
||||
the new table inherits from any tables that have OIDs, then
|
||||
<literal>WITH OIDS</> is forced even if the command says
|
||||
<literal>WITHOUT OIDS</>.)
|
||||
</para>
|
||||
|
||||
<para>
|
||||
If <literal>WITHOUT OIDS</literal> is specified or implied, the new
|
||||
table does not store OIDs and no OID will be assigned for a row inserted
|
||||
into it. This is generally considered worthwhile, since it
|
||||
will reduce OID consumption and thereby postpone the wraparound
|
||||
of the 32-bit OID counter. Once the counter wraps around, OIDs
|
||||
can no longer be assumed to be unique, which makes them
|
||||
considerably less useful. In addition, excluding OIDs from a
|
||||
table reduces the space required to store the table on disk by
|
||||
4 bytes per row (on most machines), slightly improving performance.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To remove OIDs from a table after it has been created, use <xref
|
||||
linkend="sql-altertable" endterm="sql-altertable-title">.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>WITH (FILLFACTOR = <replaceable>fillfactor</replaceable>)</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This optional clause specifies the table's fillfactor in percentage.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable></literal></term>
|
||||
<listitem>
|
||||
@ -407,7 +368,7 @@ and <replaceable class="PARAMETER">table_constraint</replaceable> is:
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>CHECK (<replaceable class="PARAMETER">expression</replaceable>)</literal></term>
|
||||
<term><literal>CHECK ( <replaceable class="PARAMETER">expression</replaceable> )</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
The <literal>CHECK</> clause specifies an expression producing a
|
||||
@ -581,6 +542,57 @@ and <replaceable class="PARAMETER">table_constraint</replaceable> is:
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] )</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This clause specifies optional storage parameters for a table or index;
|
||||
see <xref linkend="sql-createtable-storage-parameters"
|
||||
endterm="sql-createtable-storage-parameters-title"> for more
|
||||
information. The <literal>WITH</> clause for a
|
||||
table can also include <literal>OIDS=TRUE</> (or just <literal>OIDS</>)
|
||||
to specify that rows of the new table
|
||||
should have OIDs (object identifiers) assigned to them, or
|
||||
<literal>OIDS=FALSE</> to specify that the rows should not have OIDs.
|
||||
If <literal>OIDS</> is not specified, the default setting depends upon
|
||||
the <xref linkend="guc-default-with-oids"> configuration parameter.
|
||||
(If the new table inherits from any tables that have OIDs, then
|
||||
<literal>OIDS=TRUE</> is forced even if the command says
|
||||
<literal>OIDS=FALSE</>.)
|
||||
</para>
|
||||
|
||||
<para>
|
||||
If <literal>OIDS=FALSE</literal> is specified or implied, the new
|
||||
table does not store OIDs and no OID will be assigned for a row inserted
|
||||
into it. This is generally considered worthwhile, since it
|
||||
will reduce OID consumption and thereby postpone the wraparound
|
||||
of the 32-bit OID counter. Once the counter wraps around, OIDs
|
||||
can no longer be assumed to be unique, which makes them
|
||||
considerably less useful. In addition, excluding OIDs from a
|
||||
table reduces the space required to store the table on disk by
|
||||
4 bytes per row (on most machines), slightly improving performance.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To remove OIDs from a table after it has been created, use <xref
|
||||
linkend="sql-altertable" endterm="sql-altertable-title">.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>WITH OIDS</></term>
|
||||
<term><literal>WITHOUT OIDS</></term>
|
||||
<listitem>
|
||||
<para>
|
||||
These are obsolescent syntaxes equivalent to <literal>WITH (OIDS)</>
|
||||
and <literal>WITH (OIDS=FALSE)</>, respectively. If you wish to give
|
||||
both an <literal>OIDS</> setting and storage parameters, you must use
|
||||
the <literal>WITH ( ... )</> syntax; see above.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>ON COMMIT</literal></term>
|
||||
<listitem>
|
||||
@ -656,6 +668,42 @@ and <replaceable class="PARAMETER">table_constraint</replaceable> is:
|
||||
</varlistentry>
|
||||
|
||||
</variablelist>
|
||||
|
||||
<refsect2 id="SQL-CREATETABLE-storage-parameters">
|
||||
<title id="SQL-CREATETABLE-storage-parameters-title">Storage Parameters</title>
|
||||
|
||||
<para>
|
||||
The <literal>WITH</> clause can specify <firstterm>storage parameters</>
|
||||
for tables, and for indexes associated with a <literal>UNIQUE</literal> or
|
||||
<literal>PRIMARY KEY</literal> constraint. Storage parameters for
|
||||
indexes are documented in <xref linkend="SQL-CREATEINDEX"
|
||||
endterm="sql-createindex-title">. The only storage parameter currently
|
||||
available for tables is:
|
||||
</para>
|
||||
|
||||
<variablelist>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>FILLFACTOR</></term>
|
||||
<listitem>
|
||||
<para>
|
||||
The fillfactor for a table is a percentage between 10 and 100.
|
||||
100 (complete packing) is the default. When a smaller fillfactor
|
||||
is specified, <command>INSERT</> operations pack table pages only
|
||||
to the indicated percentage; the remaining space on each page is
|
||||
reserved for updating rows on that page. This gives <command>UPDATE</>
|
||||
a chance to place the updated copy of a row on the same page as the
|
||||
original, which is more efficient than placing it on a different page.
|
||||
For a table whose entries are never updated, complete packing is the
|
||||
best choice, but in heavily updated tables smaller fillfactors are
|
||||
appropriate.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
</variablelist>
|
||||
|
||||
</refsect2>
|
||||
</refsect1>
|
||||
|
||||
<refsect1 id="SQL-CREATETABLE-notes">
|
||||
@ -677,7 +725,7 @@ and <replaceable class="PARAMETER">table_constraint</replaceable> is:
|
||||
|
||||
<tip>
|
||||
<para>
|
||||
The use of <literal>WITHOUT OIDS</literal> is not recommended
|
||||
The use of <literal>OIDS=FALSE</literal> is not recommended
|
||||
for tables with no primary key, since without either an OID or a
|
||||
unique data key, it is difficult to identify specific rows.
|
||||
</para>
|
||||
@ -697,10 +745,10 @@ and <replaceable class="PARAMETER">table_constraint</replaceable> is:
|
||||
inheritance and unique constraints rather dysfunctional.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
A table cannot have more than 1600 columns. (In practice, the
|
||||
effective limit is lower because of tuple-length constraints.)
|
||||
</para>
|
||||
<para>
|
||||
A table cannot have more than 1600 columns. (In practice, the
|
||||
effective limit is usually lower because of tuple-length constraints.)
|
||||
</para>
|
||||
|
||||
</refsect1>
|
||||
|
||||
@ -784,8 +832,7 @@ CREATE TABLE distributors (
|
||||
|
||||
<para>
|
||||
Define a primary key table constraint for the table
|
||||
<structname>films</>. Primary key table constraints can be defined
|
||||
on one or more columns of the table.
|
||||
<structname>films</>:
|
||||
|
||||
<programlisting>
|
||||
CREATE TABLE films (
|
||||
@ -804,7 +851,7 @@ CREATE TABLE films (
|
||||
Define a primary key constraint for table
|
||||
<structname>distributors</>. The following two examples are
|
||||
equivalent, the first using the table constraint syntax, the second
|
||||
the column constraint syntax.
|
||||
the column constraint syntax:
|
||||
|
||||
<programlisting>
|
||||
CREATE TABLE distributors (
|
||||
@ -823,12 +870,12 @@ CREATE TABLE distributors (
|
||||
</para>
|
||||
|
||||
<para>
|
||||
This assigns a literal constant default value for the column
|
||||
<literal>name</literal>, arranges for the default value of column
|
||||
Assign a literal constant default value for the column
|
||||
<literal>name</literal>, arrange for the default value of column
|
||||
<literal>did</literal> to be generated by selecting the next value
|
||||
of a sequence object, and makes the default value of
|
||||
of a sequence object, and make the default value of
|
||||
<literal>modtime</literal> be the time at which the row is
|
||||
inserted.
|
||||
inserted:
|
||||
|
||||
<programlisting>
|
||||
CREATE TABLE distributors (
|
||||
@ -862,7 +909,7 @@ CREATE TABLE distributors (
|
||||
);
|
||||
</programlisting>
|
||||
|
||||
The above is equivalent to the following specified as a table constraint:
|
||||
The same, specified as a table constraint:
|
||||
|
||||
<programlisting>
|
||||
CREATE TABLE distributors (
|
||||
@ -873,6 +920,20 @@ CREATE TABLE distributors (
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Create the same table, specifying 70% fill factor for both the table
|
||||
and its unique index:
|
||||
|
||||
<programlisting>
|
||||
CREATE TABLE distributors (
|
||||
did integer,
|
||||
name varchar(40),
|
||||
UNIQUE(name) WITH (fillfactor=70)
|
||||
)
|
||||
WITH (fillfactor=70);
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Create table <structname>cinemas</> in tablespace <structname>diskvol1</>:
|
||||
|
||||
@ -977,15 +1038,6 @@ CREATE TABLE cinemas (
|
||||
</para>
|
||||
</refsect2>
|
||||
|
||||
<refsect2>
|
||||
<title>Object IDs</title>
|
||||
|
||||
<para>
|
||||
The <productname>PostgreSQL</productname> concept of OIDs is not
|
||||
standard.
|
||||
</para>
|
||||
</refsect2>
|
||||
|
||||
<refsect2>
|
||||
<title>Zero-column tables</title>
|
||||
|
||||
@ -999,6 +1051,15 @@ CREATE TABLE cinemas (
|
||||
</para>
|
||||
</refsect2>
|
||||
|
||||
<refsect2>
|
||||
<title><literal>WITH</> clause</title>
|
||||
|
||||
<para>
|
||||
The <literal>WITH</> clause is a <productname>PostgreSQL</productname>
|
||||
extension; neither storage parameters nor OIDs are in the standard.
|
||||
</para>
|
||||
</refsect2>
|
||||
|
||||
<refsect2>
|
||||
<title>Tablespaces</title>
|
||||
|
||||
|
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/create_table_as.sgml,v 1.33 2006/07/02 02:23:18 momjian Exp $
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/create_table_as.sgml,v 1.34 2006/07/04 18:07:24 tgl Exp $
|
||||
PostgreSQL documentation
|
||||
-->
|
||||
|
||||
@ -22,8 +22,7 @@ PostgreSQL documentation
|
||||
<synopsis>
|
||||
CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE <replaceable>table_name</replaceable>
|
||||
[ (<replaceable>column_name</replaceable> [, ...] ) ]
|
||||
[ WITH OIDS | WITHOUT OIDS ]
|
||||
[ WITH (FILLFACTOR = <replaceable>fillfactor</replaceable>) ]
|
||||
[ WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] ) | WITH OIDS | WITHOUT OIDS ]
|
||||
[ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
|
||||
[ TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable> ]
|
||||
AS <replaceable>query</replaceable>
|
||||
@ -104,24 +103,32 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE <replaceable>table_name
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>WITH OIDS</literal></term>
|
||||
<term><literal>WITHOUT OIDS</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This optional clause specifies whether the table created by
|
||||
<command>CREATE TABLE AS</command> should include OIDs. If
|
||||
neither form of this clause is specified, the value of the
|
||||
<xref linkend="guc-default-with-oids"> configuration parameter is
|
||||
used.
|
||||
</para>
|
||||
</listitem>
|
||||
<term><literal>WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] )</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This clause specifies optional storage parameters for the new table;
|
||||
see <xref linkend="sql-createtable-storage-parameters"
|
||||
endterm="sql-createtable-storage-parameters-title"> for more
|
||||
information. The <literal>WITH</> clause
|
||||
can also include <literal>OIDS=TRUE</> (or just <literal>OIDS</>)
|
||||
to specify that rows of the new table
|
||||
should have OIDs (object identifiers) assigned to them, or
|
||||
<literal>OIDS=FALSE</> to specify that the rows should not have OIDs.
|
||||
See <xref linkend="sql-createtable"
|
||||
endterm="sql-createtable-title"> for more information.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>WITH (FILLFACTOR = <replaceable>fillfactor</replaceable>)</literal></term>
|
||||
<term><literal>WITH OIDS</></term>
|
||||
<term><literal>WITHOUT OIDS</></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This optional clause specifies the table's fillfactor in percentage.
|
||||
These are obsolescent syntaxes equivalent to <literal>WITH (OIDS)</>
|
||||
and <literal>WITH (OIDS=FALSE)</>, respectively. If you wish to give
|
||||
both an <literal>OIDS</> setting and storage parameters, you must use
|
||||
the <literal>WITH ( ... )</> syntax; see above.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
@ -225,7 +232,7 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE <replaceable>table_name
|
||||
this variable is false by default, so the default behavior is not
|
||||
identical to pre-8.0 releases. Applications that
|
||||
require OIDs in the table created by <command>CREATE TABLE
|
||||
AS</command> should explicitly specify <literal>WITH OIDS</literal>
|
||||
AS</command> should explicitly specify <literal>WITH (OIDS)</literal>
|
||||
to ensure proper behavior.
|
||||
</para>
|
||||
</refsect1>
|
||||
@ -244,15 +251,14 @@ CREATE TABLE films_recent AS
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Create a new temporary table that will be dropped at commit
|
||||
<literal>films_recent</literal> with oids consisting of only
|
||||
recent entries from the table <literal>films</literal> using a
|
||||
prepared statement:
|
||||
Create a new temporary table <literal>films_recent</literal>, consisting of
|
||||
only recent entries from the table <literal>films</literal>, using a
|
||||
prepared statement. The new table has OIDs and will be dropped at commit:
|
||||
|
||||
<programlisting>
|
||||
PREPARE recentfilms(date) AS
|
||||
SELECT * FROM films WHERE date_prod > $1;
|
||||
CREATE TEMP TABLE films_recent WITH OIDS ON COMMIT DROP AS
|
||||
CREATE TEMP TABLE films_recent WITH (OIDS) ON COMMIT DROP AS
|
||||
EXECUTE recentfilms('2002-01-01');
|
||||
</programlisting>
|
||||
</para>
|
||||
@ -280,13 +286,8 @@ CREATE TEMP TABLE films_recent WITH OIDS ON COMMIT DROP AS
|
||||
this is not currently implemented by <productname>PostgreSQL</>.
|
||||
The behavior provided by <productname>PostgreSQL</> is equivalent
|
||||
to the standard's <literal>WITH DATA</literal> case.
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
<literal>WITH/WITHOUT OIDS</> is a <productname>PostgreSQL</>
|
||||
extension.
|
||||
<literal>WITH NO DATA</literal> can be simulated by appending
|
||||
<literal>LIMIT 0</> to the query.
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
@ -299,6 +300,13 @@ CREATE TEMP TABLE films_recent WITH OIDS ON COMMIT DROP AS
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The <literal>WITH</> clause is a <productname>PostgreSQL</productname>
|
||||
extension; neither storage parameters nor OIDs are in the standard.
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The <productname>PostgreSQL</productname> concept of tablespaces is not
|
||||
|
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/reindex.sgml,v 1.30 2006/06/18 15:38:36 petere Exp $
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/reindex.sgml,v 1.31 2006/07/04 18:07:24 tgl Exp $
|
||||
PostgreSQL documentation
|
||||
-->
|
||||
|
||||
@ -30,7 +30,7 @@ REINDEX { INDEX | TABLE | DATABASE | SYSTEM } <replaceable class="PARAMETER">nam
|
||||
<para>
|
||||
<command>REINDEX</command> rebuilds an index using the data
|
||||
stored in the index's table, replacing the old copy of the index. There are
|
||||
two main reasons to use <command>REINDEX</command>:
|
||||
three main reasons to use <command>REINDEX</command>:
|
||||
|
||||
<itemizedlist>
|
||||
<listitem>
|
||||
@ -45,15 +45,22 @@ REINDEX { INDEX | TABLE | DATABASE | SYSTEM } <replaceable class="PARAMETER">nam
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The index in question contains a lot of dead index pages that
|
||||
are not being reclaimed. This can occur with B-tree indexes in
|
||||
<productname>PostgreSQL</productname> under certain access
|
||||
An index has become <quote>bloated</>, that it is contains many
|
||||
empty or nearly-empty pages. This can occur with B-tree indexes in
|
||||
<productname>PostgreSQL</productname> under certain uncommon access
|
||||
patterns. <command>REINDEX</command> provides a way to reduce
|
||||
the space consumption of the index by writing a new version of
|
||||
the index without the dead pages. See <xref
|
||||
linkend="routine-reindex"> for more information.
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
You have altered a storage parameter (such as fillfactor)
|
||||
for an index, and wish to ensure that the change has taken full effect.
|
||||
</para>
|
||||
</listitem>
|
||||
</itemizedlist>
|
||||
</para>
|
||||
</refsect1>
|
||||
@ -239,14 +246,6 @@ REINDEX { INDEX | TABLE | DATABASE | SYSTEM } <replaceable class="PARAMETER">nam
|
||||
<refsect1>
|
||||
<title>Examples</title>
|
||||
|
||||
<para>
|
||||
Recreate the indexes on the table <literal>my_table</literal>:
|
||||
|
||||
<programlisting>
|
||||
REINDEX TABLE my_table;
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Rebuild a single index:
|
||||
|
||||
@ -255,6 +254,14 @@ REINDEX INDEX my_index;
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Rebuild all the indexes on the table <literal>my_table</literal>:
|
||||
|
||||
<programlisting>
|
||||
REINDEX TABLE my_table;
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Rebuild all indexes in a particular database, without trusting the
|
||||
system indexes to be valid already:
|
||||
|
Loading…
Reference in New Issue
Block a user