-
Notifications
You must be signed in to change notification settings - Fork 29k
[SPARK-30579][DOC] Document ORDER BY Clause of SELECT statement in SQL Reference #27288
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Changes from 3 commits
581a1e9
cb78d8d
d1fb7bd
a9dfbb4
ff61fa8
7e46a5f
c409609
File filter
Filter by extension
Conversations
Jump to
Diff view
Diff view
There are no files selected for viewing
| Original file line number | Diff line number | Diff line change |
|---|---|---|
|
|
@@ -18,5 +18,121 @@ license: | | |
| See the License for the specific language governing permissions and | ||
| limitations under the License. | ||
| --- | ||
| The <code>ORDER BY</code> clause is used to return the result rows in a sorted manner | ||
| in the user specified order. Unlike the <code>SORT BY</code> clause, this clause guarantees | ||
| total order in the output. | ||
|
||
|
|
||
| **This page is under construction** | ||
| ### Syntax | ||
| {% highlight sql %} | ||
| ORDER BY { expression [ sort_direction | nulls_sort_oder ] [ , ...] } | ||
| {% endhighlight %} | ||
|
|
||
| ### Parameters | ||
| <dl> | ||
| <dt><code><em>ORDER BY</em></code></dt> | ||
| <dd> | ||
| Specifies a comma-separated list of expressions along with optional parameters <code>sort_direction</code> | ||
| and <code>nulls_sort_order</code> which are used to sort the rows. | ||
| </dd> | ||
| <dt><code><em>sort_direction</em></code></dt> | ||
| <dd> | ||
| Optionally specifies whether to sort the rows in ascending (lowest to highest) or descending | ||
|
||
| (highest to lowest) order. The valid values for sort direction are <code>ASC</code> for ascending | ||
|
||
| and <code>DESC</code> for descending. If sort direction is not explicitly specified then by default | ||
| rows are sorted in ascending manner. <br><br> | ||
|
||
| <b>Syntax:</b> | ||
| <code> | ||
| [ ASC | DESC ] | ||
| </code> | ||
| </dd> | ||
| <dt><code><em>nulls_sort_order</em></code></dt> | ||
| <dd> | ||
| Optionally specifies whether NULL values are returned before/after non-NULL values, based on the | ||
| sort direction. In Spark, NULL values are considered to be lower than any non-NULL values by default. | ||
| Therefore the ordering of NULL values depend on the sort direction.<br><br> | ||
| <ol> | ||
| <li>If the sort order is ASC, NULLS are returned first; to force NULLS to be last, use NULLS LAST</li> | ||
|
||
| <li>If the sort order is DESC, NULLS are returned last; to force NULLS to be first, use NULLS FIRST</li> | ||
| </ol><br> | ||
| <b>Syntax:</b> | ||
| <code> | ||
| [ NULLS { FIRST | LAST } ] | ||
| </code> | ||
| </dd> | ||
| </dl> | ||
|
|
||
| ### Examples | ||
| {% highlight sql %} | ||
| CREATE TABLE person (id INT, name STRING, age INT); | ||
| INSERT INTO person VALUES (100, 'John', 30), | ||
| (200, 'Mary', NULL), | ||
| (300, 'Mike', 80), | ||
| (400, 'Jerry', NULL), | ||
| (500, 'Dan', 50); | ||
|
|
||
| -- Sort rows by age. By default rows are sorted in ascending manner. | ||
| SELECT name, age FROM person ORDER BY age; | ||
|
|
||
| +-----+----+ | ||
| |name |age | | ||
| +-----+----+ | ||
| |Jerry|null| | ||
| |Mary |null| | ||
| |John |30 | | ||
| |Dan |50 | | ||
| |Mike |80 | | ||
| +-----+----+ | ||
|
|
||
| -- Sort rows in ascending manner keeping null values to be last. | ||
| SELECT name, age FROM person ORDER BY age NULLS LAST; | ||
|
|
||
| +-----+----+ | ||
| |name |age | | ||
| +-----+----+ | ||
| |John |30 | | ||
| |Dan |50 | | ||
| |Mike |80 | | ||
| |Mary |null| | ||
| |Jerry|null| | ||
| +-----+----+ | ||
|
|
||
| -- Sort rows by age in descending manner. | ||
| SELECT name, age FROM person ORDER BY age DESC; | ||
|
|
||
| +-----+----+ | ||
| |name |age | | ||
| +-----+----+ | ||
| |Mike |80 | | ||
| |Dan |50 | | ||
| |John |30 | | ||
| |Jerry|null| | ||
| |Mary |null| | ||
| +-----+----+ | ||
|
|
||
| -- Sort rows in ascending manner keeping null values to be first. | ||
| SELECT name, age FROM person ORDER BY age DESC NULLS FIRST; | ||
|
|
||
| +-----+----+ | ||
| |name |age | | ||
| +-----+----+ | ||
| |Jerry|null| | ||
| |Mary |null| | ||
| |Mike |80 | | ||
| |Dan |50 | | ||
| |John |30 | | ||
| +-----+----+ | ||
|
|
||
| -- Sort rows based on more than one column with each column having different | ||
| -- sort direction. | ||
| SELECT * FROM person ORDER BY name ASC, age DESC; | ||
|
|
||
| +---+-----+----+ | ||
| |id |name |age | | ||
| +---+-----+----+ | ||
| |500|Dan |50 | | ||
| |400|Jerry|null| | ||
| |100|John |30 | | ||
| |200|Mary |null| | ||
| |300|Mike |80 | | ||
| +---+-----+----+ | ||
| {% endhighlight %} | ||
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
link to
SORT BY?There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
@huaxingao will do it in the finalization pr.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
OK if you want to take care of that at the end