1<!--
2doc/src/sgml/ref/cluster.sgml
3PostgreSQL documentation
4-->
5
6<refentry id="SQL-CLUSTER">
7 <indexterm zone="sql-cluster">
8  <primary>CLUSTER</primary>
9 </indexterm>
10
11 <refmeta>
12  <refentrytitle>CLUSTER</refentrytitle>
13  <manvolnum>7</manvolnum>
14  <refmiscinfo>SQL - Language Statements</refmiscinfo>
15 </refmeta>
16
17 <refnamediv>
18  <refname>CLUSTER</refname>
19  <refpurpose>cluster a table according to an index</refpurpose>
20 </refnamediv>
21
22 <refsynopsisdiv>
23<synopsis>
24CLUSTER [VERBOSE] <replaceable class="PARAMETER">table_name</replaceable> [ USING <replaceable class="PARAMETER">index_name</replaceable> ]
25CLUSTER [VERBOSE]
26</synopsis>
27 </refsynopsisdiv>
28
29 <refsect1>
30  <title>Description</title>
31
32  <para>
33   <command>CLUSTER</command> instructs <productname>PostgreSQL</productname>
34   to cluster the table specified
35   by <replaceable class="parameter">table_name</replaceable>
36   based on the index specified by
37   <replaceable class="parameter">index_name</replaceable>. The index must
38   already have been defined on
39   <replaceable class="parameter">table_name</replaceable>.
40  </para>
41
42  <para>
43   When a table is clustered, it is physically reordered
44   based on the index information. Clustering is a one-time operation:
45   when the table is subsequently updated, the changes are
46   not clustered.  That is, no attempt is made to store new or
47   updated rows according to their index order.  (If one wishes, one can
48   periodically recluster by issuing the command again.  Also, setting
49   the table's <literal>fillfactor</literal> storage parameter to less than
50   100% can aid in preserving cluster ordering during updates, since updated
51   rows are kept on the same page if enough space is available there.)
52  </para>
53
54  <para>
55   When a table is clustered, <productname>PostgreSQL</productname>
56   remembers which index it was clustered by.  The form
57   <command>CLUSTER <replaceable class="parameter">table_name</replaceable></command>
58   reclusters the table using the same index as before.  You can also
59   use the <literal>CLUSTER</literal> or <literal>SET WITHOUT CLUSTER</literal>
60   forms of <xref linkend="SQL-ALTERTABLE"> to set the index to be used for
61   future cluster operations, or to clear any previous setting.
62  </para>
63
64  <para>
65   <command>CLUSTER</command> without any parameter reclusters all the
66   previously-clustered tables in the current database that the calling user
67   owns, or all such tables if called by a superuser.  This
68   form of <command>CLUSTER</command> cannot be executed inside a transaction
69   block.
70  </para>
71
72  <para>
73   When a table is being clustered, an <literal>ACCESS
74   EXCLUSIVE</literal> lock is acquired on it. This prevents any other
75   database operations (both reads and writes) from operating on the
76   table until the <command>CLUSTER</command> is finished.
77  </para>
78 </refsect1>
79
80 <refsect1>
81  <title>Parameters</title>
82
83  <variablelist>
84   <varlistentry>
85    <term><replaceable class="PARAMETER">table_name</replaceable></term>
86    <listitem>
87     <para>
88      The name (possibly schema-qualified) of a table.
89     </para>
90    </listitem>
91   </varlistentry>
92
93   <varlistentry>
94    <term><replaceable class="PARAMETER">index_name</replaceable></term>
95    <listitem>
96     <para>
97      The name of an index.
98     </para>
99    </listitem>
100   </varlistentry>
101
102   <varlistentry>
103    <term><literal>VERBOSE</literal></term>
104    <listitem>
105     <para>
106      Prints a progress report as each table is clustered.
107     </para>
108    </listitem>
109   </varlistentry>
110  </variablelist>
111 </refsect1>
112
113 <refsect1>
114  <title>Notes</title>
115
116   <para>
117    In cases where you are accessing single rows randomly
118    within a table, the actual order of the data in the
119    table is unimportant. However, if you tend to access some
120    data more than others, and there is an index that groups
121    them together, you will benefit from using <command>CLUSTER</command>.
122    If you are requesting a range of indexed values from a table, or a
123    single indexed value that has multiple rows that match,
124    <command>CLUSTER</command> will help because once the index identifies the
125    table page for the first row that matches, all other rows
126    that match are probably already on the same table page,
127    and so you save disk accesses and speed up the query.
128   </para>
129
130   <para>
131    <command>CLUSTER</> can re-sort the table using either an index scan
132    on the specified index, or (if the index is a b-tree) a sequential
133    scan followed by sorting.  It will attempt to choose the method that
134    will be faster, based on planner cost parameters and available statistical
135    information.
136   </para>
137
138   <para>
139    When an index scan is used, a temporary copy of the table is created that
140    contains the table data in the index order.  Temporary copies of each
141    index on the table are created as well.  Therefore, you need free space on
142    disk at least equal to the sum of the table size and the index sizes.
143   </para>
144
145   <para>
146    When a sequential scan and sort is used, a temporary sort file is
147    also created, so that the peak temporary space requirement is as much
148    as double the table size, plus the index sizes.  This method is often
149    faster than the index scan method, but if the disk space requirement is
150    intolerable, you can disable this choice by temporarily setting <xref
151    linkend="guc-enable-sort"> to <literal>off</>.
152   </para>
153
154   <para>
155    It is advisable to set <xref linkend="guc-maintenance-work-mem"> to
156    a reasonably large value (but not more than the amount of RAM you can
157    dedicate to the <command>CLUSTER</> operation) before clustering.
158   </para>
159
160   <para>
161    Because the planner records statistics about the ordering of
162    tables, it is advisable to run <xref linkend="sql-analyze">
163    on the newly clustered table.
164    Otherwise, the planner might make poor choices of query plans.
165   </para>
166
167   <para>
168    Because <command>CLUSTER</command> remembers which indexes are clustered,
169    one can cluster the tables one wants clustered manually the first time,
170    then set up a periodic maintenance script that executes
171    <command>CLUSTER</> without any parameters, so that the desired tables
172    are periodically reclustered.
173   </para>
174
175 </refsect1>
176
177 <refsect1>
178  <title>Examples</title>
179
180  <para>
181   Cluster the table <literal>employees</literal> on the basis of
182   its index <literal>employees_ind</literal>:
183<programlisting>
184CLUSTER employees USING employees_ind;
185</programlisting>
186  </para>
187
188  <para>
189   Cluster the <literal>employees</literal> table using the same
190   index that was used before:
191<programlisting>
192CLUSTER employees;
193</programlisting>
194  </para>
195
196  <para>
197   Cluster all tables in the database that have previously been clustered:
198<programlisting>
199CLUSTER;
200</programlisting></para>
201 </refsect1>
202
203 <refsect1>
204  <title>Compatibility</title>
205
206  <para>
207   There is no <command>CLUSTER</command> statement in the SQL standard.
208  </para>
209
210  <para>
211   The syntax
212<synopsis>
213CLUSTER <replaceable class="PARAMETER">index_name</replaceable> ON <replaceable class="PARAMETER">table_name</replaceable>
214</synopsis>
215  is also supported for compatibility with pre-8.3 <productname>PostgreSQL</>
216  versions.
217  </para>
218 </refsect1>
219
220 <refsect1>
221  <title>See Also</title>
222
223  <simplelist type="inline">
224   <member><xref linkend="app-clusterdb"></member>
225  </simplelist>
226 </refsect1>
227</refentry>
228