Join us on
Star us on
Get Started
Slack
GitHub
Get Started
v2.5 (latest) v2.2 (stable) 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
        • NodeJS
        • Go
        • Python
        • Ruby
        • C#
        • PHP
        • C++
        • C
        • Scala
    • Explore features
      • Linear scalability
      • Fault tolerance
      • Global distribution
      • Auto sharding
      • Follower reads
      • Observability
      • Colocated tables
      • Change data capture (CDC)
      • Two data center (2DC)
    • 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
      • Ecosystem integrations
        • Apache Kafka
        • Apache Spark
        • JanusGraph
        • KairosDB
        • Presto
        • Metabase
      • Build GraphQL apps
        • Hasura
        • Prisma
      • Real-world examples
        • E-Commerce app
        • IoT fleet management
        • Retail Analytics
      • Explore sample apps
      • Best practices
    • Migrate
      • Migration Process
      • Migrating From PostgreSQL
        • Schema Migration
        • App Migration
        • Export Data
        • Prepare Cluster
        • Import 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)
        • Two data center (2DC)
        • Read replica clusters
      • Change data capture (CDC)
        • CDC to Kafka
    • Benchmark
      • TPC-C
      • sysbench
      • YCSB
      • Key-value workload
      • Large datasets
      • Scalability
        • Scaling queries
      • Resilience
        • Jepsen testing
    • Secure
      • Security checklist
      • Authentication
        • Authentication
        • Fine-grained authentication
      • Encryption in transit
        • Create client certificates
        • Create server certificates
        • Enable server-to-server encryption
        • Enable client-to-server encryption
        • Connect to clusters
      • Encryption at rest
      • Authorization
        • RBAC model
        • Create roles
        • Grant privileges
      • Audit logging
    • Manage
      • Back up and restore
        • Back up data
        • Restore data
        • Snapshot and restore data
      • Migrate data
        • Bulk import
        • Bulk export
      • Change cluster configuration
      • Diagnostics reporting
      • Upgrade a deployment
    • Troubleshoot
      • Troubleshooting
      • Cluster level issues
        • YCQL connection issues
        • YEDIS connection Issues
        • Recover tserver/master
      • Node level issues
        • Check servers
        • Inspect logs
        • System statistics
        • Disk failure
    • Contribute
  • YUGABYTE PLATFORM
    • 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 and health checking
        • Create and edit instance tags
      • Create deployments
        • Multi-zone universe
        • Multi-region universe
        • Read replica cluster
      • Manage deployments
        • Start and stop processes
        • Add a node
        • Remove a node
        • Edit a universe
        • Edit configuration flags
        • Upgrade the YugabyteDB software
        • Delete a universe
        • Migrate to Helm 3
      • Back up and restore universes
        • Configure backup storage
        • Back up universe data
        • Restore universe data
        • Schedule data backups
      • Security
        • Security checklist
        • Customize ports
        • Authorization platform
        • Create a KMS configuration
        • Enable encryption at rest
        • Enable encryption in transit (TLS)
        • Network security
      • Troubleshoot
        • Install and upgrade
        • Universe
      • Administer Yugabyte Platform
        • Back up and restore Yugabyte Platform
  • YUGABYTE CLOUD
    • Yugabyte Cloud
      • Free tier
      • Create clusters
      • Monitor clusters
      • Create databases
      • Manage database access
      • Connect to clusters
  • REFERENCE
    • Reference
    • Architecture
      • Design goals
      • Key concepts
        • Universe
        • YB-TServer Service
        • YB-Master Service
      • Layered architecture
      • Query layer
        • Overview
      • DocDB transactions layer
        • Transactions overview
        • Transaction isolation levels
        • Explicit locking
        • 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
        • Statements
          • ABORT
          • ALTER DATABASE
          • ALTER DEFAULT PRIVILEGES
          • ALTER DOMAIN
          • ALTER GROUP
          • ALTER POLICY
          • ALTER ROLE
          • ALTER SEQUENCE
          • ALTER TABLE
          • ALTER USER
          • BEGIN
          • COMMENT
          • COMMIT
          • COPY
          • CREATE AGGREGATE
          • CREATE CAST
          • CREATE DATABASE
          • CREATE DOMAIN
          • CREATE EXTENSION
          • CREATE FUNCTION
          • CREATE GROUP
          • CREATE INDEX
          • 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 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
          • RESET
          • REVOKE
          • ROLLBACK
          • SELECT
          • SET
          • SET CONSTRAINTS
          • SET ROLE
          • SET SESSION AUTHORIZATION
          • SET TRANSACTION
          • SHOW
          • SHOW TRANSACTION
          • TRUNCATE
          • UPDATE
        • 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
          • 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
          • Serial
          • UUID
        • Functions and operators
          • currval()
          • lastval()
          • nextval()
          • Window functions
            • Informal functionality overview
            • Invocation SQL 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
            • 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
        • 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 API
      • YugabyteDB JDBC Driver
      • Client drivers for YCQL
      • Spring Data YugabyteDB
    • Connectors
      • Kafka Connect YugabyteDB
    • Third party tools
      • DBeaver
      • DbSchema
      • pgAdmin
      • SQL Workbench/J
      • TablePlus
      • Visual Studio Code
    • Sample datasets
      • Chinook
      • Northwind
      • PgExercises
      • SportsDB
  • RELEASES
    • Releases
    • Releases overview
    • Release versioning
    • What's new
      • 2.3 (latest)
      • 2.2 (stable)
    • Earlier releases
      • v2.1.8
      • v2.1.6
      • v2.1.5
      • v2.1.4
      • v2.1.3
      • v2.1.2
      • v2.1.1
      • v2.1.0
      • v2.0.11
      • v2.0.10
      • v2.0.9
      • v2.0.8
      • v2.0.7
      • v2.0.6
      • v2.0.5
      • v2.0.3
      • v2.0.1
      • v2.0.0
      • v1.3.1
      • v1.3.0
      • v1.2.12
      • v1.2.11
      • v1.2.10
      • v1.2.9
      • v1.2.8
      • v1.2.6
      • v1.2.5
      • v1.2.4
  • 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
    • FAQs
      • 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 > Per function signature and purpose >

first_value(), nth_value(), last_value()

Attention

This page documents an earlier version. Go to the latest (v2.3) version.
  • first_value()
  • nth_value()
  • last_value()
  • Examples that illustrate all three functions

These three window functions fall into the second group, Window functions that return column(s) of another row within the window in the section List of all window functions. Each of the functions in the second group makes obvious sense when the scope within which the specified row is found is the entire window. Only this use will be described here. When used this way, each of these functions, as their names suggest, return the same result for each row in the current window. See Examples that illustrate all three functions below.

If you have a use case that requires a specifically tailored window frame, then see the section The frame_clause.

first_value()

Signature:

input value:       anyelement
return value:      anyelement

Purpose: Return the specified value from the first row, in the specified sort order, in the current window frame. If you specify the frame_clause to start at a fixed offset before the current row, then first_value() would produce the same result as would the correspondingly parameterized lag(). If this is your aim, then you should use lag() for clarity.

nth_value()

Signature:

input value:       anyelement, int
return value:      anyelement

Purpose: Return the specified value from the "Nth" row, in the specified sort order, in the current window frame. The second, mandatory, parameter specifies "N" in "Nth".

last_value()

Signature:

input value:       anyelement
return value:      anyelement

Purpose: Return the specified value from the last row, in the specified sort order, in the current window frame.

Examples that illustrate all three functions

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.

This example uses table "t1". Notice that it has been contrived so that the last "v" (ordered by "k") for each value of "class" is NULL.

Use the technique shown in the section Using nth_value() and last_value() to return the whole row so that each of the three window functions produces all of the fields in each row:

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

select
  class,
  k,
  first_value((class, k, v)::rt::text)    over w as fv,
  nth_value  ((class, k, v)::rt::text, 3) over w as nv,
  last_value ((class, k, v)::rt::text)    over w as lv
from t1
window w as (
  partition by class
  order by k
  range between unbounded preceding and unbounded following);

Here is the result. To make it easier to see the pattern, a break has been manually inserted here between each successive set of rows with the same value for "class".

 class | k  |    fv     |    nv     |   lv    
-------+----+-----------+-----------+---------
     1 |  1 | (1,1,1)   | (1,3,3)   | (1,5,)
     1 |  2 | (1,1,1)   | (1,3,3)   | (1,5,)
     1 |  3 | (1,1,1)   | (1,3,3)   | (1,5,)
     1 |  4 | (1,1,1)   | (1,3,3)   | (1,5,)
     1 |  5 | (1,1,1)   | (1,3,3)   | (1,5,)

     2 |  6 | (2,6,6)   | (2,8,8)   | (2,10,)
     2 |  7 | (2,6,6)   | (2,8,8)   | (2,10,)
     2 |  8 | (2,6,6)   | (2,8,8)   | (2,10,)
     2 |  9 | (2,6,6)   | (2,8,8)   | (2,10,)
     2 | 10 | (2,6,6)   | (2,8,8)   | (2,10,)

     3 | 11 | (3,11,11) | (3,13,13) | (3,15,)
     3 | 12 | (3,11,11) | (3,13,13) | (3,15,)
     3 | 13 | (3,11,11) | (3,13,13) | (3,15,)
     3 | 14 | (3,11,11) | (3,13,13) | (3,15,)
     3 | 15 | (3,11,11) | (3,13,13) | (3,15,)

     4 | 16 | (4,16,16) | (4,18,18) | (4,20,)
     4 | 17 | (4,16,16) | (4,18,18) | (4,20,)
     4 | 18 | (4,16,16) | (4,18,18) | (4,20,)
     4 | 19 | (4,16,16) | (4,18,18) | (4,20,)
     4 | 20 | (4,16,16) | (4,18,18) | (4,20,)

     5 | 21 | (5,21,21) | (5,23,23) | (5,25,)
     5 | 22 | (5,21,21) | (5,23,23) | (5,25,)
     5 | 23 | (5,21,21) | (5,23,23) | (5,25,)
     5 | 24 | (5,21,21) | (5,23,23) | (5,25,)
     5 | 25 | (5,21,21) | (5,23,23) | (5,25,)

Notice that the ::text typecast of a "row" type value renders NULL simply as an absence. This explains why you see, for example, "(1,5,)" for each value produced by last_value() in the window where "k=1". This basic example certainly demonstrates the meaning of "first", "Nth" (for "N=3"), and "last". But it isn't very useful because, just as these names suggest, the output is the same for each row in a particular window. The following query adds a conventional GROUP BY clause. It also extracts the interesting fields from the "row" type value that each window function produces as individual values.

drop type if exists rt cascade;
create type rt as (class int, k int, v int);
\pset null '??'

with a as (
  select
    class,
    first_value((class, k, v)::rt)    over w as fv,
    nth_value  ((class, k, v)::rt, 3) over w as nv,
    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
  (fv).class as fv_class,
  (fv).k     as fv_k,
  (fv).v     as fv_v,
  (nv).k     as nv_k,
  (nv).v     as nv_v,
  (lv).k     as lv_k,
  (lv).v     as lv_v
from a
group by
  (fv).class,
  (fv).k,
  (fv).v,
  (nv).k,
  (nv).v,
  (lv).k,
  (lv).v
order by 1;

This is the result:

 fv_class | fv_k | fv_v | nv_k | nv_v | lv_k | lv_v 
----------+------+------+------+------+------+------
        1 |    1 |    1 |    3 |    3 |    5 |   ??
        2 |    6 |    6 |    8 |    8 |   10 |   ??
        3 |   11 |   11 |   13 |   13 |   15 |   ??
        4 |   16 |   16 |   18 |   18 |   20 |   ??
        5 |   21 |   21 |   23 |   23 |   25 |   ??
  • first_value()
  • nth_value()
  • last_value()
  • Examples that illustrate all three functions
Ask our community
  • Slack
  • Github
  • Forum
  • StackOverflow
Yugabyte
Contact Us
Copyright © 2017-2020 Yugabyte, Inc. All rights reserved.