blob: 2fb32d54ee54b90a1028e8e94a2567501843e064 (
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
|
<?xml version="1.0" encoding="UTF-8" standalone="no"?>
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>11.7. Indexes on Expressions</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="indexes-unique.html" title="11.6. Unique Indexes" /><link rel="next" href="indexes-partial.html" title="11.8. Partial Indexes" /></head><body id="docContent" class="container-fluid col-10"><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">11.7. Indexes on Expressions</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="indexes-unique.html" title="11.6. Unique Indexes">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="indexes.html" title="Chapter 11. Indexes">Up</a></td><th width="60%" align="center">Chapter 11. Indexes</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 14.5 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="indexes-partial.html" title="11.8. Partial Indexes">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="INDEXES-EXPRESSIONAL"><div class="titlepage"><div><div><h2 class="title" style="clear: both">11.7. Indexes on Expressions</h2></div></div></div><a id="id-1.5.10.10.2" class="indexterm"></a><p>
An index column need not be just a column of the underlying table,
but can be a function or scalar expression computed from one or
more columns of the table. This feature is useful to obtain fast
access to tables based on the results of computations.
</p><p>
For example, a common way to do case-insensitive comparisons is to
use the <code class="function">lower</code> function:
</p><pre class="programlisting">
SELECT * FROM test1 WHERE lower(col1) = 'value';
</pre><p>
This query can use an index if one has been
defined on the result of the <code class="literal">lower(col1)</code>
function:
</p><pre class="programlisting">
CREATE INDEX test1_lower_col1_idx ON test1 (lower(col1));
</pre><p>
</p><p>
If we were to declare this index <code class="literal">UNIQUE</code>, it would prevent
creation of rows whose <code class="literal">col1</code> values differ only in case,
as well as rows whose <code class="literal">col1</code> values are actually identical.
Thus, indexes on expressions can be used to enforce constraints that
are not definable as simple unique constraints.
</p><p>
As another example, if one often does queries like:
</p><pre class="programlisting">
SELECT * FROM people WHERE (first_name || ' ' || last_name) = 'John Smith';
</pre><p>
then it might be worth creating an index like this:
</p><pre class="programlisting">
CREATE INDEX people_names ON people ((first_name || ' ' || last_name));
</pre><p>
</p><p>
The syntax of the <code class="command">CREATE INDEX</code> command normally requires
writing parentheses around index expressions, as shown in the second
example. The parentheses can be omitted when the expression is just
a function call, as in the first example.
</p><p>
Index expressions are relatively expensive to maintain, because the
derived expression(s) must be computed for each row insertion
and non-HOT update. However, the index expressions are
<span class="emphasis"><em>not</em></span> recomputed during an indexed search, since they are
already stored in the index. In both examples above, the system
sees the query as just <code class="literal">WHERE indexedcolumn = 'constant'</code>
and so the speed of the search is equivalent to any other simple index
query. Thus, indexes on expressions are useful when retrieval speed
is more important than insertion and update speed.
</p></div><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navfooter"><hr></hr><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="indexes-unique.html" title="11.6. Unique Indexes">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="indexes.html" title="Chapter 11. Indexes">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="indexes-partial.html" title="11.8. Partial Indexes">Next</a></td></tr><tr><td width="40%" align="left" valign="top">11.6. Unique Indexes </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 14.5 Documentation">Home</a></td><td width="40%" align="right" valign="top"> 11.8. Partial Indexes</td></tr></table></div></body></html>
|