LEAD [analytic]

窗口内当前行之后的行返回值,以便您可以同时访问表中的多行。这对于在可以可靠地知道行的相对位置时比较值很有用。借助它还可以避免成本较高的自联接,从而加快查询处理速度。

行为类型

不可变

语法

LEAD ( expression[, offset ] [, default ] ) OVER (
    [ window-partition-clause ]
    window-order-clause )

参数

表达式
要进行求值的表达式,例如常数、列、非统计函数、函数表达式或任何涉及以上内容的表达式。
offset
是一个可选参数,默认值为 1(下一行)。此参数的计算结果必须为常数正整数。
default
offset 超出表或分区的边界时返回的值。此值必须是一个常数值或者可以解析为常数的表达式;数据类型强制转换为第一个实参的类型。

示例

LEAD 在当前行之后找到了员工的雇佣日期:


=> SELECT employee_region, hire_date, employee_key, employee_last_name,
   LEAD(hire_date, 1) OVER (PARTITION BY employee_region ORDER BY hire_date) AS "next_hired"
   FROM employee_dimension ORDER BY employee_region, hire_date, employee_key;
  employee_region  | hire_date  | employee_key | employee_last_name | next_hired
-------------------+------------+--------------+--------------------+------------
 East              | 1956-04-08 |         9218 | Harris             | 1957-02-06
 East              | 1957-02-06 |         7799 | Stein              | 1957-05-25
 East              | 1957-05-25 |         3687 | Farmer             | 1957-06-26
 East              | 1957-06-26 |         9474 | Bauer              | 1957-08-18
 East              | 1957-08-18 |          570 | Jefferson          | 1957-08-24
 East              | 1957-08-24 |         4363 | Wilson             | 1958-02-17
 East              | 1958-02-17 |         6457 | McCabe             | 1958-06-26
 East              | 1958-06-26 |         6196 | Li                 | 1958-07-16
 East              | 1958-07-16 |         7749 | Harris             | 1958-09-18
 East              | 1958-09-18 |         9678 | Sanchez            | 1958-11-10
(10 rows)

接下来的示例使用 LEADLAG 返回了当前行工资后的第三行以及当前行工资之前的第五行。

=> SELECT hire_date, employee_key, employee_last_name,
   LEAD(hire_date, 1) OVER (ORDER BY hire_date) AS "next_hired" ,
   LAG(hire_date, 1) OVER (ORDER BY hire_date) AS "last_hired"
   FROM employee_dimension ORDER BY hire_date, employee_key;
 hire_date  | employee_key | employee_last_name | next_hired | last_hired
------------+--------------+--------------------+------------+------------
 1956-04-11 |         2694 | Farmer             | 1956-05-12 |
 1956-05-12 |         5486 | Winkler            | 1956-09-18 | 1956-04-11
 1956-09-18 |         5525 | McCabe             | 1957-01-15 | 1956-05-12
 1957-01-15 |          560 | Greenwood          | 1957-02-06 | 1956-09-18
 1957-02-06 |         9781 | Bauer              | 1957-05-25 | 1957-01-15
 1957-05-25 |         9506 | Webber             | 1957-07-04 | 1957-02-06
 1957-07-04 |         6723 | Kramer             | 1957-07-07 | 1957-05-25
 1957-07-07 |         5827 | Garnett            | 1957-11-11 | 1957-07-04
 1957-11-11 |          373 | Reyes              | 1957-11-21 | 1957-07-07
 1957-11-21 |         3874 | Martin             | 1958-02-06 | 1957-11-11
(10 rows)

以下例子返回员工名和工资,以及最高工资和最低工资。

=> SELECT employee_last_name, annual_salary,
       NVL(LEAD(annual_salary) OVER (ORDER BY annual_salary),
         MIN(annual_salary) OVER()) "Next Highest",
       NVL(LAG(annual_salary) OVER (ORDER BY annual_salary),
         MAX(annual_salary)  OVER()) "Next Lowest"
   FROM employee_dimension;
 employee_last_name | annual_salary | Next Highest | Next Lowest
--------------------+---------------+--------------+-------------
 Nielson            |          1200 |         1200 |      995533
 Lewis              |          1200 |         1200 |        1200
 Harris             |          1200 |         1202 |        1200
 Robinson           |          1202 |         1202 |        1200
 Garnett            |          1202 |         1202 |        1202
 Weaver             |          1202 |         1202 |        1202
 Nielson            |          1202 |         1202 |        1202
 McNulty            |          1202 |         1204 |        1202
 Farmer             |          1204 |         1204 |        1202
 Martin             |          1204 |         1204 |        1204
(10 rows)

下一个例子在员工表中每一个助理总监,在当前行总监之后入职的总监的雇用日期。例如,Jackson 被雇佣日期是 2016/12/28,下一个雇佣的总监是 Bauer:

=> SELECT employee_last_name, hire_date,
       LEAD(hire_date, 1) OVER (ORDER BY hire_date DESC) as "NextHired"
   FROM employee_dimension WHERE job_title = 'Assistant Director';
 employee_last_name | hire_date  | NextHired
--------------------+------------+------------
 Jackson            | 2016-12-28 | 2016-12-26
 Bauer              | 2016-12-26 | 2016-12-11
 Miller             | 2016-12-11 | 2016-12-07
 Fortin             | 2016-12-07 | 2016-11-27
 Harris             | 2016-11-27 | 2016-11-15
 Goldberg           | 2016-11-15 |
(5 rows)

另请参阅