summaryrefslogtreecommitdiff
path: root/doc/src/sgml/citext.sgml
blob: 28c5043183cd2c0417c7f8f588d16409122d7982 (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
223
224
225
226
227
228
229
230
231
232
233
<!-- $PostgreSQL: pgsql/doc/src/sgml/citext.sgml,v 1.5 2010/07/29 19:34:40 petere Exp $ -->

<sect1 id="citext">
 <title>citext</title>

 <indexterm zone="citext">
  <primary>citext</primary>
 </indexterm>

 <para>
  The <filename>citext</> module provides a case-insensitive
  character string type, <type>citext</>. Essentially, it internally calls
  <function>lower</> when comparing values. Otherwise, it behaves almost
  exactly like <type>text</>.
 </para>

 <sect2>
  <title>Rationale</title>

  <para>
   The standard approach to doing case-insensitive matches
   in <productname>PostgreSQL</> has been to use the <function>lower</>
   function when comparing values, for example

<programlisting>
SELECT * FROM tab WHERE lower(col) = LOWER(?);
</programlisting>
  </para>

  <para>
   This works reasonably well, but has a number of drawbacks:
  </para>

   <itemizedlist>
    <listitem>
     <para>
      It makes your SQL statements verbose, and you always have to remember to
      use <function>lower</> on both the column and the query value.
     </para>
    </listitem>
    <listitem>
     <para>
      It won't use an index, unless you create a functional index using
      <function>lower</>.
     </para>
    </listitem>
    <listitem>
     <para>
      If you declare a column as <literal>UNIQUE</> or <literal>PRIMARY
      KEY</>, the implicitly generated index is case-sensitive.  So it's
      useless for case-insensitive searches, and it won't enforce
      uniqueness case-insensitively.
     </para>
    </listitem>
   </itemizedlist>

   <para>
    The <type>citext</> data type allows you to eliminate calls
    to <function>lower</> in SQL queries, and allows a primary key to
    be case-insensitive. <type>citext</> is locale-aware, just
    like <type>text</>, which means that the comparison of upper case and
    lower case characters is dependent on the rules of
    the <literal>LC_CTYPE</> locale setting. Again, this behavior is
    identical to the use of <function>lower</> in queries. But because it's
    done transparently by the datatype, you don't have to remember to do
    anything special in your queries.
   </para>

 </sect2>

 <sect2>
  <title>How to Use It</title>

  <para>
   Here's a simple example of usage:

<programlisting>
CREATE TABLE users (
    nick CITEXT PRIMARY KEY,
    pass TEXT   NOT NULL
);

INSERT INTO users VALUES ( 'larry',  md5(random()::text) );
INSERT INTO users VALUES ( 'Tom',    md5(random()::text) );
INSERT INTO users VALUES ( 'Damian', md5(random()::text) );
INSERT INTO users VALUES ( 'NEAL',   md5(random()::text) );
INSERT INTO users VALUES ( 'Bj&oslash;rn',  md5(random()::text) );

SELECT * FROM users WHERE nick = 'Larry';
</programlisting>

   The <command>SELECT</> statement will return one tuple, even though
   the <structfield>nick</> column was set to <quote>larry</> and the query
   was for <quote>Larry</>.
  </para>
 </sect2>

 <sect2>
  <title>String Comparison Behavior</title>
  <para>
   In order to emulate a case-insensitive collation as closely as possible,
   there are <type>citext</>-specific versions of a number of the comparison
   operators and functions.  So, for example, the regular expression
   operators <literal>~</> and <literal>~*</> exhibit the same behavior when
   applied to <type>citext</>: they both compare case-insensitively.
   The same is true
   for <literal>!~</> and <literal>!~*</>, as well as for the
   <literal>LIKE</> operators <literal>~~</> and <literal>~~*</>, and
   <literal>!~~</> and <literal>!~~*</>. If you'd like to match
   case-sensitively, you can always cast to <type>text</> before comparing.
  </para>

  <para>
   Similarly, all of the following functions perform matching
   case-insensitively if their arguments are <type>citext</>:
  </para>

  <itemizedlist>
   <listitem>
    <para>
      <function>regexp_replace()</>
    </para>
   </listitem>
   <listitem>
    <para>
      <function>regexp_split_to_array()</>
    </para>
   </listitem>
   <listitem>
    <para>
      <function>regexp_split_to_table()</>
    </para>
   </listitem>
   <listitem>
    <para>
      <function>replace()</>
    </para>
   </listitem>
   <listitem>
    <para>
      <function>split_part()</>
    </para>
   </listitem>
   <listitem>
    <para>
      <function>strpos()</>
    </para>
   </listitem>
   <listitem>
    <para>
      <function>translate()</>
    </para>
   </listitem>
  </itemizedlist>

  <para>
   For the regexp functions, if you want to match case-sensitively, you can
   specify the <quote>c</> flag to force a case-sensitive match.  Otherwise,
   you must cast to <type>text</> before using one of these functions if
   you want case-sensitive behavior.
  </para>

 </sect2>

 <sect2>
  <title>Limitations</title>

   <itemizedlist>
    <listitem>
     <para>
      <type>citext</>'s behavior depends on
      the <literal>LC_CTYPE</> setting of your database. How it compares
      values is therefore determined when
      <application>initdb</> is run to create the cluster. It is not truly
      case-insensitive in the terms defined by the Unicode standard.
      Effectively, what this means is that, as long as you're happy with your
      collation, you should be happy with <type>citext</>'s comparisons. But
      if you have data in different languages stored in your database, users
      of one language may find their query results are not as expected if the
      collation is for another language.
     </para>
    </listitem>

    <listitem>
     <para>
       <type>citext</> is not as efficient as <type>text</> because the
       operator functions and the btree comparison functions must make copies
       of the data and convert it to lower case for comparisons. It is,
       however, slightly more efficient than using <function>lower</> to get
       case-insensitive matching.
     </para>
    </listitem>

    <listitem>
     <para>
      <type>citext</> doesn't help much if you need data to compare
      case-sensitively in some contexts and case-insensitively in other
      contexts.  The standard answer is to use the <type>text</> type and
      manually use the <function>lower</> function when you need to compare
      case-insensitively; this works all right if case-insensitive comparison
      is needed only infrequently.  If you need case-insensitive most of
      the time and case-sensitive infrequently, consider storing the data
      as <type>citext</> and explicitly casting the column to <type>text</>
      when you want case-sensitive comparison.  In either situation, you
      will need two indexes if you want both types of searches to be fast.
    </para>
    </listitem>

    <listitem>
     <para>
      The schema containing the <type>citext</> operators must be
      in the current <varname>search_path</> (typically <literal>public</>);
      if it is not, a normal case-sensitive <type>text</> comparison
      is performed.
    </para>
    </listitem>
   </itemizedlist>
 </sect2>

 <sect2>
  <title>Author</title>

  <para>
   David E. Wheeler <email>[email protected]</email>
  </para>

  <para>
    Inspired by the original <type>citext</> module by Donald Fraser.
  </para>

 </sect2>

</sect1>