aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/func/func-comparisons.sgml
blob: 6a6e0bd401920426b9db0ba94f6e96ccd1b987f5 (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
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
 <sect1 id="functions-comparisons">
  <title>Row and Array Comparisons</title>

  <indexterm>
   <primary>IN</primary>
  </indexterm>

  <indexterm>
   <primary>NOT IN</primary>
  </indexterm>

  <indexterm>
   <primary>ANY</primary>
  </indexterm>

  <indexterm>
   <primary>ALL</primary>
  </indexterm>

  <indexterm>
   <primary>SOME</primary>
  </indexterm>

  <indexterm>
   <primary>composite type</primary>
   <secondary>comparison</secondary>
  </indexterm>

  <indexterm>
   <primary>row-wise comparison</primary>
  </indexterm>

  <indexterm>
   <primary>comparison</primary>
   <secondary>composite type</secondary>
  </indexterm>

  <indexterm>
   <primary>comparison</primary>
   <secondary>row constructor</secondary>
  </indexterm>

  <indexterm>
   <primary>IS DISTINCT FROM</primary>
  </indexterm>

  <indexterm>
   <primary>IS NOT DISTINCT FROM</primary>
  </indexterm>

  <para>
   This section describes several specialized constructs for making
   multiple comparisons between groups of values.  These forms are
   syntactically related to the subquery forms of the previous section,
   but do not involve subqueries.
   The forms involving array subexpressions are
   <productname>PostgreSQL</productname> extensions; the rest are
   <acronym>SQL</acronym>-compliant.
   All of the expression forms documented in this section return
   Boolean (true/false) results.
  </para>

  <sect2 id="functions-comparisons-in-scalar">
   <title><literal>IN</literal></title>

<synopsis>
<replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
</synopsis>

  <para>
   The right-hand side is a parenthesized list
   of expressions.  The result is <quote>true</quote> if the left-hand expression's
   result is equal to any of the right-hand expressions.  This is a shorthand
   notation for

<synopsis>
<replaceable>expression</replaceable> = <replaceable>value1</replaceable>
OR
<replaceable>expression</replaceable> = <replaceable>value2</replaceable>
OR
...
</synopsis>
  </para>

  <para>
   Note that if the left-hand expression yields null, or if there are
   no equal right-hand values and at least one right-hand expression yields
   null, the result of the <token>IN</token> construct will be null, not false.
   This is in accordance with SQL's normal rules for Boolean combinations
   of null values.
  </para>
  </sect2>

  <sect2 id="functions-comparisons-not-in">
   <title><literal>NOT IN</literal></title>

<synopsis>
<replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
</synopsis>

  <para>
   The right-hand side is a parenthesized list
   of expressions.  The result is <quote>true</quote> if the left-hand expression's
   result is unequal to all of the right-hand expressions.  This is a shorthand
   notation for

<synopsis>
<replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
AND
<replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
AND
...
</synopsis>
  </para>

  <para>
   Note that if the left-hand expression yields null, or if there are
   no equal right-hand values and at least one right-hand expression yields
   null, the result of the <token>NOT IN</token> construct will be null, not true
   as one might naively expect.
   This is in accordance with SQL's normal rules for Boolean combinations
   of null values.
  </para>

  <tip>
  <para>
   <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
   cases.  However, null values are much more likely to trip up the novice when
   working with <token>NOT IN</token> than when working with <token>IN</token>.
   It is best to express your condition positively if possible.
  </para>
  </tip>
  </sect2>

  <sect2 id="functions-comparisons-any-some">
   <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>

<synopsis>
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
</synopsis>

  <para>
   The right-hand side is a parenthesized expression, which must yield an
   array value.
   The left-hand expression
   is evaluated and compared to each element of the array using the
   given <replaceable>operator</replaceable>, which must yield a Boolean
   result.
   The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained.
   The result is <quote>false</quote> if no true result is found (including the
   case where the array has zero elements).
  </para>

  <para>
   If the array expression yields a null array, the result of
   <token>ANY</token> will be null.  If the left-hand expression yields null,
   the result of <token>ANY</token> is ordinarily null (though a non-strict
   comparison operator could possibly yield a different result).
   Also, if the right-hand array contains any null elements and no true
   comparison result is obtained, the result of <token>ANY</token>
   will be null, not false (again, assuming a strict comparison operator).
   This is in accordance with SQL's normal rules for Boolean combinations
   of null values.
  </para>

  <para>
   <token>SOME</token> is a synonym for <token>ANY</token>.
  </para>
  </sect2>

  <sect2 id="functions-comparisons-all">
   <title><literal>ALL</literal> (array)</title>

<synopsis>
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
</synopsis>

  <para>
   The right-hand side is a parenthesized expression, which must yield an
   array value.
   The left-hand expression
   is evaluated and compared to each element of the array using the
   given <replaceable>operator</replaceable>, which must yield a Boolean
   result.
   The result of <token>ALL</token> is <quote>true</quote> if all comparisons yield true
   (including the case where the array has zero elements).
   The result is <quote>false</quote> if any false result is found.
  </para>

  <para>
   If the array expression yields a null array, the result of
   <token>ALL</token> will be null.  If the left-hand expression yields null,
   the result of <token>ALL</token> is ordinarily null (though a non-strict
   comparison operator could possibly yield a different result).
   Also, if the right-hand array contains any null elements and no false
   comparison result is obtained, the result of <token>ALL</token>
   will be null, not true (again, assuming a strict comparison operator).
   This is in accordance with SQL's normal rules for Boolean combinations
   of null values.
  </para>
  </sect2>

  <sect2 id="row-wise-comparison">
   <title>Row Constructor Comparison</title>

<synopsis>
<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
</synopsis>

  <para>
   Each side is a row constructor,
   as described in <xref linkend="sql-syntax-row-constructors"/>.
   The two row constructors must have the same number of fields.
   The given <replaceable>operator</replaceable> is applied to each pair
   of corresponding fields.  (Since the fields could be of different
   types, this means that a different specific operator could be selected
   for each pair.)
   All the selected operators must be members of some B-tree operator
   class, or be the negator of an <literal>=</literal> member of a B-tree
   operator class, meaning that row constructor comparison is only
   possible when the <replaceable>operator</replaceable> is
   <literal>=</literal>,
   <literal>&lt;&gt;</literal>,
   <literal>&lt;</literal>,
   <literal>&lt;=</literal>,
   <literal>&gt;</literal>, or
   <literal>&gt;=</literal>,
   or has semantics similar to one of these.
  </para>

  <para>
   The <literal>=</literal> and <literal>&lt;&gt;</literal> cases work slightly differently
   from the others.  Two rows are considered
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
   otherwise the result of the row comparison is unknown (null).
  </para>

  <para>
   For the <literal>&lt;</literal>, <literal>&lt;=</literal>, <literal>&gt;</literal> and
   <literal>&gt;=</literal> cases, the row elements are compared left-to-right,
   stopping as soon as an unequal or null pair of elements is found.
   If either of this pair of elements is null, the result of the
   row comparison is unknown (null); otherwise comparison of this pair
   of elements determines the result.  For example,
   <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</literal>
   yields true, not null, because the third pair of elements are not
   considered.
  </para>

<synopsis>
<replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
</synopsis>

  <para>
   This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
   but it does not yield null for null inputs.  Instead, any null value is
   considered unequal to (distinct from) any non-null value, and any two
   nulls are considered equal (not distinct).  Thus the result will
   either be true or false, never null.
  </para>

<synopsis>
<replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
</synopsis>

  <para>
   This construct is similar to a <literal>=</literal> row comparison,
   but it does not yield null for null inputs.  Instead, any null value is
   considered unequal to (distinct from) any non-null value, and any two
   nulls are considered equal (not distinct).  Thus the result will always
   be either true or false, never null.
  </para>

  </sect2>

  <sect2 id="composite-type-comparison">
   <title>Composite Type Comparison</title>

<synopsis>
<replaceable>record</replaceable> <replaceable>operator</replaceable> <replaceable>record</replaceable>
</synopsis>

  <para>
   The SQL specification requires row-wise comparison to return NULL if the
   result depends on comparing two NULL values or a NULL and a non-NULL.
   <productname>PostgreSQL</productname> does this only when comparing the
   results of two row constructors (as in
   <xref linkend="row-wise-comparison"/>) or comparing a row constructor
   to the output of a subquery (as in <xref linkend="functions-subquery"/>).
   In other contexts where two composite-type values are compared, two
   NULL field values are considered equal, and a NULL is considered larger
   than a non-NULL.  This is necessary in order to have consistent sorting
   and indexing behavior for composite types.
  </para>

  <para>
   Each side is evaluated and they are compared row-wise.  Composite type
   comparisons are allowed when the <replaceable>operator</replaceable> is
   <literal>=</literal>,
   <literal>&lt;&gt;</literal>,
   <literal>&lt;</literal>,
   <literal>&lt;=</literal>,
   <literal>&gt;</literal> or
   <literal>&gt;=</literal>,
   or has semantics similar to one of these.  (To be specific, an operator
   can be a row comparison operator if it is a member of a B-tree operator
   class, or is the negator of the <literal>=</literal> member of a B-tree operator
   class.)  The default behavior of the above operators is the same as for
   <literal>IS [ NOT ] DISTINCT FROM</literal> for row constructors (see
   <xref linkend="row-wise-comparison"/>).
  </para>

  <para>
   To support matching of rows which include elements without a default
   B-tree operator class, the following operators are defined for composite
   type comparison:
   <literal>*=</literal>,
   <literal>*&lt;&gt;</literal>,
   <literal>*&lt;</literal>,
   <literal>*&lt;=</literal>,
   <literal>*&gt;</literal>, and
   <literal>*&gt;=</literal>.
   These operators compare the internal binary representation of the two
   rows.  Two rows might have a different binary representation even
   though comparisons of the two rows with the equality operator is true.
   The ordering of rows under these comparison operators is deterministic
   but not otherwise meaningful.  These operators are used internally
   for materialized views and might be useful for other specialized
   purposes such as replication and B-Tree deduplication (see <xref
   linkend="btree-deduplication"/>).  They are not intended to be
   generally useful for writing queries, though.
  </para>
  </sect2>
 </sect1>