With Window Functions, there is always something to learn. They have numerous moving parts but allow for powerful queries that return powerful results. I recently learned of (new to me, but not new to the SQL world) another interesting Window Function, FIRST_VALUE()
. Read on as I explore more about it…
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!
What I am learning and sharing in this post, is inspired by a fantastic video, FIRST VALUE function in SQL Server that I highly recommend watching.
I’ll use a couple of tables from the PostgreSQL practice DVD Rental database for the example queries below.
We will start off with this query that determines those customers who spent amounts greater than 150.00 in DVD rentals and using CASE
, assign them a member status based on their spending:
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 | SELECT c.first_name, c.last_name, SUM(p.amount), CASE WHEN SUM(p.amount) > 190 THEN 'platinum' WHEN SUM(p.amount) BETWEEN 170 AND 190 THEN 'gold' WHEN SUM(p.amount) BETWEEN 160 AND 170 THEN 'bronze' ELSE 'standard' END AS member_status 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; first_name | last_name | sum | member_status ------------+-----------+--------+--------------- Lena | Jensen | 154.70 | standard Tommy | Collazo | 183.63 | gold Ana | Bradley | 167.67 | bronze Clara | Shaw | 189.60 | gold Brittany | Riley | 151.73 | standard Warren | Sherrod | 152.69 | standard Karl | Seal | 208.58 | platinum Arnold | Havens | 161.68 | bronze Mike | Way | 162.67 | bronze Wesley | Bull | 158.65 | standard Gordon | Allard | 157.69 | standard Marcia | Dean | 166.61 | bronze June | Carroll | 151.68 | standard Tim | Cary | 154.66 | standard Eleanor | Hunt | 211.55 | platinum Marion | Snyder | 194.61 | platinum Steve | Mackenzie | 152.68 | standard Guy | Brownlee | 151.69 | standard Curtis | Irby | 167.62 | bronze Louis | Leone | 156.66 | standard Rhonda | Kennedy | 191.62 | platinum (21 rows) |
Using the FIRST_VALUE()
function, we can determine the first value for the argument supplied to the function. However, the ORDER BY
clause must be present in the OVER()
clause.
The following query uses the ‘first_name’ column as the parameter for FIRST_VALUE()
and orders the results by SUM(p.amount)
in DESC
order within the OVER()
clause. Let’s see those 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 | SELECT c.first_name, c.last_name, SUM(p.amount), CASE WHEN SUM(p.amount) > 190 THEN 'platinum' WHEN SUM(p.amount) BETWEEN 170 AND 190 THEN 'gold' WHEN SUM(p.amount) BETWEEN 160 AND 170 THEN 'bronze' ELSE 'standard' END AS member_status, FIRST_VALUE(c.first_name) OVER(ORDER BY SUM(p.amount) DESC) 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; first_name | last_name | sum | member_status | first_value ------------+-----------+--------+---------------+------------- Eleanor | Hunt | 211.55 | platinum | Eleanor Karl | Seal | 208.58 | platinum | Eleanor Marion | Snyder | 194.61 | platinum | Eleanor Rhonda | Kennedy | 191.62 | platinum | Eleanor Clara | Shaw | 189.60 | gold | Eleanor Tommy | Collazo | 183.63 | gold | Eleanor Ana | Bradley | 167.67 | bronze | Eleanor Curtis | Irby | 167.62 | bronze | Eleanor Marcia | Dean | 166.61 | bronze | Eleanor Mike | Way | 162.67 | bronze | Eleanor Arnold | Havens | 161.68 | bronze | Eleanor Wesley | Bull | 158.65 | standard | Eleanor Gordon | Allard | 157.69 | standard | Eleanor Louis | Leone | 156.66 | standard | Eleanor Lena | Jensen | 154.70 | standard | Eleanor Tim | Cary | 154.66 | standard | Eleanor Warren | Sherrod | 152.69 | standard | Eleanor Steve | Mackenzie | 152.68 | standard | Eleanor Brittany | Riley | 151.73 | standard | Eleanor Guy | Brownlee | 151.69 | standard | Eleanor June | Carroll | 151.68 | standard | Eleanor (21 rows) |
Sorting by SUM()
in DESC
order, we can see that first_name ‘Eleanor’ is returned as that row does indeed have the largest SUM()
value across all rows that make up the final result set.
But, even more, interesting results can be obtained by incorporating the optional PARTITION BY
clause in the OVER()
clause. The ‘member_status’ column seems to be a great candidate to form sub-groups with. Also, this is an exceptional opportunity to use another of my favorite SQL nuggets, CTE’s, which I absolutely need (and want) to dig into deeper.
Here’s the complete query with CTE leading the charge:
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 37 38 39 40 41 42 43 44 | WITH valued_customers AS ( SELECT c.first_name AS first_name, c.last_name AS last_name, SUM(p.amount) AS total_spent, CASE WHEN SUM(p.amount) > 190 THEN 'platinum' WHEN SUM(p.amount) BETWEEN 170 AND 190 THEN 'gold' WHEN SUM(p.amount) BETWEEN 160 AND 170 THEN 'bronze' ELSE 'standard' END AS member_status 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 vc.first_name, vc.last_name, vc.total_spent, vc.member_status, FIRST_VALUE(vc.first_name) OVER(PARTITION BY vc.member_status ORDER BY total_spent DESC) FROM valued_customers AS vc; first_name | last_name | total_spent | member_status | first_value ------------+-----------+-------------+---------------+------------- Ana | Bradley | 167.67 | bronze | Ana Curtis | Irby | 167.62 | bronze | Ana Marcia | Dean | 166.61 | bronze | Ana Mike | Way | 162.67 | bronze | Ana Arnold | Havens | 161.68 | bronze | Ana Clara | Shaw | 189.60 | gold | Clara Tommy | Collazo | 183.63 | gold | Clara Eleanor | Hunt | 211.55 | platinum | Eleanor Karl | Seal | 208.58 | platinum | Eleanor Marion | Snyder | 194.61 | platinum | Eleanor Rhonda | Kennedy | 191.62 | platinum | Eleanor Wesley | Bull | 158.65 | standard | Wesley Gordon | Allard | 157.69 | standard | Wesley Louis | Leone | 156.66 | standard | Wesley Lena | Jensen | 154.70 | standard | Wesley Tim | Cary | 154.66 | standard | Wesley Warren | Sherrod | 152.69 | standard | Wesley Steve | Mackenzie | 152.68 | standard | Wesley Brittany | Riley | 151.73 | standard | Wesley Guy | Brownlee | 151.69 | standard | Wesley June | Carroll | 151.68 | standard | Wesley (21 rows) |
In my opinion, this is where the PARTITION BY
clause is such a game changer. By forming sub-groups of rows with it, based on the member_status column, we have now displayed a big spender (so to speak) name for each individual sub-group. If we changed the ORDER BY
clause to ASC
, we would be returned the least total_spent amount per sub-group.
The rundown is as follows:
- For the bronze group, Ann (total_spent: 167.67)
- For the gold group, Clara (total_spent: 189.60)
- For the platinum group, Eleanor (total_spent: 211.55)
- For the standard group, Wesley (total_spent: 158.65)
I’ve likely said this before, but it’s worth repeating: Window Functions are simply incredible. The more time I get to explore them, the more I learn about them. More importantly, the more I learn what I do not know about them, in itself, keeps me coming back for even more. Explore the FIRST_VALUE()
window function (among the others) and see if you can find a great use case for it. I’d love to know about them in the comments below!
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.