spark-instrumented-optimizer/docs/sql-ref-syntax-qry-select-setops.md
Huaxin Gao 75da05038b [MINOR][SQL][DOCS] Remove two leading spaces from sql tables
### What changes were proposed in this pull request?
Remove two leading spaces from sql tables.

### Why are the changes needed?

Follow the format of other references such as https://docs.snowflake.com/en/sql-reference/constructs/join.html, https://docs.oracle.com/cd/B19306_01/server.102/b14200/statements_10002.htm, https://www.postgresql.org/docs/10/sql-select.html.

### Does this PR introduce any user-facing change?

before
```
SELECT * FROM  test;
  +-+
  ...
  +-+
```
after
```
SELECT * FROM  test;
+-+
...
+-+
```

### How was this patch tested?
Manually build and check

Closes #28348 from huaxingao/sql-format.

Authored-by: Huaxin Gao <huaxing@us.ibm.com>
Signed-off-by: gatorsmile <gatorsmile@gmail.com>
2020-05-01 10:11:43 -07:00

3.7 KiB

layout title displayTitle license
global Set Operators Set Operators Licensed to the Apache Software Foundation (ASF) under one or more contributor license agreements. See the NOTICE file distributed with this work for additional information regarding copyright ownership. The ASF licenses this file to You under the Apache License, Version 2.0 (the "License"); you may not use this file except in compliance with the License. You may obtain a copy of the License at http://www.apache.org/licenses/LICENSE-2.0 Unless required by applicable law or agreed to in writing, software distributed under the License is distributed on an "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. See the License for the specific language governing permissions and limitations under the License.

Description

Set operators are used to combine two input relations into a single one. Spark SQL supports three types of set operators:

  • EXCEPT or MINUS
  • INTERSECT
  • UNION

Note that input relations must have the same number of columns and compatible data types for the respective columns.

EXCEPT

EXCEPT and EXCEPT ALL return the rows that are found in one relation but not the other. EXCEPT (alternatively, EXCEPT DISTINCT) takes only distinct rows while EXCEPT ALL does not remove duplicates from the result rows. Note that MINUS is an alias for EXCEPT.

Syntax

{% highlight sql %} [ ( ] relation [ ) ] EXCEPT | MINUS [ ALL | DISTINCT ] [ ( ] relation [ ) ] {% endhighlight %}

Examples

{% highlight sql %} -- Use number1 and number2 tables to demonstrate set operators in this page. SELECT * FROM number1; +---+ | c| +---+ | 3| | 1| | 2| | 2| | 3| | 4| +---+

SELECT * FROM number2; +---+ | c| +---+ | 5| | 1| | 2| | 2| +---+

SELECT c FROM number1 EXCEPT SELECT c FROM number2; +---+ | c| +---+ | 3| | 4| +---+

SELECT c FROM number1 MINUS SELECT c FROM number2; +---+ | c| +---+ | 3| | 4| +---+

SELECT c FROM number1 EXCEPT ALL (SELECT c FROM number2); +---+ | c| +---+ | 3| | 3| | 4| +---+

SELECT c FROM number1 MINUS ALL (SELECT c FROM number2); +---+ | c| +---+ | 3| | 3| | 4| +---+ {% endhighlight %}

INTERSECT

INTERSECT and INTERSECT ALL return the rows that are found in both relations. INTERSECT (alternatively, INTERSECT DISTINCT) takes only distinct rows while INTERSECT ALL does not remove duplicates from the result rows.

Syntax

{% highlight sql %} [ ( ] relation [ ) ] INTERSECT [ ALL | DISTINCT ] [ ( ] relation [ ) ] {% endhighlight %}

Examples

{% highlight sql %} (SELECT c FROM number1) INTERSECT (SELECT c FROM number2); +---+ | c| +---+ | 1| | 2| +---+

(SELECT c FROM number1) INTERSECT DISTINCT (SELECT c FROM number2); +---+ | c| +---+ | 1| | 2| +---+

(SELECT c FROM number1) INTERSECT ALL (SELECT c FROM number2); +---+ | c| +---+ | 1| | 2| | 2| +---+ {% endhighlight %}

UNION

UNION and UNION ALL return the rows that are found in either relation. UNION (alternatively, UNION DISTINCT) takes only distinct rows while UNION ALL does not remove duplicates from the result rows.

Syntax

{% highlight sql %} [ ( ] relation [ ) ] UNION [ ALL | DISTINCT ] [ ( ] relation [ ) ] {% endhighlight %}

Examples

{% highlight sql %} (SELECT c FROM number1) UNION (SELECT c FROM number2); +---+ | c| +---+ | 1| | 3| | 5| | 4| | 2| +---+

(SELECT c FROM number1) UNION DISTINCT (SELECT c FROM number2); +---+ | c| +---+ | 1| | 3| | 5| | 4| | 2| +---+

SELECT c FROM number1 UNION ALL (SELECT c FROM number2); +---+ | c| +---+ | 3| | 1| | 2| | 2| | 3| | 4| | 5| | 1| | 2| | 2| +---+ {% endhighlight %}