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
223
224
225
226
227
228
229
230
231
232
|
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/cluster.sgml,v 1.20 2002/09/21 18:32:54 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>
<refsynopsisdiv>
<refsynopsisdivinfo>
<date>1999-07-20</date>
</refsynopsisdivinfo>
<synopsis>
CLUSTER <replaceable class="PARAMETER">indexname</replaceable> ON <replaceable class="PARAMETER">tablename</replaceable>
</synopsis>
<refsect2 id="R2-SQL-CLUSTER-1">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
Inputs
</title>
<para>
</para>
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">indexname</replaceable></term>
<listitem>
<para>
The name of an index.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">table</replaceable></term>
<listitem>
<para>
The name (possibly schema-qualified) of a table.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect2>
<refsect2 id="R2-SQL-CLUSTER-2">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
CLUSTER
</computeroutput></term>
<listitem>
<para>
The clustering was done successfully.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv>
<refsect1 id="R1-SQL-CLUSTER-1">
<refsect1info>
<date>1998-09-08</date>
</refsect1info>
<title>
Description
</title>
<para>
<command>CLUSTER</command> instructs <productname>PostgreSQL</productname>
to cluster the table specified
by <replaceable class="parameter">table</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 tuples according to their index order. If one wishes, one can
periodically re-cluster by issuing the command again.
</para>
<refsect2 id="R2-SQL-CLUSTER-3">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
Notes
</title>
<para>
In cases where you are accessing single rows randomly
within a table, the actual order of the data in the heap
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>.
</para>
<para>
Another place where <command>CLUSTER</command> is helpful is in
cases where you use an
index to pull out several rows from a table. 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
heap page for the first row that matches, all other rows
that match are probably already on the same heap page,
saving disk accesses and speeding 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>
CLUSTER preserves GRANT, inheritance, index, foreign key, and other
ancillary information about the table.
</para>
<para>
Because the optimizer records statistics about the ordering of tables, it
is advisable to run <command>ANALYZE</command> on the newly clustered
table. Otherwise, the optimizer may make poor choices of query plans.
</para>
<para>
There is another way to cluster data. The
<command>CLUSTER</command> command reorders the original table using
the ordering of the index you specify. This can be slow
on large tables because the rows are fetched from the heap
in index order, and if the heap table is unordered, 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>
SELECT <replaceable class="parameter">columnlist</replaceable> INTO TABLE <replaceable class="parameter">newtable</replaceable>
FROM <replaceable class="parameter">table</replaceable> ORDER BY <replaceable class="parameter">columnlist</replaceable>
</programlisting>
which uses the <productname>PostgreSQL</productname> sorting code in
the ORDER BY clause to create the desired order; this is usually much
faster than an index scan for
unordered data. You then 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. However, this approach does not preserve
OIDs, constraints, foreign key relationships, granted privileges, and
other ancillary properties of the table --- all such items must be
manually recreated.
</para>
</refsect2>
</refsect1>
<refsect1 id="R1-SQL-CLUSTER-2">
<title>
Usage
</title>
<para>
Cluster the employees relation on the basis of its ID attribute:
</para>
<programlisting>
CLUSTER emp_ind ON emp;
</programlisting>
</refsect1>
<refsect1 id="R1-SQL-CLUSTER-3">
<title>
Compatibility
</title>
<refsect2 id="R2-SQL-CLUSTER-4">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
SQL92
</title>
<para>
There is no <command>CLUSTER</command> statement in SQL92.
</para>
</refsect2>
</refsect1>
</refentry>
<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->
|