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 >

Using the GROUPING SETS, ROLLUP, and CUBE syntax for aggregate function invocation

Report a doc issue Suggest new content
  • Semantics
    • GROUPING SETS
    • ROLLUP
    • CUBE
    • Using the GROUPING keyword in the SELECT list to label the different GROUPING SETS
    • Further detail
  • Examples
    • GROUPING SETS
    • ROLLUP
    • CUBE
    • Using the GROUPING keyword in the SELECT list to label the different GROUPING SETS

This section shows how to use the GROUPING SETS, ROLLUP, and CUBE syntax, as part of the GROUP BY clause, in concert with the invocation, as a SELECT list item, of one or more aggregate functions. These constructs are useful when the relation defined by a subquery's FROM list has two or more columns that you want to use in the GROUP BY clause and when you want to use them with singly or in combinations that have fewer columns than the available number.

Semantics

GROUPING SETS (...), is a shorthand notation to let you achieve, in a single terse subquery, what you could achieve by the union of several subqueries that each uses the plain GROUP BY <expression list> syntax.

ROLLUP (...) and CUBE are each shorthand notations for specifying two common uses of the GROUPING SET syntax.

To_do: x-ref to GROUP BY in syntax diagrams.

GROUPING SETS

Suppose that the list of candidate columns (or expressions) is "g1",... "g2",... "gN" and you want to produce the results from a set of aggregate functions using each individual one in turn as the GROUP BY argument and also using no GROUP BY clause at all. You can easily simply write several individual queries, like this:

select... fn(...) filter (where... ),... from... group by g1 having...;
select... fn(...) filter (where... ),... from... group by g2 having...;
...
select... fn(...) filter (where... ),... from... group by gN having...;
select... fn(...) filter (where... ),... from... having...;

You could also, by appropriate use of subqueries defined in a WITH clause, UNION the results of each to create a single joint results set. While doing this is straightforward, it can become quite verbose—especially if, for example, you want to use a FILTER clause as part of the aggregate function invocation and want to use a HAVING clause to restrict the result set.

The GROUPING SETS syntax lets you achieve the required result in a terse fashion:

select fn(...) filter (where... ),... from... group by grouping sets ((g1), (g2), ()) having...

You can include any number of columns (or expressions) within each successive parenthesis pair. The empty parenthesis brings the effect of no GROUP BY clause at all.

ROLLUP

This:

rollup (g1, g2, g3,... )

represents the given list of expressions and all prefixes of the list including the empty list; thus it is equivalent to this:

grouping sets (
  (g1, g2, g3,... ),
  ...
  (g1, g2, g3),
  (g1, g2),
  (g1),
  ()
)

This is commonly used for analysis over hierarchical data, for example "total salary" by "department", "division", and "company-wide total".

CUBE

This:

cube (g1, g2, g3,... )

is equivalent to GROUPING SETS with the given list and all of its possible subsets (i.e. the power set). Therefore this:

cube (g1, g2, g3)

is equivalent to this:

grouping sets (
  (g1, g2, g3),
  (g1, g2    ),
  (    g2, g3),
  (g1,     g3),
  (g1        ),
  (    g2    ),
  (        g3),
  (          )
)

Using the GROUPING keyword in the SELECT list to label the different GROUPING SETS

The GROUPING keyword is used to introduce a SELECT list item when the GROUP BY clause uses GROUPING SETS, ROLLUP, or CUBE. It produces a label so that result rows can be distinguished. The GROUPING arguments are not evaluated, but they must match exactly expressions given in the GROUP BY clause of the associated query level. Bits are assigned with the rightmost argument being the least-significant bit; each bit is 0 if the corresponding expression is included in the grouping criteria of the grouping set generating the result row, and 1 if it is not. See the section Using the GROUPING keyword in the SELECT list to label the different GROUPING SETS at the end of the Examples section below.

Further detail

The individual elements of a ROLLUP or CUBE clause may be either individual expressions, or sublists of elements in parentheses. In the latter case, the sublists are treated as single units for the purposes of generating the individual grouping sets. For example, this:

rollup (g1, (g2, g3), g4)

is equivalent to this:

grouping sets (
  (g1, g2, g3, g4),
  (g1, g2, g3    ),
  (g1            ),
  (              )
)

And this:

cube ((g1, g2), (g3, g4))

is equivalent to this:

grouping sets (
  (g1, g2, g3, g4),
  (g1, g2        ),
  (        g3, g4),
  (              )
)

The ROLLUP and CUBE constructs can be used either directly in the GROUP BY clause, or nested inside a GROUPING SETS clause. If one GROUPING SETS clause is nested inside another, the effect is the same as if all the elements of the inner clause had been written directly in the outer clause.

If many grouping items are specified in a single GROUP BY clause, then the final list of grouping sets is the cross product of the individual items. For example, this:

group by g1, cube (g2, g3), grouping sets ((g4), (g5))

is equivalent to this:

group by grouping sets (
  (g1, g2, g3, g4), (g1, g2, g3, g5),
  (g1, g2, g4    ), (g1, g2, g5    ),
  (g1, g3, g4    ), (g1, g3, g5    ),
  (g1, g4        ), (g1, g5        )
)

Examples

Create and populate the test table. Notice the assert that tests that each of the grouping columns "g1" and "g2" has at least two rows for each of its two values. The reason for this test is that stddev() returns NULL when it is presented with just a single row. This unlucky outcome is very unlikely. But it was seen while developing this code example. This outcome, while not wrong, or even remarkable, makes the results produced by the verbose approach and the terse approach, below, a little harder to compare—thereby making the semantics demonstration a little less convincing.

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

drop procedure if exists populate_t cascade;
create procedure populate_t(no_of_rows in int)
  language plpgsql
as $body$
declare
  s0 constant double precision not null := to_number(to_char(clock_timestamp(), 'ms'), '9999');
  s  constant double precision not null := s0/500.0 - 1.0;
begin
  perform setseed(s);

  delete from t;
  insert into t(k, g1, g2, v)
  select
    g.v,
    case random() < 0.5::double precision
      when true then 1
                else 2
    end,
    case random() < 0.5::double precision
      when true then 1
                else 2
    end,
    round(100*random())
  from generate_series(1, no_of_rows) as g(v);

  declare
    c_g1_1 constant int = (select count(v) from t where g1 = 1);
    c_g1_2 constant int = (select count(v) from t where g1 = 2);
    c_g2_1 constant int = (select count(v) from t where g2 = 1);
    c_g2_2 constant int = (select count(v) from t where g2 = 2);
  begin
    assert
      c_g1_1 > 1 and c_g1_2 > 1 and c_g2_1 > 1 and c_g2_2 > 1,
    'Unlucky outcome. Try again.';
  end;
end;
$body$;

call populate_t(100);

GROUPING SETS

Now do three simple GROUP BY queries. (See avg() and stddev() for the specification of these two aggregate functions.)

-- First:
select
  g1,
  to_char(avg(v), '999.99') as avg,
  to_char(stddev(v), '999.99') as stddev
from t
group by g1
order by g1;

-- Second:
select
  g2,
  to_char(avg(v), '999.99') as avg,
  to_char(stddev(v), '999.99') as stddev
from t
group by g2
order by g2;

-- Third:
select
  to_char(avg(v), '999.99') as avg,
  to_char(stddev(v), '999.99') as stddev
from t;

Here are typical results:

 g1 |   avg   | stddev  
----+---------+---------
  1 |   53.65 |   26.94
  2 |   52.16 |   30.64
  
 g2 |   avg   | stddev  
----+---------+---------
  1 |   54.55 |   30.04
  2 |   51.81 |   26.72
  
   avg   | stddev  
---------+---------
   53.10 |   28.22

Now combine these three queries into a single, verbose, query:

with
  a1 as (
    select g1, avg(v) as avg, stddev(v) as stddev from t group by g1),

  a2 as (
    select g2, avg(v) as avg, stddev(v) as stddev from t group by g2),

  a3 as (
    select avg(v) as avg, stddev(v) as stddev from t),

  a4 as (
    select g1,              null::int as g2, avg, stddev from a1
    union all
    select null::int as g1,              g2, avg, stddev from a2
    union all
    select null::int as g1, null::int as g2, avg, stddev from a3)

select
  g1,
  g2,
  to_char(avg,    '999.99') as avg,
  to_char(stddev, '999.99') as stddev
from a4
order by g1 nulls last, g2 nulls last;

This is the result for the table population that produced the typical results shown above:

 g1 | g2 |   avg   | stddev  
----+----+---------+---------
  1 |    |   53.65 |   26.94
  2 |    |   52.16 |   30.64
    |  1 |   54.55 |   30.04
    |  2 |   51.81 |   26.72
    |    |   53.10 |   28.22

The same result is given by this terse query using the GROUPING SETS syntax:

select
  g1,
  g2,
  to_char(avg(v),    '999.99') as avg,
  to_char(stddev(v), '999.99') as stddev
from t
group by grouping sets ((g1), (g2), ())
order by g1 nulls last, g2 nulls last;

Notice that it's easy to include a HAVING clause in the terse GROUPING SETS syntax:

select
  g1,
  g2,
  to_char(avg(v),    '999.99') as avg,
  to_char(stddev(v), '999.99') as stddev
from t
group by grouping sets ((g1), (g2), ())
having avg(v) > 53.0::numeric
order by g1 nulls last, g2 nulls last;

This is the result with the table population that produced the results above:

 g1 | g2 |   avg   | stddev  
----+----+---------+---------
  1 |    |   53.65 |   26.94
    |  1 |   54.55 |   30.04
    |    |   53.10 |   28.22

The actual result here will depend on the outcome of the "no_of_rows" invocations of the random() function. It's possible (but quite rare) that you'll see no rows at all.

To get the same semantics with the verbose query, you must, of course, include the identical HAVING clause in each of the three WITH clause subqueries, "a1", "a2", and "a3" that it uses. This makes the verbose formulation yet more verbose and, more importantly, yet more subject to copy-and-paste error when the aim is to repeat this identical text three times:

...avg(v) as avg, stddev(v) as stddev from t... having avg(v) > 50.0::numeric...

Extending this thinking, the terse syntax also makes it easier to add a FILTER clause:

select
  g1,
  g2,
  to_char(avg(v)    filter (where v > 20), '999.99') as avg,
  to_char(stddev(v) filter (where v > 20), '999.99') as stddev
from t
group by grouping sets ((g1), (g2), ())
having avg(v) > 53.0::numeric
order by g1 nulls last, g2 nulls last;

This is the result with the table population that produced the results above:

 g1 | g2 |   avg   | stddev  
----+----+---------+---------
  1 |    |   59.93 |   22.60
    |  1 |   63.79 |   23.85
    |    |   60.78 |   23.13

ROLLUP

This GROUP BY ROLLUP clause:

group by rollup (g1, g2)

has the same meaning as this GROUP BY GROUPING SETS clause:

group by grouping sets ((g1, g2), (g1), ())

So this query:

select
  g1,
  g2,
  to_char(avg(v), '999.99') as avg,
  to_char(stddev(v), '999.99') as stddev
from t
group by rollup (g1, g2)
order by g1 nulls last, g2 nulls last;

has the same meaning as this:

select
  g1,
  g2,
  to_char(avg(v), '999.99') as avg,
  to_char(stddev(v), '999.99') as stddev
from t
group by grouping sets ((g1, g2), (g1), ())
order by g1 nulls last, g2 nulls last;

Each produces this result with the table population that produced the results above:

 g1 | g2 |   avg   | stddev  
----+----+---------+---------
  1 |  1 |   54.00 |   29.37
  1 |  2 |   53.35 |   25.12
  1 |    |   53.65 |   26.94
  2 |  1 |   55.44 |   31.93
  2 |  2 |   49.05 |   29.90
  2 |    |   52.16 |   30.64
    |    |   53.10 |   28.22

CUBE

This GROUP BY CUBE clause:

group by cube (g1, g2)

has the same meaning as this GROUP BY GROUPING SETS clause:

group by grouping sets ((g1, g2), (g1), (g2), ())

So this query:

select
  g1,
  g2,
  to_char(avg(v), '999.99') as avg,
  to_char(stddev(v), '999.99') as stddev
from t
group by cube (g1, g2)
order by g1 nulls last, g2 nulls last;

has the same meaning as this:

select
  g1,
  g2,
  to_char(avg(v), '999.99') as avg,
  to_char(stddev(v), '999.99') as stddev
from t
group by grouping sets ((g1, g2), (g1), (g2), ())
order by g1 nulls last, g2 nulls last;

Each produces this result with the table population that produced the results above:

 g1 | g2 |   avg   | stddev  
----+----+---------+---------
  1 |  1 |   54.00 |   29.37
  1 |  2 |   53.35 |   25.12
  1 |    |   53.65 |   26.94
  2 |  1 |   55.44 |   31.93
  2 |  2 |   49.05 |   29.90
  2 |    |   52.16 |   30.64
    |  1 |   54.55 |   30.04
    |  2 |   51.81 |   26.72
    |    |   53.10 |   28.22

Using the GROUPING keyword in the SELECT list to label the different GROUPING SETS

Try this:

select
  grouping(g1, g2),
  g1,
  g2,
  to_char(avg(v), '999.99') as avg,
  to_char(stddev(v), '999.99') as stddev
from t
group by cube (g1, g2)
order by g1 nulls last, g2 nulls last;

It's equivalent to this:

select
  grouping(g1, g2),
  g1,
  g2,
  to_char(avg(v), '999.99') as avg,
  to_char(stddev(v), '999.99') as stddev
from t
group by grouping sets ((g1, g2), (g1), (g2), ())
order by g1 nulls last, g2 nulls last;

Each produces this result with the table population that produced the results above:

 grouping | g1 | g2 |   avg   | stddev  
----------+----+----+---------+---------
        0 |  1 |  1 |   54.00 |   29.37
        0 |  1 |  2 |   53.35 |   25.12
        1 |  1 |    |   53.65 |   26.94
        0 |  2 |  1 |   55.44 |   31.93
        0 |  2 |  2 |   49.05 |   29.90
        1 |  2 |    |   52.16 |   30.64
        2 |    |  1 |   54.55 |   30.04
        2 |    |  2 |   51.81 |   26.72
        3 |    |    |   53.10 |   28.22

You might prefer to order first by the GROUPING item and not include it in the SELECT list:

select
  g1,
  g2,
  to_char(avg(v), '999.99') as avg,
  to_char(stddev(v), '999.99') as stddev
from t
group by grouping sets ((g1, g2), (g1), (g2), ())
order by grouping(g1, g2), g1 nulls last, g2 nulls last;

It produces this result with the table population that produced the results above:

 g1 | g2 |   avg   | stddev  
----+----+---------+---------
  1 |  1 |   54.00 |   29.37
  1 |  2 |   53.35 |   25.12
  2 |  1 |   55.44 |   31.93
  2 |  2 |   49.05 |   29.90
  1 |    |   53.65 |   26.94
  2 |    |   52.16 |   30.64
    |  1 |   54.55 |   30.04
    |  2 |   51.81 |   26.72
    |    |   53.10 |   28.22
  • Semantics
    • GROUPING SETS
    • ROLLUP
    • CUBE
    • Using the GROUPING keyword in the SELECT list to label the different GROUPING SETS
    • Further detail
  • Examples
    • GROUPING SETS
    • ROLLUP
    • CUBE
    • Using the GROUPING keyword in the SELECT list to label the different GROUPING SETS
Ask our community
  • Slack
  • Github
  • Forum
  • StackOverflow
Yugabyte
Contact Us
Copyright © 2017-2022 Yugabyte, Inc. All rights reserved.