File: indexes-opclass.html

package info (click to toggle)
pgadmin3 1.4.3-2
  • links: PTS
  • area: main
  • in suites: etch, etch-m68k
  • size: 29,796 kB
  • ctags: 10,758
  • sloc: cpp: 55,356; sh: 6,164; ansic: 1,520; makefile: 576; sql: 482; xml: 100; perl: 18
file content (92 lines) | stat: -rw-r--r-- 4,929 bytes parent folder | download
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
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>11.8.Operator Classes</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="indexes.html" title="Chapter11.Indexes">
<link rel="prev" href="indexes-partial.html" title="11.7.Partial Indexes">
<link rel="next" href="indexes-examine.html" title="11.9.Examining Index Usage">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="sect1" lang="en">
<div class="titlepage"><div><div><h2 class="title" style="clear: both">
<a name="indexes-opclass"></a>11.8.Operator Classes</h2></div></div></div>
<a name="id629345"></a><p>   An index definition may specify an <em class="firstterm">operator
   class</em> for each column of an index.
</p>
<pre class="synopsis">CREATE INDEX <em class="replaceable"><code>name</code></em> ON <em class="replaceable"><code>table</code></em> (<em class="replaceable"><code>column</code></em> <em class="replaceable"><code>opclass</code></em> [<span class="optional">, ...</span>]);</pre>
<p>
   The operator class identifies the operators to be used by the index
   for that column.  For example, a B-tree index on the type <code class="type">int4</code>
   would use the <code class="literal">int4_ops</code> class; this operator
   class includes comparison functions for values of type <code class="type">int4</code>.
   In practice the default operator class for the column's data type is
   usually sufficient.  The main point of having operator classes is
   that for some data types, there could be more than one meaningful
   index behavior.  For example, we might want to sort a complex-number data
   type either by absolute value or by real part.  We could do this by
   defining two operator classes for the data type and then selecting
   the proper class when making an index.
  </p>
<p>   There are also some built-in operator classes besides the default ones:

   </p>
<div class="itemizedlist"><ul type="disc"><li>
<p>      The operator classes <code class="literal">text_pattern_ops</code>,
      <code class="literal">varchar_pattern_ops</code>,
      <code class="literal">bpchar_pattern_ops</code>, and
      <code class="literal">name_pattern_ops</code> support B-tree indexes on
      the types <code class="type">text</code>, <code class="type">varchar</code>,
      <code class="type">char</code>, and <code class="type">name</code>, respectively.  The
      difference from the default operator classes is that the values
      are compared strictly character by character rather than
      according to the locale-specific collation rules.  This makes
      these operator classes suitable for use by queries involving
      pattern matching expressions (<code class="literal">LIKE</code> or POSIX
      regular expressions) when the server does not use the standard
      &#8220;<span class="quote">C</span>&#8221; locale.  As an example, you might index a
      <code class="type">varchar</code> column like this:
</p>
<pre class="programlisting">CREATE INDEX test_index ON test_table (col varchar_pattern_ops);</pre>
<p>
      Note that you should also create an index with the default operator
      class if you want queries involving ordinary comparisons to use an
      index.  Such queries cannot use the
      <code class="literal"><em class="replaceable"><code>xxx</code></em>_pattern_ops</code>
      operator classes.  It is allowed to create multiple
      indexes on the same column with different operator classes.
      If you do use the C locale, you do not need the
      <code class="literal"><em class="replaceable"><code>xxx</code></em>_pattern_ops</code>
      operator classes, because an index with the default operator class
      is usable for pattern-matching queries in the C locale.
     </p>
</li></ul></div>
<p>
  </p>
<p>    The following query shows all defined operator classes:

</p>
<pre class="programlisting">SELECT am.amname AS index_method,
       opc.opcname AS opclass_name
    FROM pg_am am, pg_opclass opc
    WHERE opc.opcamid = am.oid
    ORDER BY index_method, opclass_name;</pre>
<p>

    It can be extended to show all the operators included in each class:
</p>
<pre class="programlisting">SELECT am.amname AS index_method,
       opc.opcname AS opclass_name,
       opr.oid::regoperator AS opclass_operator
    FROM pg_am am, pg_opclass opc, pg_amop amop, pg_operator opr
    WHERE opc.opcamid = am.oid AND
          amop.amopclaid = opc.oid AND
          amop.amopopr = opr.oid
    ORDER BY index_method, opclass_name, opclass_operator;</pre>
<p>
  </p>
</div></body>
</html>