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
|
<?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>7.4. Combining Queries (UNION, INTERSECT, EXCEPT)</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="queries-select-lists.html" title="7.3. Select Lists" /><link rel="next" href="queries-order.html" title="7.5. Sorting Rows (ORDER BY)" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">7.4. Combining Queries (<code class="literal">UNION</code>, <code class="literal">INTERSECT</code>, <code class="literal">EXCEPT</code>)</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="queries-select-lists.html" title="7.3. Select Lists">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="queries.html" title="Chapter 7. Queries">Up</a></td><th width="60%" align="center">Chapter 7. Queries</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 15.5 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="queries-order.html" title="7.5. Sorting Rows (ORDER BY)">Next</a></td></tr></table><hr /></div><div class="sect1" id="QUERIES-UNION"><div class="titlepage"><div><div><h2 class="title" style="clear: both">7.4. Combining Queries (<code class="literal">UNION</code>, <code class="literal">INTERSECT</code>, <code class="literal">EXCEPT</code>)</h2></div></div></div><a id="id-1.5.6.8.2" class="indexterm"></a><a id="id-1.5.6.8.3" class="indexterm"></a><a id="id-1.5.6.8.4" class="indexterm"></a><a id="id-1.5.6.8.5" class="indexterm"></a><a id="id-1.5.6.8.6" class="indexterm"></a><a id="id-1.5.6.8.7" class="indexterm"></a><a id="id-1.5.6.8.8" class="indexterm"></a><p>
The results of two queries can be combined using the set operations
union, intersection, and difference. The syntax is
</p><pre class="synopsis">
<em class="replaceable"><code>query1</code></em> UNION [<span class="optional">ALL</span>] <em class="replaceable"><code>query2</code></em>
<em class="replaceable"><code>query1</code></em> INTERSECT [<span class="optional">ALL</span>] <em class="replaceable"><code>query2</code></em>
<em class="replaceable"><code>query1</code></em> EXCEPT [<span class="optional">ALL</span>] <em class="replaceable"><code>query2</code></em>
</pre><p>
where <em class="replaceable"><code>query1</code></em> and
<em class="replaceable"><code>query2</code></em> are queries that can use any of
the features discussed up to this point.
</p><p>
<code class="literal">UNION</code> effectively appends the result of
<em class="replaceable"><code>query2</code></em> to the result of
<em class="replaceable"><code>query1</code></em> (although there is no guarantee
that this is the order in which the rows are actually returned).
Furthermore, it eliminates duplicate rows from its result, in the same
way as <code class="literal">DISTINCT</code>, unless <code class="literal">UNION ALL</code> is used.
</p><p>
<code class="literal">INTERSECT</code> returns all rows that are both in the result
of <em class="replaceable"><code>query1</code></em> and in the result of
<em class="replaceable"><code>query2</code></em>. Duplicate rows are eliminated
unless <code class="literal">INTERSECT ALL</code> is used.
</p><p>
<code class="literal">EXCEPT</code> returns all rows that are in the result of
<em class="replaceable"><code>query1</code></em> but not in the result of
<em class="replaceable"><code>query2</code></em>. (This is sometimes called the
<em class="firstterm">difference</em> between two queries.) Again, duplicates
are eliminated unless <code class="literal">EXCEPT ALL</code> is used.
</p><p>
In order to calculate the union, intersection, or difference of two
queries, the two queries must be <span class="quote">“<span class="quote">union compatible</span>”</span>,
which means that they return the same number of columns and
the corresponding columns have compatible data types, as
described in <a class="xref" href="typeconv-union-case.html" title="10.5. UNION, CASE, and Related Constructs">Section 10.5</a>.
</p><p>
Set operations can be combined, for example
</p><pre class="synopsis">
<em class="replaceable"><code>query1</code></em> UNION <em class="replaceable"><code>query2</code></em> EXCEPT <em class="replaceable"><code>query3</code></em>
</pre><p>
which is equivalent to
</p><pre class="synopsis">
(<em class="replaceable"><code>query1</code></em> UNION <em class="replaceable"><code>query2</code></em>) EXCEPT <em class="replaceable"><code>query3</code></em>
</pre><p>
As shown here, you can use parentheses to control the order of
evaluation. Without parentheses, <code class="literal">UNION</code>
and <code class="literal">EXCEPT</code> associate left-to-right,
but <code class="literal">INTERSECT</code> binds more tightly than those two
operators. Thus
</p><pre class="synopsis">
<em class="replaceable"><code>query1</code></em> UNION <em class="replaceable"><code>query2</code></em> INTERSECT <em class="replaceable"><code>query3</code></em>
</pre><p>
means
</p><pre class="synopsis">
<em class="replaceable"><code>query1</code></em> UNION (<em class="replaceable"><code>query2</code></em> INTERSECT <em class="replaceable"><code>query3</code></em>)
</pre><p>
You can also surround an individual <em class="replaceable"><code>query</code></em>
with parentheses. This is important if
the <em class="replaceable"><code>query</code></em> needs to use any of the clauses
discussed in following sections, such as <code class="literal">LIMIT</code>.
Without parentheses, you'll get a syntax error, or else the clause will
be understood as applying to the output of the set operation rather
than one of its inputs. For example,
</p><pre class="synopsis">
SELECT a FROM b UNION SELECT x FROM y LIMIT 10
</pre><p>
is accepted, but it means
</p><pre class="synopsis">
(SELECT a FROM b UNION SELECT x FROM y) LIMIT 10
</pre><p>
not
</p><pre class="synopsis">
SELECT a FROM b UNION (SELECT x FROM y LIMIT 10)
</pre><p>
</p></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="queries-select-lists.html" title="7.3. Select Lists">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="queries.html" title="Chapter 7. Queries">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="queries-order.html" title="7.5. Sorting Rows (ORDER BY)">Next</a></td></tr><tr><td width="40%" align="left" valign="top">7.3. Select Lists </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 15.5 Documentation">Home</a></td><td width="40%" align="right" valign="top"> 7.5. Sorting Rows (<code class="literal">ORDER BY</code>)</td></tr></table></div></body></html>
|