aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/cluster.sgml
blob: 89e48737f4094fb95387234b4ff88790ff046d77 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/cluster.sgml,v 1.44 2007/11/07 14:07:53 petere Exp $
PostgreSQL documentation
-->

<refentry id="SQL-CLUSTER">
 <refmeta>
  <refentrytitle id="sql-cluster-title">CLUSTER</refentrytitle>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>CLUSTER</refname>
  <refpurpose>cluster a table according to an index</refpurpose>
 </refnamediv>

 <indexterm zone="sql-cluster">
  <primary>CLUSTER</primary>
 </indexterm>

 <refsynopsisdiv>
<synopsis>
CLUSTER <replaceable class="PARAMETER">tablename</replaceable> [ USING <replaceable class="PARAMETER">indexname</replaceable> ]
CLUSTER
</synopsis>
 </refsynopsisdiv>

 <refsect1>
  <title>Description</title>

  <para>
   <command>CLUSTER</command> instructs <productname>PostgreSQL</productname> 
   to cluster the table specified
   by <replaceable class="parameter">tablename</replaceable>
   based on the index specified by
   <replaceable class="parameter">indexname</replaceable>. The index must
   already have been defined on 
   <replaceable class="parameter">tablename</replaceable>.
  </para>

  <para>
   When a table is clustered, it is physically reordered
   based on the index information. Clustering is a one-time operation:
   when the table is subsequently updated, the changes are
   not clustered.  That is, no attempt is made to store new or
   updated rows according to their index order.  (If one wishes, one can
   periodically recluster by issuing the command again.  Also, setting
   the table's <literal>FILLFACTOR</literal> storage parameter to less than 100% can aid
   in preserving cluster ordering during updates, since updated rows
   are preferentially kept on the same page.)
  </para>

  <para>
   When a table is clustered, <productname>PostgreSQL</productname>
   remembers which index it was clustered by.  The form
   <command>CLUSTER <replaceable class="parameter">tablename</replaceable></command>
   reclusters the table using the same index as before.
  </para>

  <para>
   <command>CLUSTER</command> without any parameter reclusters all the
   previously-clustered tables in the current database that the calling user
   owns, or all such tables if called by a superuser.  This
   form of <command>CLUSTER</command> cannot be executed inside a transaction
   block.
  </para>

  <para>
   When a table is being clustered, an <literal>ACCESS
   EXCLUSIVE</literal> lock is acquired on it. This prevents any other
   database operations (both reads and writes) from operating on the
   table until the <command>CLUSTER</command> is finished.
  </para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

  <variablelist>
   <varlistentry>
    <term><replaceable class="PARAMETER">tablename</replaceable></term>
    <listitem>
     <para>
      The name (possibly schema-qualified) of a table.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="PARAMETER">indexname</replaceable></term>
    <listitem>
     <para>
      The name of an index.
     </para>
    </listitem>
   </varlistentry>
  </variablelist>
 </refsect1>

 <refsect1>
  <title>Notes</title>

   <para>
    In cases where you are accessing single rows randomly
    within a table, the actual order of the data in the
    table is unimportant. However, if you tend to access some
    data more than others, and there is an index that groups
    them together, you will benefit from using <command>CLUSTER</command>.
    If you are requesting a range of indexed values from a table, or a
    single indexed value that has multiple rows that match,
    <command>CLUSTER</command> will help because once the index identifies the
    table page for the first row that matches, all other rows
    that match are probably already on the same table page,
    and so you save disk accesses and speed up the query.
   </para>

   <para>
    During the cluster operation, a temporary copy of the table is created
    that contains the table data in the index order.  Temporary copies of
    each index on the table are created as well.  Therefore, you need free
    space on disk at least equal to the sum of the table size and the index
    sizes.
   </para>

   <para>
    Because <command>CLUSTER</command> remembers the clustering information,
    one can cluster the tables one wants clustered manually the first time, and
    setup a timed event similar to <command>VACUUM</command> so that the tables
    are periodically reclustered.
   </para>

   <para>
    Because the planner records statistics about the ordering of
    tables, it is advisable to run <xref linkend="sql-analyze"
    endterm="sql-analyze-title"> on the newly clustered table.
    Otherwise, the planner might make poor choices of query plans.
   </para>

   <para>
    There is another way to cluster data. The
    <command>CLUSTER</command> command reorders the original table by
    scanning it using the index you specify. This can be slow
    on large tables because the rows are fetched from the table
    in index order, and if the table is disordered, the
    entries are on random pages, so there is one disk page
    retrieved for every row moved. (<productname>PostgreSQL</productname> has
    a cache, but the majority of a big table will not fit in the cache.)
    The other way to cluster a table is to use:

<programlisting>
CREATE TABLE <replaceable class="parameter">newtable</replaceable> AS
    SELECT * FROM <replaceable class="parameter">table</replaceable> ORDER BY <replaceable class="parameter">columnlist</replaceable>;
</programlisting>

    which uses the <productname>PostgreSQL</productname> sorting code
    to produce the desired order;
    this is usually much faster than an index scan for disordered data.
    Then you drop the old table, use
    <command>ALTER TABLE ... RENAME</command>
    to rename <replaceable class="parameter">newtable</replaceable> to the
    old name, and recreate the table's indexes.
    The big disadvantage of this approach is that it does not preserve
    OIDs, constraints, foreign key relationships, granted privileges, and
    other ancillary properties of the table &mdash; all such items must be
    manually recreated.  Another disadvantage is that this way requires a sort
    temporary file about the same size as the table itself, so peak disk usage
    is about three times the table size instead of twice the table size.
   </para>
 </refsect1>

 <refsect1>
  <title>Examples</title>

  <para>
   Cluster the table <literal>employees</literal> on the basis of
   its index <literal>employees_ind</literal>:
<programlisting>
CLUSTER employees USING employees_ind;
</programlisting>
  </para>

  <para>
   Cluster the <literal>employees</literal> table using the same
   index that was used before:
<programlisting>
CLUSTER employees;
</programlisting>
  </para>

  <para>
   Cluster all tables in the database that have previously been clustered:
<programlisting>
CLUSTER;
</programlisting>
  </para>
 </refsect1>

 <refsect1>
  <title>Compatibility</title>

  <para>
   There is no <command>CLUSTER</command> statement in the SQL standard.
  </para>

  <para>
   The syntax
<synopsis>
CLUSTER <replaceable class="PARAMETER">indexname</replaceable> ON <replaceable class="PARAMETER">tablename</replaceable>
</synopsis>
  is also supported for compatibility with pre-8.3 <productname>PostgreSQL</>
  versions.
  </para>
 </refsect1>

 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="app-clusterdb" endterm="app-clusterdb-title"></member>
  </simplelist>
 </refsect1>
</refentry>