LAG
Access data from a preceding row. This function returns the value of an expression from a row at a specified physical offset prior to the current row.
Syntax
LAG (expr[, offset]) OVER (
[ PARTITION BY partition_expression ]
< ORDER BY order_list >
)Description
The LAG function accesses data from a previous row according to the ORDER BY clause without the need for a self-join. The specific row is determined by the offset (default 1), which specifies the number of rows behind the current row to use. An offset of 0 is the current row.
Examples
CREATE TABLE t1 (pk int primary key, a int, b int, c char(10), d decimal(10, 3), e real);
INSERT INTO t1 VALUES
( 1, 0, 1, 'one', 0.1, 0.001),
( 2, 0, 2, 'two', 0.2, 0.002),
( 3, 0, 3, 'three', 0.3, 0.003),
( 4, 1, 2, 'three', 0.4, 0.004),
( 5, 1, 1, 'two', 0.5, 0.005),
( 6, 1, 1, 'one', 0.6, 0.006),
( 7, 2, NULL, 'n_one', 0.5, 0.007),
( 8, 2, 1, 'n_two', NULL, 0.008),
( 9, 2, 2, NULL, 0.7, 0.009),
(10, 2, 0, 'n_four', 0.8, 0.010),
(11, 2, 10, NULL, 0.9, NULL);
SELECT pk, LAG(pk) OVER (ORDER BY pk) AS l,
LAG(pk,1) OVER (ORDER BY pk) AS l1,
LAG(pk,2) OVER (ORDER BY pk) AS l2,
LAG(pk,0) OVER (ORDER BY pk) AS l0,
LAG(pk,-1) OVER (ORDER BY pk) AS lm1,
LAG(pk,-2) OVER (ORDER BY pk) AS lm2
FROM t1;
+----+------+------+------+------+------+------+
| pk | l | l1 | l2 | l0 | lm1 | lm2 |
+----+------+------+------+------+------+------+
| 1 | NULL | NULL | NULL | 1 | 2 | 3 |
| 2 | 1 | 1 | NULL | 2 | 3 | 4 |
| 3 | 2 | 2 | 1 | 3 | 4 | 5 |
| 4 | 3 | 3 | 2 | 4 | 5 | 6 |
| 5 | 4 | 4 | 3 | 5 | 6 | 7 |
| 6 | 5 | 5 | 4 | 6 | 7 | 8 |
| 7 | 6 | 6 | 5 | 7 | 8 | 9 |
| 8 | 7 | 7 | 6 | 8 | 9 | 10 |
| 9 | 8 | 8 | 7 | 9 | 10 | 11 |
| 10 | 9 | 9 | 8 | 10 | 11 | NULL |
| 11 | 10 | 10 | 9 | 11 | NULL | NULL |
+----+------+------+------+------+------+------+See Also
LEAD - Window function to access a following row
This page is licensed: CC BY-SA / Gnu FDL
Last updated
Was this helpful?

