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 > Data types > Array >

Looping through arrays in PL/pgSQL

Report a doc issue Suggest new content
  • Overview
  • Syntax and semantics
  • Looping over the values in an array without the SLICE keyword
  • Looping over the contents of a multidimensional array taking advantage of a non-zero SLICE operand
  • Using FOREACH to iterate over the elements in an array of DOMAIN values
  • Using a wrapper PL/pgSQL table function to expose the SLICE operand as a formal parameter

The PL/pgSQL FOREACH loop brings dedicated syntax for looping over the contents of an array.

Overview

Note: See array_lower(), array_upper(), array_ndims() and cardinality() for descriptions of the functions that the following account mentions. It also mentions "row-major order". See Joint semantics, within the section "Functions for reporting the geometric properties of an array", for an explanation of this term. Syntax and semantics shows where, in the FOREACH loop header, the SLICE keyword is used.

  • When the operand of the SLICE clause is 0, and for the general case where the iterand array has any number of dimensions, YSQL assigns its successive values, in row-major order, to the loop iterator. Here, its effect is functionally analogous to that of unnest().

  • For the special case where the iterand array is one-dimensional, the FOREACH loop is useful only when the operand of the SLICE clause is 0. In this use, it is a syntactically more compact way to achieve the effect that is achieved with a FOR var IN loop like this:

    for var in array_lower(iterand_arr, 1)..array_upper(iterand_arr, 1) loop
      ... iterand_arr[var] ...
    end loop;
    
  • When the operand of the SLICE clause is greater than 0, and when the dimensionality of the iterand array is greater than 1, the FOREACH loop provides functionality that unnest() cannot provide. Briefly, when the iterand array has n dimensions and the operand of the SLICE clause is s, YSQL assigns slices (that is, subarrays) of dimensionality s to the iterator. The values in such a slice are those from the iterand array that remain when the distinct values of the first (n - s) indexes are used to drive the iteration. These two pseudocode blocks illustrate the idea:

    -- In this example, the SLICE operand is 1.
    -- As a consequence, array_ndims(iterator_array) is 1.
    -- Assume that array_ndims(iterand_arr) is 4.
    -- There are therefore (4 - 1) = 3 nested loops in this pseudocode.
    for i in array_lower(iterand_arr, 1)..array_upper(iterand_arr, 1) loop
      for j in array_lower(iterand_arr, 2)..array_upper(iterand_arr, 2) loop
        for k in array_lower(iterand_arr, 3)..array_upper(iterand_arr, 3) loop
    
          the (i, j, k)th iterator_array is set to
            iterand_arr[i][j][k][ for all values the remaining 4th index ]
    
        end loop;
      end loop;
    end loop;
    
    -- In this example, the SLICE operand is 3.
    -- As a consequence, array_ndims(iterator_array) is 3.
    -- Assume that array_ndims(iterand_arr) is 4.
    -- There is therefore (4 - 3) = 1 nested loop in this pseudocode.
    for i in array_lower(iterand_arr, 1)..array_upper(iterand_arr, 1) loop
    
      the (i)th iterator_array is set to
        iterand_arr[i][ for all values the remaining 2nd, 3rd, and 4th indexes ]
    
    end loop;
    

The examples below clarify the behavior of FOREACH.

Syntax and semantics

[ <<label>> ]
FOREACH var [ SLICE non_negative_integer_literal ] IN ARRAY expression LOOP
  statements
END LOOP [ label ];
  • var must be explicitly declared before the FOREACH loop.

  • The operand of the optional SLICE clause must be a non-negative int literal.

  • Assume that expression has the data type some_type[]. - When SLICE 0 is used, var must be declared as some_type.

    • When the SLICE clause's operand is positive, var must be declared as some_type[].
  • SLICE 0 has the same effect as omitting the SLICE clause.

  • When SLICE 0 is used, or the SLICE clause is omitted, YSQL assigns each in turn of the array's values, visited in row-major order, to var.

  • When the SLICE clause's operand is positive, then YSQL assigns successive slices of the iterand array to var according to the following rule:

    • The extracted slices all have the same dimensionality given by this equality:
      array_ndims(iterator_array) = slice_operand.
    • The number of extracted slices is given by this equality:
      number_of_slices = cardinality(iterand_array)/cardinality(iterator_array).
    • The value of the SLICE operand must not exceed array_ndims(iterator_array).
    • When the value of the SLICE operand is equal to array_ndims(iterator_array) - 1, the FOREACH loop produces just a single iterator array value, and this is identical to the iterand array.
  • The useful range for the SLICE operand is therefore 0..(array_ndims(iterator_array) - 1).

Looping over the values in an array without the SLICE keyword

This loop is functionally identical to the FOR var IN loop. However, in the FOR loop, YSQL automatically defines var with the type int so that its scope is limited to the loop; but in the FOREACH loop, var must be explicitly declared, as noted in the "Syntax and semantics" section above.

do $body$
declare
  arr1 int[] := array[1, 2];
  arr2 int[] := array[3, 4, 5];
  var int;
begin
  <<"FOREACH eaxmple">>
  foreach var in array arr1||arr2 loop
    raise info '%', var;
  end loop "FOREACH eaxmple";
end;
$body$;

It shows this (after manually stripping the "INFO:" prompt):

1
2
3
4
5

The || operator is used only to emphasize that the iterand can be any expression whose data type is an array.

The next loop shows these things of note:

  • The iterand array is multidimensional.
  • The array type is "rt[]" where rt is a user-defined "row" type.
  • The syntax spot where "var" is used above need not be occupied by a single variable. Rather, "f1" and "f2" are used, to correspond to the fields in "rt".
  • The FOREACH loop is followed by a "cursor" loop whose SELECT statement uses unnest().
  • The FOREACH loop is more terse than the "cursor" loop. In particular, you can use the pair of declared variables "f1" and "f2" without any fuss (just as you could have used a single variable "r" of type "rt" without any fuss) as the iterator. YSQL looks after the proper assignment in both cases. But when you use unnest(), you have to look after this yourself.
create type rt as (f1 int, f2 text);

do $body$
declare
  a1 rt[] := array[(1, 'dog'), (2, 'cat')];
  a2 rt[] := array[(3, 'ant'), (4, 'rat')];
  arr rt[] := array[a1, a2];
  f1 int;
  f2 text;
begin
  raise info '';
  raise info 'FOREACH';
  foreach f1, f2 in array arr loop
    raise info '% | %', f1::text, f2;
  end loop;

  raise info '';
  raise info 'unnest()';
  for f1, f2 in (
    with v as (
      select unnest(arr) as r)
    select (r).f1, (r).f2 from v)
  loop
    raise info '% | %', f1::text, f2;
  end loop;
end;
$body$;

It shows this:

FOREACH
1 | dog
2 | cat
3 | ant
4 | rat

unnest()
1 | dog
2 | cat
3 | ant
4 | rat

This shows that this use of the FOREACH loop (with an implied 0 as the SLICE clause's operand) is functionally equivalent to unnest().

Looping over the contents of a multidimensional array taking advantage of a non-zero SLICE operand

First, store a three-dimensional two-by-two-by-two array in a ::text[] field in a single-row table. Each of the subsequent DO blocks uses it.

create table t(k int primary key, arr text[] not null);
insert into t(k, arr) values(1, '
  {
    {
      {001,002},
      {003,004}
    },
    {
      {005,006},
      {007,008}
    }
  }'::text[]);

Next, show the outcome when a bad value is used for the SLICE operand:

do $body$
declare
  arr constant text[] not null := (select arr from t where k = 1);
  slice_iterator text[] not null := '{?}';
begin
  raise info 'array_ndims(arr): %', array_ndims(arr)::text;
  foreach slice_iterator slice 4 in array arr loop
    raise info '%', slice_iterator::text;
  end loop;
end;
$body$;

It shows array_ndims(arr): 3 and then it reports this error:

2202E: slice dimension (4) is out of the valid range 0..3

This test confirms that the value of the SLICE operand must not exceed the iterand array's dimensionality.

As has been seen, SLICE 0 (or equivalently omitting the SLICE clause) scans the array values in row-major order. The next test, with SLICE 3, demonstrates the meaning when the SLICE operand is equal to the iterand array's dimensionality.

do $body$
declare
  arr constant text[] not null := (select arr from t where k = 1);
  slice_iterator text[] not null := '{?}';
  n int not null := 0;
begin
  raise info 'FOREACH SLICE 3';
  n := 0;
  foreach slice_iterator slice 3 in array arr loop
    assert
      (array_ndims(slice_iterator) = 3) and
      (slice_iterator = arr)           ,
    'assert failed';
    n := n + 1;
    raise info '% | %', n::text, slice_iterator::text;
  end loop;
end;
$body$;

It shows this:

FOREACH SLICE 3
1 | {{{001,002},{003,004}},{{005,006},{007,008}}}

The FOREACH loop generates just a single iterator slice. And, as the assert shows, this is identical to the iterand array. In other words, setting the SLICE operand to be equal to the iterand array's dimensionality, while the result is well-defined, is not useful. So, using this example iterand array, the useful range for the SLICE operand is 0..2.

The next test uses SLICE 2:

do $body$
declare
  arr constant text[] not null := (select arr from t where k = 1);
  slice_iterator text[] not null := '{?}';
  n int not null := 0;
begin
  raise info 'FOREACH SLICE 2';
  n := 0;
  foreach slice_iterator slice 2 in array arr loop
    assert (array_ndims(slice_iterator) = 2), 'assert failed';
    n := n + 1;
    raise info '% | %', n::text, slice_iterator::text;
  end loop;
end;
$body$;

It shows this:

FOREACH SLICE 2
1 | {{001,002},{003,004}}
2 | {{005,006},{007,008}}

As the assert shows, the operand of the SLICE operator determines the dimensionality of the iterator slices.

The next test uses SLICE 1:

do $body$
declare
  arr constant text[] not null := (select arr from t where k = 1);
  slice_iterator text[] not null := '{?}';
  n int not null := 0;
begin
  raise info 'FOREACH SLICE 1';
  n := 0;
  foreach slice_iterator slice 1 in array arr loop
    assert (array_ndims(slice_iterator) = 1), 'assert failed';
    n := n + 1;
    raise info '% | %', n::text, slice_iterator::text;
  end loop;
end;
$body$;

It shows this:

FOREACH SLICE 1
1 | {001,002}
2 | {003,004}
3 | {005,006}
4 | {007,008}

Once again, the assert shows that the operand of the SLICE operator determines the dimensionality of the iterator slices.

The last FOREACH test uses SLICE 0. Notice that, now, the iterator is declared as the scalar text variable "var":

do $body$
declare
  arr constant text[] not null := (select arr from t where k = 1);
  var text not null := '?';
  n int not null := 0;
begin
  raise info 'FOREACH SLICE 0';
  n := 0;
  foreach var slice 0 in array arr loop
    n := n + 1;
    raise info '% | %', n::text, var;
  end loop;
end;
$body$;

It shows this:

FOREACH SLICE 0
1 | 001
2 | 002
3 | 003
4 | 004
5 | 005
6 | 006
7 | 007
8 | 008

This is functionally equivalent to unnest() as the final test shows:

do $body$
<<b>>declare
  arr constant text[] not null := (select arr from t where k = 1);
  var text not null := '?';
  n int not null := 0;
begin
  raise info 'unnest()';
  n := 0;
  for b.n, b.var in (
    with
      v1 as (
        select unnest(arr) as var),
      v2 as (
        select
          v1.var,
          row_number() over(order by v1.var) as n
        from v1)
    select v2.n, v2.var from v2)
  loop
    n := n + 1;
    raise info '% | %', n::text, var;
  end loop;
end b;
$body$;

It shows this:

unnest()
2 | 001
3 | 002
4 | 003
5 | 004
6 | 005
7 | 006
8 | 007
9 | 008

Using FOREACH to iterate over the elements in an array of DOMAIN values

You need to be aware of some special considerations to implement this scenario. Using FOREACH with an array of DOMAINs, within the dedicated section Using an array of DOMAIN values explains what you need to know.

Using a wrapper PL/pgSQL table function to expose the SLICE operand as a formal parameter

The fact that the SLICE operand must be a literal means that there are only two ways two parameterize this—and neither is satisfactory for real application code. Each uses a table function whose input is the iterand array and the value for the SLICE operand, and whose output is a SETOF iterator array values.

  • The first approach is to encapsulate some particular range of SLICE operand values in an ordinary statically defined function that uses a CASE statement to select the FOREACH loop that has the required SLICE operand literal. This is unsatisfactory because you have to decide the range of SLICE operand values that you'll support up front.
  • The second approach overcomes the limitation of the up front determination of the supported range of SLICE operand values by encapsulating code in, a statically defined function, that in turn dynamically generates a function with the requiredFOREACH loop and SLICE operand value and that then invokes it dynamically. This is unsatisfactory because it's some effort to implement and test such an approach. But it's unsatisfactory mainly because of the performance cost that dynamic generation and execution brings.

However, the requirements specification for real application code is unlikely to need more than one, or possibly just a few, specific values for the SLICE operand. Therefore, in overwhelming majority of practically important use cases, you can write exactly the code you need where you need it.

The code that follows uses the first approach. It's included here because it demonstrates a generically valuable PL/pgSQL programming technique: user-defined functions and procedures with polymorphic formal parameters (in this case anyarray and anyelement). The examples also use assert statements to confirm that the expected relationships hold between these quantities:

  • the dimensionality of the iterand array
  • the value of the SLICE operand
  • the lengths along the iterand array's dimensions
  • the cardinalities of the iterand array and the iterator arrays
  • the number of returned iterator values.

Here is the basic encapsulation. It's hard-coded to handle values for the SLICE operand in the range 0..4.

Recall that the iterator for SLICE 0 is a scalar and that the iterators for other values of the SLICE operand are arrays. And recall that a pair of functions with the same definitions of the input formal parameters cannot be overload-distinguished by the data type of their return values. For this reason, the encapsulation of the FOREACH loop for SLICE 0 is a dedicated function with just one input formal parameter: the iterand array. And the encapsulation of the FOREACH loop for other values of the SLICE operand is a second function with two input formal parameters: the iterand array and the value of the SLICE operand. Here they are:

-- First overload
create function array_slices(arr in anyarray)
  returns table(ret anyelement)
  language plpgsql
as $body$
declare
  no_of_values int not null := 0;
begin
  -- "slice 0" means the same
  -- as omitting the "slice" clause.
  foreach ret slice 0 in array arr
  loop
    no_of_values := no_of_values + 1;
    return next;
  end loop;
  assert
    (no_of_values = cardinality(arr)),
  'array_slices 1st overload: no_of_values assert failed';
end;
$body$;

And:

-- Second overload
create function array_slices(arr in anyarray, slice_operand in int)
  returns table(ret anyarray)
  language plpgsql
as $body$
declare
  no_of_values int not null := 0;
  lengths_product int not null := 0;
begin
  case slice_operand
    when 1 then
      lengths_product := array_length(arr, 4);
      foreach ret slice 1 in array arr
      loop
        no_of_values := no_of_values + 1;
        assert
          (array_ndims(ret) = 1)               and
          (cardinality(ret) = lengths_product) ,
        'assert failed';
        return next;
      end loop;
      assert
        (no_of_values = cardinality(arr)/lengths_product),
      'array_slices 2nd overload: no_of_values assert #1 failed';

    when 2 then
      lengths_product := array_length(arr, 4) *
                         array_length(arr, 3);
      foreach ret slice 2 in array arr
      loop
        no_of_values := no_of_values + 1;
        assert
          (array_ndims(ret) = 2)               and
          (cardinality(ret) = lengths_product) ,
        'assert failed';
        return next;
      end loop;
      assert
        (no_of_values = cardinality(arr)/lengths_product),
      'array_slices 2nd overload: no_of_values assert #2 failed';

    when 3 then
      lengths_product := array_length(arr, 4) *
                         array_length(arr, 3) *
                         array_length(arr, 2);
      foreach ret slice 3 in array arr
      loop
        no_of_values := no_of_values + 1;
        assert
          (array_ndims(ret) = 3)               and
          (cardinality(ret) = lengths_product) ,
        'assert failed';
        return next;
      end loop;
      assert
        (no_of_values = cardinality(arr)/lengths_product),
      'array_slices 2nd overload: no_of_values assert #3 failed';

    when 4 then
      lengths_product := array_length(arr, 4) *
                         array_length(arr, 3) *
                         array_length(arr, 2) *
                         array_length(arr, 1);
      foreach ret slice 4 in array arr
      loop
        no_of_values := no_of_values + 1;
        assert
          (array_ndims(ret) = 4)               and
          (cardinality(ret) = lengths_product) ,
        'assert failed';
        return next;
      end loop;
      assert
        (no_of_values = cardinality(arr)/lengths_product),
      'array_slices 2nd overload: no_of_values assert #4 failed';

    else
      raise exception 'slice_operand > 4 not supported';
  end case;
end;
$body$;

You can see that each leg of the CASE is "generated" formulaically—albeit manually—by following a pattern that could be parameterized. You can use these encapsulations for iterand arrays of any dimensionality. But you must take responsibility for following the rule that the value of the SLICE operand must fall within the acceptable range. Otherwise, you'll get the error that was demonstrated above:

2202E: slice dimension % is out of the valid range 0..%

Here is the test harness. Both this procedure and the function that generates the to-be-tested iterand array are hard-coding for a dimensionality of 4.

-- Exercise each of the meaningful calls to array_slices().
--
-- You cannot declare local variables as "anyelement" or "anyarray".
-- (The attempt causes a compilation error). It's obvious why.
-- It's the caller's responsibility to determine the
-- real type by using appropriate actual arguments.
-- "val" (scalar) and "slice" (array) are needed as FOREACH loop runners.
-- "in out" is used to avoid the nominal performance penalty
--  of extra copying brought by plain "out".
-- The caller has no interest in whatever values they have
-- on return from this procedure.
--
-- NOTE: while you _can_ declare a local variable as
-- "some_formal%type", you _cannot_ use that mechanism to declare
-- a scalar with the data type that defines an array when
-- all you have to anchor "%type" to is the array.
--
create procedure test_array_slices(
  -- The "real" formal.
  arr   in     anyarray,

  -- used as "local varables
  val   in out anyelement,
  slice in out anyarray)
  language plpgsql
as $body$
declare
  arr_ndims constant int := array_ndims(arr);
begin
  assert
    (arr_ndims = 4),
  'assert failed: test_array_slices() requires a 4-d array';
  raise info '%', array_dims(arr);

  declare
    len_1 constant int := array_length(arr, 1);
    len_2 constant int := array_length(arr, 2);
    len_3 constant int := array_length(arr, 3);
    len_4 constant int := array_length(arr, 4);

    expected_slice_cardinalities constant int[] not null :=
      array[
        len_4,
        len_4*len_3,
        len_4*len_3,
        len_4*len_3*len_2,
        len_4*len_3*len_2*len_1];

    slice_cardinality int not null := 0;

    -- val anyelement not null := '?';
    -- slice anyarray not null := '{?}';
  begin
    raise info ''; raise info 'slice_operand: %', 0;

    for val in (select array_slices(arr)) loop
      raise info '%', val::text;
    end loop;

    for slice_operand in 1..arr_ndims loop
      raise info ''; raise info 'slice_operand: %', slice_operand;

      for slice in (select array_slices(arr, slice_operand)) loop
        slice_cardinality := cardinality(slice);
        assert
          (array_ndims(slice) = slice_operand) ,
          (slice_cardinality = expected_slice_cardinalities[slice_operand]) ,
        'assert failed.';
        raise info '%', slice::text;
        if slice_operand = arr_ndims then
          assert (slice = arr), 'assert (slice = arr) failed';
        end if;
      end loop;
    end loop;
  end;
end;
$body$;

Here is a function to generate a four-dimensional array. Notice that the actual argument for the "lengths" formal parameter must be a one-dimensional int[] array with four values. These specify the lengths along each of the output array's dimensions.

create function four_d_array(lengths in int[])
  returns text[]
  language plpgsql
as $body$
declare
  lengths_ndims       constant int := array_ndims(lengths);
  lengths_cardinality constant int := cardinality(lengths);
begin
  assert
    (lengths_ndims = 1)       and
    (lengths_cardinality = 4) ,
  'assert failed: four_d_array() creates only a 4-d array.';

  declare
    -- Take the default for array_fill's optional 2nd formal:
    -- all lower bounds are 1.
    arr text[] not null := array_fill('00'::text, lengths);
  begin
    -- For readability of the results, define the created array's values so that,
    -- when scanned in row-major order, they are seen to be a dense series
    -- that increases in even steps, 001, 002, 003, and so on.
    declare
      n int not null := 0;
    begin
      for i1 in 1..lengths[1] loop
        for i2 in 1..lengths[2] loop
          for i3 in 1..lengths[3] loop
            for i4 in 1..lengths[4] loop
              n := n + 1;
              arr[i1][i2][i3][i4] := ltrim(to_char(n, '009'));
            end loop;
          end loop;
        end loop;
      end loop;
    end;
    assert
      (array_ndims(arr) = lengths_cardinality),
    'assert failed.';

    -- Sanity check. Include to demonstrate the useful
    -- terseness of the FOREACH loop.
    declare
      product int not null := 1;
      len int not null := 0;
    begin
      foreach len in array lengths loop
        product := product*len;
      end loop;
      assert
        (cardinality(arr) = product) ,
      'assert failed.';
    end;
    return arr;
  end;
end;
$body$;

And here is one example test invocation:

do $body$
declare
  arr constant text[] not null := four_d_array('{2, 2, 2, 2}'::int[]);
  dummy_var text := '?';
  dummy_arr text[] := '{/}';
begin
  call test_array_slices(arr, dummy_var, dummy_arr);
end;
$body$;

It produces this result:

[1:2][1:2][1:2][1:2]

slice_operand: 0
001
002
003
004
005
006
007
008
009
010
011
012
013
014
015
016

slice_operand: 1
{001,002}
{003,004}
{005,006}
{007,008}
{009,010}
{011,012}
{013,014}
{015,016}

slice_operand: 2
{{001,002},{003,004}}
{{005,006},{007,008}}
{{009,010},{011,012}}
{{013,014},{015,016}}

slice_operand: 3
{{{001,002},{003,004}},{{005,006},{007,008}}}
{{{009,010},{011,012}},{{013,014},{015,016}}}

slice_operand: 4
{{{{001,002},{003,004}},{{005,006},{007,008}}},{{{009,010},{011,012}},{{013,014},{015,016}}}}
  • Overview
  • Syntax and semantics
  • Looping over the values in an array without the SLICE keyword
  • Looping over the contents of a multidimensional array taking advantage of a non-zero SLICE operand
  • Using FOREACH to iterate over the elements in an array of DOMAIN values
  • Using a wrapper PL/pgSQL table function to expose the SLICE operand as a formal parameter
Ask our community
  • Slack
  • Github
  • Forum
  • StackOverflow
Yugabyte
Contact Us
Copyright © 2017-2022 Yugabyte, Inc. All rights reserved.