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 > Aggregate functions >

Aggregate function invocation—SQL syntax and semantics

Report a doc issue Suggest new content
  • Syntax
    • Reproduced from the SELECT statement section
  • Semantics
    • The ordinary_aggregate_fn_invocation rule
    • The within_group_aggregate_fn_invocation rule
    • The GROUP BY clause
    • The HAVING clause

Syntax

Reproduced from the SELECT statement section

The following six diagrams, select_start, ordinary_aggregate_fn_invocation, within_group_aggregate_fn_invocation, group_by_clause, grouping_element, and having_clause are reproduced from the section that describes the SELECT statement.

  • Grammar
  • Diagram
select_start ::= SELECT [ ALL | 
                          DISTINCT [ ON { ( expression [ , ... ] ) } ] ] 
                 [ * | { { expression
                           | fn_over_window
                           | ordinary_aggregate_fn_invocation
                           | within_group_aggregate_fn_invocation } 
                       [ [ AS ] name ] } [ , ... ] ]

ordinary_aggregate_fn_invocation ::= name  ( 
                                     { [ ALL | DISTINCT ] expression 
                                       [ , ... ]
                                       | * } 
                                     [ ORDER BY order_expr [ , ... ] ] 
                                     )  [ FILTER ( WHERE 
                                          boolean_expression ) ]

within_group_aggregate_fn_invocation ::= name  ( 
                                         { expression [ , ... ] } )  
                                         WITHIN GROUP ( ORDER BY 
                                         order_expr [ , ... ] )  
                                         [ FILTER ( WHERE 
                                           boolean_expression ) ]

select_start

SELECTALLDISTINCTON(,expression)*,expressionfn_over_windowordinary_aggregate_fn_invocationwithin_group_aggregate_fn_invocationASname

ordinary_aggregate_fn_invocation

name(ALLDISTINCT,expression*ORDERBY,order_expr)FILTER(WHEREboolean_expression)

within_group_aggregate_fn_invocation

name(,expression)WITHINGROUP(ORDERBY,order_expr)FILTER(WHEREboolean_expression)

These rules govern the invocation of aggregate functions as `SELECT` list items.

The aggregate functions listed in the sections General-purpose aggregate functions and Statistical aggregate functions are governed by the ordinary_aggregate_fn_invocation rule. These functions may also be invoked as window functions. See the account of the fn_over_window rule, and everything else that qualifies this, in the section Window function invocation—SQL syntax and semantics.

The aggregate functions listed in the sections Within-group ordered-set aggregate functions and Within-group hypothetical-set aggregate functions are governed by the within_group_aggregate_fn_invocation rule. "Within-group ordered-set" aggregate functions may not be invoked as window functions. But "within-group hypothetical-set" aggregate functions may be invoked as window functions. The reasons for this difference are explained in the two relevant dedicated sections.

When aggregate functions are invoked using the syntax specified by either the ordinary_aggregate_fn_invocation rule or the within_group_aggregate_fn_invocation rule, users very often determine the result set with the GROUP BY clause.

  • Grammar
  • Diagram
group_by_clause ::= GROUP BY { grouping_element [ , ... ] }

grouping_element ::= ( ) | ( expression [ , ... ] )
                     | ROLLUP ( expression [ , ... ] )
                     | CUBE ( expression [ , ... ] )
                     | GROUPING SETS ( grouping_element [ , ... ] )

group_by_clause

GROUPBY,grouping_element

grouping_element

()(,expression)ROLLUP(,expression)CUBE(,expression)GROUPINGSETS(,grouping_element)

The result set may be restricted by the HAVING clause:

  • Grammar
  • Diagram
having_clause ::= HAVING boolean_expression

having_clause

HAVINGboolean_expression

Semantics

The ordinary_aggregate_fn_invocation rule

This syntax rule governs the invocation of the aggregate functions that are listed in the General-purpose aggregate functions and the Statistical aggregate functions sections. Notice that (possibly to your surprise) the optional ORDER BY clause is used within the parentheses that surround the arguments with which the function is invoked and that there is no comma after the final argument and this clause. Here is an example:

drop table if exists t cascade;
create table t(
  k     int   primary key,
  class int   not null,
  v     text  not null);

insert into t(k, class, v)
select
  (1 + s.v),
  case (s.v) < 3
    when true then 1
              else 2
  end,
  chr(97 + s.v)
from generate_series(0, 5) as s(v);

select
  class,
  array_agg(v            order by k desc) as "array_agg(v)",
  string_agg(v, ' ~ '    order by k desc) as "string_agg(v)",
  jsonb_agg(v            order by v desc) as "jsonb_agg",
  jsonb_object_agg(v, k  order by v desc) as "jsonb_object_agg(v, k)"
from t
group by class
order by class;

It produces this result:

 class | array_agg(v) | string_agg(v) |    jsonb_agg    |  jsonb_object_agg(v, k)
-------+--------------+---------------+-----------------+--------------------------
     1 | {c,b,a}      | c ~ b ~ a     | ["c", "b", "a"] | {"a": 1, "b": 2, "c": 3}
     2 | {f,e,d}      | f ~ e ~ d     | ["f", "e", "d"] | {"d": 4, "e": 5, "f": 6}

This is a simplified version of the example shown in the GROUP BY syntax section within the array_agg(), string_agg(), jsonb_agg(), jsonb_object_agg() section. These three functions:

  • array_agg(), string_agg(), jsonb_agg()

are sensitive to the effect of the order of aggregation of the individual values. This is because they produce lists. However, jsonb_object_agg() is not sensitive to the order because the key-value pairs in a JSON object are defined to have no order. And neither is any other aggregate function among those that are governed by the ordinary_aggregate_fn_invocation sensitive to ordering.

The string_agg() function conveniently illustrates the effect of the FILTER clause:

select
  string_agg(v, ' ~ ' order by k     ) filter (where v <> 'f') as "string_agg(v) without f",
  string_agg(v, ' ~ ' order by k desc) filter (where v <> 'a') as "string_agg(v) without a"
from t;

This is the result:

 string_agg(v) without f | string_agg(v) without a
-------------------------+-------------------------
 a ~ b ~ c ~ d ~ e       | f ~ e ~ d ~ c ~ b

The within_group_aggregate_fn_invocation rule

This syntax rule governs the invocation of the aggregate functions that are listed in the Within-group ordered-set aggregate functions section and the Within-group hypothetical-set aggregate functions section.

The mode() function is a "within-group ordered-set" aggregate function. Here's a simple example:

drop table if exists t cascade;
create table t(
  k     int  primary key,
  class int not null,
  v     text);

insert into t(k, class, v)
select
  g.v,
  ntile(2) over(order by v),
  chr(ascii('a') -1 + g.v)
from generate_series(1, 10) as g(v)
union all
values
  (11, 1, 'e'),
  (12, 2, 'f'),
  (13, 2, null),
  (14, 2, null),
  (15, 2, null);

\pset null <null>
select k, class, v from t order by class, v nulls last, k;

This is the result:

 k  | class |   v
----+-------+--------
  1 |     1 | a
  2 |     1 | b
  3 |     1 | c
  4 |     1 | d
  5 |     1 | e
 11 |     1 | e
  6 |     2 | f
 12 |     2 | f
  7 |     2 | g
  8 |     2 | h
  9 |     2 | i
 10 |     2 | j
 13 |     2 | <null>
 14 |     2 | <null>
 15 |     2 | <null>

Now try this:

select
  class,
  mode() within group (order by k desc) as "k mode",
  mode() within group (order by v     ) as "v mode"
from t
group by class
order by class;

This is the result:

 class | k mode | v mode
-------+--------+--------
     1 |     11 | e
     2 |     15 | f

Because "k" happens to be unique, the modal value is chosen arbitrarily from the set of candidate values. It might appear that the ORBER BY clause determines which value is chosen. Don't rely on this—it's an undocumented effect of the implementation and might change at some future release boundary.

Notice that the expression for which the modal value for each value of "class", as the GROUP BY clause requests, is specified not as the argument of the mode() function but, rather, as the argument of the invocation's ORDER BY clause. This explains why the within_group_aggregate_fn_invocation rule specifies that ORDER BY is mandatory. If you execute the \df mode metacommand in ysqlsh, you'll see that both the argument data type and the result data type is anyelement. In other words, the argument of the ORDER BY clause in the invocation of the mode() aggregate function must be just a single scalar expression. Notice that this is more restrictive than the general case for the ORDER BY clause that you use at top level in a subquery or within the window definition for the OVER clause that you use to invoke a window function.

The expression need not correspond just to a bare column, as this example shows:

select
  mode() within group (order by v||'x')                                              as "expr-1 mode",
  mode() within group (order by (case v is null when true then '<null>' else v end)) as "expr-2 mode"
from t;

This is the result:

 expr-1 mode | expr-2 mode
-------------+-------------
 ex          | <null>

The parameterization story for the other two "within-group ordered-set" aggregate functions, percentile_disc() and percentile_cont(), is more subtle. Each has two overloads. One takes a scalar, and the other takes an array. These arguments specify how the functions should determine their result. The expression, for which the result is produced, is specified as the argument of the ORDER BY clause.

The syntax rules for the four within-group hypothetical-set aggregate functions, rank(), dense_rank(), percent_rank(), and cume_dist(), are, as stated, the same as for the within-group ordered-set aggregate functions. But the semantics are importantly different—and this difference is reflected in how the invocations are parameterized. This is best understood by reading the accounts of the four functions and the general introduction to the section that describes these. Briefly, the argument to the function specifies the value that is to be hypothetically inserted. And the ORDER BY argument specifies the expression to which that value will be assigned as a result of the hypothetical insert.

The GROUP BY clause

The group_by_clause rule, together with the grouping_element rule, show that the GROUP BY clause can be composed as a comma-separated list of an unlimited number of terms, each of which can be chosen from a list of five kinds of element. Moreover, the GROUPING SETS alternative itself takes a comma-separated list of an unlimited number of terms, each of which can be chosen from the same list of five kinds of element. Further, this freedom can be exercised recursively. Here's an exotic example to illustrate this freedom of composition:

drop table if exists t cascade;
create table t(
  k  int primary key,
  g1 int not null,
  g2 int not null,
  g3 int not null,
  g4 int not null,
  v  int not null);

insert into t(k, g1, g2, g3, g4, v)
select
  g.v,
  g.v%2,
  g.v%4,
  g.v%8,
  g.v%16,
  g.v*100
from generate_series(1, 80) as g(v);

select count(*) as "number of resulting rows" from (
  select g1, g2, g3, g4, avg(v)
  from t
  group by (), g1, (g2, g3), rollup (g1, g2), cube (g3, g4), grouping sets (g1, g2, (), rollup (g1, g3), cube (g2, g4))
  order by g1 nulls last, g2 nulls last)
as a;

This is the result:

 number of resulting rows
--------------------------
                     1536

You can, of course, remove the surrounding select count(*)... from... as a; from this:

select count(*) as "number of resulting rows" from (
  select ...)
as a;

and look at all 1,536 resulting rows. But it's very unlikely that you'll be able to discern any meaning from what you see. Here are two more legal examples whose meaning is obscured by the way they're written:

select avg(v)
from t
group by ();

and

select g1, avg(v)
from t
group by (), g1;

The meaning of each of the last three constructs of the five that the grouping_element rule allows is explained in the section Using the GROUPING SETS, ROLLUP, and CUBE syntax for aggregate function invocation.

The second construct is the familiar bare list of GROUP BY expressions. This may be surrounded by parentheses, and arbitrary sequences of expressions may themselves be surrounded by arbitrary numbers of arbitrarily deeply nested parentheses pairs. However, doing this brings no meaning—just as it brings no meaning in this contrived, but legal, example:

select (((((1 + 2)))) + (((((3 + (4))))))) as x;

It produces the answer 10.

The first construct, the empty () pair has no semantic value except when it's used within, for example, the ROLLUP argument.

The overwhelmingly common way to take advantage of the freedoms that the grouping_element rule allows is to use exactly one of the last four constructs and to take advantage of the empty () pair in that context.

The HAVING clause

The HAVING clause is functionally equivalent to the WHERE clause. However, it is legal only in a subquery that has a GROUP BY clause, and it must be placed after the GROUP BY. First, create and populate a test table:

drop table if exists t cascade;
create table t(
  k     int      primary key,
  class int      not null,
  v     numeric);

insert into t(k, class, v)
select
  (1 + s.v),
  case (s.v) < 5
    when true then 1
              else 2
  end,
  case (s.v) <> 4
    when true then (100.0 + s.v)::numeric
              else null
  end
from generate_series(0, 9) as s(v);

\pset null <null>
select k, class, v from t order by k;

This is the result:

 k  | class |   v
----+-------+--------
  1 |     1 |    100
  2 |     1 |    101
  3 |     1 |    102
  4 |     1 |    103
  5 |     1 | <null>
  6 |     2 |    105
  7 |     2 |    106
  8 |     2 |    107
  9 |     2 |    108
 10 |     2 |    109

Now try this counter-example:

select v from t having v >= 105;

It causes this error:

42803: column "t.v" must appear in the GROUP BY clause or be used in an aggregate function

The meaning is "...must be used in an expression in the GROUP BY clause or be used in an expression in an aggregate function invocation".

Here is an example of the legal use of the HAVING clause:

select class, count(v)
from t
group by class
having count(v) > 4
order by class;

This is the result:

 class | count
-------+-------
     2 |     5

This illustrates the use case that motivates the HAVING clause: you want to restrict the results using a predicate that references an aggregate function. Try this counter-example:

select class, count(v)
from t
where count(v) > 4
group by class
order by class;

It causes this error:

42803: aggregate functions are not allowed in WHERE

(The error code 42803 maps to the exception name grouping_error in PL/pgSQL.)

In contrast, this is legal:

select class, count(v)
from t
where class = 1
group by class
order by class;

The WHERE clause restricts the set on which aggregate functions are evaluated. And the HAVING clause restricts the result set after aggregation. This informs you that a subquery that uses a HAVING clause legally can always be re-written to use a WHERE clause, albeit at the cost of increased verbosity, to restrict the result set of a subquery defined in a WITH clause, like this:

with a as (
  select class, count(v)
  from t
  group by class)
select class, count
from a
where count > 4
order by class;
  • Syntax
    • Reproduced from the SELECT statement section
  • Semantics
    • The ordinary_aggregate_fn_invocation rule
    • The within_group_aggregate_fn_invocation rule
    • The GROUP BY clause
    • The HAVING clause
Ask our community
  • Slack
  • Github
  • Forum
  • StackOverflow
Yugabyte
Contact Us
Copyright © 2017-2022 Yugabyte, Inc. All rights reserved.