Window Function windowing options – with examples in PostgreSQL

More window functions here on the blog? What can I say? The deeper I get into them, the more I realize their power. Yet, I have not covered any of the Windowing options available in the OVER() clause so far and that ends with this post. I will share what I have learned, and what I am still learning. Join me and we can learn together…

four-windows-on-a-white-house
Photo by Steinar Engeland 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)

Using the FIRST_VALUE() window function, this query returns the ‘first_name’ value for what I like to think of as, the big spender:

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

However, behind the scenes, there is a Windowing clause in the OVER() clause that can make a significant impact on returned results

Let’s incorporate one in this next query:

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
SELECT vc.first_name, vc.last_name, vc.total_spent,
FIRST_VALUE(vc.first_name) OVER(ORDER BY total_spent DESC ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING)
FROM valued_customers AS vc;
 first_name | last_name | total_spent | first_value
------------+-----------+-------------+-------------
 Eleanor    | Hunt      |      211.55 | Eleanor
 Karl       | Seal      |      208.58 | Eleanor
 Marion     | Snyder    |      194.61 | Eleanor
 Rhonda     | Kennedy   |      191.62 | Eleanor
 Clara      | Shaw      |      189.60 | Eleanor
 Tommy      | Collazo   |      183.63 | Eleanor
 Ana        | Bradley   |      167.67 | Eleanor
 Curtis     | Irby      |      167.62 | Eleanor
 Marcia     | Dean      |      166.61 | Eleanor
 Mike       | Way       |      162.67 | Eleanor
 Arnold     | Havens    |      161.68 | Eleanor
 Wesley     | Bull      |      158.65 | Eleanor
 Gordon     | Allard    |      157.69 | Eleanor
 Louis      | Leone     |      156.66 | Eleanor
 Lena       | Jensen    |      154.70 | Eleanor
 Tim        | Cary      |      154.66 | Eleanor
 Warren     | Sherrod   |      152.69 | Eleanor
 Steve      | Mackenzie |      152.68 | Eleanor
 Brittany   | Riley     |      151.73 | Eleanor
 Guy        | Brownlee  |      151.69 | Eleanor
 June       | Carroll   |      151.68 | Eleanor
(21 rows)

Via the explicit, ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING, windowing clause, you can now see what is, default windowing behavior when using ROWS in this instance.

Notice the change in this next query where I use an integer value:

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
SELECT vc.first_name, vc.last_name, vc.total_spent,
FIRST_VALUE(vc.first_name) OVER(ORDER BY total_spent DESC ROWS BETWEEN 2 PRECEDING AND CURRENT ROW)
FROM valued_customers AS vc;
 first_name | last_name | total_spent | first_value
------------+-----------+-------------+-------------
 Eleanor    | Hunt      |      211.55 | Eleanor
 Karl       | Seal      |      208.58 | Eleanor
 Marion     | Snyder    |      194.61 | Eleanor
 Rhonda     | Kennedy   |      191.62 | Karl
 Clara      | Shaw      |      189.60 | Marion
 Tommy      | Collazo   |      183.63 | Rhonda
 Ana        | Bradley   |      167.67 | Clara
 Curtis     | Irby      |      167.62 | Tommy
 Marcia     | Dean      |      166.61 | Ana
 Mike       | Way       |      162.67 | Curtis
 Arnold     | Havens    |      161.68 | Marcia
 Wesley     | Bull      |      158.65 | Mike
 Gordon     | Allard    |      157.69 | Arnold
 Louis      | Leone     |      156.66 | Wesley
 Lena       | Jensen    |      154.70 | Gordon
 Tim        | Cary      |      154.66 | Louis
 Warren     | Sherrod   |      152.69 | Lena
 Steve      | Mackenzie |      152.68 | Tim
 Brittany   | Riley     |      151.73 | Warren
 Guy        | Brownlee  |      151.69 | Steve
 June       | Carroll   |      151.68 | Brittany
(21 rows)

With ROWS BETWEEN 2 PRECEDING, the FIRST_VALUE() function is applied to the current row and that specified number of rows back (preceding) from it.

The CURRENT ROW portion of the windowing clause is what enables (or prohibits) any returned rows beyond the current row, in the results set.

How about 5 ROWS PRECEDING?

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
SELECT vc.first_name, vc.last_name, vc.total_spent,
FIRST_VALUE(vc.first_name) OVER(ORDER BY total_spent DESC ROWS BETWEEN 5 PRECEDING AND CURRENT ROW)
FROM valued_customers AS vc;
 first_name | last_name | total_spent | first_value
------------+-----------+-------------+-------------
 Eleanor    | Hunt      |      211.55 | Eleanor
 Karl       | Seal      |      208.58 | Eleanor
 Marion     | Snyder    |      194.61 | Eleanor
 Rhonda     | Kennedy   |      191.62 | Eleanor
 Clara      | Shaw      |      189.60 | Eleanor
 Tommy      | Collazo   |      183.63 | Eleanor
 Ana        | Bradley   |      167.67 | Karl
 Curtis     | Irby      |      167.62 | Marion
 Marcia     | Dean      |      166.61 | Rhonda
 Mike       | Way       |      162.67 | Clara
 Arnold     | Havens    |      161.68 | Tommy
 Wesley     | Bull      |      158.65 | Ana
 Gordon     | Allard    |      157.69 | Curtis
 Louis      | Leone     |      156.66 | Marcia
 Lena       | Jensen    |      154.70 | Mike
 Tim        | Cary      |      154.66 | Arnold
 Warren     | Sherrod   |      152.69 | Wesley
 Steve      | Mackenzie |      152.68 | Gordon
 Brittany   | Riley     |      151.73 | Louis
 Guy        | Brownlee  |      151.69 | Lena
 June       | Carroll   |      151.68 | Tim
(21 rows)

Finally, one last example with 15 ROWS PRECEDING:

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
SELECT vc.first_name, vc.last_name, vc.total_spent,
FIRST_VALUE(vc.first_name) OVER(ORDER BY total_spent DESC ROWS BETWEEN 15 PRECEDING AND CURRENT ROW)
FROM valued_customers AS vc;
 first_name | last_name | total_spent | first_value
------------+-----------+-------------+-------------
 Eleanor    | Hunt      |      211.55 | Eleanor
 Karl       | Seal      |      208.58 | Eleanor
 Marion     | Snyder    |      194.61 | Eleanor
 Rhonda     | Kennedy   |      191.62 | Eleanor
 Clara      | Shaw      |      189.60 | Eleanor
 Tommy      | Collazo   |      183.63 | Eleanor
 Ana        | Bradley   |      167.67 | Eleanor
 Curtis     | Irby      |      167.62 | Eleanor
 Marcia     | Dean      |      166.61 | Eleanor
 Mike       | Way       |      162.67 | Eleanor
 Arnold     | Havens    |      161.68 | Eleanor
 Wesley     | Bull      |      158.65 | Eleanor
 Gordon     | Allard    |      157.69 | Eleanor
 Louis      | Leone     |      156.66 | Eleanor
 Lena       | Jensen    |      154.70 | Eleanor
 Tim        | Cary      |      154.66 | Eleanor
 Warren     | Sherrod   |      152.69 | Karl
 Steve      | Mackenzie |      152.68 | Marion
 Brittany   | Riley     |      151.73 | Rhonda
 Guy        | Brownlee  |      151.69 | Clara
 June       | Carroll   |      151.68 | Tommy
(21 rows)

Up to this point, we have established: 1) Specifying UNBOUNDED PRECEDING envelopes all rows back as far as possible, and the current row. 2) An explicit (integer) ROWS value includes the current row and number of rows preceding.

Once again, I have thoroughly enjoyed learning and writing this post. Look for more blog posts to come here on Digital Owl’s Prose regarding Window Functions and SQL goodness.

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.

3 thoughts on “Window Function windowing options – with examples in PostgreSQL

  1. Thanks for explaining such a complex concept in so simple way! Feel free to visit Vertabelo Academy Blog where you can find similar content and maybe inspire 😉 I think we have a lot in common–strong passion to SQL 😉

    • Thanks so much for such a wonderful and inspiring comment! It means a great deal to me for others to find something useful in what I write and learn about SQL. Glad you enjoyed the post👍🙏👏

Hey thanks for commenting! Leave a Reply

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