Skip to content

Commit

Permalink
SQL: Implement CASE... WHEN... THEN... ELSE... END
Browse files Browse the repository at this point in the history
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: elastic#36200
  • Loading branch information
matriv committed Apr 18, 2019
1 parent 8d03825 commit 8fd1da2
Show file tree
Hide file tree
Showing 32 changed files with 2,860 additions and 1,769 deletions.
81 changes: 80 additions & 1 deletion docs/reference/sql/functions/conditional.asciidoc
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`,
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
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.

[[sql-functions-conditional-coalesce]]
==== `COALESCE`

Expand Down
1 change: 1 addition & 0 deletions docs/reference/sql/functions/index.asciidoc
Original file line number Diff line number Diff line change
Expand Up @@ -127,6 +127,7 @@
** <<sql-functions-type-conversion-cast>>
** <<sql-functions-type-conversion-convert>>
* <<sql-functions-conditional>>
** <<sql-functions-conditional-case>>
** <<sql-functions-conditional-coalesce>>
** <<sql-functions-conditional-greatest>>
** <<sql-functions-conditional-ifnull>>
Expand Down
1 change: 1 addition & 0 deletions x-pack/plugin/sql/qa/src/main/resources/command.csv-spec
Original file line number Diff line number Diff line change
Expand Up @@ -25,6 +25,7 @@ STDDEV_POP |AGGREGATE
SUM_OF_SQUARES |AGGREGATE
VAR_POP |AGGREGATE
HISTOGRAM |GROUPING
CASE |CONDITIONAL
COALESCE |CONDITIONAL
GREATEST |CONDITIONAL
IFNULL |CONDITIONAL
Expand Down
74 changes: 73 additions & 1 deletion x-pack/plugin/sql/qa/src/main/resources/docs/docs.csv-spec
Original file line number Diff line number Diff line change
Expand Up @@ -202,6 +202,7 @@ STDDEV_POP |AGGREGATE
SUM_OF_SQUARES |AGGREGATE
VAR_POP |AGGREGATE
HISTOGRAM |GROUPING
CASE |CONDITIONAL
COALESCE |CONDITIONAL
GREATEST |CONDITIONAL
IFNULL |CONDITIONAL
Expand Down Expand Up @@ -1987,10 +1988,81 @@ SELECT TRUNCATE(-345.153, 1) AS trimmed;

///////////////////////////////
//
// Null handling
// Conditional
//
///////////////////////////////

case
schema::case:s
// tag::case
SELECT CASE WHEN 1 > 2 THEN 'elastic'
WHEN 2 <= 3 THEN 'search'
END AS "case";

case
---------------
search
// end::case
;

caseReturnNull
schema::case:s
// tag::caseReturnNull
SELECT CASE WHEN 1 > 2 THEN 'elastic'
WHEN 2 > 10 THEN 'search'
END AS "case";

case
---------------
null
// end::caseReturnNull
;

caseWithElse
schema::case:s
// tag::caseWithElse
SELECT CASE WHEN 1 > 2 THEN 'elastic'
WHEN 2 > 10 THEN 'search'
ELSE 'default'
END AS "case";

case
---------------
default
// end::caseWithElse
;

caseWithOperand
schema::case:s
// tag::caseWithOperand
SELECT CASE 5
WHEN 1 THEN 'elastic'
WHEN 2 THEN 'search'
WHEN 5 THEN 'elasticsearch'
END AS "case";

case
---------------
elasticsearch
// end::caseWithOperand
;

caseWithOperandAndElse
schema::case:s
// tag::caseWithOperandAndElse
SELECT CASE 5
WHEN 1 THEN 'elastic'
WHEN 2 THEN 'search'
WHEN 3 THEN 'elasticsearch'
ELSE 'default'
END AS "case";

case
---------------
default
// end::caseWithOperandAndElse
;

coalesceReturnNonNull
// tag::coalesceReturnNonNull
SELECT COALESCE(null, 'elastic', 'search') AS "coalesce";
Expand Down
36 changes: 0 additions & 36 deletions x-pack/plugin/sql/qa/src/main/resources/null.csv-spec
Original file line number Diff line number Diff line change
Expand Up @@ -37,39 +37,3 @@ SELECT COALESCE(null, null, null) AS c;
c
null
;

coalesceFirstNotNull
SELECT COALESCE(123) AS c;

c
123
;


coalesceWithFirstNullOfString
SELECT COALESCE(null, 'first') AS c;

c:s
first
;

coalesceWithFirstNullOfNumber
SELECT COALESCE(null, 123) AS c;

c:i
123
;

coalesceMixed
SELECT COALESCE(null, 123, null, 321) AS c;

c:i
123
;

coalesceScalar
SELECT COALESCE(null, ABS(123) + 1) AS c;

c:i
124
;
17 changes: 16 additions & 1 deletion x-pack/plugin/sql/qa/src/main/resources/null.sql-spec
Original file line number Diff line number Diff line change
@@ -1,7 +1,22 @@
//
// Null expressions
// Null conditionals
//

coalesceFirstNotNull
SELECT COALESCE(123) AS c;

coalesceWithFirstNullOfString
SELECT COALESCE(null, 'first') AS c;

coalesceWithFirstNullOfNumber
SELECT COALESCE(null, 123) AS c;

coalesceMixed
SELECT COALESCE(null, 123, null, 321) AS c;

coalesceScalar
SELECT COALESCE(null, ABS(123) + 1) AS c;

coalesceField
SELECT COALESCE(null, ABS(emp_no) + 1) AS c FROM test_emp ORDER BY emp_no LIMIT 5;

Expand Down
30 changes: 20 additions & 10 deletions x-pack/plugin/sql/src/main/antlr/SqlBase.g4
Original file line number Diff line number Diff line change
Expand Up @@ -213,16 +213,17 @@ valueExpression
;

primaryExpression
: castExpression #cast
| primaryExpression CAST_OP dataType #castOperatorExpression
| extractExpression #extract
| builtinDateTimeFunction #currentDateTimeFunction
| constant #constantDefault
| (qualifiedName DOT)? ASTERISK #star
| functionExpression #function
| '(' query ')' #subqueryExpression
| qualifiedName #dereference
| '(' expression ')' #parenthesizedExpression
: castExpression #cast
| primaryExpression CAST_OP dataType #castOperatorExpression
| extractExpression #extract
| builtinDateTimeFunction #currentDateTimeFunction
| constant #constantDefault
| (qualifiedName DOT)? ASTERISK #star
| functionExpression #function
| '(' query ')' #subqueryExpression
| qualifiedName #dereference
| '(' expression ')' #parenthesizedExpression
| CASE (operand=booleanExpression)? whenClause+ (ELSE elseClause=booleanExpression)? END #case
;

builtinDateTimeFunction
Expand Down Expand Up @@ -337,6 +338,10 @@ string
| STRING
;

whenClause
: WHEN condition=expression THEN result=expression
;

// http://developer.mimer.se/validator/sql-reserved-words.tml
nonReserved
: ANALYZE | ANALYZED
Expand Down Expand Up @@ -368,6 +373,7 @@ AS: 'AS';
ASC: 'ASC';
BETWEEN: 'BETWEEN';
BY: 'BY';
CASE: 'CASE';
CAST: 'CAST';
CATALOG: 'CATALOG';
CATALOGS: 'CATALOGS';
Expand All @@ -382,6 +388,8 @@ DEBUG: 'DEBUG';
DESC: 'DESC';
DESCRIBE: 'DESCRIBE';
DISTINCT: 'DISTINCT';
ELSE: 'ELSE';
END: 'END';
ESCAPE: 'ESCAPE';
EXECUTABLE: 'EXECUTABLE';
EXISTS: 'EXISTS';
Expand Down Expand Up @@ -437,12 +445,14 @@ SYS: 'SYS';
TABLE: 'TABLE';
TABLES: 'TABLES';
TEXT: 'TEXT';
THEN: 'THEN';
TRUE: 'TRUE';
TO: 'TO';
TYPE: 'TYPE';
TYPES: 'TYPES';
USING: 'USING';
VERIFY: 'VERIFY';
WHEN: 'WHEN';
WHERE: 'WHERE';
WITH: 'WITH';
YEAR: 'YEAR';
Expand Down
Loading

0 comments on commit 8fd1da2

Please sign in to comment.