document the SQL-statements INTERSECT, EXCEPT and ANY, ALL operators

This commit is contained in:
Tatiana Kirillova 2021-10-20 20:18:14 +03:00
parent 3c8e963420
commit 1241db3795
4 changed files with 223 additions and 0 deletions

View File

@ -71,6 +71,54 @@ ClickHouse transforms operators to their corresponding functions at the query pa
`a GLOBAL NOT IN ...` The `globalNotIn(a, b)` function.
`ALL` The operator allows you to get data by comparing the value with the list of values returned by the subquery. The comparison condition must be running for all values of the subquery.
The subquery must select values of the same type as those compared in the main predicate.
**Example**
Query:
``` sql
SELECT number AS a FROM numbers(10) WHERE a > all(SELECT number FROM numbers(3, 3));
```
Result:
``` text
┌─a─┐
│ 6 │
│ 7 │
│ 8 │
│ 9 │
└───┘
```
`ANY` The operator is comparing a value to a set of values returned by a subquery. The comparison condition must be running for any values of the subquery.
The subquery must select values of the same type as those compared in the main predicate.
**Example**
Query:
``` sql
SELECT number AS a FROM numbers(10) WHERE a > any(SELECT number FROM numbers(3, 3));
```
Result:
``` text
┌─a─┐
│ 4 │
│ 5 │
│ 6 │
│ 7 │
│ 8 │
│ 9 │
└───┘
```
## Operators for Working with Dates and Times {#operators-datetime}
### EXTRACT {#operator-extract}

View File

@ -0,0 +1,86 @@
---
toc_title: EXCEPT
---
# EXCEPT Clause {#except-clause}
The `EXCEPT` clause returns only those rows that result from the first query without the second. The queries must match the number of columns, order, and type. The result of `EXCEPT` can contain duplicate rows.
Multiple `EXCEPT` statements execute left to right if brackets are not specified. The `EXCEPT` operator has the same priority as the `UNION` clause and lower priority as the `INTERSECT` clause.
``` sql
SELECT column1 [, column2 ]
FROM table1
[WHERE condition]
EXCEPT
SELECT column1 [, column2 ]
FROM table2
[WHERE condition]
```
The condition could be any expression based on your requirements.
**Example**
Query:
``` sql
SELECT number FROM numbers(1,10) EXCEPT SELECT number FROM numbers(3,6);
```
Result:
``` text
┌─number─┐
│ 1 │
│ 2 │
│ 9 │
│ 10 │
└────────┘
```
Query:
``` sql
SELECT number FROM numbers(1,10) WHERE number > 5 EXCEPT SELECT number FROM numbers(3,6) WHERE number < 7;
```
Result:
``` text
┌─number─┐
│ 7 │
│ 8 │
│ 9 │
│ 10 │
└────────┘
```
Query:
``` sql
CREATE TABLE t1(one String, two String, three String) ENGINE=Memory();
CREATE TABLE t2(four String, five String, six String) ENGINE=Memory();
INSERT INTO t1 VALUES ('q', 'm', 'b'), ('s', 'd', 'f'), ('l', 'p', 'o'), ('s', 'd', 'f'), ('s', 'd', 'f'), ('k', 't', 'd'), ('l', 'p', 'o');
INSERT INTO t2 VALUES ('q', 'm', 'b'), ('b', 'd', 'k'), ('s', 'y', 't'), ('s', 'd', 'f'), ('m', 'f', 'o'), ('k', 'k', 'd');
SELECT * FROM t1 EXCEPT SELECT * FROM t2;
```
Result:
``` text
┌─one─┬─two─┬─three─┐
│ l │ p │ o │
│ k │ t │ d │
│ l │ p │ o │
└─────┴─────┴───────┘
```
**See Also**
- [UNION](union.md#union-clause)
- [INTERSECT](except.md#except-clause)

View File

@ -49,6 +49,8 @@ Specifics of each optional clause are covered in separate sections, which are li
- [LIMIT clause](../../../sql-reference/statements/select/limit.md)
- [OFFSET clause](../../../sql-reference/statements/select/offset.md)
- [UNION clause](../../../sql-reference/statements/select/union.md)
- [INTERSECT clause](../../../sql-reference/statements/select/intersect.md)
- [EXCEPT clause](../../../sql-reference/statements/select/except.md)
- [INTO OUTFILE clause](../../../sql-reference/statements/select/into-outfile.md)
- [FORMAT clause](../../../sql-reference/statements/select/format.md)

View File

@ -0,0 +1,87 @@
---
toc_title: INTERSECT
---
# INTERSECT Clause {#intersect-clause}
The `INTERSECT` clause returns only those rows that result from first and second queries. The queries must match the number of columns, order, type, and names. The result of `INTERSECT` can contain duplicate rows.
Multiple `INTERSECT` statements execute left to right if brackets are not specified. The `INTERSECT` operator has a higher priority than the `UNION` and `EXCEPT` clause.
``` sql
SELECT column1 [, column2 ]
FROM table1
[WHERE condition]
INTERSECT
SELECT column1 [, column2 ]
FROM table2
[WHERE condition]
```
The condition could be any expression based on your requirements.
**Example**
Query:
``` sql
SELECT number FROM numbers(1,10) INTERSECT SELECT number FROM numbers(3,6);
```
Result:
``` text
┌─number─┐
│ 3 │
│ 4 │
│ 5 │
│ 6 │
│ 7 │
│ 8 │
└────────┘
```
Query:
``` sql
SELECT number FROM numbers(1,10) WHERE number > 5 INTERSECT SELECT number FROM numbers(3,6) WHERE number < 7;
```
Result:
``` text
┌─number─┐
│ 6 │
└────────┘
```
Query:
``` sql
CREATE TABLE t1(one String, two String, three String) ENGINE=Memory();
CREATE TABLE t2(four String, five String, six String) ENGINE=Memory();
INSERT INTO t1 VALUES ('q', 'm', 'b'), ('s', 'd', 'f'), ('l', 'p', 'o'), ('s', 'd', 'f'), ('s', 'd', 'f'), ('k', 't', 'd'), ('l', 'p', 'o');
INSERT INTO t2 VALUES ('q', 'm', 'b'), ('b', 'd', 'k'), ('s', 'y', 't'), ('s', 'd', 'f'), ('m', 'f', 'o'), ('k', 'k', 'd');
SELECT * FROM t1 INTERSECT SELECT * FROM t2;
```
Result:
``` text
┌─one─┬─two─┬─three─┐
│ q │ m │ b │
│ s │ d │ f │
│ s │ d │ f │
│ s │ d │ f │
└─────┴─────┴───────┘
```
**See Also**
- [UNION](union.md#union-clause)
- [EXCEPT](except.md#except-clause)