At update of non-LP_NORMAL TID, fail instead of corrupting page header.
[pgsql.git] / doc / src / sgml / indices.sgml
blob6d731e0701fdda4e2c89349d79a7816e26981b46
1 <!-- doc/src/sgml/indices.sgml -->
3 <chapter id="indexes">
4 <title>Indexes</title>
6 <indexterm zone="indexes">
7 <primary>index</primary>
8 </indexterm>
10 <para>
11 Indexes are a common way to enhance database performance. An index
12 allows the database server to find and retrieve specific rows much
13 faster than it could do without an index. But indexes also add
14 overhead to the database system as a whole, so they should be used
15 sensibly.
16 </para>
19 <sect1 id="indexes-intro">
20 <title>Introduction</title>
22 <para>
23 Suppose we have a table similar to this:
24 <programlisting>
25 CREATE TABLE test1 (
26 id integer,
27 content varchar
29 </programlisting>
30 and the application issues many queries of the form:
31 <programlisting>
32 SELECT content FROM test1 WHERE id = <replaceable>constant</replaceable>;
33 </programlisting>
34 With no advance preparation, the system would have to scan the entire
35 <structname>test1</structname> table, row by row, to find all
36 matching entries. If there are many rows in
37 <structname>test1</structname> and only a few rows (perhaps zero
38 or one) that would be returned by such a query, this is clearly an
39 inefficient method. But if the system has been instructed to maintain an
40 index on the <structfield>id</structfield> column, it can use a more
41 efficient method for locating matching rows. For instance, it
42 might only have to walk a few levels deep into a search tree.
43 </para>
45 <para>
46 A similar approach is used in most non-fiction books: terms and
47 concepts that are frequently looked up by readers are collected in
48 an alphabetic index at the end of the book. The interested reader
49 can scan the index relatively quickly and flip to the appropriate
50 page(s), rather than having to read the entire book to find the
51 material of interest. Just as it is the task of the author to
52 anticipate the items that readers are likely to look up,
53 it is the task of the database programmer to foresee which indexes
54 will be useful.
55 </para>
57 <para>
58 The following command can be used to create an index on the
59 <structfield>id</structfield> column, as discussed:
60 <programlisting>
61 CREATE INDEX test1_id_index ON test1 (id);
62 </programlisting>
63 The name <structname>test1_id_index</structname> can be chosen
64 freely, but you should pick something that enables you to remember
65 later what the index was for.
66 </para>
68 <para>
69 To remove an index, use the <command>DROP INDEX</command> command.
70 Indexes can be added to and removed from tables at any time.
71 </para>
73 <para>
74 Once an index is created, no further intervention is required: the
75 system will update the index when the table is modified, and it will
76 use the index in queries when it thinks doing so would be more efficient
77 than a sequential table scan. But you might have to run the
78 <command>ANALYZE</command> command regularly to update
79 statistics to allow the query planner to make educated decisions.
80 See <xref linkend="performance-tips"/> for information about
81 how to find out whether an index is used and when and why the
82 planner might choose <emphasis>not</emphasis> to use an index.
83 </para>
85 <para>
86 Indexes can also benefit <command>UPDATE</command> and
87 <command>DELETE</command> commands with search conditions.
88 Indexes can moreover be used in join searches. Thus,
89 an index defined on a column that is part of a join condition can
90 also significantly speed up queries with joins.
91 </para>
93 <para>
94 In general, <productname>PostgreSQL</productname> indexes can be used
95 to optimize queries that contain one or more <literal>WHERE</literal>
96 or <literal>JOIN</literal> clauses of the form
98 <synopsis>
99 <replaceable>indexed-column</replaceable> <replaceable>indexable-operator</replaceable> <replaceable>comparison-value</replaceable>
100 </synopsis>
102 Here, the <replaceable>indexed-column</replaceable> is whatever
103 column or expression the index has been defined on.
104 The <replaceable>indexable-operator</replaceable> is an operator that
105 is a member of the index's <firstterm>operator class</firstterm> for
106 the indexed column. (More details about that appear below.)
107 And the <replaceable>comparison-value</replaceable> can be any
108 expression that is not volatile and does not reference the index's
109 table.
110 </para>
112 <para>
113 In some cases the query planner can extract an indexable clause of
114 this form from another SQL construct. A simple example is that if
115 the original clause was
117 <synopsis>
118 <replaceable>comparison-value</replaceable> <replaceable>operator</replaceable> <replaceable>indexed-column</replaceable>
119 </synopsis>
121 then it can be flipped around into indexable form if the
122 original <replaceable>operator</replaceable> has a commutator
123 operator that is a member of the index's operator class.
124 </para>
126 <para>
127 Creating an index on a large table can take a long time. By default,
128 <productname>PostgreSQL</productname> allows reads (<command>SELECT</command> statements) to occur
129 on the table in parallel with index creation, but writes (<command>INSERT</command>,
130 <command>UPDATE</command>, <command>DELETE</command>) are blocked until the index build is finished.
131 In production environments this is often unacceptable.
132 It is possible to allow writes to occur in parallel with index
133 creation, but there are several caveats to be aware of &mdash;
134 for more information see <xref linkend="sql-createindex-concurrently"/>.
135 </para>
137 <para>
138 After an index is created, the system has to keep it synchronized with the
139 table. This adds overhead to data manipulation operations. Indexes can
140 also prevent the creation of <link linkend="storage-hot">heap-only
141 tuples</link>.
142 Therefore indexes that are seldom or never used in queries
143 should be removed.
144 </para>
145 </sect1>
148 <sect1 id="indexes-types">
149 <title>Index Types</title>
151 <para>
152 <productname>PostgreSQL</productname> provides several index types:
153 B-tree, Hash, GiST, SP-GiST, GIN, BRIN, and the extension <link
154 linkend="bloom">bloom</link>.
155 Each index type uses a different
156 algorithm that is best suited to different types of indexable clauses.
157 By default, the <link linkend="sql-createindex"><command>CREATE
158 INDEX</command></link> command creates
159 B-tree indexes, which fit the most common situations.
160 The other index types are selected by writing the keyword
161 <literal>USING</literal> followed by the index type name.
162 For example, to create a Hash index:
163 <programlisting>
164 CREATE INDEX <replaceable>name</replaceable> ON <replaceable>table</replaceable> USING HASH (<replaceable>column</replaceable>);
165 </programlisting>
166 </para>
168 <sect2 id="indexes-types-btree">
169 <title>B-Tree</title>
171 <indexterm>
172 <primary>index</primary>
173 <secondary>B-Tree</secondary>
174 </indexterm>
175 <indexterm>
176 <primary>B-Tree</primary>
177 <see>index</see>
178 </indexterm>
180 <para>
181 B-trees can handle equality and range queries on data that can be sorted
182 into some ordering.
183 In particular, the <productname>PostgreSQL</productname> query planner
184 will consider using a B-tree index whenever an indexed column is
185 involved in a comparison using one of these operators:
187 <synopsis>
188 &lt; &nbsp; &lt;= &nbsp; = &nbsp; &gt;= &nbsp; &gt;
189 </synopsis>
191 Constructs equivalent to combinations of these operators, such as
192 <literal>BETWEEN</literal> and <literal>IN</literal>, can also be implemented with
193 a B-tree index search. Also, an <literal>IS NULL</literal> or <literal>IS NOT
194 NULL</literal> condition on an index column can be used with a B-tree index.
195 </para>
197 <para>
198 The optimizer can also use a B-tree index for queries involving the
199 pattern matching operators <literal>LIKE</literal> and <literal>~</literal>
200 <emphasis>if</emphasis> the pattern is a constant and is anchored to
201 the beginning of the string &mdash; for example, <literal>col LIKE
202 'foo%'</literal> or <literal>col ~ '^foo'</literal>, but not
203 <literal>col LIKE '%bar'</literal>. However, if your database does not
204 use the C locale you will need to create the index with a special
205 operator class to support indexing of pattern-matching queries; see
206 <xref linkend="indexes-opclass"/> below. It is also possible to use
207 B-tree indexes for <literal>ILIKE</literal> and
208 <literal>~*</literal>, but only if the pattern starts with
209 non-alphabetic characters, i.e., characters that are not affected by
210 upper/lower case conversion.
211 </para>
213 <para>
214 B-tree indexes can also be used to retrieve data in sorted order.
215 This is not always faster than a simple scan and sort, but it is
216 often helpful.
217 </para>
218 </sect2>
220 <sect2 id="indexes-types-hash">
221 <title>Hash</title>
223 <indexterm>
224 <primary>index</primary>
225 <secondary>hash</secondary>
226 </indexterm>
227 <indexterm>
228 <primary>hash</primary>
229 <see>index</see>
230 </indexterm>
232 <para>
233 Hash indexes store a 32-bit hash code derived from the
234 value of the indexed column. Hence,
235 such indexes can only handle simple equality comparisons.
236 The query planner will consider using a hash index whenever an
237 indexed column is involved in a comparison using the
238 equal operator:
240 <synopsis>
242 </synopsis>
243 </para>
244 </sect2>
246 <sect2 id="indexes-type-gist">
247 <title>GiST</title>
249 <indexterm>
250 <primary>index</primary>
251 <secondary>GiST</secondary>
252 </indexterm>
253 <indexterm>
254 <primary>GiST</primary>
255 <see>index</see>
256 </indexterm>
258 <para>
259 GiST indexes are not a single kind of index, but rather an infrastructure
260 within which many different indexing strategies can be implemented.
261 Accordingly, the particular operators with which a GiST index can be
262 used vary depending on the indexing strategy (the <firstterm>operator
263 class</firstterm>). As an example, the standard distribution of
264 <productname>PostgreSQL</productname> includes GiST operator classes
265 for several two-dimensional geometric data types, which support indexed
266 queries using these operators:
268 <synopsis>
269 &lt;&lt; &nbsp; &amp;&lt; &nbsp; &amp;&gt; &nbsp; &gt;&gt; &nbsp; &lt;&lt;| &nbsp; &amp;&lt;| &nbsp; |&amp;&gt; &nbsp; |&gt;&gt; &nbsp; @&gt; &nbsp; &lt;@ &nbsp; ~= &nbsp; &amp;&amp;
270 </synopsis>
272 (See <xref linkend="functions-geometry"/> for the meaning of
273 these operators.)
274 The GiST operator classes included in the standard distribution are
275 documented in <xref linkend="gist-builtin-opclasses-table"/>.
276 Many other GiST operator
277 classes are available in the <literal>contrib</literal> collection or as separate
278 projects. For more information see <xref linkend="gist"/>.
279 </para>
281 <para>
282 GiST indexes are also capable of optimizing <quote>nearest-neighbor</quote>
283 searches, such as
284 <programlisting><![CDATA[
285 SELECT * FROM places ORDER BY location <-> point '(101,456)' LIMIT 10;
287 </programlisting>
288 which finds the ten places closest to a given target point. The ability
289 to do this is again dependent on the particular operator class being used.
290 In <xref linkend="gist-builtin-opclasses-table"/>, operators that can be
291 used in this way are listed in the column <quote>Ordering Operators</quote>.
292 </para>
293 </sect2>
295 <sect2 id="indexes-type-spgist">
296 <title>SP-GiST</title>
298 <indexterm>
299 <primary>index</primary>
300 <secondary>SP-GiST</secondary>
301 </indexterm>
302 <indexterm>
303 <primary>SP-GiST</primary>
304 <see>index</see>
305 </indexterm>
307 <para>
308 SP-GiST indexes, like GiST indexes, offer an infrastructure that supports
309 various kinds of searches. SP-GiST permits implementation of a wide range
310 of different non-balanced disk-based data structures, such as quadtrees,
311 k-d trees, and radix trees (tries). As an example, the standard distribution of
312 <productname>PostgreSQL</productname> includes SP-GiST operator classes
313 for two-dimensional points, which support indexed
314 queries using these operators:
316 <synopsis>
317 &lt;&lt; &nbsp; &gt;&gt; &nbsp; ~= &nbsp; &lt;@ &nbsp; &lt;&lt;| &nbsp; |&gt;&gt;
318 </synopsis>
320 (See <xref linkend="functions-geometry"/> for the meaning of
321 these operators.)
322 The SP-GiST operator classes included in the standard distribution are
323 documented in <xref linkend="spgist-builtin-opclasses-table"/>.
324 For more information see <xref linkend="spgist"/>.
325 </para>
327 <para>
328 Like GiST, SP-GiST supports <quote>nearest-neighbor</quote> searches.
329 For SP-GiST operator classes that support distance ordering, the
330 corresponding operator is listed in the <quote>Ordering Operators</quote>
331 column in <xref linkend="spgist-builtin-opclasses-table"/>.
332 </para>
333 </sect2>
335 <sect2 id="indexes-types-gin">
336 <title>GIN</title>
338 <indexterm>
339 <primary>index</primary>
340 <secondary>GIN</secondary>
341 </indexterm>
342 <indexterm>
343 <primary>GIN</primary>
344 <see>index</see>
345 </indexterm>
347 <para>
348 GIN indexes are <quote>inverted indexes</quote> which are appropriate for
349 data values that contain multiple component values, such as arrays. An
350 inverted index contains a separate entry for each component value, and
351 can efficiently handle queries that test for the presence of specific
352 component values.
353 </para>
355 <para>
356 Like GiST and SP-GiST, GIN can support
357 many different user-defined indexing strategies, and the particular
358 operators with which a GIN index can be used vary depending on the
359 indexing strategy.
360 As an example, the standard distribution of
361 <productname>PostgreSQL</productname> includes a GIN operator class
362 for arrays, which supports indexed queries using these operators:
364 <synopsis>
365 &lt;@ &nbsp; @&gt; &nbsp; = &nbsp; &amp;&amp;
366 </synopsis>
368 (See <xref linkend="functions-array"/> for the meaning of
369 these operators.)
370 The GIN operator classes included in the standard distribution are
371 documented in <xref linkend="gin-builtin-opclasses-table"/>.
372 Many other GIN operator
373 classes are available in the <literal>contrib</literal> collection or as separate
374 projects. For more information see <xref linkend="gin"/>.
375 </para>
376 </sect2>
378 <sect2 id="indexes-types-brin">
379 <title>BRIN</title>
381 <indexterm>
382 <primary>index</primary>
383 <secondary>BRIN</secondary>
384 </indexterm>
385 <indexterm>
386 <primary>BRIN</primary>
387 <see>index</see>
388 </indexterm>
390 <para>
391 BRIN indexes (a shorthand for Block Range INdexes) store summaries about
392 the values stored in consecutive physical block ranges of a table.
393 Thus, they are most effective for columns whose values are well-correlated
394 with the physical order of the table rows.
395 Like GiST, SP-GiST and GIN,
396 BRIN can support many different indexing strategies,
397 and the particular operators with which a BRIN index can be used
398 vary depending on the indexing strategy.
399 For data types that have a linear sort order, the indexed data
400 corresponds to the minimum and maximum values of the
401 values in the column for each block range. This supports indexed queries
402 using these operators:
404 <synopsis>
405 &lt; &nbsp; &lt;= &nbsp; = &nbsp; &gt;= &nbsp; &gt;
406 </synopsis>
408 The BRIN operator classes included in the standard distribution are
409 documented in <xref linkend="brin-builtin-opclasses-table"/>.
410 For more information see <xref linkend="brin"/>.
411 </para>
412 </sect2>
413 </sect1>
416 <sect1 id="indexes-multicolumn">
417 <title>Multicolumn Indexes</title>
419 <indexterm zone="indexes-multicolumn">
420 <primary>index</primary>
421 <secondary>multicolumn</secondary>
422 </indexterm>
424 <para>
425 An index can be defined on more than one column of a table. For example, if
426 you have a table of this form:
427 <programlisting>
428 CREATE TABLE test2 (
429 major int,
430 minor int,
431 name varchar
433 </programlisting>
434 (say, you keep your <filename class="directory">/dev</filename>
435 directory in a database...) and you frequently issue queries like:
436 <programlisting>
437 SELECT name FROM test2 WHERE major = <replaceable>constant</replaceable> AND minor = <replaceable>constant</replaceable>;
438 </programlisting>
439 then it might be appropriate to define an index on the columns
440 <structfield>major</structfield> and
441 <structfield>minor</structfield> together, e.g.:
442 <programlisting>
443 CREATE INDEX test2_mm_idx ON test2 (major, minor);
444 </programlisting>
445 </para>
447 <para>
448 Currently, only the B-tree, GiST, GIN, and BRIN index types support
449 multiple-key-column indexes. Whether there can be multiple key
450 columns is independent of whether <literal>INCLUDE</literal> columns
451 can be added to the index. Indexes can have up to 32 columns,
452 including <literal>INCLUDE</literal> columns. (This limit can be
453 altered when building <productname>PostgreSQL</productname>; see the
454 file <filename>pg_config_manual.h</filename>.)
455 </para>
457 <para>
458 A multicolumn B-tree index can be used with query conditions that
459 involve any subset of the index's columns, but the index is most
460 efficient when there are constraints on the leading (leftmost) columns.
461 The exact rule is that equality constraints on leading columns, plus
462 any inequality constraints on the first column that does not have an
463 equality constraint, will be used to limit the portion of the index
464 that is scanned. Constraints on columns to the right of these columns
465 are checked in the index, so they save visits to the table proper, but
466 they do not reduce the portion of the index that has to be scanned.
467 For example, given an index on <literal>(a, b, c)</literal> and a
468 query condition <literal>WHERE a = 5 AND b &gt;= 42 AND c &lt; 77</literal>,
469 the index would have to be scanned from the first entry with
470 <literal>a</literal> = 5 and <literal>b</literal> = 42 up through the last entry with
471 <literal>a</literal> = 5. Index entries with <literal>c</literal> &gt;= 77 would be
472 skipped, but they'd still have to be scanned through.
473 This index could in principle be used for queries that have constraints
474 on <literal>b</literal> and/or <literal>c</literal> with no constraint on <literal>a</literal>
475 &mdash; but the entire index would have to be scanned, so in most cases
476 the planner would prefer a sequential table scan over using the index.
477 </para>
479 <para>
480 A multicolumn GiST index can be used with query conditions that
481 involve any subset of the index's columns. Conditions on additional
482 columns restrict the entries returned by the index, but the condition on
483 the first column is the most important one for determining how much of
484 the index needs to be scanned. A GiST index will be relatively
485 ineffective if its first column has only a few distinct values, even if
486 there are many distinct values in additional columns.
487 </para>
489 <para>
490 A multicolumn GIN index can be used with query conditions that
491 involve any subset of the index's columns. Unlike B-tree or GiST,
492 index search effectiveness is the same regardless of which index column(s)
493 the query conditions use.
494 </para>
496 <para>
497 A multicolumn BRIN index can be used with query conditions that
498 involve any subset of the index's columns. Like GIN and unlike B-tree or
499 GiST, index search effectiveness is the same regardless of which index
500 column(s) the query conditions use. The only reason to have multiple BRIN
501 indexes instead of one multicolumn BRIN index on a single table is to have
502 a different <literal>pages_per_range</literal> storage parameter.
503 </para>
505 <para>
506 Of course, each column must be used with operators appropriate to the index
507 type; clauses that involve other operators will not be considered.
508 </para>
510 <para>
511 Multicolumn indexes should be used sparingly. In most situations,
512 an index on a single column is sufficient and saves space and time.
513 Indexes with more than three columns are unlikely to be helpful
514 unless the usage of the table is extremely stylized. See also
515 <xref linkend="indexes-bitmap-scans"/> and
516 <xref linkend="indexes-index-only-scans"/> for some discussion of the
517 merits of different index configurations.
518 </para>
519 </sect1>
522 <sect1 id="indexes-ordering">
523 <title>Indexes and <literal>ORDER BY</literal></title>
525 <indexterm zone="indexes-ordering">
526 <primary>index</primary>
527 <secondary>and <literal>ORDER BY</literal></secondary>
528 </indexterm>
530 <para>
531 In addition to simply finding the rows to be returned by a query,
532 an index may be able to deliver them in a specific sorted order.
533 This allows a query's <literal>ORDER BY</literal> specification to be honored
534 without a separate sorting step. Of the index types currently
535 supported by <productname>PostgreSQL</productname>, only B-tree
536 can produce sorted output &mdash; the other index types return
537 matching rows in an unspecified, implementation-dependent order.
538 </para>
540 <para>
541 The planner will consider satisfying an <literal>ORDER BY</literal> specification
542 either by scanning an available index that matches the specification,
543 or by scanning the table in physical order and doing an explicit
544 sort. For a query that requires scanning a large fraction of the
545 table, an explicit sort is likely to be faster than using an index
546 because it requires
547 less disk I/O due to following a sequential access pattern. Indexes are
548 more useful when only a few rows need be fetched. An important
549 special case is <literal>ORDER BY</literal> in combination with
550 <literal>LIMIT</literal> <replaceable>n</replaceable>: an explicit sort will have to process
551 all the data to identify the first <replaceable>n</replaceable> rows, but if there is
552 an index matching the <literal>ORDER BY</literal>, the first <replaceable>n</replaceable>
553 rows can be retrieved directly, without scanning the remainder at all.
554 </para>
556 <para>
557 By default, B-tree indexes store their entries in ascending order
558 with nulls last (table TID is treated as a tiebreaker column among
559 otherwise equal entries). This means that a forward scan of an
560 index on column <literal>x</literal> produces output satisfying <literal>ORDER BY x</literal>
561 (or more verbosely, <literal>ORDER BY x ASC NULLS LAST</literal>). The
562 index can also be scanned backward, producing output satisfying
563 <literal>ORDER BY x DESC</literal>
564 (or more verbosely, <literal>ORDER BY x DESC NULLS FIRST</literal>, since
565 <literal>NULLS FIRST</literal> is the default for <literal>ORDER BY DESC</literal>).
566 </para>
568 <para>
569 You can adjust the ordering of a B-tree index by including the
570 options <literal>ASC</literal>, <literal>DESC</literal>, <literal>NULLS FIRST</literal>,
571 and/or <literal>NULLS LAST</literal> when creating the index; for example:
572 <programlisting>
573 CREATE INDEX test2_info_nulls_low ON test2 (info NULLS FIRST);
574 CREATE INDEX test3_desc_index ON test3 (id DESC NULLS LAST);
575 </programlisting>
576 An index stored in ascending order with nulls first can satisfy
577 either <literal>ORDER BY x ASC NULLS FIRST</literal> or
578 <literal>ORDER BY x DESC NULLS LAST</literal> depending on which direction
579 it is scanned in.
580 </para>
582 <para>
583 You might wonder why bother providing all four options, when two
584 options together with the possibility of backward scan would cover
585 all the variants of <literal>ORDER BY</literal>. In single-column indexes
586 the options are indeed redundant, but in multicolumn indexes they can be
587 useful. Consider a two-column index on <literal>(x, y)</literal>: this can
588 satisfy <literal>ORDER BY x, y</literal> if we scan forward, or
589 <literal>ORDER BY x DESC, y DESC</literal> if we scan backward.
590 But it might be that the application frequently needs to use
591 <literal>ORDER BY x ASC, y DESC</literal>. There is no way to get that
592 ordering from a plain index, but it is possible if the index is defined
593 as <literal>(x ASC, y DESC)</literal> or <literal>(x DESC, y ASC)</literal>.
594 </para>
596 <para>
597 Obviously, indexes with non-default sort orderings are a fairly
598 specialized feature, but sometimes they can produce tremendous
599 speedups for certain queries. Whether it's worth maintaining such an
600 index depends on how often you use queries that require a special
601 sort ordering.
602 </para>
603 </sect1>
606 <sect1 id="indexes-bitmap-scans">
607 <title>Combining Multiple Indexes</title>
609 <indexterm zone="indexes-bitmap-scans">
610 <primary>index</primary>
611 <secondary>combining multiple indexes</secondary>
612 </indexterm>
614 <indexterm zone="indexes-bitmap-scans">
615 <primary>bitmap scan</primary>
616 </indexterm>
618 <para>
619 A single index scan can only use query clauses that use the index's
620 columns with operators of its operator class and are joined with
621 <literal>AND</literal>. For example, given an index on <literal>(a, b)</literal>
622 a query condition like <literal>WHERE a = 5 AND b = 6</literal> could
623 use the index, but a query like <literal>WHERE a = 5 OR b = 6</literal> could not
624 directly use the index.
625 </para>
627 <para>
628 Fortunately,
629 <productname>PostgreSQL</productname> has the ability to combine multiple indexes
630 (including multiple uses of the same index) to handle cases that cannot
631 be implemented by single index scans. The system can form <literal>AND</literal>
632 and <literal>OR</literal> conditions across several index scans. For example,
633 a query like <literal>WHERE x = 42 OR x = 47 OR x = 53 OR x = 99</literal>
634 could be broken down into four separate scans of an index on <literal>x</literal>,
635 each scan using one of the query clauses. The results of these scans are
636 then ORed together to produce the result. Another example is that if we
637 have separate indexes on <literal>x</literal> and <literal>y</literal>, one possible
638 implementation of a query like <literal>WHERE x = 5 AND y = 6</literal> is to
639 use each index with the appropriate query clause and then AND together
640 the index results to identify the result rows.
641 </para>
643 <para>
644 To combine multiple indexes, the system scans each needed index and
645 prepares a <firstterm>bitmap</firstterm> in memory giving the locations of
646 table rows that are reported as matching that index's conditions.
647 The bitmaps are then ANDed and ORed together as needed by the query.
648 Finally, the actual table rows are visited and returned. The table rows
649 are visited in physical order, because that is how the bitmap is laid
650 out; this means that any ordering of the original indexes is lost, and
651 so a separate sort step will be needed if the query has an <literal>ORDER
652 BY</literal> clause. For this reason, and because each additional index scan
653 adds extra time, the planner will sometimes choose to use a simple index
654 scan even though additional indexes are available that could have been
655 used as well.
656 </para>
658 <para>
659 In all but the simplest applications, there are various combinations of
660 indexes that might be useful, and the database developer must make
661 trade-offs to decide which indexes to provide. Sometimes multicolumn
662 indexes are best, but sometimes it's better to create separate indexes
663 and rely on the index-combination feature. For example, if your
664 workload includes a mix of queries that sometimes involve only column
665 <literal>x</literal>, sometimes only column <literal>y</literal>, and sometimes both
666 columns, you might choose to create two separate indexes on
667 <literal>x</literal> and <literal>y</literal>, relying on index combination to
668 process the queries that use both columns. You could also create a
669 multicolumn index on <literal>(x, y)</literal>. This index would typically be
670 more efficient than index combination for queries involving both
671 columns, but as discussed in <xref linkend="indexes-multicolumn"/>, it
672 would be almost useless for queries involving only <literal>y</literal>, so it
673 should not be the only index. A combination of the multicolumn index
674 and a separate index on <literal>y</literal> would serve reasonably well. For
675 queries involving only <literal>x</literal>, the multicolumn index could be
676 used, though it would be larger and hence slower than an index on
677 <literal>x</literal> alone. The last alternative is to create all three
678 indexes, but this is probably only reasonable if the table is searched
679 much more often than it is updated and all three types of query are
680 common. If one of the types of query is much less common than the
681 others, you'd probably settle for creating just the two indexes that
682 best match the common types.
683 </para>
685 </sect1>
688 <sect1 id="indexes-unique">
689 <title>Unique Indexes</title>
691 <indexterm zone="indexes-unique">
692 <primary>index</primary>
693 <secondary>unique</secondary>
694 </indexterm>
696 <para>
697 Indexes can also be used to enforce uniqueness of a column's value,
698 or the uniqueness of the combined values of more than one column.
699 <synopsis>
700 CREATE UNIQUE INDEX <replaceable>name</replaceable> ON <replaceable>table</replaceable> (<replaceable>column</replaceable> <optional>, ...</optional>) <optional> NULLS <optional> NOT </optional> DISTINCT </optional>;
701 </synopsis>
702 Currently, only B-tree indexes can be declared unique.
703 </para>
705 <para>
706 When an index is declared unique, multiple table rows with equal
707 indexed values are not allowed. By default, null values in a unique column
708 are not considered equal, allowing multiple nulls in the column. The
709 <literal>NULLS NOT DISTINCT</literal> option modifies this and causes the
710 index to treat nulls as equal. A multicolumn unique index will only reject
711 cases where all indexed columns are equal in multiple rows.
712 </para>
714 <para>
715 <productname>PostgreSQL</productname> automatically creates a unique
716 index when a unique constraint or primary key is defined for a table.
717 The index covers the columns that make up the primary key or unique
718 constraint (a multicolumn index, if appropriate), and is the mechanism
719 that enforces the constraint.
720 </para>
722 <note>
723 <para>
724 There's no need to manually
725 create indexes on unique columns; doing so would just duplicate
726 the automatically-created index.
727 </para>
728 </note>
729 </sect1>
732 <sect1 id="indexes-expressional">
733 <title>Indexes on Expressions</title>
735 <indexterm zone="indexes-expressional">
736 <primary>index</primary>
737 <secondary sortas="expressions">on expressions</secondary>
738 </indexterm>
740 <para>
741 An index column need not be just a column of the underlying table,
742 but can be a function or scalar expression computed from one or
743 more columns of the table. This feature is useful to obtain fast
744 access to tables based on the results of computations.
745 </para>
747 <para>
748 For example, a common way to do case-insensitive comparisons is to
749 use the <function>lower</function> function:
750 <programlisting>
751 SELECT * FROM test1 WHERE lower(col1) = 'value';
752 </programlisting>
753 This query can use an index if one has been
754 defined on the result of the <literal>lower(col1)</literal>
755 function:
756 <programlisting>
757 CREATE INDEX test1_lower_col1_idx ON test1 (lower(col1));
758 </programlisting>
759 </para>
761 <para>
762 If we were to declare this index <literal>UNIQUE</literal>, it would prevent
763 creation of rows whose <literal>col1</literal> values differ only in case,
764 as well as rows whose <literal>col1</literal> values are actually identical.
765 Thus, indexes on expressions can be used to enforce constraints that
766 are not definable as simple unique constraints.
767 </para>
769 <para>
770 As another example, if one often does queries like:
771 <programlisting>
772 SELECT * FROM people WHERE (first_name || ' ' || last_name) = 'John Smith';
773 </programlisting>
774 then it might be worth creating an index like this:
775 <programlisting>
776 CREATE INDEX people_names ON people ((first_name || ' ' || last_name));
777 </programlisting>
778 </para>
780 <para>
781 The syntax of the <command>CREATE INDEX</command> command normally requires
782 writing parentheses around index expressions, as shown in the second
783 example. The parentheses can be omitted when the expression is just
784 a function call, as in the first example.
785 </para>
787 <para>
788 Index expressions are relatively expensive to maintain, because the
789 derived expression(s) must be computed for each row insertion
790 and <link linkend="storage-hot">non-HOT update</link>. However, the index expressions are
791 <emphasis>not</emphasis> recomputed during an indexed search, since they are
792 already stored in the index. In both examples above, the system
793 sees the query as just <literal>WHERE indexedcolumn = 'constant'</literal>
794 and so the speed of the search is equivalent to any other simple index
795 query. Thus, indexes on expressions are useful when retrieval speed
796 is more important than insertion and update speed.
797 </para>
798 </sect1>
801 <sect1 id="indexes-partial">
802 <title>Partial Indexes</title>
804 <indexterm zone="indexes-partial">
805 <primary>index</primary>
806 <secondary>partial</secondary>
807 </indexterm>
809 <para>
810 A <firstterm>partial index</firstterm> is an index built over a
811 subset of a table; the subset is defined by a conditional
812 expression (called the <firstterm>predicate</firstterm> of the
813 partial index). The index contains entries only for those table
814 rows that satisfy the predicate. Partial indexes are a specialized
815 feature, but there are several situations in which they are useful.
816 </para>
818 <para>
819 One major reason for using a partial index is to avoid indexing common
820 values. Since a query searching for a common value (one that
821 accounts for more than a few percent of all the table rows) will not
822 use the index anyway, there is no point in keeping those rows in the
823 index at all. This reduces the size of the index, which will speed
824 up those queries that do use the index. It will also speed up many table
825 update operations because the index does not need to be
826 updated in all cases. <xref linkend="indexes-partial-ex1"/> shows a
827 possible application of this idea.
828 </para>
830 <example id="indexes-partial-ex1">
831 <title>Setting up a Partial Index to Exclude Common Values</title>
833 <para>
834 Suppose you are storing web server access logs in a database.
835 Most accesses originate from the IP address range of your organization but
836 some are from elsewhere (say, employees on dial-up connections).
837 If your searches by IP are primarily for outside accesses,
838 you probably do not need to index the IP range that corresponds to your
839 organization's subnet.
840 </para>
842 <para>
843 Assume a table like this:
844 <programlisting>
845 CREATE TABLE access_log (
846 url varchar,
847 client_ip inet,
850 </programlisting>
851 </para>
853 <para>
854 To create a partial index that suits our example, use a command
855 such as this:
856 <programlisting>
857 CREATE INDEX access_log_client_ip_ix ON access_log (client_ip)
858 WHERE NOT (client_ip &gt; inet '192.168.100.0' AND
859 client_ip &lt; inet '192.168.100.255');
860 </programlisting>
861 </para>
863 <para>
864 A typical query that can use this index would be:
865 <programlisting>
866 SELECT *
867 FROM access_log
868 WHERE url = '/index.html' AND client_ip = inet '212.78.10.32';
869 </programlisting>
870 Here the query's IP address is covered by the partial index. The
871 following query cannot use the partial index, as it uses an IP address
872 that is excluded from the index:
873 <programlisting>
874 SELECT *
875 FROM access_log
876 WHERE url = '/index.html' AND client_ip = inet '192.168.100.23';
877 </programlisting>
878 </para>
880 <para>
881 Observe that this kind of partial index requires that the common
882 values be predetermined, so such partial indexes are best used for
883 data distributions that do not change. Such indexes can be recreated
884 occasionally to adjust for new data distributions, but this adds
885 maintenance effort.
886 </para>
887 </example>
889 <para>
890 Another possible use for a partial index is to exclude values from the
891 index that the
892 typical query workload is not interested in; this is shown in <xref
893 linkend="indexes-partial-ex2"/>. This results in the same
894 advantages as listed above, but it prevents the
895 <quote>uninteresting</quote> values from being accessed via that
896 index, even if an index scan might be profitable in that
897 case. Obviously, setting up partial indexes for this kind of
898 scenario will require a lot of care and experimentation.
899 </para>
901 <example id="indexes-partial-ex2">
902 <title>Setting up a Partial Index to Exclude Uninteresting Values</title>
904 <para>
905 If you have a table that contains both billed and unbilled orders,
906 where the unbilled orders take up a small fraction of the total
907 table and yet those are the most-accessed rows, you can improve
908 performance by creating an index on just the unbilled rows. The
909 command to create the index would look like this:
910 <programlisting>
911 CREATE INDEX orders_unbilled_index ON orders (order_nr)
912 WHERE billed is not true;
913 </programlisting>
914 </para>
916 <para>
917 A possible query to use this index would be:
918 <programlisting>
919 SELECT * FROM orders WHERE billed is not true AND order_nr &lt; 10000;
920 </programlisting>
921 However, the index can also be used in queries that do not involve
922 <structfield>order_nr</structfield> at all, e.g.:
923 <programlisting>
924 SELECT * FROM orders WHERE billed is not true AND amount &gt; 5000.00;
925 </programlisting>
926 This is not as efficient as a partial index on the
927 <structfield>amount</structfield> column would be, since the system has to
928 scan the entire index. Yet, if there are relatively few unbilled
929 orders, using this partial index just to find the unbilled orders
930 could be a win.
931 </para>
933 <para>
934 Note that this query cannot use this index:
935 <programlisting>
936 SELECT * FROM orders WHERE order_nr = 3501;
937 </programlisting>
938 The order 3501 might be among the billed or unbilled
939 orders.
940 </para>
941 </example>
943 <para>
944 <xref linkend="indexes-partial-ex2"/> also illustrates that the
945 indexed column and the column used in the predicate do not need to
946 match. <productname>PostgreSQL</productname> supports partial
947 indexes with arbitrary predicates, so long as only columns of the
948 table being indexed are involved. However, keep in mind that the
949 predicate must match the conditions used in the queries that
950 are supposed to benefit from the index. To be precise, a partial
951 index can be used in a query only if the system can recognize that
952 the <literal>WHERE</literal> condition of the query mathematically implies
953 the predicate of the index.
954 <productname>PostgreSQL</productname> does not have a sophisticated
955 theorem prover that can recognize mathematically equivalent
956 expressions that are written in different forms. (Not
957 only is such a general theorem prover extremely difficult to
958 create, it would probably be too slow to be of any real use.)
959 The system can recognize simple inequality implications, for example
960 <quote>x &lt; 1</quote> implies <quote>x &lt; 2</quote>; otherwise
961 the predicate condition must exactly match part of the query's
962 <literal>WHERE</literal> condition
963 or the index will not be recognized as usable. Matching takes
964 place at query planning time, not at run time. As a result,
965 parameterized query clauses do not work with a partial index. For
966 example a prepared query with a parameter might specify
967 <quote>x &lt; ?</quote> which will never imply
968 <quote>x &lt; 2</quote> for all possible values of the parameter.
969 </para>
971 <para>
972 A third possible use for partial indexes does not require the
973 index to be used in queries at all. The idea here is to create
974 a unique index over a subset of a table, as in <xref
975 linkend="indexes-partial-ex3"/>. This enforces uniqueness
976 among the rows that satisfy the index predicate, without constraining
977 those that do not.
978 </para>
980 <example id="indexes-partial-ex3">
981 <title>Setting up a Partial Unique Index</title>
983 <para>
984 Suppose that we have a table describing test outcomes. We wish
985 to ensure that there is only one <quote>successful</quote> entry for
986 a given subject and target combination, but there might be any number of
987 <quote>unsuccessful</quote> entries. Here is one way to do it:
988 <programlisting>
989 CREATE TABLE tests (
990 subject text,
991 target text,
992 success boolean,
996 CREATE UNIQUE INDEX tests_success_constraint ON tests (subject, target)
997 WHERE success;
998 </programlisting>
999 This is a particularly efficient approach when there are few
1000 successful tests and many unsuccessful ones. It is also possible to
1001 allow only one null in a column by creating a unique partial index
1002 with an <literal>IS NULL</literal> restriction.
1003 </para>
1005 </example>
1007 <para>
1008 Finally, a partial index can also be used to override the system's
1009 query plan choices. Also, data sets with peculiar
1010 distributions might cause the system to use an index when it really
1011 should not. In that case the index can be set up so that it is not
1012 available for the offending query. Normally,
1013 <productname>PostgreSQL</productname> makes reasonable choices about index
1014 usage (e.g., it avoids them when retrieving common values, so the
1015 earlier example really only saves index size, it is not required to
1016 avoid index usage), and grossly incorrect plan choices are cause
1017 for a bug report.
1018 </para>
1020 <para>
1021 Keep in mind that setting up a partial index indicates that you
1022 know at least as much as the query planner knows, in particular you
1023 know when an index might be profitable. Forming this knowledge
1024 requires experience and understanding of how indexes in
1025 <productname>PostgreSQL</productname> work. In most cases, the
1026 advantage of a partial index over a regular index will be minimal.
1027 There are cases where they are quite counterproductive, as in <xref
1028 linkend="indexes-partial-ex4"/>.
1029 </para>
1031 <example id="indexes-partial-ex4">
1032 <title>Do Not Use Partial Indexes as a Substitute for Partitioning</title>
1034 <para>
1035 You might be tempted to create a large set of non-overlapping partial
1036 indexes, for example
1038 <programlisting>
1039 CREATE INDEX mytable_cat_1 ON mytable (data) WHERE category = 1;
1040 CREATE INDEX mytable_cat_2 ON mytable (data) WHERE category = 2;
1041 CREATE INDEX mytable_cat_3 ON mytable (data) WHERE category = 3;
1043 CREATE INDEX mytable_cat_<replaceable>N</replaceable> ON mytable (data) WHERE category = <replaceable>N</replaceable>;
1044 </programlisting>
1046 This is a bad idea! Almost certainly, you'll be better off with a
1047 single non-partial index, declared like
1049 <programlisting>
1050 CREATE INDEX mytable_cat_data ON mytable (category, data);
1051 </programlisting>
1053 (Put the category column first, for the reasons described in
1054 <xref linkend="indexes-multicolumn"/>.) While a search in this larger
1055 index might have to descend through a couple more tree levels than a
1056 search in a smaller index, that's almost certainly going to be cheaper
1057 than the planner effort needed to select the appropriate one of the
1058 partial indexes. The core of the problem is that the system does not
1059 understand the relationship among the partial indexes, and will
1060 laboriously test each one to see if it's applicable to the current
1061 query.
1062 </para>
1064 <para>
1065 If your table is large enough that a single index really is a bad idea,
1066 you should look into using partitioning instead (see
1067 <xref linkend="ddl-partitioning"/>). With that mechanism, the system
1068 does understand that the tables and indexes are non-overlapping, so
1069 far better performance is possible.
1070 </para>
1071 </example>
1073 <para>
1074 More information about partial indexes can be found in <xref
1075 linkend="ston89b"/>, <xref linkend="olson93"/>, and <xref
1076 linkend="seshadri95"/>.
1077 </para>
1078 </sect1>
1081 <sect1 id="indexes-index-only-scans">
1082 <title>Index-Only Scans and Covering Indexes</title>
1084 <indexterm zone="indexes-index-only-scans">
1085 <primary>index</primary>
1086 <secondary>index-only scans</secondary>
1087 </indexterm>
1088 <indexterm zone="indexes-index-only-scans">
1089 <primary>index-only scan</primary>
1090 </indexterm>
1091 <indexterm zone="indexes-index-only-scans">
1092 <primary>index</primary>
1093 <secondary>covering</secondary>
1094 </indexterm>
1095 <indexterm zone="indexes-index-only-scans">
1096 <primary>covering index</primary>
1097 </indexterm>
1099 <para>
1100 All indexes in <productname>PostgreSQL</productname>
1101 are <firstterm>secondary</firstterm> indexes, meaning that each index is
1102 stored separately from the table's main data area (which is called the
1103 table's <firstterm>heap</firstterm>
1104 in <productname>PostgreSQL</productname> terminology). This means that
1105 in an ordinary index scan, each row retrieval requires fetching data from
1106 both the index and the heap. Furthermore, while the index entries that
1107 match a given indexable <literal>WHERE</literal> condition are usually
1108 close together in the index, the table rows they reference might be
1109 anywhere in the heap. The heap-access portion of an index scan thus
1110 involves a lot of random access into the heap, which can be slow,
1111 particularly on traditional rotating media. (As described in
1112 <xref linkend="indexes-bitmap-scans"/>, bitmap scans try to alleviate
1113 this cost by doing the heap accesses in sorted order, but that only goes
1114 so far.)
1115 </para>
1117 <para>
1118 To solve this performance problem, <productname>PostgreSQL</productname>
1119 supports <firstterm>index-only scans</firstterm>, which can answer
1120 queries from an index alone without any heap access. The basic idea is
1121 to return values directly out of each index entry instead of consulting
1122 the associated heap entry. There are two fundamental restrictions on
1123 when this method can be used:
1125 <orderedlist>
1126 <listitem>
1127 <para>
1128 The index type must support index-only scans. B-tree indexes always
1129 do. GiST and SP-GiST indexes support index-only scans for some
1130 operator classes but not others. Other index types have no support.
1131 The underlying requirement is that the index must physically store, or
1132 else be able to reconstruct, the original data value for each index
1133 entry. As a counterexample, GIN indexes cannot support index-only
1134 scans because each index entry typically holds only part of the
1135 original data value.
1136 </para>
1137 </listitem>
1139 <listitem>
1140 <para>
1141 The query must reference only columns stored in the index. For
1142 example, given an index on columns <literal>x</literal>
1143 and <literal>y</literal> of a table that also has a
1144 column <literal>z</literal>, these queries could use index-only scans:
1145 <programlisting>
1146 SELECT x, y FROM tab WHERE x = 'key';
1147 SELECT x FROM tab WHERE x = 'key' AND y &lt; 42;
1148 </programlisting>
1149 but these queries could not:
1150 <programlisting>
1151 SELECT x, z FROM tab WHERE x = 'key';
1152 SELECT x FROM tab WHERE x = 'key' AND z &lt; 42;
1153 </programlisting>
1154 (Expression indexes and partial indexes complicate this rule,
1155 as discussed below.)
1156 </para>
1157 </listitem>
1158 </orderedlist>
1159 </para>
1161 <para>
1162 If these two fundamental requirements are met, then all the data values
1163 required by the query are available from the index, so an index-only scan
1164 is physically possible. But there is an additional requirement for any
1165 table scan in <productname>PostgreSQL</productname>: it must verify that
1166 each retrieved row be <quote>visible</quote> to the query's MVCC
1167 snapshot, as discussed in <xref linkend="mvcc"/>. Visibility information
1168 is not stored in index entries, only in heap entries; so at first glance
1169 it would seem that every row retrieval would require a heap access
1170 anyway. And this is indeed the case, if the table row has been modified
1171 recently. However, for seldom-changing data there is a way around this
1172 problem. <productname>PostgreSQL</productname> tracks, for each page in
1173 a table's heap, whether all rows stored in that page are old enough to be
1174 visible to all current and future transactions. This information is
1175 stored in a bit in the table's <firstterm>visibility map</firstterm>. An
1176 index-only scan, after finding a candidate index entry, checks the
1177 visibility map bit for the corresponding heap page. If it's set, the row
1178 is known visible and so the data can be returned with no further work.
1179 If it's not set, the heap entry must be visited to find out whether it's
1180 visible, so no performance advantage is gained over a standard index
1181 scan. Even in the successful case, this approach trades visibility map
1182 accesses for heap accesses; but since the visibility map is four orders
1183 of magnitude smaller than the heap it describes, far less physical I/O is
1184 needed to access it. In most situations the visibility map remains
1185 cached in memory all the time.
1186 </para>
1188 <para>
1189 In short, while an index-only scan is possible given the two fundamental
1190 requirements, it will be a win only if a significant fraction of the
1191 table's heap pages have their all-visible map bits set. But tables in
1192 which a large fraction of the rows are unchanging are common enough to
1193 make this type of scan very useful in practice.
1194 </para>
1196 <para>
1197 <indexterm>
1198 <primary><literal>INCLUDE</literal></primary>
1199 <secondary>in index definitions</secondary>
1200 </indexterm>
1201 To make effective use of the index-only scan feature, you might choose to
1202 create a <firstterm>covering index</firstterm>, which is an index
1203 specifically designed to include the columns needed by a particular
1204 type of query that you run frequently. Since queries typically need to
1205 retrieve more columns than just the ones they search
1206 on, <productname>PostgreSQL</productname> allows you to create an index
1207 in which some columns are just <quote>payload</quote> and are not part
1208 of the search key. This is done by adding an <literal>INCLUDE</literal>
1209 clause listing the extra columns. For example, if you commonly run
1210 queries like
1211 <programlisting>
1212 SELECT y FROM tab WHERE x = 'key';
1213 </programlisting>
1214 the traditional approach to speeding up such queries would be to create
1215 an index on <literal>x</literal> only. However, an index defined as
1216 <programlisting>
1217 CREATE INDEX tab_x_y ON tab(x) INCLUDE (y);
1218 </programlisting>
1219 could handle these queries as index-only scans,
1220 because <literal>y</literal> can be obtained from the index without
1221 visiting the heap.
1222 </para>
1224 <para>
1225 Because column <literal>y</literal> is not part of the index's search
1226 key, it does not have to be of a data type that the index can handle;
1227 it's merely stored in the index and is not interpreted by the index
1228 machinery. Also, if the index is a unique index, that is
1229 <programlisting>
1230 CREATE UNIQUE INDEX tab_x_y ON tab(x) INCLUDE (y);
1231 </programlisting>
1232 the uniqueness condition applies to just column <literal>x</literal>,
1233 not to the combination of <literal>x</literal> and <literal>y</literal>.
1234 (An <literal>INCLUDE</literal> clause can also be written
1235 in <literal>UNIQUE</literal> and <literal>PRIMARY KEY</literal>
1236 constraints, providing alternative syntax for setting up an index like
1237 this.)
1238 </para>
1240 <para>
1241 It's wise to be conservative about adding non-key payload columns to an
1242 index, especially wide columns. If an index tuple exceeds the
1243 maximum size allowed for the index type, data insertion will fail.
1244 In any case, non-key columns duplicate data from the index's table
1245 and bloat the size of the index, thus potentially slowing searches.
1246 And remember that there is little point in including payload columns in an
1247 index unless the table changes slowly enough that an index-only scan is
1248 likely to not need to access the heap. If the heap tuple must be visited
1249 anyway, it costs nothing more to get the column's value from there.
1250 Other restrictions are that expressions are not currently supported as
1251 included columns, and that only B-tree, GiST and SP-GiST indexes currently
1252 support included columns.
1253 </para>
1255 <para>
1256 Before <productname>PostgreSQL</productname> had
1257 the <literal>INCLUDE</literal> feature, people sometimes made covering
1258 indexes by writing the payload columns as ordinary index columns,
1259 that is writing
1260 <programlisting>
1261 CREATE INDEX tab_x_y ON tab(x, y);
1262 </programlisting>
1263 even though they had no intention of ever using <literal>y</literal> as
1264 part of a <literal>WHERE</literal> clause. This works fine as long as
1265 the extra columns are trailing columns; making them be leading columns is
1266 unwise for the reasons explained in <xref linkend="indexes-multicolumn"/>.
1267 However, this method doesn't support the case where you want the index to
1268 enforce uniqueness on the key column(s).
1269 </para>
1271 <para>
1272 <firstterm>Suffix truncation</firstterm> always removes non-key
1273 columns from upper B-Tree levels. As payload columns, they are
1274 never used to guide index scans. The truncation process also
1275 removes one or more trailing key column(s) when the remaining
1276 prefix of key column(s) happens to be sufficient to describe tuples
1277 on the lowest B-Tree level. In practice, covering indexes without
1278 an <literal>INCLUDE</literal> clause often avoid storing columns
1279 that are effectively payload in the upper levels. However,
1280 explicitly defining payload columns as non-key columns
1281 <emphasis>reliably</emphasis> keeps the tuples in upper levels
1282 small.
1283 </para>
1285 <para>
1286 In principle, index-only scans can be used with expression indexes.
1287 For example, given an index on <literal>f(x)</literal>
1288 where <literal>x</literal> is a table column, it should be possible to
1289 execute
1290 <programlisting>
1291 SELECT f(x) FROM tab WHERE f(x) &lt; 1;
1292 </programlisting>
1293 as an index-only scan; and this is very attractive
1294 if <literal>f()</literal> is an expensive-to-compute function.
1295 However, <productname>PostgreSQL</productname>'s planner is currently not
1296 very smart about such cases. It considers a query to be potentially
1297 executable by index-only scan only when all <emphasis>columns</emphasis>
1298 needed by the query are available from the index. In this
1299 example, <literal>x</literal> is not needed except in the
1300 context <literal>f(x)</literal>, but the planner does not notice that and
1301 concludes that an index-only scan is not possible. If an index-only scan
1302 seems sufficiently worthwhile, this can be worked around by
1303 adding <literal>x</literal> as an included column, for example
1304 <programlisting>
1305 CREATE INDEX tab_f_x ON tab (f(x)) INCLUDE (x);
1306 </programlisting>
1307 An additional caveat, if the goal is to avoid
1308 recalculating <literal>f(x)</literal>, is that the planner won't
1309 necessarily match uses of <literal>f(x)</literal> that aren't in
1310 indexable <literal>WHERE</literal> clauses to the index column. It will
1311 usually get this right in simple queries such as shown above, but not in
1312 queries that involve joins. These deficiencies may be remedied in future
1313 versions of <productname>PostgreSQL</productname>.
1314 </para>
1316 <para>
1317 Partial indexes also have interesting interactions with index-only scans.
1318 Consider the partial index shown in <xref linkend="indexes-partial-ex3"/>:
1319 <programlisting>
1320 CREATE UNIQUE INDEX tests_success_constraint ON tests (subject, target)
1321 WHERE success;
1322 </programlisting>
1323 In principle, we could do an index-only scan on this index to satisfy a
1324 query like
1325 <programlisting>
1326 SELECT target FROM tests WHERE subject = 'some-subject' AND success;
1327 </programlisting>
1328 But there's a problem: the <literal>WHERE</literal> clause refers
1329 to <literal>success</literal> which is not available as a result column
1330 of the index. Nonetheless, an index-only scan is possible because the
1331 plan does not need to recheck that part of the <literal>WHERE</literal>
1332 clause at run time: all entries found in the index necessarily
1333 have <literal>success = true</literal> so this need not be explicitly
1334 checked in the plan. <productname>PostgreSQL</productname> versions 9.6
1335 and later will recognize such cases and allow index-only scans to be
1336 generated, but older versions will not.
1337 </para>
1338 </sect1>
1341 <sect1 id="indexes-opclass">
1342 <title>Operator Classes and Operator Families</title>
1344 <indexterm zone="indexes-opclass">
1345 <primary>operator class</primary>
1346 </indexterm>
1348 <indexterm zone="indexes-opclass">
1349 <primary>operator family</primary>
1350 </indexterm>
1352 <para>
1353 An index definition can specify an <firstterm>operator
1354 class</firstterm> for each column of an index.
1355 <synopsis>
1356 CREATE INDEX <replaceable>name</replaceable> ON <replaceable>table</replaceable> (<replaceable>column</replaceable> <replaceable>opclass</replaceable> [ ( <replaceable>opclass_options</replaceable> ) ] <optional><replaceable>sort options</replaceable></optional> <optional>, ...</optional>);
1357 </synopsis>
1358 The operator class identifies the operators to be used by the index
1359 for that column. For example, a B-tree index on the type <type>int4</type>
1360 would use the <literal>int4_ops</literal> class; this operator
1361 class includes comparison functions for values of type <type>int4</type>.
1362 In practice the default operator class for the column's data type is
1363 usually sufficient. The main reason for having operator classes is
1364 that for some data types, there could be more than one meaningful
1365 index behavior. For example, we might want to sort a complex-number data
1366 type either by absolute value or by real part. We could do this by
1367 defining two operator classes for the data type and then selecting
1368 the proper class when making an index. The operator class determines
1369 the basic sort ordering (which can then be modified by adding sort options
1370 <literal>COLLATE</literal>,
1371 <literal>ASC</literal>/<literal>DESC</literal> and/or
1372 <literal>NULLS FIRST</literal>/<literal>NULLS LAST</literal>).
1373 </para>
1375 <para>
1376 There are also some built-in operator classes besides the default ones:
1378 <itemizedlist>
1379 <listitem>
1380 <para>
1381 The operator classes <literal>text_pattern_ops</literal>,
1382 <literal>varchar_pattern_ops</literal>, and
1383 <literal>bpchar_pattern_ops</literal> support B-tree indexes on
1384 the types <type>text</type>, <type>varchar</type>, and
1385 <type>char</type> respectively. The
1386 difference from the default operator classes is that the values
1387 are compared strictly character by character rather than
1388 according to the locale-specific collation rules. This makes
1389 these operator classes suitable for use by queries involving
1390 pattern matching expressions (<literal>LIKE</literal> or POSIX
1391 regular expressions) when the database does not use the standard
1392 <quote>C</quote> locale. As an example, you might index a
1393 <type>varchar</type> column like this:
1394 <programlisting>
1395 CREATE INDEX test_index ON test_table (col varchar_pattern_ops);
1396 </programlisting>
1397 Note that you should also create an index with the default operator
1398 class if you want queries involving ordinary <literal>&lt;</literal>,
1399 <literal>&lt;=</literal>, <literal>&gt;</literal>, or <literal>&gt;=</literal> comparisons
1400 to use an index. Such queries cannot use the
1401 <literal><replaceable>xxx</replaceable>_pattern_ops</literal>
1402 operator classes. (Ordinary equality comparisons can use these
1403 operator classes, however.) It is possible to create multiple
1404 indexes on the same column with different operator classes.
1405 If you do use the C locale, you do not need the
1406 <literal><replaceable>xxx</replaceable>_pattern_ops</literal>
1407 operator classes, because an index with the default operator class
1408 is usable for pattern-matching queries in the C locale.
1409 </para>
1410 </listitem>
1411 </itemizedlist>
1412 </para>
1414 <para>
1415 The following query shows all defined operator classes:
1417 <programlisting>
1418 SELECT am.amname AS index_method,
1419 opc.opcname AS opclass_name,
1420 opc.opcintype::regtype AS indexed_type,
1421 opc.opcdefault AS is_default
1422 FROM pg_am am, pg_opclass opc
1423 WHERE opc.opcmethod = am.oid
1424 ORDER BY index_method, opclass_name;
1425 </programlisting>
1426 </para>
1428 <para>
1429 An operator class is actually just a subset of a larger structure called an
1430 <firstterm>operator family</firstterm>. In cases where several data types have
1431 similar behaviors, it is frequently useful to define cross-data-type
1432 operators and allow these to work with indexes. To do this, the operator
1433 classes for each of the types must be grouped into the same operator
1434 family. The cross-type operators are members of the family, but are not
1435 associated with any single class within the family.
1436 </para>
1438 <para>
1439 This expanded version of the previous query shows the operator family
1440 each operator class belongs to:
1441 <programlisting>
1442 SELECT am.amname AS index_method,
1443 opc.opcname AS opclass_name,
1444 opf.opfname AS opfamily_name,
1445 opc.opcintype::regtype AS indexed_type,
1446 opc.opcdefault AS is_default
1447 FROM pg_am am, pg_opclass opc, pg_opfamily opf
1448 WHERE opc.opcmethod = am.oid AND
1449 opc.opcfamily = opf.oid
1450 ORDER BY index_method, opclass_name;
1451 </programlisting>
1452 </para>
1454 <para>
1455 This query shows all defined operator families and all
1456 the operators included in each family:
1457 <programlisting>
1458 SELECT am.amname AS index_method,
1459 opf.opfname AS opfamily_name,
1460 amop.amopopr::regoperator AS opfamily_operator
1461 FROM pg_am am, pg_opfamily opf, pg_amop amop
1462 WHERE opf.opfmethod = am.oid AND
1463 amop.amopfamily = opf.oid
1464 ORDER BY index_method, opfamily_name, opfamily_operator;
1465 </programlisting>
1466 </para>
1468 <tip>
1469 <para>
1470 <xref linkend="app-psql"/> has
1471 commands <command>\dAc</command>, <command>\dAf</command>,
1472 and <command>\dAo</command>, which provide slightly more sophisticated
1473 versions of these queries.
1474 </para>
1475 </tip>
1476 </sect1>
1479 <sect1 id="indexes-collations">
1480 <title>Indexes and Collations</title>
1482 <para>
1483 An index can support only one collation per index column.
1484 If multiple collations are of interest, multiple indexes may be needed.
1485 </para>
1487 <para>
1488 Consider these statements:
1489 <programlisting>
1490 CREATE TABLE test1c (
1491 id integer,
1492 content varchar COLLATE "x"
1495 CREATE INDEX test1c_content_index ON test1c (content);
1496 </programlisting>
1497 The index automatically uses the collation of the
1498 underlying column. So a query of the form
1499 <programlisting>
1500 SELECT * FROM test1c WHERE content &gt; <replaceable>constant</replaceable>;
1501 </programlisting>
1502 could use the index, because the comparison will by default use the
1503 collation of the column. However, this index cannot accelerate queries
1504 that involve some other collation. So if queries of the form, say,
1505 <programlisting>
1506 SELECT * FROM test1c WHERE content &gt; <replaceable>constant</replaceable> COLLATE "y";
1507 </programlisting>
1508 are also of interest, an additional index could be created that supports
1509 the <literal>"y"</literal> collation, like this:
1510 <programlisting>
1511 CREATE INDEX test1c_content_y_index ON test1c (content COLLATE "y");
1512 </programlisting>
1513 </para>
1514 </sect1>
1517 <sect1 id="indexes-examine">
1518 <title>Examining Index Usage</title>
1520 <indexterm zone="indexes-examine">
1521 <primary>index</primary>
1522 <secondary>examining usage</secondary>
1523 </indexterm>
1525 <para>
1526 Although indexes in <productname>PostgreSQL</productname> do not need
1527 maintenance or tuning, it is still important to check
1528 which indexes are actually used by the real-life query workload.
1529 Examining index usage for an individual query is done with the
1530 <xref linkend="sql-explain"/>
1531 command; its application for this purpose is
1532 illustrated in <xref linkend="using-explain"/>.
1533 It is also possible to gather overall statistics about index usage
1534 in a running server, as described in <xref linkend="monitoring-stats"/>.
1535 </para>
1537 <para>
1538 It is difficult to formulate a general procedure for determining
1539 which indexes to create. There are a number of typical cases that
1540 have been shown in the examples throughout the previous sections.
1541 A good deal of experimentation is often necessary.
1542 The rest of this section gives some tips for that:
1543 </para>
1545 <itemizedlist>
1546 <listitem>
1547 <para>
1548 Always run <xref linkend="sql-analyze"/>
1549 first. This command
1550 collects statistics about the distribution of the values in the
1551 table. This information is required to estimate the number of rows
1552 returned by a query, which is needed by the planner to assign
1553 realistic costs to each possible query plan. In absence of any
1554 real statistics, some default values are assumed, which are
1555 almost certain to be inaccurate. Examining an application's
1556 index usage without having run <command>ANALYZE</command> is
1557 therefore a lost cause.
1558 See <xref linkend="vacuum-for-statistics"/>
1559 and <xref linkend="autovacuum"/> for more information.
1560 </para>
1561 </listitem>
1563 <listitem>
1564 <para>
1565 Use real data for experimentation. Using test data for setting
1566 up indexes will tell you what indexes you need for the test data,
1567 but that is all.
1568 </para>
1570 <para>
1571 It is especially fatal to use very small test data sets.
1572 While selecting 1000 out of 100000 rows could be a candidate for
1573 an index, selecting 1 out of 100 rows will hardly be, because the
1574 100 rows probably fit within a single disk page, and there
1575 is no plan that can beat sequentially fetching 1 disk page.
1576 </para>
1578 <para>
1579 Also be careful when making up test data, which is often
1580 unavoidable when the application is not yet in production.
1581 Values that are very similar, completely random, or inserted in
1582 sorted order will skew the statistics away from the distribution
1583 that real data would have.
1584 </para>
1585 </listitem>
1587 <listitem>
1588 <para>
1589 When indexes are not used, it can be useful for testing to force
1590 their use. There are run-time parameters that can turn off
1591 various plan types (see <xref linkend="runtime-config-query-enable"/>).
1592 For instance, turning off sequential scans
1593 (<varname>enable_seqscan</varname>) and nested-loop joins
1594 (<varname>enable_nestloop</varname>), which are the most basic plans,
1595 will force the system to use a different plan. If the system
1596 still chooses a sequential scan or nested-loop join then there is
1597 probably a more fundamental reason why the index is not being
1598 used; for example, the query condition does not match the index.
1599 (What kind of query can use what kind of index is explained in
1600 the previous sections.)
1601 </para>
1602 </listitem>
1604 <listitem>
1605 <para>
1606 If forcing index usage does use the index, then there are two
1607 possibilities: Either the system is right and using the index is
1608 indeed not appropriate, or the cost estimates of the query plans
1609 are not reflecting reality. So you should time your query with
1610 and without indexes. The <command>EXPLAIN ANALYZE</command>
1611 command can be useful here.
1612 </para>
1613 </listitem>
1615 <listitem>
1616 <para>
1617 If it turns out that the cost estimates are wrong, there are,
1618 again, two possibilities. The total cost is computed from the
1619 per-row costs of each plan node times the selectivity estimate of
1620 the plan node. The costs estimated for the plan nodes can be adjusted
1621 via run-time parameters (described in <xref
1622 linkend="runtime-config-query-constants"/>).
1623 An inaccurate selectivity estimate is due to
1624 insufficient statistics. It might be possible to improve this by
1625 tuning the statistics-gathering parameters (see
1626 <xref linkend="sql-altertable"/>).
1627 </para>
1629 <para>
1630 If you do not succeed in adjusting the costs to be more
1631 appropriate, then you might have to resort to forcing index usage
1632 explicitly. You might also want to contact the
1633 <productname>PostgreSQL</productname> developers to examine the issue.
1634 </para>
1635 </listitem>
1636 </itemizedlist>
1637 </sect1>
1638 </chapter>