DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Refcards Trend Reports Events Over 2 million developers have joined DZone. Join Today! Thanks for visiting DZone today,
Edit Profile Manage Email Subscriptions Moderation Admin Console How to Post to DZone Article Submission Guidelines
View Profile
Sign Out
Refcards
Trend Reports
Events
Zones
Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
  1. DZone
  2. Data Engineering
  3. Databases
  4. On Par With Window Functions

On Par With Window Functions

See an introduction to window functions and an example.

Keshav Murthy user avatar by
Keshav Murthy
CORE ·
May. 13, 20 · Tutorial
Like (7)
Save
Tweet
Share
20.82K Views

Join the DZone community and get the full member experience.

Join For Free

Use a 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 and 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, and calculating commissions and inventory based on subgroups, positions, etc. These have been in SQL standard in 2003. Every BI layer (like Tableau, Looker, Cognos) exploits this functionality.

Now, Couchbase 6.5 includes Window functions in both query service and analytical service — making it easier for you to write reports and use with BI too.s

You may also like: Fun With SQL: Window Functions in Postgres

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.

Ranked leaderboard using SQL

Insert the data into Couchbase.

Java
 




x


 
1
INSERT INTO golf 
2
VALUES("KP1", {"player": "Marco", "round1":75, "round2":73}),
3
VALUES("KP2", {"player": "Johan", "round1":72, "round2":68}),
4
VALUES("KP3", {"player": "Chang", "round1":67, "round2":76}),
5
VALUES("KP4", {"player": "Isha", "round1":74, "round2":71}),
6
VALUES("KP5", {"player": "Sitaram", "round1":68, "round2":72}),
7
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.

Java
 




xxxxxxxxxx
1
19


 
1
WITH g1 as (select player, round1, round2 from golf)
2
SELECT    g3.player                                AS player,
3
          (g3.round1+g3.round2)                    AS T,
4
          ((g3.round1+g3.round2) - 144)            AS ToPar, 
5
          (select raw 1+COUNT(*) 
6
             from g1 as g2 
7
               where (g2.round1 + g2.round2) < 
8
                     (g3.round1 + g3.round2))[0]   AS sqlrankR2
9
FROM g1 as g3
10
ORDER BY sqlrankR2
11

          
12
Results: 
13
T ToPar player sqlrankR2
14
138 -6 "Bingjie"    1
15
140 -4 "Johan"      2
16
140 -4 "Sitaram"    2
17
143 -1 "Chang"      4
18
145 1 "Isha"       5
19
148 4 "Marco"      6



With window functions in Mad-Hatter (upcoming release) 

This query returns the player, the total after two rounds (T), how much of the score is over/under par (ToPar), and then ranks them based on the scores of the 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.

Java
 




xxxxxxxxxx
1
14


 
1
SELECT    player                                AS player,
2
          (round1+round2)                       AS T,
3
          ((round1+round2) - 144)               AS ToPar,
4
          RANK() OVER(ORDER BY (round1+round2)) AS rankR2
5
FROM golf;
6

          
7

          
8
T ToPar player    rankR2
9
138 -6 "Bingjie"    1
10
140 -4 "Johan"      2
11
140 -4 "Sitaram"    2
12
143 -1 "Chang"      4
13
145 1 "Isha"      5
14
148 4 "Marco"      6



Observations

The query expresses the requirements simply and clearly.

  1. Performance of this query in a real-world scenario is much better. We plan to measure.
  2. When the ranking requirements depend on multiple documents, the query becomes quite complex to write, optimize, and run.
  3. All of 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.

Java
 




xxxxxxxxxx
1
23


 
1
SELECT    player                                AS player,
2
          (round1+round2)                       AS T,
3
          ((round1+round2) - 144)               AS ToPar,
4
          RANK() OVER(ORDER BY (round1+round2)) AS rankR2,
5
          DENSE_RANK() OVER (ORDER BY (round1+round2)) AS rankR2Dense,
6
          ROW_NUMBER() OVER() rownum,
7
          ((round1+round2) - 
8
              FIRST_VALUE(round1+round2) 
9
                OVER(ORDER BY (round1+round2))) AS strokesbehind,
10
          RANK() OVER(ORDER BY (round1))        AS rankR1,
11
          LAG(player, 1, "None") OVER(ORDER BY round1+round2) 
12
                                                AS inFront
13
FROM golf
14
ORDER BY rankR2
15

          
16

          
17
T ToPar inFront   player    rankR1  rankR2 rankR2Dense rownum strokesbehind
18
138 -6 "None"    "Bingjie" 3 1 1 3 0
19
140 -4 "Johan"   "Sitaram" 2 2 2 2 2
20
140 -4 "Bingjie" "Johan" 4 2 2 4 2
21
143 -1 "Sitaram" "Chang" 1 4 3 1 5
22
145 1 "Chang"  "Isha"        5 5 4 5 7
23
148 4 "Isha"   "Marco" 6 6 5 6 10



As you saw earlier, doing this query with six window functions using the 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 Couchbase documentation and 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

  1. Couchbase 6.5 Documentation for Window Functions: https://docs.couchbase.com/server/current/n1ql/n1ql-language-reference/windowfun.html
  2. Probably the Coolest SQL Feature: Window Functions
  3. A Window into the World of Analytic Functions
  4. Oracle Reference

Further Reading

  • WINDOW Function
Database Par (command)

Published at DZone with permission of Keshav Murthy, DZone MVB. See the original article here.

Opinions expressed by DZone contributors are their own.

Popular on DZone

  • API Design Patterns Review
  • How Observability Is Redefining Developer Roles
  • What Is a Kubernetes CI/CD Pipeline?
  • Bye Bye, Regular Dev [Comic]

Comments

Partner Resources

X

ABOUT US

  • About DZone
  • Send feedback
  • Careers
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 600 Park Offices Drive
  • Suite 300
  • Durham, NC 27709
  • support@dzone.com
  • +1 (919) 678-0300

Let's be friends: