Skip to content

Commit e76cd76

Browse files
committed
upd
1 parent ae813cf commit e76cd76

File tree

5 files changed

+353
-0
lines changed
  • docs/sql-manual/sql-functions/scalar-functions/conditional-functions
  • i18n/zh-CN/docusaurus-plugin-content-docs
    • current/sql-manual/sql-functions/scalar-functions/conditional-functions
    • version-4.x/sql-manual/sql-functions/scalar-functions/conditional-functions
  • versioned_docs/version-4.x/sql-manual/sql-functions/scalar-functions/conditional-functions

5 files changed

+353
-0
lines changed
Lines changed: 88 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,88 @@
1+
---
2+
{
3+
"title": "Conditional Functions Overview",
4+
"language": "en",
5+
"description": "Conditional functions are built-in functions used to perform conditional logic and branching in SQL queries."
6+
}
7+
---
8+
9+
# Conditional Functions Overview
10+
11+
Conditional functions are built-in functions used to perform conditional logic and branching in SQL queries. They help execute different operations based on specified conditions, such as selecting values, handling NULL values, and performing case-based logic.
12+
13+
## Vectorized Execution and Conditional Functions
14+
15+
Doris is a vectorized execution engine. However, conditional functions may behave in ways that seem counterintuitive.
16+
17+
Consider the following example:
18+
19+
```sql
20+
mysql> set enable_strict_cast = true;
21+
Query OK, 0 rows affected (0.00 sec)
22+
23+
mysql> select count(
24+
-> if(number < 128 ,
25+
-> cast(number as tinyint),
26+
-> cast(number as String))
27+
-> ) from numbers("number" = "300");
28+
ERROR 1105 (HY000): errCode = 2, detailMessage = (127.0.0.1)[INVALID_ARGUMENT]Value 128 out of range for type tinyint
29+
```
30+
31+
In this example, even though we only cast to `tinyint` when `number < 128` in the `if` function, an error still occurs. This is because of how conditional functions like `if(cond, colA, colB)` were traditionally executed:
32+
33+
1. First, both `colA` and `colB` are fully computed
34+
2. Then, based on the value of `cond`, the corresponding result is selected and returned
35+
36+
So even if `colA`'s value is not actually used in practice, since `colA` is fully computed, it will still trigger an error.
37+
38+
Functions like `if`, `ifnull`, `case`, and `coalesce` have similar behavior.
39+
40+
Note that functions like `LEAST` do not have this issue because they inherently need to compute all parameters to compare values.
41+
42+
## Short-Circuit Evaluation
43+
44+
In Doris 4.0, we improved the execution logic of conditional functions to allow short-circuit evaluation.
45+
46+
```sql
47+
mysql> set short_circuit_evaluation = true;
48+
Query OK, 0 rows affected (0.00 sec)
49+
50+
mysql> select count(
51+
-> if(number < 128 ,
52+
-> cast(number as tinyint),
53+
-> cast(number as String))
54+
-> ) from numbers("number" = "300");
55+
+-------------------------------------------------------------------------+
56+
| count(if(number < 128, cast(number as tinyint), cast(number as String)))|
57+
+-------------------------------------------------------------------------+
58+
| 300 |
59+
+-------------------------------------------------------------------------+
60+
```
61+
62+
With short-circuit evaluation enabled, functions like `if`, `ifnull`, `case`, and `coalesce` can avoid unnecessary computations in many scenarios, thus preventing errors and improving performance.
63+
64+
### Enabling Short-Circuit Evaluation
65+
66+
To enable short-circuit evaluation, set the session variable:
67+
68+
```sql
69+
SET short_circuit_evaluation = true;
70+
```
71+
72+
### Benefits of Short-Circuit Evaluation
73+
74+
1. **Error Prevention**: Avoids executing branches that would cause errors when conditions exclude them
75+
2. **Performance Improvement**: Reduces unnecessary computations by only evaluating branches that are actually needed
76+
3. **More Intuitive Behavior**: Makes conditional functions behave more like traditional programming language conditionals
77+
78+
## Common Conditional Functions
79+
80+
Common conditional functions that benefit from short-circuit evaluation include:
81+
82+
- `IF`: Returns one of two values based on a condition
83+
- `IFNULL`: Returns the first argument if it's not NULL, otherwise returns the second argument
84+
- `CASE`: Provides multiple conditional branches similar to switch-case statements
85+
- `COALESCE`: Returns the first non-NULL value from a list of arguments
86+
- `NULLIF`: Returns NULL if two arguments are equal, otherwise returns the first argument
87+
88+
For detailed information about each function, please refer to their respective documentation pages.
Lines changed: 88 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,88 @@
1+
---
2+
{
3+
"title": "条件函数概述",
4+
"language": "zh-CN",
5+
"description": "条件函数是用于在 SQL 查询中执行条件逻辑和分支的内置函数。"
6+
}
7+
---
8+
9+
# 条件函数概述
10+
11+
条件函数是用于在 SQL 查询中执行条件逻辑和分支的内置函数。它们帮助根据指定的条件执行不同的操作,例如选择值、处理 NULL 值以及执行基于条件的逻辑判断。
12+
13+
## 向量化执行与条件函数
14+
15+
Doris 是向量化执行的引擎。但是对于条件函数,可能会有一些反直觉的地方。
16+
17+
考虑以下示例:
18+
19+
```sql
20+
mysql> set enable_strict_cast = true;
21+
Query OK, 0 rows affected (0.00 sec)
22+
23+
mysql> select count(
24+
-> if(number < 128 ,
25+
-> cast(number as tinyint),
26+
-> cast(number as String))
27+
-> ) from numbers("number" = "300");
28+
ERROR 1105 (HY000): errCode = 2, detailMessage = (127.0.0.1)[INVALID_ARGUMENT]Value 128 out of range for type tinyint
29+
```
30+
31+
上面的例子中,虽然我们在 `if` 函数中,`number < 128` 的分支才会被转换为 `tinyint` 类型,但是还是报错了。这是因为对于 `if(cond, colA, colB)` 这个条件函数,传统的执行方式是:
32+
33+
1. 先完整计算 `colA``colB`
34+
2. 然后根据 `cond` 的值,选择对应的结果返回
35+
36+
所以即使在实际执行中,并没有用到 `colA` 的值,但是因为 `colA` 被完整计算了,所以会报错。
37+
38+
`if``ifnull``case``coalesce` 等函数都有类似的问题。
39+
40+
注意,例如 `LEAST` 这样的函数是没有这样的问题的,因为它本身就需要把所有的参数都计算出来,才能比较大小。
41+
42+
## 短路执行
43+
44+
在 Doris 4.0 版本中,我们对条件函数的执行逻辑进行了改进,允许短路执行。
45+
46+
```sql
47+
mysql> set short_circuit_evaluation = true;
48+
Query OK, 0 rows affected (0.00 sec)
49+
50+
mysql> select count(
51+
-> if(number < 128 ,
52+
-> cast(number as tinyint),
53+
-> cast(number as String))
54+
-> ) from numbers("number" = "300");
55+
+-------------------------------------------------------------------------+
56+
| count(if(number < 128, cast(number as tinyint), cast(number as String)))|
57+
+-------------------------------------------------------------------------+
58+
| 300 |
59+
+-------------------------------------------------------------------------+
60+
```
61+
62+
开启短路执行后,`if``ifnull``case``coalesce` 等函数在很多场景下可以避免不必要的计算,从而避免报错并提升性能。
63+
64+
### 开启短路执行
65+
66+
要开启短路执行,需要设置会话变量:
67+
68+
```sql
69+
SET short_circuit_evaluation = true;
70+
```
71+
72+
### 短路执行的优势
73+
74+
1. **避免错误**:当条件排除某些分支时,避免执行会导致错误的分支
75+
2. **性能提升**:只计算实际需要的分支,减少不必要的计算
76+
3. **更直观的行为**:使条件函数的行为更接近传统编程语言中的条件语句
77+
78+
## 常见条件函数
79+
80+
受益于短路执行的常见条件函数包括:
81+
82+
- `IF`:根据条件返回两个值中的一个
83+
- `IFNULL`:如果第一个参数不为 NULL 则返回第一个参数,否则返回第二个参数
84+
- `CASE`:提供多个条件分支,类似于 switch-case 语句
85+
- `COALESCE`:从参数列表中返回第一个非 NULL 的值
86+
- `NULLIF`:如果两个参数相等则返回 NULL,否则返回第一个参数
87+
88+
有关每个函数的详细信息,请参阅各自的文档页面。
Lines changed: 88 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,88 @@
1+
---
2+
{
3+
"title": "条件函数概述",
4+
"language": "zh-CN",
5+
"description": "条件函数是用于在 SQL 查询中执行条件逻辑和分支的内置函数。"
6+
}
7+
---
8+
9+
# 条件函数概述
10+
11+
条件函数是用于在 SQL 查询中执行条件逻辑和分支的内置函数。它们帮助根据指定的条件执行不同的操作,例如选择值、处理 NULL 值以及执行基于条件的逻辑判断。
12+
13+
## 向量化执行与条件函数
14+
15+
Doris 是向量化执行的引擎。但是对于条件函数,可能会有一些反直觉的地方。
16+
17+
考虑以下示例:
18+
19+
```sql
20+
mysql> set enable_strict_cast = true;
21+
Query OK, 0 rows affected (0.00 sec)
22+
23+
mysql> select count(
24+
-> if(number < 128 ,
25+
-> cast(number as tinyint),
26+
-> cast(number as String))
27+
-> ) from numbers("number" = "300");
28+
ERROR 1105 (HY000): errCode = 2, detailMessage = (127.0.0.1)[INVALID_ARGUMENT]Value 128 out of range for type tinyint
29+
```
30+
31+
上面的例子中,虽然我们在 `if` 函数中,`number < 128` 的分支才会被转换为 `tinyint` 类型,但是还是报错了。这是因为对于 `if(cond, colA, colB)` 这个条件函数,传统的执行方式是:
32+
33+
1. 先完整计算 `colA``colB`
34+
2. 然后根据 `cond` 的值,选择对应的结果返回
35+
36+
所以即使在实际执行中,并没有用到 `colA` 的值,但是因为 `colA` 被完整计算了,所以会报错。
37+
38+
`if``ifnull``case``coalesce` 等函数都有类似的问题。
39+
40+
注意,例如 `LEAST` 这样的函数是没有这样的问题的,因为它本身就需要把所有的参数都计算出来,才能比较大小。
41+
42+
## 短路执行
43+
44+
在 Doris 4.0 版本中,我们对条件函数的执行逻辑进行了改进,允许短路执行。
45+
46+
```sql
47+
mysql> set short_circuit_evaluation = true;
48+
Query OK, 0 rows affected (0.00 sec)
49+
50+
mysql> select count(
51+
-> if(number < 128 ,
52+
-> cast(number as tinyint),
53+
-> cast(number as String))
54+
-> ) from numbers("number" = "300");
55+
+-------------------------------------------------------------------------+
56+
| count(if(number < 128, cast(number as tinyint), cast(number as String)))|
57+
+-------------------------------------------------------------------------+
58+
| 300 |
59+
+-------------------------------------------------------------------------+
60+
```
61+
62+
开启短路执行后,`if``ifnull``case``coalesce` 等函数在很多场景下可以避免不必要的计算,从而避免报错并提升性能。
63+
64+
### 开启短路执行
65+
66+
要开启短路执行,需要设置会话变量:
67+
68+
```sql
69+
SET short_circuit_evaluation = true;
70+
```
71+
72+
### 短路执行的优势
73+
74+
1. **避免错误**:当条件排除某些分支时,避免执行会导致错误的分支
75+
2. **性能提升**:只计算实际需要的分支,减少不必要的计算
76+
3. **更直观的行为**:使条件函数的行为更接近传统编程语言中的条件语句
77+
78+
## 常见条件函数
79+
80+
受益于短路执行的常见条件函数包括:
81+
82+
- `IF`:根据条件返回两个值中的一个
83+
- `IFNULL`:如果第一个参数不为 NULL 则返回第一个参数,否则返回第二个参数
84+
- `CASE`:提供多个条件分支,类似于 switch-case 语句
85+
- `COALESCE`:从参数列表中返回第一个非 NULL 的值
86+
- `NULLIF`:如果两个参数相等则返回 NULL,否则返回第一个参数
87+
88+
有关每个函数的详细信息,请参阅各自的文档页面。

sidebars.ts

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1824,6 +1824,7 @@ const sidebars: SidebarsConfig = {
18241824
type: 'category',
18251825
label: 'Conditional Functions',
18261826
items: [
1827+
'sql-manual/sql-functions/scalar-functions/conditional-functions/overview',
18271828
'sql-manual/sql-functions/scalar-functions/conditional-functions/coalesce',
18281829
'sql-manual/sql-functions/scalar-functions/conditional-functions/greatest',
18291830
'sql-manual/sql-functions/scalar-functions/conditional-functions/if',
Lines changed: 88 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,88 @@
1+
---
2+
{
3+
"title": "Conditional Functions Overview",
4+
"language": "en",
5+
"description": "Conditional functions are built-in functions used to perform conditional logic and branching in SQL queries."
6+
}
7+
---
8+
9+
# Conditional Functions Overview
10+
11+
Conditional functions are built-in functions used to perform conditional logic and branching in SQL queries. They help execute different operations based on specified conditions, such as selecting values, handling NULL values, and performing case-based logic.
12+
13+
## Vectorized Execution and Conditional Functions
14+
15+
Doris is a vectorized execution engine. However, conditional functions may behave in ways that seem counterintuitive.
16+
17+
Consider the following example:
18+
19+
```sql
20+
mysql> set enable_strict_cast = true;
21+
Query OK, 0 rows affected (0.00 sec)
22+
23+
mysql> select count(
24+
-> if(number < 128 ,
25+
-> cast(number as tinyint),
26+
-> cast(number as String))
27+
-> ) from numbers("number" = "300");
28+
ERROR 1105 (HY000): errCode = 2, detailMessage = (127.0.0.1)[INVALID_ARGUMENT]Value 128 out of range for type tinyint
29+
```
30+
31+
In this example, even though we only cast to `tinyint` when `number < 128` in the `if` function, an error still occurs. This is because of how conditional functions like `if(cond, colA, colB)` were traditionally executed:
32+
33+
1. First, both `colA` and `colB` are fully computed
34+
2. Then, based on the value of `cond`, the corresponding result is selected and returned
35+
36+
So even if `colA`'s value is not actually used in practice, since `colA` is fully computed, it will still trigger an error.
37+
38+
Functions like `if`, `ifnull`, `case`, and `coalesce` have similar behavior.
39+
40+
Note that functions like `LEAST` do not have this issue because they inherently need to compute all parameters to compare values.
41+
42+
## Short-Circuit Evaluation
43+
44+
In Doris 4.0, we improved the execution logic of conditional functions to allow short-circuit evaluation.
45+
46+
```sql
47+
mysql> set short_circuit_evaluation = true;
48+
Query OK, 0 rows affected (0.00 sec)
49+
50+
mysql> select count(
51+
-> if(number < 128 ,
52+
-> cast(number as tinyint),
53+
-> cast(number as String))
54+
-> ) from numbers("number" = "300");
55+
+-------------------------------------------------------------------------+
56+
| count(if(number < 128, cast(number as tinyint), cast(number as String)))|
57+
+-------------------------------------------------------------------------+
58+
| 300 |
59+
+-------------------------------------------------------------------------+
60+
```
61+
62+
With short-circuit evaluation enabled, functions like `if`, `ifnull`, `case`, and `coalesce` can avoid unnecessary computations in many scenarios, thus preventing errors and improving performance.
63+
64+
### Enabling Short-Circuit Evaluation
65+
66+
To enable short-circuit evaluation, set the session variable:
67+
68+
```sql
69+
SET short_circuit_evaluation = true;
70+
```
71+
72+
### Benefits of Short-Circuit Evaluation
73+
74+
1. **Error Prevention**: Avoids executing branches that would cause errors when conditions exclude them
75+
2. **Performance Improvement**: Reduces unnecessary computations by only evaluating branches that are actually needed
76+
3. **More Intuitive Behavior**: Makes conditional functions behave more like traditional programming language conditionals
77+
78+
## Common Conditional Functions
79+
80+
Common conditional functions that benefit from short-circuit evaluation include:
81+
82+
- `IF`: Returns one of two values based on a condition
83+
- `IFNULL`: Returns the first argument if it's not NULL, otherwise returns the second argument
84+
- `CASE`: Provides multiple conditional branches similar to switch-case statements
85+
- `COALESCE`: Returns the first non-NULL value from a list of arguments
86+
- `NULLIF`: Returns NULL if two arguments are equal, otherwise returns the first argument
87+
88+
For detailed information about each function, please refer to their respective documentation pages.

0 commit comments

Comments
 (0)