Skip to content

Commit e991175

Browse files
committed
SQL: Implement IIF(<cond>, <result1>, <result2>) (#41420)
Implement a more trivial case of the CASE expression which is expressed as a traditional function with 2 or 3 arguments. e.g.: IIF(a = 1, 'one', 'many') IIF(a > 0, 'positive') Closes: #40917 (cherry picked from commit add02f4)
1 parent 31c609d commit e991175

File tree

16 files changed

+432
-25
lines changed

16 files changed

+432
-25
lines changed

docs/reference/sql/functions/conditional.asciidoc

Lines changed: 46 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -223,6 +223,52 @@ include-tagged::{sql-specs}/docs/docs.csv-spec[ifNullReturnFirst]
223223
include-tagged::{sql-specs}/docs/docs.csv-spec[ifNullReturnSecond]
224224
----
225225

226+
[[sql-functions-conditional-iif]]
227+
==== `IFF`
228+
229+
.Synopsis:
230+
[source, sql]
231+
----
232+
IIF(expression<1>, expression<2>, [expression<3>])
233+
----
234+
235+
*Input*:
236+
237+
<1> boolean condition to check
238+
239+
<2> return value if the boolean condition evaluates to `true`
240+
241+
<3> return value if the boolean condition evaluates `false`; optional
242+
243+
*Output*: 2nd expression if 1st expression (condition) evaluates to `true`. If it evaluates to `false`
244+
return 3rd expression. If 3rd expression is not provided return `null`.
245+
246+
.Description
247+
248+
Conditional function that implements the standard _IF <condition> THEN <result1> ELSE <result2>_
249+
logic of programming languages. If the 3rd expression is not provided and the condition evaluates to `false`,
250+
`null` is returned.
251+
252+
253+
["source","sql",subs="attributes,callouts,macros"]
254+
----
255+
include-tagged::{sql-specs}/docs/docs.csv-spec[iifWithDefaultValue]
256+
----
257+
258+
["source","sql",subs="attributes,callouts,macros"]
259+
----
260+
include-tagged::{sql-specs}/docs/docs.csv-spec[iifWithoutDefaultValue]
261+
----
262+
263+
[TIP]
264+
=================
265+
*IIF* functions can be combined to implement more complex logic simulating the <<sql-functions-conditional-case>>
266+
expression. E.g.:
267+
268+
[source, sql]
269+
IIF(a = 1, 'one', IIF(a = 2, 'two', IIF(a = 3, 'three', 'many')))
270+
=================
271+
226272

227273
[[sql-functions-conditional-isnull]]
228274
==== `ISNULL`

docs/reference/sql/functions/index.asciidoc

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -131,6 +131,7 @@
131131
** <<sql-functions-conditional-coalesce>>
132132
** <<sql-functions-conditional-greatest>>
133133
** <<sql-functions-conditional-ifnull>>
134+
** <<sql-functions-conditional-iif>>
134135
** <<sql-functions-conditional-isnull>>
135136
** <<sql-functions-conditional-least>>
136137
** <<sql-functions-conditional-nullif>>

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
@@ -29,6 +29,7 @@ CASE |CONDITIONAL
2929
COALESCE |CONDITIONAL
3030
GREATEST |CONDITIONAL
3131
IFNULL |CONDITIONAL
32+
IIF |CONDITIONAL
3233
ISNULL |CONDITIONAL
3334
LEAST |CONDITIONAL
3435
NULLIF |CONDITIONAL

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

Lines changed: 139 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -179,3 +179,142 @@ count | gender | languages
179179
11 | M | 3
180180
11 | M | 4
181181
;
182+
183+
184+
iifField
185+
SELECT emp_no, IIF(emp_no - 10000 < 10, 'First 10', 'Second 10') as "iif_result" FROM test_emp WHERE emp_no >= 10005
186+
ORDER BY emp_no LIMIT 10;
187+
188+
emp_no | iif_result
189+
--------+-----------
190+
10005 | First 10
191+
10006 | First 10
192+
10007 | First 10
193+
10008 | First 10
194+
10009 | First 10
195+
10010 | Second 10
196+
10011 | Second 10
197+
10012 | Second 10
198+
10013 | Second 10
199+
10014 | Second 10
200+
;
201+
202+
iifFieldWithoutAlias
203+
SELECT emp_no, IIF(emp_no - 10000 < 10, emp_no, emp_no % 10) FROM test_emp WHERE emp_no >= 10005
204+
ORDER BY emp_no LIMIT 10;
205+
206+
emp_no | IIF(emp_no - 10000 < 10, emp_no, emp_no % 10)
207+
--------+----------------------------------------------
208+
10005 | 10005
209+
10006 | 10006
210+
10007 | 10007
211+
10008 | 10008
212+
10009 | 10009
213+
10010 | 0
214+
10011 | 1
215+
10012 | 2
216+
10013 | 3
217+
10014 | 4
218+
;
219+
220+
iifFieldNoElse
221+
SELECT emp_no, IIF(emp_no - 10000 < 10, 'First 10') as "iif_result" FROM test_emp WHERE emp_no >= 10005
222+
ORDER BY emp_no LIMIT 10;
223+
224+
emp_no | iif_result
225+
--------+----------
226+
10005 | First 10
227+
10006 | First 10
228+
10007 | First 10
229+
10008 | First 10
230+
10009 | First 10
231+
10010 | null
232+
10011 | null
233+
10012 | null
234+
10013 | null
235+
10014 | null
236+
;
237+
238+
iifWhere
239+
SELECT last_name FROM test_emp WHERE IIF(LENGTH(last_name) < 7, 'ShortName') IS NOT NULL ORDER BY emp_no LIMIT 10;
240+
241+
last_name
242+
-----------
243+
Simmel
244+
Peac
245+
Sluis
246+
Terkki
247+
Genin
248+
Peha
249+
Erde
250+
Famili
251+
Pettey
252+
Heyers
253+
;
254+
255+
iifOrderBy
256+
SELECT last_name FROM test_emp ORDER BY IIF(languages >= 3, 'first', 'second'), emp_no LIMIT 10;
257+
258+
last_name
259+
-----------
260+
Simmel
261+
Bamford
262+
Koblick
263+
Preusig
264+
Zielinski
265+
Piveteau
266+
Sluis
267+
Bridgland
268+
Genin
269+
Nooteboom
270+
;
271+
272+
iifGroupBy
273+
schema::count:l|lang_skills:s
274+
SELECT count(*) AS count, IIF(NVL(languages, 0) <= 1 , 'zero-to-one', 'multilingual') as lang_skills FROM test_emp
275+
GROUP BY lang_skills ORDER BY 2;
276+
277+
count | lang_skills
278+
---------------+---------------
279+
75 |multilingual
280+
25 |zero-to-one
281+
;
282+
283+
iifGroupByComplexNested
284+
schema::count:l|lang_skills:s
285+
SELECT count(*) AS count,
286+
IIF(NVL(languages, 0) = 0, 'zero',
287+
IIF(languages = 1, 'one',
288+
IIF(languages = 2, 'bilingual',
289+
IIF(languages = 3, 'trilingual', 'multilingual')))) as lang_skills FROM test_emp GROUP BY lang_skills ORDER BY 2;
290+
291+
count | lang_skills
292+
---------------+---------------
293+
19 |bilingual
294+
39 |multilingual
295+
15 |one
296+
17 |trilingual
297+
10 |zero
298+
;
299+
300+
iifGroupByAndHaving
301+
schema::count:l|gender:s|languages:byte
302+
SELECT count(*) AS count, gender, languages FROM test_emp
303+
GROUP BY 2, 3 HAVING IIF(count(*) > 10, 'many', 'a few') = 'many'
304+
ORDER BY 2, 3;
305+
306+
count | gender | languages
307+
---------------+---------------+---------------
308+
11 |M |2
309+
11 |M |3
310+
11 |M |4
311+
;
312+
313+
iifWithConvertAndGroupBy
314+
SELECT CONVERT(IIF(languages > 1, IIF(languages = 3, '3')), SQL_BIGINT) AS cond FROM test_emp GROUP BY cond ORDER BY cond DESC;
315+
316+
cond:l
317+
-------
318+
3
319+
null
320+
;

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

Lines changed: 24 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -206,6 +206,7 @@ CASE |CONDITIONAL
206206
COALESCE |CONDITIONAL
207207
GREATEST |CONDITIONAL
208208
IFNULL |CONDITIONAL
209+
IIF |CONDITIONAL
209210
ISNULL |CONDITIONAL
210211
LEAST |CONDITIONAL
211212
NULLIF |CONDITIONAL
@@ -2095,6 +2096,29 @@ elastic
20952096
;
20962097

20972098

2099+
iifWithDefaultValue
2100+
schema::result1:s|result2:s
2101+
// tag::iifWithDefaultValue
2102+
SELECT IIF(1 < 2, 'TRUE', 'FALSE') AS result1, IIF(1 > 2, 'TRUE', 'FALSE') AS result2;
2103+
2104+
result1 | result2
2105+
---------------+---------------
2106+
TRUE |FALSE
2107+
// end::iifWithDefaultValue
2108+
;
2109+
2110+
iifWithoutDefaultValue
2111+
schema::result1:s|result2:s
2112+
// tag::iifWithoutDefaultValue
2113+
SELECT IIF(1 < 2, 'TRUE') AS result1, IIF(1 > 2 , 'TRUE') AS result2;
2114+
2115+
result1 | result2
2116+
---------------+---------------
2117+
TRUE |null
2118+
// end::iifWithoutDefaultValue
2119+
;
2120+
2121+
20982122
ifNullReturnSecond
20992123
// tag::ifNullReturnSecond
21002124
SELECT IFNULL(null, 'search') AS "ifnull";

x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/function/FunctionRegistry.java

Lines changed: 5 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -97,6 +97,7 @@
9797
import org.elasticsearch.xpack.sql.expression.predicate.conditional.Case;
9898
import org.elasticsearch.xpack.sql.expression.predicate.conditional.Coalesce;
9999
import org.elasticsearch.xpack.sql.expression.predicate.conditional.Greatest;
100+
import org.elasticsearch.xpack.sql.expression.predicate.conditional.Iif;
100101
import org.elasticsearch.xpack.sql.expression.predicate.conditional.IfNull;
101102
import org.elasticsearch.xpack.sql.expression.predicate.conditional.Least;
102103
import org.elasticsearch.xpack.sql.expression.predicate.conditional.NullIf;
@@ -172,6 +173,7 @@ private void defineDefaultFunctions() {
172173
// Conditional
173174
addToMap(def(Case.class, Case::new, "CASE"),
174175
def(Coalesce.class, Coalesce::new, "COALESCE"),
176+
def(Iif.class, Iif::new, "IIF"),
175177
def(IfNull.class, IfNull::new, "IFNULL", "ISNULL", "NVL"),
176178
def(NullIf.class, NullIf::new, "NULLIF"),
177179
def(Greatest.class, Greatest::new, "GREATEST"),
@@ -544,10 +546,10 @@ private interface FunctionBuilder {
544546
static <T extends Function> FunctionDefinition def(Class<T> function,
545547
ThreeParametersFunctionBuilder<T> ctorRef, String... names) {
546548
FunctionBuilder builder = (source, children, distinct, cfg) -> {
547-
boolean isLocateFunction = function.isAssignableFrom(Locate.class);
548-
if (isLocateFunction && (children.size() > 3 || children.size() < 2)) {
549+
boolean hasMinimumTwo = function.isAssignableFrom(Locate.class) || function.isAssignableFrom(Iif.class);
550+
if (hasMinimumTwo && (children.size() > 3 || children.size() < 2)) {
549551
throw new SqlIllegalArgumentException("expects two or three arguments");
550-
} else if (!isLocateFunction && children.size() != 3) {
552+
} else if (!hasMinimumTwo && children.size() != 3) {
551553
throw new SqlIllegalArgumentException("expects exactly three arguments");
552554
}
553555
if (distinct) {

x-pack/plugin/sql/src/main/java/org/elasticsearch/xpack/sql/expression/predicate/conditional/Case.java

Lines changed: 14 additions & 14 deletions
Original file line numberDiff line numberDiff line change
@@ -30,28 +30,28 @@
3030
public class Case extends ConditionalFunction {
3131

3232
private final List<IfConditional> conditions;
33-
private final Expression defaultElse;
33+
private final Expression elseResult;
3434

3535
@SuppressWarnings("unchecked")
3636
public Case(Source source, List<Expression> expressions) {
3737
super(source, expressions);
3838
this.conditions = (List<IfConditional>) (List<?>) expressions.subList(0, expressions.size() - 1);
39-
this.defaultElse = expressions.get(expressions.size() - 1);
39+
this.elseResult = expressions.get(expressions.size() - 1);
4040
}
4141

4242
public List<IfConditional> conditions() {
4343
return conditions;
4444
}
4545

46-
public Expression defaultElse() {
47-
return defaultElse;
46+
public Expression elseResult() {
47+
return elseResult;
4848
}
4949

5050
@Override
5151
public DataType dataType() {
5252
if (dataType == null) {
5353
if (conditions.isEmpty()) {
54-
dataType = defaultElse().dataType();
54+
dataType = elseResult().dataType();
5555
} else {
5656
dataType = DataType.NULL;
5757

@@ -83,7 +83,7 @@ protected TypeResolution resolveType() {
8383
}
8484
}
8585
if (expectedResultDataType == null) {
86-
expectedResultDataType = defaultElse().dataType();
86+
expectedResultDataType = elseResult().dataType();
8787
}
8888

8989
for (IfConditional conditional : conditions) {
@@ -102,12 +102,12 @@ protected TypeResolution resolveType() {
102102
}
103103
}
104104

105-
if (DataTypes.areTypesCompatible(expectedResultDataType, defaultElse.dataType()) == false) {
105+
if (DataTypes.areTypesCompatible(expectedResultDataType, elseResult.dataType()) == false) {
106106
return new TypeResolution(format(null, "ELSE clause of [{}] must be [{}], found value [{}] type [{}]",
107-
defaultElse.sourceText(),
107+
elseResult.sourceText(),
108108
expectedResultDataType.typeName,
109-
Expressions.name(defaultElse),
110-
defaultElse.dataType().typeName));
109+
Expressions.name(elseResult),
110+
elseResult.dataType().typeName));
111111
}
112112

113113
return TypeResolution.TYPE_RESOLVED;
@@ -119,7 +119,7 @@ protected TypeResolution resolveType() {
119119
*/
120120
@Override
121121
public boolean foldable() {
122-
return (conditions.isEmpty() && defaultElse.foldable()) ||
122+
return (conditions.isEmpty() && elseResult.foldable()) ||
123123
(conditions.size() == 1 && conditions.get(0).condition().foldable() && conditions.get(0).result().foldable());
124124
}
125125

@@ -128,7 +128,7 @@ public Object fold() {
128128
if (conditions.isEmpty() == false && conditions.get(0).condition().fold() == Boolean.TRUE) {
129129
return conditions.get(0).result().fold();
130130
}
131-
return defaultElse.fold();
131+
return elseResult.fold();
132132
}
133133

134134
@Override
@@ -138,7 +138,7 @@ protected Pipe makePipe() {
138138
pipes.add(Expressions.pipe(ifConditional.condition()));
139139
pipes.add(Expressions.pipe(ifConditional.result()));
140140
}
141-
pipes.add(Expressions.pipe(defaultElse));
141+
pipes.add(Expressions.pipe(elseResult));
142142
return new CasePipe(source(), this, pipes);
143143
}
144144

@@ -149,7 +149,7 @@ public ScriptTemplate asScript() {
149149
templates.add(asScript(ifConditional.condition()));
150150
templates.add(asScript(ifConditional.result()));
151151
}
152-
templates.add(asScript(defaultElse));
152+
templates.add(asScript(elseResult));
153153

154154
StringJoiner template = new StringJoiner(",", "{sql}.caseFunction([", "])");
155155
ParamsBuilder params = paramsBuilder();

0 commit comments

Comments
 (0)