SORT BY 子句SORT BY clause

返回按用户指定顺序在每个分区内排序的结果行。Returns the result rows sorted within each partition in the user specified order. 当有多个分区 SORT BY 可能返回部分排序的结果时。When there is more than one partition SORT BY may return result that is partially ordered. 这与 ORDER BY 子句不同,后者可保证输出的总体顺序。This is different than ORDER BY clause which guarantees a total order of the output.

语法Syntax

SORT BY { expression [ sort_direction | nulls_sort_order ] [ , ... ] }

参数Parameters

  • 排序方式SORT BY

    一个逗号分隔的表达式列表,其中包含可选参数 sort_direction 以及 nulls_sort_order 用于对每个分区中的行进行排序的表达式。A comma-separated list of expressions along with optional parameters sort_direction and nulls_sort_order which are used to sort the rows within each partition.

  • sort_directionsort_direction

    根据需要指定是否按升序或降序对行进行排序。Optionally specifies whether to sort the rows in ascending or descending order. 排序方向的有效值 ASC 为升序和 DESC 降序。The valid values for the sort direction are ASC for ascending and DESC for descending. 如果未显式指定排序方向,则默认情况下,行按升序排序。If sort direction is not explicitly specified, then by default rows are sorted ascending.

    语法:[ ASC | DESC ]Syntax: [ ASC | DESC ]

  • nulls_sort_ordernulls_sort_order

    选择性地指定是否在非 NULL 值之前/之后返回 NULL 值。Optionally specifies whether NULL values are returned before/after non-NULL values. 如果 null_sort_order 未指定,则在排序顺序为时首先为 null,如果 ASC 排序顺序为,则为最后一个值排序 DESCIf null_sort_order is not specified, then NULLs sort first if sort order is ASC and NULLS sort last if sort order is DESC.

    1. 如果 NULLS FIRST 指定了,则将首先返回 NULL 值,而不考虑排序顺序。If NULLS FIRST is specified, then NULL values are returned first regardless of the sort order.
    2. 如果 NULLS LAST 指定了,则将最后返回 NULL 值,而不考虑排序顺序。If NULLS LAST is specified, then NULL values are returned last regardless of the sort order.

    语法:[ NULLS { FIRST | LAST } ]Syntax: [ NULLS { FIRST | LAST } ]

示例Examples

CREATE TABLE person (zip_code INT, name STRING, age INT);
INSERT INTO person VALUES
    (94588, 'Zen Hui', 50),
    (94588, 'Dan Li', 18),
    (94588, 'Anil K', 27),
    (94588, 'John V', NULL),
    (94511, 'David K', 42),
    (94511, 'Aryan B.', 18),
    (94511, 'Lalit B.', NULL);

-- Use `REPARTITION` hint to partition the data by `zip_code` to
-- examine the `SORT BY` behavior. This is used in rest of the
-- examples.

-- Sort rows by `name` within each partition in ascending manner
SELECT /*+ REPARTITION(zip_code) */ name, age, zip_code FROM person SORT BY name;
+--------+----+--------+
|    name| age|zip_code|
+--------+----+--------+
|  Anil K|  27|   94588|
|  Dan Li|  18|   94588|
|  John V|null|   94588|
| Zen Hui|  50|   94588|
|Aryan B.|  18|   94511|
| David K|  42|   94511|
|Lalit B.|null|   94511|
+--------+----+--------+

-- Sort rows within each partition using column position.
SELECT /*+ REPARTITION(zip_code) */ name, age, zip_code FROM person SORT BY 1;
+--------+----+--------+
|    name| age|zip_code|
+--------+----+--------+
|  Anil K|  27|   94588|
|  Dan Li|  18|   94588|
|  John V|null|   94588|
| Zen Hui|  50|   94588|
|Aryan B.|  18|   94511|
| David K|  42|   94511|
|Lalit B.|null|   94511|
+--------+----+--------+

-- Sort rows within partition in ascending manner keeping null values to be last.
SELECT /*+ REPARTITION(zip_code) */ age, name, zip_code FROM person SORT BY age NULLS LAST;
+----+--------+--------+
| age|    name|zip_code|
+----+--------+--------+
|  18|  Dan Li|   94588|
|  27|  Anil K|   94588|
|  50| Zen Hui|   94588|
|null|  John V|   94588|
|  18|Aryan B.|   94511|
|  42| David K|   94511|
|null|Lalit B.|   94511|
+----+--------+--------+

-- Sort rows by age within each partition in descending manner, which defaults to NULL LAST.
SELECT /*+ REPARTITION(zip_code) */ age, name, zip_code FROM person SORT BY age DESC;
+----+--------+--------+
| age|    name|zip_code|
+----+--------+--------+
|  50| Zen Hui|   94588|
|  27|  Anil K|   94588|
|  18|  Dan Li|   94588|
|null|  John V|   94588|
|  42| David K|   94511|
|  18|Aryan B.|   94511|
|null|Lalit B.|   94511|
+----+--------+--------+

-- Sort rows by age within each partition in descending manner keeping null values to be first.
SELECT /*+ REPARTITION(zip_code) */ age, name, zip_code FROM person SORT BY age DESC NULLS FIRST;
+----+--------+--------+
| age|    name|zip_code|
+----+--------+--------+
|null|  John V|   94588|
|  50| Zen Hui|   94588|
|  27|  Anil K|   94588|
|  18|  Dan Li|   94588|
|null|Lalit B.|   94511|
|  42| David K|   94511|
|  18|Aryan B.|   94511|
+----+--------+--------+

-- Sort rows within each partition based on more than one column with each column having
-- different sort direction.
SELECT /*+ REPARTITION(zip_code) */ name, age, zip_code FROM person
    SORT BY name ASC, age DESC;
+--------+----+--------+
|    name| age|zip_code|
+--------+----+--------+
|  Anil K|  27|   94588|
|  Dan Li|  18|   94588|
|  John V|null|   94588|
| Zen Hui|  50|   94588|
|Aryan B.|  18|   94511|
| David K|  42|   94511|
|Lalit B.|null|   94511|
+--------+----+--------+