LEAD() Window Function – with examples in PostgreSQL

Having been forewarned in several of my previous blog posts that I am on a SQL Window Function kick, it should be no surprise that here I am again; sharing what I am studying and learning. I continue to find these powerful constructs highly interesting, to say the least. In this post, I visit the LEAD() Window Function with examples in PostgreSQL. Read on and let’s learn something together…

Photo by Luca Nicoletti on Unsplash

Note: All data, names or naming found within the database presented in this post, are strictly used for practice, learning, instruction, and testing purposes. It by no means depicts actual data belonging to or being used by any party or organization.

OS and DB used:
  • Xubuntu Linux 18.04.2 LTS (Bionic Beaver)
  • PostgreSQL 11.2


Self-Promotion:

If you enjoy the content written here, by all means, share this blog and your favorite post(s) with others who may benefit from or like it as well. Since coffee is my favorite drink, you can even buy me one if you would like!


I’ll use a couple of tables from the PostgreSQL practice DVD Rental database for the example queries below.

Throughout this post, let’s assume we have this CTE that returns the below query results:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
WITH valued_customers AS (
SELECT
        c.first_name AS first_name,
        c.last_name AS last_name,
        SUM(p.amount) AS total_spent
        FROM customer AS c
INNER JOIN payment AS p
ON c.customer_id = p.customer_id
GROUP by c.first_name, c.last_name
HAVING SUM(p.amount) > 150)

SELECT * FROM valued_customers;
 first_name | last_name | total_spent
------------+-----------+-------------
 Lena       | Jensen    |      154.70
 Tommy      | Collazo   |      183.63
 Ana        | Bradley   |      167.67
 Clara      | Shaw      |      189.60
 Brittany   | Riley     |      151.73
 Warren     | Sherrod   |      152.69
 Karl       | Seal      |      208.58
 Arnold     | Havens    |      161.68
 Mike       | Way       |      162.67
 Wesley     | Bull      |      158.65
 Gordon     | Allard    |      157.69
 Marcia     | Dean      |      166.61
 June       | Carroll   |      151.68
 Tim        | Cary      |      154.66
 Eleanor    | Hunt      |      211.55
 Marion     | Snyder    |      194.61
 Steve      | Mackenzie |      152.68
 Guy        | Brownlee  |      151.69
 Curtis     | Irby      |      167.62
 Louis      | Leone     |      156.66
 Rhonda     | Kennedy   |      191.62
(21 rows)

What does the LEAD() function do?

For a better understanding, let’s first know of its syntax structure:

1
LEAD(column_name or expression, [offset value], [default value]) OVER(ORDER BY col_1, col_2, etc...)

Syntax observations:

  • Accepts at most, 3 parameters: 1 which is mandatory, while the other 2 (denoted in the syntax above by square brackets) are optional.
  • offset value parameter – Dictates the number of rows to lead (or access) with the current row. 1 is the default.
  • default value parameter – Indicates what will be returned should no more rows be available in the results set according to the offset parameter value. NULL is the default.
  • ORDER BY clause is required in the OVER() clause.

In a nutshell, LEAD() accesses current row and subsequent row data. The accessed row beyond the current row depends upon the (2nd) offset value parameter, as we will see with examples that follow.

Prior to reviewing any query results, I’ll set NULL to something a bit more visible for the psql session:

1
2
dvdrental=> \pset null '!#!'
Null display is "!#!".

Here is a base query without supplying both the 2nd and 3rd LEAD() function parameters:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
SELECT
first_name, last_name, total_spent,
LEAD(total_spent) OVER(ORDER BY total_spent) as leading
FROM valued_customers;
 first_name | last_name | total_spent | leading
------------+-----------+-------------+---------
 June       | Carroll   |      151.68 |  151.69
 Guy        | Brownlee  |      151.69 |  151.73
 Brittany   | Riley     |      151.73 |  152.68
 Steve      | Mackenzie |      152.68 |  152.69
 Warren     | Sherrod   |      152.69 |  154.66
 Tim        | Cary      |      154.66 |  154.70
 Lena       | Jensen    |      154.70 |  156.66
 Louis      | Leone     |      156.66 |  157.69
 Gordon     | Allard    |      157.69 |  158.65
 Wesley     | Bull      |      158.65 |  161.68
 Arnold     | Havens    |      161.68 |  162.67
 Mike       | Way       |      162.67 |  166.61
 Marcia     | Dean      |      166.61 |  167.62
 Curtis     | Irby      |      167.62 |  167.67
 Ana        | Bradley   |      167.67 |  183.63
 Tommy      | Collazo   |      183.63 |  189.60
 Clara      | Shaw      |      189.60 |  191.62
 Rhonda     | Kennedy   |      191.62 |  194.61
 Marion     | Snyder    |      194.61 |  208.58
 Karl       | Seal      |      208.58 |  211.55
 Eleanor    | Hunt      |      211.55 |     !#!
(21 rows)

The above query is basically mirrored with the next one, in which I specify the defaults for the 2nd and 3rd parameters:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
SELECT
first_name, last_name, total_spent,
LEAD(total_spent, 1, NULL) OVER(ORDER BY total_spent) as leading
FROM valued_customers;
 first_name | last_name | total_spent | leading
------------+-----------+-------------+---------
 June       | Carroll   |      151.68 |  151.69
 Guy        | Brownlee  |      151.69 |  151.73
 Brittany   | Riley     |      151.73 |  152.68
 Steve      | Mackenzie |      152.68 |  152.69
 Warren     | Sherrod   |      152.69 |  154.66
 Tim        | Cary      |      154.66 |  154.70
 Lena       | Jensen    |      154.70 |  156.66
 Louis      | Leone     |      156.66 |  157.69
 Gordon     | Allard    |      157.69 |  158.65
 Wesley     | Bull      |      158.65 |  161.68
 Arnold     | Havens    |      161.68 |  162.67
 Mike       | Way       |      162.67 |  166.61
 Marcia     | Dean      |      166.61 |  167.62
 Curtis     | Irby      |      167.62 |  167.67
 Ana        | Bradley   |      167.67 |  183.63
 Tommy      | Collazo   |      183.63 |  189.60
 Clara      | Shaw      |      189.60 |  191.62
 Rhonda     | Kennedy   |      191.62 |  194.61
 Marion     | Snyder    |      194.61 |  208.58
 Karl       | Seal      |      208.58 |  211.55
 Eleanor    | Hunt      |      211.55 |     !#!
(21 rows)

So just what is going on with this LEAD() function? Let’ dissect the below screen shot:

commandline-output-of-postgresql-qurey
LEAD() function default values…

Notice the first row’s ‘leading’ column value of 151.69 is the ‘total_spent’ column value for the next row in the result set. Proceeding from there, the 2nd row’s ‘leading’ column value of 151.73 is in fact, the 3rd rows’ ‘total_spent’ column value.

This pattern continues for all remaining rows in the results set.

All that being said, LEAD() returns the 1st parameter value (‘total_spent’ column in this particular query) for the subsequent row -established by the 2nd function parameter- along with the current row. What subsequent row data is returned when all rows from the query results have been exhausted?

See the below screen shot:

3rd parameter default value of NULL…

Seeing as there are no remaining rows beyond this last row, !#! is returned. (Which is NULL for this psql session.)

Next, I will change up the parameter values for LEAD() and explore those results:

1
2
3
4
SELECT
first_name, last_name, total_spent,
LEAD(total_spent, 4) OVER(ORDER BY total_spent) as leading
FROM valued_customers;

psql-command-line-query-results
Leading by 4 rows…

Even though the image only indicates a couple of rows’ ‘leading’ and corresponding ‘total_spent’ column values, all rows in the result set follow this same pattern.

Notice what happens to the ‘leading’ column value at the 4th row from the end of the results. Since for each of those remaining 4 rows, there is not a ‘total_spent’ value for LEAD() to access, they are indicated with the marker I set for NULl (which is the default).

Perhaps you pose the question of how to access the current and a previous row? Well, you are in luck! There is a LAG() Window Function capable of those type of queries. However, that will be another blog post in the future so be sure and check back when that post drops!

Like what you have read? See anything incorrect? Please comment below and thanks for reading!!!

Explore the official PostgreSQL 11 On-line Documentation for more information.

A Call To Action!

Thank you for taking the time to read this post. I truly hope you discovered something interesting and enlightening. Please share your findings here, with someone else you know who would get the same value out of it as well.

Visit the Portfolio-Projects page to see blog post/technical writing I have completed for clients.

Have I mentioned how much I love a cup of coffee?!?!

To receive email notifications (Never Spam) from this blog (“Digital Owl’s Prose”) for the latest blog posts as they are published, please subscribe (of your own volition) by clicking the โ€˜Click To Subscribe!โ€™ button in the sidebar on the homepage! (Feel free at any time to review the Digital Owl’s Prose Privacy Policy Page for any questions you may have about: email updates, opt-in, opt-out, contact forms, etc…)

Be sure and visit the “Best Of” page for a collection of my best blog posts.


Josh Otwell has a passion to study and grow as a SQL Developer and blogger. Other favorite activities find him with his nose buried in a good book, article, or the Linux command line. Among those, he shares a love of tabletop RPG games, reading fantasy novels, and spending time with his wife and two daughters.

Disclaimer: The examples presented in this post are hypothetical ideas of how to achieve similar types of results. They are not the utmost best solution(s). The majority, if not all, of the examples provided, is performed on a personal development/learning workstation-environment and should not be considered production quality or ready. Your particular goals and needs may vary. Use those practices that best benefit your needs and goals. Opinions are my own.

One thought on “LEAD() Window Function – with examples in PostgreSQL

Hey thanks for commenting! Leave a Reply

This site uses Akismet to reduce spam. Learn how your comment data is processed.