Skip to content

Commit 67d4e39

Browse files
committed
SQL: Implement CASE... WHEN... THEN... ELSE... END (#41349)
Implement the ANSI SQL CASE expression which provides the if/else functionality common to most programming languages. The CASE expression can have multiple WHEN branches and becomes a powerful tool for SQL queries as it can be used in SELECT, WHERE, GROUP BY, HAVING and ORDER BY clauses. Closes: #36200 (cherry picked from commit 8b25774)
1 parent eb2295a commit 67d4e39

File tree

33 files changed

+3114
-1769
lines changed

33 files changed

+3114
-1769
lines changed

docs/reference/sql/functions/conditional.asciidoc

Lines changed: 94 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,10 +1,103 @@
11
[role="xpack"]
22
[testenv="basic"]
33
[[sql-functions-conditional]]
4-
=== Conditional Functions
4+
=== Conditional Functions And Expressions
55

66
Functions that return one of their arguments by evaluating in an if-else manner.
77

8+
[[sql-functions-conditional-case]]
9+
==== `CASE`
10+
11+
.Synopsis:
12+
[source, sql]
13+
----
14+
CASE WHEN condition THEN result
15+
[WHEN ...]
16+
[ELSE default_result]
17+
END
18+
----
19+
20+
*Input*:
21+
22+
One or multiple _WHEN *condition* THEN *result_* clauses are used and the expression can optionally have
23+
an _ELSE *default_result_* clause. Every *condition* should be a boolean expression.
24+
25+
*Output*: one of the *result* expressions if the corresponding _WHEN *condition_* evaluates to `true` or
26+
the *default_result* if all _WHEN *condition_* clauses evaluate to `false`. If the optional _ELSE *default_result_*
27+
clause is missing and all _WHEN *condition_* clauses evaluate to `false` then `null` is returned.
28+
29+
.Description
30+
31+
The CASE expression is a generic conditional expression which simulates if/else statements of other programming languages
32+
If the condition’s result is true, the value of the result expression that follows the condition will be the returned
33+
the subsequent when clauses will be skipped and not processed.
34+
35+
36+
["source","sql",subs="attributes,callouts,macros"]
37+
----
38+
include-tagged::{sql-specs}/docs/docs.csv-spec[case]
39+
----
40+
41+
["source","sql",subs="attributes,callouts,macros"]
42+
----
43+
include-tagged::{sql-specs}/docs/docs.csv-spec[caseReturnNull]
44+
----
45+
46+
["source","sql",subs="attributes,callouts,macros"]
47+
----
48+
include-tagged::{sql-specs}/docs/docs.csv-spec[caseWithElse]
49+
----
50+
51+
52+
As a variant, a case expression can be expressed with a syntax similar to *switch-case* of other programming languages:
53+
[source, sql]
54+
----
55+
CASE expression
56+
WHEN value1 THEN result1
57+
[WHEN value2 THEN result2]
58+
[WHEN ...]
59+
[ELSE default_result]
60+
END
61+
----
62+
63+
In this case it's transformed internally to:
64+
[source, sql]
65+
----
66+
CASE WHEN expression = value1 THEN result1
67+
[WHEN expression = value2 THEN result2]
68+
[WHEN ...]
69+
[ELSE default_result]
70+
END
71+
----
72+
73+
["source","sql",subs="attributes,callouts,macros"]
74+
----
75+
include-tagged::{sql-specs}/docs/docs.csv-spec[caseWithOperand]
76+
----
77+
78+
["source","sql",subs="attributes,callouts,macros"]
79+
----
80+
include-tagged::{sql-specs}/docs/docs.csv-spec[caseWithOperandAndElse]
81+
----
82+
83+
[NOTE]
84+
===============================
85+
All result expressions must be of compatible data types. More specifically all result
86+
expressions should have a compatible data type with the 1st _non-null_ result expression.
87+
E.g.:
88+
89+
for the following query:
90+
91+
[source, sql]
92+
CASE WHEN a = 1 THEN null
93+
WHEN a > 2 THEN 10
94+
WHEN a > 5 THEN 'foo'
95+
END
96+
97+
an error message would be returned, mentioning that *'foo'* is of data type *keyword*,
98+
which does not match the expected data type *integer* (based on result *10*).
99+
===============================
100+
8101
[[sql-functions-conditional-coalesce]]
9102
==== `COALESCE`
10103

docs/reference/sql/functions/index.asciidoc

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -127,6 +127,7 @@
127127
** <<sql-functions-type-conversion-cast>>
128128
** <<sql-functions-type-conversion-convert>>
129129
* <<sql-functions-conditional>>
130+
** <<sql-functions-conditional-case>>
130131
** <<sql-functions-conditional-coalesce>>
131132
** <<sql-functions-conditional-greatest>>
132133
** <<sql-functions-conditional-ifnull>>

x-pack/plugin/sql/qa/src/main/resources/command.csv-spec

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -25,6 +25,7 @@ STDDEV_POP |AGGREGATE
2525
SUM_OF_SQUARES |AGGREGATE
2626
VAR_POP |AGGREGATE
2727
HISTOGRAM |GROUPING
28+
CASE |CONDITIONAL
2829
COALESCE |CONDITIONAL
2930
GREATEST |CONDITIONAL
3031
IFNULL |CONDITIONAL
Lines changed: 181 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,181 @@
1+
caseField
2+
SELECT emp_no, CASE WHEN emp_no - 10000 < 10 THEN 'First 10' ELSE 'Second 10' END as "case" FROM test_emp WHERE emp_no >= 10005
3+
ORDER BY emp_no LIMIT 10;
4+
5+
emp_no | case
6+
--------+-----------
7+
10005 | First 10
8+
10006 | First 10
9+
10007 | First 10
10+
10008 | First 10
11+
10009 | First 10
12+
10010 | Second 10
13+
10011 | Second 10
14+
10012 | Second 10
15+
10013 | Second 10
16+
10014 | Second 10
17+
;
18+
19+
caseFieldWithoutAlias
20+
SELECT emp_no, CASE WHEN emp_no - 10000 < 10 THEN emp_no ELSE emp_no % 10 END FROM test_emp WHERE emp_no >= 10005
21+
ORDER BY emp_no LIMIT 10;
22+
23+
emp_no | CASE WHEN emp_no - 10000 < 10 THEN emp_no ELSE emp_no % 10 END
24+
--------+----------------------------------------------------------------
25+
10005 | 10005
26+
10006 | 10006
27+
10007 | 10007
28+
10008 | 10008
29+
10009 | 10009
30+
10010 | 0
31+
10011 | 1
32+
10012 | 2
33+
10013 | 3
34+
10014 | 4
35+
;
36+
37+
caseFieldNoElse
38+
SELECT emp_no, CASE WHEN emp_no - 10000 < 10 THEN 'First 10' END as "case" FROM test_emp WHERE emp_no >= 10005
39+
ORDER BY emp_no LIMIT 10;
40+
41+
emp_no | case
42+
--------+----------
43+
10005 | First 10
44+
10006 | First 10
45+
10007 | First 10
46+
10008 | First 10
47+
10009 | First 10
48+
10010 | null
49+
10011 | null
50+
10012 | null
51+
10013 | null
52+
10014 | null
53+
;
54+
55+
caseWhere
56+
SELECT last_name FROM test_emp WHERE CASE WHEN LENGTH(last_name) < 7 THEN 'ShortName' ELSE 'LongName' END = 'LongName'
57+
ORDER BY emp_no LIMIT 10;
58+
59+
last_name
60+
-----------
61+
Facello
62+
Bamford
63+
Koblick
64+
Maliniak
65+
Preusig
66+
Zielinski
67+
Kalloufi
68+
Piveteau
69+
Bridgland
70+
Nooteboom
71+
;
72+
73+
caseWhereNoElse
74+
SELECT last_name FROM test_emp WHERE CASE WHEN LENGTH(last_name) < 7 THEN 'ShortName' END IS NOT NULL
75+
ORDER BY emp_no LIMIT 10;
76+
77+
last_name
78+
-----------
79+
Simmel
80+
Peac
81+
Sluis
82+
Terkki
83+
Genin
84+
Peha
85+
Erde
86+
Famili
87+
Pettey
88+
Heyers
89+
;
90+
91+
caseOrderBy
92+
schema::last_name:s|languages:byte|emp_no:i
93+
SELECT last_name, languages, emp_no FROM test_emp WHERE emp_no BETWEEN 10005 AND 10015
94+
ORDER BY CASE WHEN languages >= 3 THEN 'first' ELSE 'second' END, emp_no LIMIT 10;
95+
96+
last_name | languages | emp_no
97+
-----------+-----------+--------
98+
Preusig | 3 | 10006
99+
Zielinski | 4 | 10007
100+
Piveteau | 4 | 10010
101+
Sluis | 5 | 10011
102+
Bridgland | 5 | 10012
103+
Genin | 5 | 10014
104+
Nooteboom | 5 | 10015
105+
Maliniak | 1 | 10005
106+
Kalloufi | 2 | 10008
107+
Peac | 1 | 10009
108+
;
109+
110+
caseOrderByNoElse
111+
schema::last_name:s|languages:byte|emp_no:i
112+
SELECT last_name, languages, emp_no FROM test_emp WHERE emp_no BETWEEN 10005 AND 10015
113+
ORDER BY CASE WHEN languages >= 3 THEN 'first' END NULLS FIRST, emp_no LIMIT 10;
114+
115+
last_name | languages | emp_no
116+
-----------+-----------+--------
117+
Maliniak | 1 | 10005
118+
Kalloufi | 2 | 10008
119+
Peac | 1 | 10009
120+
Terkki | 1 | 10013
121+
Preusig | 3 | 10006
122+
Zielinski | 4 | 10007
123+
Piveteau | 4 | 10010
124+
Sluis | 5 | 10011
125+
Bridgland | 5 | 10012
126+
Genin | 5 | 10014
127+
;
128+
129+
caseGroupBy
130+
schema::count:l|lang_skills:s
131+
SELECT count(*) AS count, CASE WHEN NVL(languages, 0) <= 1 THEN 'zero-to-one' ELSE 'multilingual' END as lang_skills
132+
FROM test_emp GROUP BY lang_skills ORDER BY lang_skills;
133+
134+
count | lang_skills
135+
-------+--------------
136+
75 | multilingual
137+
25 | zero-to-one
138+
;
139+
140+
caseGroupByNoElse
141+
schema::count:l|lang_skills:s
142+
SELECT count(*) AS count, CASE WHEN NVL(languages, 0) <= 1 THEN 'zero-to-one' END as lang_skills
143+
FROM test_emp GROUP BY lang_skills ORDER BY lang_skills;
144+
145+
count | lang_skills
146+
-------+-------------
147+
75 | null
148+
25 | zero-to-one
149+
;
150+
151+
caseGroupByComplexNested
152+
schema::count:l|lang_skills:s
153+
SELECT count(*) AS count,
154+
CASE WHEN NVL(languages, 0) = 0 THEN 'zero'
155+
WHEN languages = 1 THEN 'one'
156+
WHEN languages = 2 THEN 'bilingual'
157+
WHEN languages = 3 THEN 'trilingual'
158+
ELSE 'multilingual'
159+
END as lang_skills FROM test_emp GROUP BY lang_skills ORDER BY 2;
160+
161+
count | lang_skills
162+
-------+--------------
163+
19 | bilingual
164+
39 | multilingual
165+
15 | one
166+
17 | trilingual
167+
10 | zero
168+
;
169+
170+
caseGroupByAndHaving
171+
schema::count:l|gender:s|languages:byte
172+
SELECT count(*) AS count, gender, languages FROM test_emp
173+
GROUP BY 2, 3 HAVING CASE WHEN count(*) > 10 THEN 'many' ELSE 'a few' END = 'many'
174+
ORDER BY 2, 3;
175+
176+
count | gender | languages
177+
----------+-------------+---------------
178+
11 | M | 2
179+
11 | M | 3
180+
11 | M | 4
181+
;

x-pack/plugin/sql/qa/src/main/resources/docs/docs.csv-spec

Lines changed: 73 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -202,6 +202,7 @@ STDDEV_POP |AGGREGATE
202202
SUM_OF_SQUARES |AGGREGATE
203203
VAR_POP |AGGREGATE
204204
HISTOGRAM |GROUPING
205+
CASE |CONDITIONAL
205206
COALESCE |CONDITIONAL
206207
GREATEST |CONDITIONAL
207208
IFNULL |CONDITIONAL
@@ -1987,10 +1988,81 @@ SELECT TRUNCATE(-345.153, 1) AS trimmed;
19871988

19881989
///////////////////////////////
19891990
//
1990-
// Null handling
1991+
// Conditional
19911992
//
19921993
///////////////////////////////
19931994

1995+
case
1996+
schema::case:s
1997+
// tag::case
1998+
SELECT CASE WHEN 1 > 2 THEN 'elastic'
1999+
WHEN 2 <= 3 THEN 'search'
2000+
END AS "case";
2001+
2002+
case
2003+
---------------
2004+
search
2005+
// end::case
2006+
;
2007+
2008+
caseReturnNull
2009+
schema::case:s
2010+
// tag::caseReturnNull
2011+
SELECT CASE WHEN 1 > 2 THEN 'elastic'
2012+
WHEN 2 > 10 THEN 'search'
2013+
END AS "case";
2014+
2015+
case
2016+
---------------
2017+
null
2018+
// end::caseReturnNull
2019+
;
2020+
2021+
caseWithElse
2022+
schema::case:s
2023+
// tag::caseWithElse
2024+
SELECT CASE WHEN 1 > 2 THEN 'elastic'
2025+
WHEN 2 > 10 THEN 'search'
2026+
ELSE 'default'
2027+
END AS "case";
2028+
2029+
case
2030+
---------------
2031+
default
2032+
// end::caseWithElse
2033+
;
2034+
2035+
caseWithOperand
2036+
schema::case:s
2037+
// tag::caseWithOperand
2038+
SELECT CASE 5
2039+
WHEN 1 THEN 'elastic'
2040+
WHEN 2 THEN 'search'
2041+
WHEN 5 THEN 'elasticsearch'
2042+
END AS "case";
2043+
2044+
case
2045+
---------------
2046+
elasticsearch
2047+
// end::caseWithOperand
2048+
;
2049+
2050+
caseWithOperandAndElse
2051+
schema::case:s
2052+
// tag::caseWithOperandAndElse
2053+
SELECT CASE 5
2054+
WHEN 1 THEN 'elastic'
2055+
WHEN 2 THEN 'search'
2056+
WHEN 3 THEN 'elasticsearch'
2057+
ELSE 'default'
2058+
END AS "case";
2059+
2060+
case
2061+
---------------
2062+
default
2063+
// end::caseWithOperandAndElse
2064+
;
2065+
19942066
coalesceReturnNonNull
19952067
// tag::coalesceReturnNonNull
19962068
SELECT COALESCE(null, 'elastic', 'search') AS "coalesce";

0 commit comments

Comments
 (0)