Join us on YugabyteDB Community Slack
Star us on
Get Started
Slack
GitHub
Get Started
v2.13 (latest) v2.12 (stable) v2.8 (earlier version) v2.6 (earlier version) v2.4 (earlier version) v2.2 (earlier version) v2.1 (earlier version) v2.0 (earlier version) v1.3 (earlier version)
  • YUGABYTEDB CORE
    • Quick start
      • 1. Install YugabyteDB
      • 2. Create a local cluster
      • 3. Explore distributed SQL
      • 4. Build an application
        • Java
        • Node.js
        • Go
        • Python
        • Ruby
        • C#
        • PHP
        • C++
        • C
        • Scala
    • Explore
      • SQL features
        • Schemas and Tables
        • Data Types
        • Data Manipulation
        • Queries and Joins
        • Expressions and Operators
        • Stored Procedures
        • Triggers
        • Advanced features
          • Cursors
          • Table Partitioning
          • Views
          • Savepoints
          • Collations
          • Extensions
        • Going beyond SQL
          • Follower reads
          • Tablespaces
      • Fault tolerance
      • Horizontal scalability
        • Scaling Transactions
        • Sharding Data
      • Transactions
        • Distributed Transactions
        • Isolation Levels
        • Explicit Locking
      • Indexes and Constraints
        • Overview
        • Unique Indexes
        • Partial Indexes
        • Expression Indexes
        • Generalized Inverted Indexes
        • Primary Key
        • Foreign Key
        • Other Constraints
      • JSON support
      • Multi-region deployments
        • Sync replication (3+ regions)
        • Async Replication (2+ regions)
        • Row-Level Geo-Partitioning
        • Read replicas
      • Query tuning
        • Introduction
        • Get query statistics using pg_stat_statements
        • Viewing live queries with pg_stat_activity
        • Analyzing queries with EXPLAIN
        • Optimizing YSQL queries using pg_hint_plan
      • Cluster management
        • Point-in-time recovery
      • Security
      • Observability
        • Prometheus Integration
        • Grafana Dashboard
    • Develop
      • Learn app development
        • 1. SQL vs NoSQL
        • 2. Data modeling
        • 3. Data types
        • 4. ACID transactions
        • 5. Aggregations
        • 6. Batch operations
        • 7. Date and time
        • 8. Strings and text
        • 9. TTL for data expiration
      • Real-world examples
        • E-Commerce app
        • IoT fleet management
      • Explore sample apps
      • Best practices
      • Cloud-native development
        • Codespaces
        • Gitpod
    • Migrate
      • Migration process overview
      • Migrate from PostgreSQL
        • Convert a PostgreSQL schema
        • Migrate a PostgreSQL application
        • Export PostgreSQL data
        • Prepare a cluster
        • Import PostgreSQL data
        • Verify Migration
    • Deploy
      • Deployment checklist
      • Manual deployment
        • 1. System configuration
        • 2. Install software
        • 3. Start YB-Masters
        • 4. Start YB-TServers
        • 5. Verify deployment
      • Kubernetes
        • Single-zone
          • Open Source
          • Amazon EKS
          • Google Kubernetes Engine
          • Azure Kubernetes Service
        • Multi-zone
          • Amazon EKS
          • Google Kubernetes Engine
        • Multi-cluster
          • Google Kubernetes Engine
        • Best practices
        • Connect Clients
      • Docker
      • Public clouds
        • Amazon Web Services
        • Google Cloud Platform
        • Microsoft Azure
      • Multi-DC deployments
        • Three+ data center (3DC)
        • Asynchronous Replication
        • Read replica clusters
    • Benchmark
      • TPC-C
      • sysbench
      • YCSB
      • Key-value workload
      • Large datasets
      • Scalability
        • Scaling queries
      • Resilience
        • Jepsen testing
      • Performance Troubleshooting
    • Secure
      • Security checklist
      • Enable Authentication
        • Enable User Authentication
        • Configure ysql_hba_conf_csv
      • Authentication Methods
        • Password Authentication
        • LDAP Authentication
        • Host-Based Authentication
        • Trust Authentication
      • Role-Based Access Control
        • Overview
        • Manage Users and Roles
        • Grant Privileges
        • Row-Level Security (RLS)
        • Column-Level Security
      • Encryption in Transit
        • Create server certificates
        • Enable server-to-server encryption
        • Enable client-to-server encryption
        • Connect to Clusters
        • TLS and authentication
      • Encryption at rest
      • Column-level encryption
      • Audit Logging
        • Configure Audit Logging
        • Session-Level Audit Logging
        • Object-Level Audit Logging
      • Vulnerability disclosure policy
    • Manage
      • Back up and restore
        • Back up data
        • Restore data
        • Point-in-time recovery
        • Snapshot and restore data
      • Migrate data
        • Bulk import
        • Bulk export
      • Change cluster configuration
      • Diagnostics reporting
      • Upgrade a deployment
      • Grow cluster
    • Troubleshoot
      • Troubleshooting
      • Cluster level issues
        • YCQL connection issues
        • YEDIS connection Issues
        • Recover tserver/master
        • Replace a failed YB-TServer
        • Replace a failed YB-Master
        • Manual remote bootstrap when a majority of peers fail
      • Node level issues
        • Check servers
        • Inspect logs
        • System statistics
        • Disk failure
        • Common error messages
    • Contribute
      • Core database
        • Contribution checklist
        • Build the source
        • Configure a CLion project
        • Run the tests
        • Coding style
  • YUGABYTE PLATFORM
    • Overview
      • Install
      • Configure
    • Install Yugabyte Platform
      • Prerequisites
      • Prepare the environment
      • Install software
      • Prepare nodes (on-prem)
      • Uninstall software
    • Configure Yugabyte Platform
      • Create admin user
      • Configure the cloud provider
      • Configure the backup target
      • Configure alerts
    • Create deployments
      • Multi-zone universe
      • Multi-region universe
      • Multi-cloud universe
      • Read replica cluster
      • Asynchronous replication
    • Manage deployments
      • Start and stop processes
      • Add a node
      • Eliminate an unresponsive node
      • Enable high availability
      • Edit configuration flags
      • Edit a universe
      • Delete a universe
      • Configure instance tags
      • Upgrade YugabyteDB software
      • Migrate to Helm 3
    • Back up universes
      • Configure backup storage
      • Back up universe data
      • Restore universe data
      • Schedule data backups
    • Security
      • Security checklist
      • Customize ports
      • LDAP authentication
      • Authorization platform
      • Create a KMS configuration
      • Enable encryption at rest
      • Enable encryption in transit (TLS)
      • Network security
    • Alerts and monitoring
      • Alerts
      • Live Queries dashboard
      • Slow Queries dashboard
    • Troubleshoot
      • Install and upgrade issues
      • Universe issues
    • Administer Yugabyte Platform
      • Back Up Yugabyte Platform
      • Authenticate with LDAP
    • Upgrade Yugabyte Platform
      • Upgrade using Replicated
  • YUGABYTE CLOUD
    • Overview
    • Quick start
      • Create a free cluster
      • Connect to the cluster
      • Create a database
      • Explore distributed SQL
      • Build an application
        • Before you begin
        • Java
        • Go
        • Python
        • Node.js
        • C
        • C++
        • C#
        • Ruby
        • Rust
        • PHP
    • Deploy clusters
      • Planning a cluster
      • Create a free cluster
      • Create a standard cluster
      • VPC network
        • Overview
        • Set up a VPC network
        • VPCs
        • Peering Connections
    • Secure clusters
      • IP allow lists
      • Database authorization
      • Add database users
      • Encryption in transit
      • Audit cloud activity
    • Connect to clusters
      • Cloud Shell
      • Client shell
      • Connect applications
    • Alerts and monitoring
      • Alerts
      • Performance metrics
      • Live queries
      • Slow YSQL queries
      • Cluster activity
    • Manage clusters
      • Backup and restore
      • Scale and configure clusters
      • Create extensions
    • Administer Yugabyte Cloud
      • Manage cloud users
      • Manage billing
      • Cluster costs
    • Example applications
      • Connect a Spring application
      • Connect a YCQL Java application
      • Hasura Cloud
      • Deploy a GraphQL application
    • Security architecture
      • Security architecture
      • Shared responsibility model
    • Troubleshoot
    • Yugabyte Cloud FAQ
    • What's new
  • INTEGRATIONS
    • Apache Kafka
    • Apache Spark
    • JanusGraph
    • KairosDB
    • Presto
    • Metabase
    • WSO2 Identity Server
    • YSQL Loader
    • Yugabyte JDBC Driver
    • Prisma
    • Hasura
      • Application Development
      • Benchmarking
    • Spring Framework
      • Spring Data YugabyteDB
      • Spring Data Cassandra
    • Flyway
    • GORM
    • Liquibase
    • Sequelize
    • SQLAlchemy
    • Entity Framework
    • Django REST framework
  • REFERENCE
    • Architecture
      • Design goals
      • Key concepts
        • Universe
        • YB-TServer Service
        • YB-Master Service
      • Core functions
        • Universe creation
        • Table creation
        • Write IO path
        • Read IO path
        • High availability
      • Layered architecture
      • Query layer
        • Overview
      • DocDB transactions layer
        • Transactions overview
        • Transaction isolation levels
        • Explicit locking
        • Read Committed
        • Single-row transactions
        • Distributed transactions
        • Transactional IO path
      • DocDB sharding layer
        • Hash & range sharding
        • Tablet splitting
        • Colocated tables
      • DocDB replication layer
        • Replication
        • xCluster replication
        • Read replicas
        • Change data capture (CDC)
      • DocDB storage layer
        • Persistence
        • Performance
    • APIs
      • YSQL
        • The SQL language
          • SQL statements
            • ABORT
            • ALTER DATABASE
            • ALTER DEFAULT PRIVILEGES
            • ALTER DOMAIN
            • ALTER GROUP
            • ALTER POLICY
            • ALTER ROLE
            • ALTER SEQUENCE
            • ALTER TABLE
            • ALTER USER
            • ANALYZE
            • BEGIN
            • CALL
            • COMMENT
            • COMMIT
            • COPY
            • CREATE AGGREGATE
            • CREATE CAST
            • CREATE DATABASE
            • CREATE DOMAIN
            • CREATE EXTENSION
            • CREATE FUNCTION
            • CREATE GROUP
            • CREATE INDEX
            • CREATE MATERIALIZED VIEW
            • CREATE OPERATOR
            • CREATE OPERATOR CLASS
            • CREATE POLICY
            • CREATE PROCEDURE
            • CREATE ROLE
            • CREATE RULE
            • CREATE SCHEMA
            • CREATE SEQUENCE
            • CREATE TABLE
            • CREATE TABLE AS
            • CREATE TRIGGER
            • CREATE TYPE
            • CREATE USER
            • CREATE VIEW
            • DEALLOCATE
            • DELETE
            • DO
            • DROP AGGREGATE
            • DROP CAST
            • DROP DATABASE
            • DROP DOMAIN
            • DROP EXTENSION
            • DROP FUNCTION
            • DROP GROUP
            • DROP MATERIALIZED VIEW
            • DROP OPERATOR
            • DROP OPERATOR CLASS
            • DROP OWNED
            • DROP POLICY
            • DROP PROCEDURE
            • DROP ROLE
            • DROP RULE
            • DROP SEQUENCE
            • DROP TABLE
            • DROP TRIGGER
            • DROP TYPE
            • DROP USER
            • END
            • EXECUTE
            • EXPLAIN
            • GRANT
            • INSERT
            • LOCK
            • PREPARE
            • REASSIGN OWNED
            • REFRESH MATERIALIZED VIEW
            • RELEASE SAVEPOINT
            • RESET
            • REVOKE
            • ROLLBACK
            • ROLLBACK TO SAVEPOINT
            • SAVEPOINT
            • SELECT
            • SET
            • SET CONSTRAINTS
            • SET ROLE
            • SET SESSION AUTHORIZATION
            • SET TRANSACTION
            • SHOW
            • SHOW TRANSACTION
            • TRUNCATE
            • UPDATE
            • VALUES
          • WITH clause
            • WITH clause—SQL syntax and semantics
            • recursive CTE
            • case study—traversing an employee hierarchy
            • traversing general graphs
              • graph representation
              • common code
              • undirected cyclic graph
              • directed cyclic graph
              • directed acyclic graph
              • rooted tree
              • Unique containing paths
              • Stress testing find_paths()
            • case study—Bacon Numbers from IMDb
              • Bacon numbers for synthetic data
              • Bacon numbers for IMDb data
        • Data types
          • Array
            • array[] constructor
            • Literals
              • Text typecasting and literals
              • Array of primitive values
              • Row
              • Array of rows
            • FOREACH loop (PL/pgSQL)
            • array of DOMAINs
            • Functions and operators
              • ANY and ALL
              • Array comparison
              • Array slice operator
              • Array concatenation
              • Array properties
              • array_agg(), unnest(), generate_subscripts()
              • array_fill()
              • array_position(), array_positions()
              • array_remove()
              • array_replace() / set value
              • array_to_string()
              • string_to_array()
          • Binary
          • Boolean
          • Character
          • Date and time
            • Conceptual background
            • Timezones and UTC offsets
              • Catalog views
              • Extended_timezone_names
                • Unrestricted full projection
                • Real timezones with DST
                • Real timezones no DST
                • Synthetic timezones no DST
              • Offset/timezone-sensitive operations
                • Timestamptz to/from timestamp conversion
                • Pure 'day' interval arithmetic
              • Four ways to specify offset
                • Name-resolution rules
                  • 1 case-insensitive resolution
                  • 2 ~names.abbrev never searched
                  • 3 'set timezone' string not resolved in ~abbrevs.abbrev
                  • 4 ~abbrevs.abbrev before ~names.name
                  • Helper functions
              • Syntax contexts for offset
              • Recommended practice
            • Typecasting between date-time and text-values
            • Semantics of the date-time data types
              • Date data type
              • Time data type
              • Plain timestamp and timestamptz
              • Interval data type
                • Interval representation
                  • Ad hoc examples
                  • Representation model
                • Interval value limits
                • Declaring intervals
                • Justify() and extract(epoch...)
                • Interval arithmetic
                  • Interval-interval comparison
                  • Interval-interval addition and subtraction
                  • Interval-number multiplication
                  • Moment-moment overloads of "-"
                  • Moment-interval overloads of "+" and "-"
                • Custom interval domains
                • Interval utility functions
            • Typecasting between date-time datatypes
            • Operators
              • Test comparison overloads
              • Test addition overloads
              • Test subtraction overloads
              • Test multiplication overloads
              • Test division overloads
            • General-purpose functions
              • Creating date-time values
              • Manipulating date-time values
              • Current date-time moment
              • Delaying execution
              • Miscellaneous
                • Function age()
                • Function extract() | date_part()
                • Implementations that model the overlaps operator
            • Formatting functions
            • Case study—SQL stopwatch
            • Download & install the date-time utilities
            • ToC
          • JSON
            • JSON literals
            • Primitive and compound data types
            • Code example conventions
            • Indexes and check constraints
            • Functions & operators
              • ::jsonb, ::json, ::text (typecast)
              • ->, ->>, #>, #>> (JSON subvalues)
              • - and #- (remove)
              • || (concatenation)
              • = (equality)
              • @> and <@ (containment)
              • ? and ?| and ?& (key or value existence)
              • array_to_json()
              • jsonb_agg()
              • jsonb_array_elements()
              • jsonb_array_elements_text()
              • jsonb_array_length()
              • jsonb_build_object()
              • jsonb_build_array()
              • jsonb_each()
              • jsonb_each_text()
              • jsonb_extract_path()
              • jsonb_extract_path_text() and json_extract_path_text()
              • jsonb_object()
              • jsonb_object_agg()
              • jsonb_object_keys()
              • jsonb_populate_record()
              • jsonb_populate_recordset()
              • jsonb_pretty()
              • jsonb_set() and jsonb_insert()
              • jsonb_strip_nulls()
              • jsonb_to_record()
              • jsonb_to_recordset()
              • jsonb_typeof()
              • row_to_json()
              • to_jsonb()
          • Money
          • Numeric
          • Range
          • Serial
          • UUID
        • Functions and operators
          • Aggregate functions
            • Informal functionality overview
            • Invocation syntax and semantics
            • grouping sets, rollup, cube
            • Per function signature and purpose
              • avg(), count(), max(), min(), sum()
              • array_agg(), string_agg(), jsonb_agg(), jsonb_object_agg()
              • bit_and(), bit_or(), bool_and(), bool_or()
              • variance(), var_pop(), var_samp(), stddev(), stddev_pop(), stddev_samp()
              • linear regression
                • covar_pop(), covar_samp(), corr()
                • regr_%()
              • mode(), percentile_disc(), percentile_cont()
              • rank(), dense_rank(), percent_rank(), cume_dist()
            • case study—percentile_cont() and the "68–95–99.7" rule
            • case study—linear regression on COVID data
              • Download the COVIDcast data
              • Ingest the COVIDcast data
                • Inspect the COVIDcast data
                • Copy the .csv files to staging tables
                • Check staged data conforms to the rules
                • Join the staged data into a single table
                • SQL scripts
                  • Create cr_staging_tables()
                  • Create cr_copy_from_scripts()
                  • Create assert_assumptions_ok()
                  • Create xform_to_covidcast_fb_survey_results()
                  • ingest-the-data.sql
              • Analyze the COVIDcast data
                • symptoms vs mask-wearing by day
                • Data for scatter-plot for 21-Oct-2020
                • Scatter-plot for 21-Oct-2020
                • SQL scripts
                  • analysis-queries.sql
                  • synthetic-data.sql
          • currval()
          • lastval()
          • nextval()
          • Window functions
            • Informal functionality overview
            • Invocation syntax and semantics
            • Per function signature and purpose
              • row_number(), rank() and dense_rank()
              • percent_rank(), cume_dist() and ntile()
              • first_value(), nth_value(), last_value()
              • lag(), lead()
              • Tables for the code examples
                • table t1
                • table t2
                • table t3
                • table t4
            • case study—analyzing a normal distribution
              • Bucket allocation scheme
              • do_clean_start.sql
              • cr_show_t4.sql
              • cr_dp_views.sql
              • cr_int_views.sql
              • cr_pr_cd_equality_report.sql
              • cr_bucket_using_width_bucket.sql
              • cr_bucket_dedicated_code.sql
              • do_assert_bucket_ok
              • cr_histogram.sql
              • cr_do_ntile.sql
              • cr_do_percent_rank.sql
              • cr_do_cume_dist.sql
              • do_populate_results.sql
              • do_report_results.sql
              • do_compare_dp_results.sql
              • do_demo.sql
              • Reports
                • Histogram report
                • dp-results
                • compare-dp-results
                • int-results
          • yb_hash_code()
        • Extensions
        • Keywords
        • Reserved names
      • YCQL
        • ALTER KEYSPACE
        • ALTER ROLE
        • ALTER TABLE
        • CREATE INDEX
        • CREATE KEYSPACE
        • CREATE ROLE
        • CREATE TABLE
        • CREATE TYPE
        • DROP INDEX
        • DROP KEYSPACE
        • DROP ROLE
        • DROP TABLE
        • DROP TYPE
        • GRANT PERMISSION
        • GRANT ROLE
        • REVOKE PERMISSION
        • REVOKE ROLE
        • USE
        • INSERT
        • SELECT
        • EXPLAIN
        • UPDATE
        • DELETE
        • TRANSACTION
        • TRUNCATE
        • Simple expressions
        • Subscripted expressions
        • Function call
        • Operators
        • BLOB
        • BOOLEAN
        • Collection
        • FROZEN
        • INET
        • Integer and counter
        • Non-integer
        • TEXT
        • DATE, TIME, and TIMESTAMP
        • UUID and TIMEUUID
        • JSONB
        • Date and time
        • BATCH
    • CLIs
      • yb-ctl
      • yb-docker-ctl
      • ysqlsh
      • ycqlsh
      • yb-admin
      • yb-ts-cli
      • ysql_dump
      • ysql_dumpall
    • Configuration
      • yb-tserver
      • yb-master
      • yugabyted
      • Default ports
    • Drivers
      • Client drivers for YSQL
      • Client drivers for YCQL
    • Connectors
      • Kafka Connect YugabyteDB
    • Third party tools
      • Arctype
      • DBeaver
      • DbSchema
      • pgAdmin
      • SQL Workbench/J
      • TablePlus
      • Visual Studio Code
    • Sample datasets
      • Chinook
      • Northwind
      • PgExercises
      • SportsDB
      • Retail Analytics
  • RELEASES
    • Releases overview
      • v2.13 series (latest)
      • v2.12 series (stable)
      • v2.11 series
      • v2.9 series
      • v2.8 series
      • v2.7 series
      • v2.6 series
      • v2.5 series
      • v2.4 series
      • v2.3 series
      • v2.2 series
      • v2.1 series
      • v2.0 series
      • v1.3 series
      • v1.2 series
    • Release versioning
  • FAQ
    • Comparisons
      • Amazon Aurora
      • Google Cloud Spanner
      • CockroachDB
      • TiDB
      • Vitess
      • MongoDB
      • FoundationDB
      • Amazon DynamoDB
      • Azure Cosmos DB
      • Apache Cassandra
      • PostgreSQL
      • Redis in-memory store
      • Apache HBase
    • General FAQ
    • Operations FAQ
    • API compatibility FAQ
    • Yugabyte Platform FAQ
  • MISC
    • YEDIS
      • Quick start
      • Develop
        • Build an application
        • C#
        • C++
        • Go
        • Java
        • NodeJS
        • Python
      • API reference
        • APPEND
        • AUTH
        • CONFIG
        • CREATEDB
        • DELETEDB
        • LISTDB
        • SELECT
        • DEL
        • ECHO
        • EXISTS
        • EXPIRE
        • EXPIREAT
        • FLUSHALL
        • FLUSHDB
        • GET
        • GETRANGE
        • GETSET
        • HDEL
        • HEXISTS
        • HGET
        • HGETALL
        • HINCRBY
        • HKEYS
        • HLEN
        • HMGET
        • HMSET
        • HSET
        • HSTRLEN
        • HVALS
        • INCR
        • INCRBY
        • KEYS
        • MONITOR
        • PEXPIRE
        • PEXPIREAT
        • PTTL
        • ROLE
        • SADD
        • SCARD
        • RENAME
        • SET
        • SETEX
        • PSETEX
        • SETRANGE
        • SISMEMBER
        • SMEMBERS
        • SREM
        • STRLEN
        • ZRANGE
        • TSADD
        • TSCARD
        • TSGET
        • TSLASTN
        • TSRANGEBYTIME
        • TSREM
        • TSREVRANGEBYTIME
        • TTL
        • ZADD
        • ZCARD
        • ZRANGEBYSCORE
        • ZREM
        • ZREVRANGE
        • ZSCORE
        • PUBSUB
        • PUBLISH
        • SUBSCRIBE
        • UNSUBSCRIBE
        • PSUBSCRIBE
        • PUNSUBSCRIBE
    • Legal
      • Third party software
> APIs > YSQL > Functions and operators > Window functions >

Informal overview of window function invocation using the OVER clause

Report a doc issue Suggest new content
  • Using row_number() in the simplest way
  • Showing the importance of the window ORDER BY clause
  • Using row_number() with "PARTITION BY"
  • Using nth_value() and last_value() to return the whole row
  • Using lag() and lead() to compute a moving average
  • Using the aggregate function avg() to compute a moving average
  • Using the aggregate function sum() with the OVER clause

A good sense of the general functionality of window functions is given by examples that use row_number(), nth_value(), last_value(), lag(), and lead().

Aggregate functions can be invoked with the OVER clause. Examples are given using avg() and sum().

These examples are sufficient to give a general sense of the following notions:

  • how window functions are invoked, and their general semantics
  • the three clauses of the window_definition : the PARTITION BY clause, the window ORDER BY clause, and the frame_clause
  • how an aggregate function gains different useful functionality when it's invoked using an OVER clause rather than (as is probably more common) in conjunction with the regular GROUP BY clause.

If you haven't yet installed the tables that the code examples use, then go to the section The data sets used by the code examples.

Using row_number() in the simplest way

The row_number() window function is the simplest among the set of eleven such functions that YSQL supports. Briefly, this function assigns an ordinal number, starting at 1, to the rows within the specified window according to the specified ordering rule. Here is the most basic example.

select
  k,
  row_number() over(order by k desc) as r
from t1
order by k asc;

The syntax and semantics of the ORDER BY clause, within the parentheses of the OVER clause, are identical to what you're used to when an ORDER BY clause is used after the FROM clause in a subquery. The DESC keyword is used in this example to emphasize this point. It says that the values returned by row_number() are to be assigned in the order corresponding to sorting the values of "k" in descending order—and it specifies nothing else. Here is the result:

 k  | r  
----+----
  1 | 25
  2 | 24
  3 | 23
  4 | 22
  5 | 21
  ...
 21 |  5
 22 |  4
 23 |  3
 24 |  2
 25 |  1

The output lines for values of "r" between 6 and 20 were manually removed to reduce the clutter.

Because the OVER clause doesn't specify a PARTITION BY clause, the so-called window that row_number() operates on coincides with all of the rows in table "t1".

The next example emphasizes the point that a window function is often used in a subquery which, like any other subquery, is used to define a WITH clause view to allow further logic to be applied—in this case, a WHERE cause restriction on the values returned by row_number() (and, of course, a final query-level ORDER BY rule).

with v as (
  select
    k,
    row_number() over(order by k desc) as r
  from t1)
select
  k,
  r
from v
where (r between 1 and 5) or (r between 21 and 25)
order by r asc;

This is the result:

 k  | r  
----+----
 25 |  1
 24 |  2
 23 |  3
 22 |  4
 21 |  5
  5 | 21
  4 | 22
  3 | 23
  2 | 24
  1 | 25

Showing the importance of the window ORDER BY clause

Here is a counter example. Notice that the window_definition doesn't specify a window ORDER BY clause.

with a as (
  select
    -- The use of the bare OVER() here brings meaningless results.
    row_number() over () as r,
    class,
    k
  from t1)
select
  r,
  class,
  k,
  case k=r
    when true then 'true'
    else           ''
  end as chk
from a
order by r;

To see the most dramatic effect of the unpredictability of the result set, save the code from table t1 into a file called, say, "unpredictable.sql". Then copy the SQL statement, above, at the end of this file and invoke it time and again in ysqlsh. Here is a typical result:

 r  | class | k  | chk  
----+-------+----+------
  1 |     5 | 23 | 
  2 |     5 | 25 | 
  3 |     2 |  9 | 
  4 |     1 |  4 | true
  5 |     3 | 11 | 
  6 |     1 |  1 | 
  7 |     3 | 13 | 
  8 |     4 | 16 | 
  9 |     1 |  2 | 
 10 |     2 |  7 | 
 11 |     1 |  3 | 
 12 |     4 | 18 | 
 13 |     3 | 15 | 
 14 |     5 | 21 | 
 15 |     3 | 14 | 
 16 |     3 | 12 | 
 17 |     4 | 17 | true
 18 |     1 |  5 | 
 19 |     2 | 10 | 
 20 |     4 | 20 | true
 21 |     5 | 24 | 
 22 |     5 | 22 | true
 23 |     2 |  6 | 
 24 |     2 |  8 | 
 25 |     4 | 19 | 

Sometimes, you'll see that, by chance, not a single output row is marked "true". Sometimes, you'll see that a few are so marked.

Using row_number() with "PARTITION BY"

This example adds a PARTITION BY clause to the window ORDER BY clause in the window_definition . It selects and orders by "v" rather than "k" because this has NULLs and demonstrates the within-window effect of NULLS FIRST. The window_definition is moved to a dedicated WINDOW clause that names it so that the OVER clause can simply reference the definition that it needs. This might seem only to add verbosity in this example. But using a dedicated WINDOW clause reduces verbosity when invocations of several different window functions in the same subquery use the same window_definition.

\pset null '??'

with a as (
  select
    class,
    v,
    row_number() over w as r
  from t1
  window w as (partition by class order by v desc nulls first))
select
  class,
  v,
  r
from a
where class in (2, 4)
order by class, r;

This is the result:

 class | v  | r 
-------+----+---
     2 | ?? | 1
     2 |  9 | 2
     2 |  8 | 3
     2 |  7 | 4
     2 |  6 | 5
     4 | ?? | 1
     4 | 19 | 2
     4 | 18 | 3
     4 | 17 | 4
     4 | 16 | 5

Using nth_value() and last_value() to return the whole row

If you want the output value for any of first_value(), last_value(), nth_value(), lag(), or lead() to include more than one column, then you must list them in a "row" type constructor. This example uses nth_value(). This accesses the Nth row within the ordered set that each window defines. It picks out the third row. The restriction "class in (3, 5)" cuts down the result set to make it easier to read.

drop type if exists rt cascade;
create type rt as (class int, k int, v int);

select
  class,
  nth_value((class, k, v)::rt, 3) over w as nv
from t1
where class in (3, 5)
window w as (
  partition by class
  order by k
  range between unbounded preceding and unbounded following
  )
order by class;

It produces this result:

 class |    nv     
-------+-----------
     3 | (3,13,13)
     3 | (3,13,13)
     3 | (3,13,13)
     3 | (3,13,13)
     3 | (3,13,13)
     5 | (5,23,23)
     5 | (5,23,23)
     5 | (5,23,23)
     5 | (5,23,23)
     5 | (5,23,23)

Each of first_value(), last_value(), and nth_value(), as their names suggest, produces the same output for each row of a window. It would be natural, therefore, to use the query above in a WITH clause whose final SELECT picks out the individual columns from the record and adds a GROUP BY clause, thus:

drop type if exists rt cascade;
create type rt as (class int, k int, v int);

\pset null '??'
with a as (
  select
    last_value((class, k, v)::rt) over w as lv
  from t1
  window w as (
    partition by class
    order by k
    range between unbounded preceding and unbounded following))
select
  (lv).class,
  (lv).k,
  (lv).v
from a
group by class, k, v
order by class;

This example uses last_value() because the data set has different values for "k" and "v" for the last row in each window. This is the result:

 class | k  | v  
-------+----+----
     1 |  5 | ??
     2 | 10 | ??
     3 | 15 | ??
     4 | 20 | ??
     5 | 25 | ??

Using lag() and lead() to compute a moving average

The aim is to compute the moving average for each day within the window, where this is feasible, over the last-but one day, the last day, the current day, the next day, and the next-but-one day.

Notice that the following section uses the aggregate function avg() to produce the same result, and it shows the advantages of that approach over using the window functions lag() and lead(). There are many other cases where lag() and/or lead()are needed and where avg() is of no use. The present use case was chosen here because it shows very clearly what lag() and lead() do and, especially, because it allows the demonstration of invoking an aggregate function with an OVER clause.

The query is specifically written to meet the exact requirements. It would need to be manually re-written to base the moving average on a bigger, or smaller, range of days. Notice that the same window_definition , "w", is used as the argument for each of the four uses of the OVER clause. This is where using a separate WINDOW clause delivers its intended benefit.

The statement of requirement implies that the computation is not feasible for the first two and the last two days in the window. Under these circumstances, lag() and lead(), return NULL—or, it you prefer, a default value that you supply using an optional third parameter. See the dedicated section on lag() and lead() for details.

with v as (
  select
    day,
    lag (price::numeric, 2) over w as lag_2,
    lag (price::numeric, 1) over w as lag_1,
    price::numeric,
    lead(price::numeric, 1) over w as lead_1,
    lead(price::numeric, 2) over w as lead_2
  from t3
  window w as (order by day))
select
  to_char(day, 'Dy DD-Mon') as "Day",
  ((lag_2 + lag_1 + price + lead_1 + lead_2)/5.0)::money as moving_avg
from v
where (lag_2 is not null) and (lead_2 is not null)
order by day;

This is the result:

    Day     | moving_avg 
------------+------------
 Wed 17-Sep |     $18.98
 Thu 18-Sep |     $19.13
 Fri 19-Sep |     $19.27
 Mon 22-Sep |     $19.64
 Tue 23-Sep |     $19.99
 Wed 24-Sep |     $20.10
 Thu 25-Sep |     $19.90
 Fri 26-Sep |     $19.62
 Mon 29-Sep |     $19.60
 Tue 30-Sep |     $19.41
 Wed 01-Oct |     $19.18
 Thu 02-Oct |     $19.08
 Fri 03-Oct |     $18.78
 Mon 06-Oct |     $18.19
 Tue 07-Oct |     $17.53
 Wed 08-Oct |     $16.97
 Thu 09-Oct |     $17.08
 Fri 10-Oct |     $17.26
 Mon 13-Oct |     $17.08
 Tue 14-Oct |     $17.23
 Wed 15-Oct |     $17.30

Using the aggregate function avg() to compute a moving average

This solution takes advantage of this window_definition to determine the rows that avg() uses:

order by day groups between $1 preceding and $1 following

Here, the statement is first prepared and then executed to emphasize the fact that a single formulation of the statement text works for any arbitrary range of days around the current row. The section Window function invocation—SQL syntax and semantics explains the full power of expression brought by the OVER clause.

Notice that this approach uses the value returned by row_number(), using an OVER clause that does no more than order the rows, to exclude the meaningless first N and last N averages, where N is the same parameterized value that "groups between N preceding and N following" uses. These rows, if not excluded, would simply show the averages over the rows that allow access. You probably don't want to see those answers.

prepare stmt(int) as
with v as (
  select
    day,
    avg(price::numeric) over w1 as a,
    row_number()        over w2 as r
  from t3
  window
    w1 as (order by day groups between $1 preceding and $1 following),
    w2 as (order by day))
select
  to_char(day, 'Dy DD-Mon') as "Day",
  a::money as moving_avg
from v
where r between ($1 + 1) and (select (count(*) - $1) from v)
order by day;

execute stmt(2);

The result is identical to that produced by the lag()/lead() approach. Try repeating the EXECUTE statement with a few different actual arguments. The bigger it gets, the fewer result rows you see, and the closer the values of the moving average get to each other.

Using the aggregate function sum() with the OVER clause

This example shows a different spelling of the frame_clause:

range between unbounded preceding and current row

so that the average includes, for each row, the row itself and only the rows that precede it in the sort order.

with v as (
  select
    class,
    k,
    sum(k) over w as s
  from t1
  window w as (
    partition by class
    order by k
    range between unbounded preceding and current row))
select
  class,
  k,
  s
from v
where class in (2, 4)
order by class, k;

This is the result:

 class | k  | s  
-------+----+----
     2 |  6 |  6
     2 |  7 | 13
     2 |  8 | 21
     2 |  9 | 30
     2 | 10 | 40
     4 | 16 | 16
     4 | 17 | 33
     4 | 18 | 51
     4 | 19 | 70
     4 | 20 | 90
  • Using row_number() in the simplest way
  • Showing the importance of the window ORDER BY clause
  • Using row_number() with "PARTITION BY"
  • Using nth_value() and last_value() to return the whole row
  • Using lag() and lead() to compute a moving average
  • Using the aggregate function avg() to compute a moving average
  • Using the aggregate function sum() with the OVER clause
Ask our community
  • Slack
  • Github
  • Forum
  • StackOverflow
Yugabyte
Contact Us
Copyright © 2017-2022 Yugabyte, Inc. All rights reserved.