Use golf analogy when explaining to executives.
Use a car analogy for all others. — Confucius.
The purpose of window functions is to translate the business reporting requirements declaratively and effectively to SQL so query performance and developer/business-analyst efficiency improve dramatically. I’ve seen real-world reports and dashboards go from hours to minutes, minutes to seconds after using window functions. Query size decreases from 40-pages to a few pages. Back in the ‘90s, Redbrick database really understood the business use case and created a new layer of functionality to do business reporting that included ranking, running totals, calculating commissions & inventory based on subgroups, positions, etc. These have been in SQL standard in 2003. Every BI layer (like Tableau, Looker, Cognos) exploits this functionality.
Introduction to Window Functions
Imagine you have scores of six golfers through two rounds. Now, you need to create the leaderboard and rank them. Rank them using SQL.
Player | Round1 | Round2 |
Marco | 75 | 73 |
Johan | 72 | 68 |
Chang | 67 | 76 |
Isha | 74 | 71 |
Sitaram | 68 | 72 |
Bingjie | 71 | 67 |
Insert the data into Couchbase.
1 2 3 4 5 6 7 8 9 10 11 |
INSERT INTO golf VALUES("KP1", {"player": "Marco", "round1":75, "round2":73}), VALUES("KP2", {"player": "Johan", "round1":72, "round2":68}), VALUES("KP3", {"player": "Chang", "round1":67, "round2":76}), VALUES("KP4", {"player": "Isha", "round1":74, "round2":71}), VALUES("KP5", {"player": "Sitaram", "round1":68, "round2":72}), VALUES("KP6", {"player": "Bingjie", "round1":71, "round2":67}); |
WITHOUT window functions (current state – Couchbase 6.0)
To write the query without the use of window functions, you need a subquery to calculate the rank for each player. This subquery has to scan through all of the data resulting in the worst algorithmic complexity of O(N^2), which dramatically increases the execution time and throughput.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 |
WITH g1 as (select player, round1, round2 from golf) SELECT g3.player AS player, (g3.round1+g3.round2) AS T, ((g3.round1+g3.round2) - 144) AS ToPar, (select raw 1+COUNT(*) from g1 as g2 where (g2.round1 + g2.round2) < (g3.round1 + g3.round2))[0] AS sqlrankR2 FROM g1 as g3 ORDER BY sqlrankR2 Results: T ToPar player sqlrankR2 138 -6 "Bingjie" 1 140 -4 "Johan" 2 140 -4 "Sitaram" 2 143 -1 "Chang" 4 145 1 "Isha" 5 148 4 "Marco" 6 |
With window functions in Mad-Hatter (upcoming release)
This query returns player, total after two rounds (T), how of the score is over/under par (ToPar) and then ranks them based on the scores of first two rounds. This is the NEW functionality in Mad-Hatter. The time complexity of this is O(N), meaning execution time will only increase linearly.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 |
SELECT player AS player, (round1+round2) AS T, ((round1+round2) - 144) AS ToPar, RANK() OVER(ORDER BY (round1+round2)) AS rankR2 FROM golf; T ToPar player rankR2 138 -6 "Bingjie" 1 140 -4 "Johan" 2 140 -4 "Sitaram" 2 143 -1 "Chang" 4 145 1 "Isha" 5 148 4 "Marco" 6 |
Observations:
- The query expresses the requirements simply and clearly.
- Performance of this query in a real-world scenario is much better. We plan to measure.
- When the ranking requirements depend on multiple documents, the query becomes quite complex — to write, optimize and run.
- All this affects the TCO overall.
Now, let’s create an expanded dashboard.
Show add dense rank, row number, who’s ahead, and the number of strokes behind the leader. All very common things in a reporting resituation. You’re seeing the new window function whenever you see the OVER() clause. The query below has six window functions.
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 player AS player, (round1+round2) AS T, ((round1+round2) - 144) AS ToPar, RANK() OVER(ORDER BY (round1+round2)) AS rankR2, DENSE_RANK() OVER (ORDER BY (round1+round2)) AS rankR2Dense, ROW_NUMBER() OVER() rownum, ((round1+round2) - FIRST_VALUE(round1+round2) OVER(ORDER BY (round1+round2))) AS strokesbehind, RANK() OVER(ORDER BY (round1)) AS rankR1, LAG(player, 1, "None") OVER(ORDER BY round1+round2) AS inFront FROM golf ORDER BY rankR2 T ToPar inFront player rankR1 rankR2 rankR2Dense rownum strokesbehind 138 -6 "None" "Bingjie" 3 1 1 3 0 140 -4 "Johan" "Sitaram" 2 2 2 2 2 140 -4 "Bingjie" "Johan" 4 2 2 4 2 143 -1 "Sitaram" "Chang" 1 4 3 1 5 145 1 "Chang" "Isha" 5 5 4 5 7 148 4 "Isha" "Marco" 6 6 5 6 10 |
As you saw earlier, doing this query with six window functions using subquery method will be a larger effort, expensive, error-prone query.
In addition to making the built-in aggregates (COUNT, SUM, AVG, etc) as window functions, Sitaram has added the following window functions. The syntax and semantics of each of them are well defined in the standard and well described in the articles of the reference section below.
RANK()
DENSE_RANK()
PERCENT_RANK()
CUME_DIST()
NTILE()
RATIO_TO_REPORT()
ROW_NUMBER()
LAG()
FIRST_VALUE()
LAST_VALUE()
NTH_VALUE()
LEAD()
References:
- Probably the Coolest SQL Feature: Window Functions. https://blog.jooq.org/2013/11/03/probably-the-coolest-sql-feature-window-functions/
- A Window into the World of Analytic Functions. https://blogs.oracle.com/oraclemagazine/a-window-into-the-world-of-analytic-functions
- Oracle Reference: https://docs.oracle.com/cd/E11882_01/server.112/e41084/functions004.htm#SQLRF06174