-
Notifications
You must be signed in to change notification settings - Fork 24.8k
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
SQL: Implement CASE... WHEN... THEN... ELSE... END #41349
Changes from 4 commits
8fd1da2
1f17aca
0a53fb6
1bd870f
83dc691
365f135
1853714
a791a84
5793884
fda4180
94d5a60
7527f49
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 |
---|---|---|
@@ -1,10 +1,89 @@ | ||
[role="xpack"] | ||
[testenv="basic"] | ||
[[sql-functions-conditional]] | ||
=== Conditional Functions | ||
=== Conditional Functions And Expressions | ||
|
||
Functions that return one of their arguments by evaluating in an if-else manner. | ||
|
||
[[sql-functions-conditional-case]] | ||
==== `CASE` | ||
|
||
.Synopsis: | ||
[source, sql] | ||
---- | ||
CASE WHEN condition THEN result | ||
[WHEN ...] | ||
[ELSE defaultResult] | ||
END | ||
---- | ||
|
||
*Input*: | ||
|
||
Multiple but at least one WHEN *condition* THEN *result* clause and optional ELSE *defaultResult* clause. | ||
Every *condition* should be boolean expression. | ||
|
||
*Output*: one of the *result* expressions if the corresponding WHEN *condition* evaluates to `true`, | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more.
|
||
the *defaultResult* if all WHEN *condition* clauses evaluate to `false`. If the optional ELSE *defaultResult* | ||
clause is missing and all WHEN *condition* clauses evaluate to `false` then `null` is returned. | ||
|
||
.Description | ||
|
||
The case expression is a generic conditional expression which simulates if/else statements of other programming languages | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more.
|
||
If the condition’s result is true, the value of the result expression that follows the condition will be the returned | ||
the subsequent when clauses will be skipped and not processed. | ||
|
||
|
||
|
||
["source","sql",subs="attributes,callouts,macros"] | ||
---- | ||
include-tagged::{sql-specs}/docs/docs.csv-spec[case] | ||
---- | ||
|
||
["source","sql",subs="attributes,callouts,macros"] | ||
---- | ||
include-tagged::{sql-specs}/docs/docs.csv-spec[caseReturnNull] | ||
---- | ||
|
||
["source","sql",subs="attributes,callouts,macros"] | ||
---- | ||
include-tagged::{sql-specs}/docs/docs.csv-spec[caseWithElse] | ||
---- | ||
|
||
|
||
As a variant, a case expression can be expressed with a syntax similar to *switch-case* of other programming languages: | ||
[source, sql] | ||
---- | ||
CASE expression | ||
WHEN value1 THEN result1 | ||
[WHEN value2 THEN result2] | ||
[WHEN ...] | ||
[ELSE defaultResult] | ||
END | ||
---- | ||
|
||
In this case it's transformed internally to: | ||
[source, sql] | ||
---- | ||
CASE WHEN expression = value1 THEN result1 | ||
[WHEN expression = value2 THEN result2] | ||
[WHEN ...] | ||
[ELSE defaultResult] | ||
END | ||
---- | ||
|
||
["source","sql",subs="attributes,callouts,macros"] | ||
---- | ||
include-tagged::{sql-specs}/docs/docs.csv-spec[caseWithOperand] | ||
---- | ||
|
||
["source","sql",subs="attributes,callouts,macros"] | ||
---- | ||
include-tagged::{sql-specs}/docs/docs.csv-spec[caseWithOperandAndElse] | ||
---- | ||
|
||
[NOTE] | ||
All result expressions must be of compatible data types. | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Can you give an example here? |
||
|
||
[[sql-functions-conditional-coalesce]] | ||
==== `COALESCE` | ||
|
||
|
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -25,6 +25,7 @@ STDDEV_POP |AGGREGATE | |
SUM_OF_SQUARES |AGGREGATE | ||
VAR_POP |AGGREGATE | ||
HISTOGRAM |GROUPING | ||
CASE |CONDITIONAL | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Do you agree with listing CASE as a conditional function? |
||
COALESCE |CONDITIONAL | ||
GREATEST |CONDITIONAL | ||
IFNULL |CONDITIONAL | ||
|
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,159 @@ | ||
caseField | ||
SELECT CASE WHEN emp_no - 10000 < 10 THEN 'First 10' ELSE 'Second 10' END as "case" FROM test_emp WHERE emp_no >= 10005 | ||
astefan marked this conversation as resolved.
Show resolved
Hide resolved
|
||
ORDER BY emp_no LIMIT 10; | ||
|
||
case | ||
----------- | ||
First 10 | ||
First 10 | ||
First 10 | ||
First 10 | ||
First 10 | ||
Second 10 | ||
Second 10 | ||
Second 10 | ||
Second 10 | ||
Second 10 | ||
; | ||
|
||
caseFieldNoElse | ||
SELECT CASE WHEN emp_no - 10000 < 10 THEN 'First 10' END as "case" FROM test_emp WHERE emp_no >= 10005 | ||
astefan marked this conversation as resolved.
Show resolved
Hide resolved
|
||
ORDER BY emp_no LIMIT 10; | ||
|
||
case | ||
----------- | ||
First 10 | ||
First 10 | ||
First 10 | ||
First 10 | ||
First 10 | ||
null | ||
null | ||
null | ||
null | ||
null | ||
; | ||
|
||
caseWhere | ||
SELECT last_name FROM test_emp WHERE CASE WHEN LENGTH(last_name) < 7 THEN 'ShortName' ELSE 'LongName' END = 'LongName' | ||
ORDER BY emp_no LIMIT 10; | ||
|
||
last_name | ||
----------- | ||
Facello | ||
Bamford | ||
Koblick | ||
Maliniak | ||
Preusig | ||
Zielinski | ||
Kalloufi | ||
Piveteau | ||
Bridgland | ||
Nooteboom | ||
; | ||
|
||
caseWhereNoElse | ||
SELECT last_name FROM test_emp WHERE CASE WHEN LENGTH(last_name) < 7 THEN 'ShortName' END IS NOT NULL | ||
ORDER BY emp_no LIMIT 10; | ||
|
||
last_name | ||
----------- | ||
Simmel | ||
Peac | ||
Sluis | ||
Terkki | ||
Genin | ||
Peha | ||
Erde | ||
Famili | ||
Pettey | ||
Heyers | ||
; | ||
|
||
caseOrderBy | ||
SELECT last_name FROM test_emp ORDER BY CASE WHEN languages >= 3 THEN 'first' ELSE 'second' END, emp_no LIMIT 10; | ||
astefan marked this conversation as resolved.
Show resolved
Hide resolved
|
||
|
||
last_name | ||
----------- | ||
Simmel | ||
Bamford | ||
Koblick | ||
Preusig | ||
Zielinski | ||
Piveteau | ||
Sluis | ||
Bridgland | ||
Genin | ||
Nooteboom | ||
; | ||
|
||
caseOrderByNoElse | ||
SELECT last_name FROM test_emp ORDER BY CASE WHEN languages >= 3 THEN 'first' END NULLS FIRST, emp_no LIMIT 10; | ||
|
||
last_name | ||
------------- | ||
Facello | ||
Maliniak | ||
Kalloufi | ||
Peac | ||
Terkki | ||
Cappelletti | ||
Bouloucos | ||
Peha | ||
Haddadi | ||
Warwick | ||
; | ||
|
||
caseGroupBy | ||
schema::count:l|lang_skills:s | ||
SELECT count(*) AS count, CASE WHEN NVL(languages, 0) <= 1 THEN 'zero-to-one' ELSE 'multilingual' END as lang_skills | ||
FROM test_emp GROUP BY lang_skills ORDER BY lang_skills; | ||
|
||
count | lang_skills | ||
-------+-------------- | ||
75 | multilingual | ||
25 | zero-to-one | ||
; | ||
|
||
caseGroupByNoElse | ||
schema::count:l|lang_skills:s | ||
SELECT count(*) AS count, CASE WHEN NVL(languages, 0) <= 1 THEN 'zero-to-one' END as lang_skills | ||
FROM test_emp GROUP BY lang_skills ORDER BY lang_skills; | ||
|
||
count | lang_skills | ||
-------+------------- | ||
75 | null | ||
25 | zero-to-one | ||
; | ||
|
||
caseGroupByComplexNested | ||
schema::count:l|lang_skills:s | ||
SELECT count(*) AS count, | ||
CASE WHEN NVL(languages, 0) = 0 THEN 'zero' | ||
WHEN languages = 1 THEN 'one' | ||
WHEN languages = 2 THEN 'bilingual' | ||
WHEN languages = 3 THEN 'trilingual' | ||
ELSE 'multilingual' | ||
END as lang_skills FROM test_emp GROUP BY lang_skills ORDER BY 2; | ||
|
||
count | lang_skills | ||
-------+-------------- | ||
19 | bilingual | ||
39 | multilingual | ||
15 | one | ||
17 | trilingual | ||
10 | zero | ||
; | ||
|
||
caseGroupByAndHaving | ||
schema::count:l|gender:s|languages:byte | ||
SELECT count(*) AS count, gender, languages FROM test_emp | ||
GROUP BY 2, 3 HAVING CASE WHEN count(*) > 10 THEN 'many' ELSE 'a few' END = 'many' | ||
ORDER BY 2, 3; | ||
|
||
count | gender | languages | ||
----------+-------------+--------------- | ||
11 | M | 2 | ||
11 | M | 3 | ||
11 | M | 4 | ||
; |
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.
This sentence sounds weird. Maybe get rid of "Multiple" and rephrase?
At least one _WHEN *condition* THEN *result*_ clause is required and the expression can optionally have an _ELSE *default_result*_ clause. Every *condition* must be boolean expression.
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.
I would rephrase with something like "One or multiple WHEN ... are used and the ..."