Files
2022-02-10 14:51:49 +08:00

2.6 KiB

查询中使用 CASE 函数

CASE 表达式可以实现类似"IF...ELSE...THEN"的逻辑而不用调用子程序。CASE 表达式有两种使用方法,简单的和带搜索条件的。

  • 示例:在查询中使用简单的 CASE 表达式,将国家代码缩写翻译为全称。
obclient> CREATE TABLE t_case(id number NOT NULL PRIMARY KEY, abbr varchar(5));
Query OK, 0 rows affected (0.08 sec)

obclient> INSERT INTO t_case(id, abbr) VALUES (1,'US'),(2,'UK'),(3,'CN'),(4,'JP');
Query OK, 4 rows affected (0.02 sec)
Records: 4  Duplicates: 0  Warnings: 0

obclient>
obclient> SELECT id, abbr,
    CASE abbr
         WHEN 'US' THEN 'America'
         WHEN 'UK' THEN 'English'
         WHEN 'CN' THEN 'China'
    ELSE 'UNKOWN'
    END full_name
 FROM t_case ;

+----+------+-----------+
| id | abbr | full_name |
+----+------+-----------+
|  1 | US   | America   |
|  2 | UK   | English   |
|  3 | CN   | China     |
|  4 | JP   | UNKOWN    |
+----+------+-----------+
4 rows in set (0.00 sec)

obclient>
  • 示例:在查询中使用带搜索条件的 CASE 表达式
obclient> DROP TABLE IF EXISTS t_case2;
Query OK, 0 rows affected (0.02 sec)

obclient> CREATE TABLE t_case2(id number NOT NULL PRIMARY KEY, c_date date );
Query OK, 0 rows affected (0.14 sec)

obclient> INSERT INTO t_case2(id,c_date) 
VALUES (1,'2019-03-01')
     ,(2,'2019-05-08')
     ,(3,'2019-07-07')
     ,(4,'2019-10-11')
     ,(5,'2019-12-12')
     ,(6,'2020-01-05');
Query OK, 6 rows affected (0.01 sec)
Records: 6  Duplicates: 0  Warnings: 0

obclient>
obclient> SELECT id, c_date,
     CASE
         WHEN datediff(now(), c_date) > 12*30 THEN 'More than one year ago'
         WHEN datediff(now(), c_date) > 9*30 THEN 'More than three quarters ago'
         WHEN datediff(now(), c_date) > 6*30 THEN 'More than half a year ago'
         WHEN datediff(now(), c_date) > 3*30 THEN 'More than a quarter ago'
         WHEN datediff(now(), c_date) >= 0 THEN 'Within a quarter'
         ELSE 'Illegal'
     END "Duration"
 FROM t_case2;
+----+------------+------------------------------+
| id | c_date     | Duration                     |
+----+------------+------------------------------+
|  1 | 2019-03-01 | More than one year ago       |
|  2 | 2019-05-08 | More than three quarters ago |
|  3 | 2019-07-07 | More than three quarters ago |
|  4 | 2019-10-11 | More than a quarter ago      |
|  5 | 2019-12-12 | More than a quarter ago      |
|  6 | 2020-01-05 | Within a quarter             |
+----+------------+------------------------------+
6 rows in set (0.01 sec)