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 > Literals >

The literal for an array of primitive values

Report a doc issue Suggest new content
  • Statement of the rules
  • Always write array literals in canonical form
  • Examples to illustrate the rules
    • One-dimensional array of int values
    • One-dimensional array of text values
    • One-dimensional array of timestamp values
    • One-dimensional array of boolean values (and NULL in general)
    • Multidimensional array of int values

This section states a sufficient subset of the rules that allow you to write a syntactically correct array literal that expresses any set of values, for arrays of any scalar data type, that you could want to create. The full set of rules allows more flexibility than do just those that are stated here. But because these are sufficient, the full, and rather complex, set is not documented here. The explanations in this section will certainly allow you to interpret the ::text typecast of any array value that you might see, for example in ysqlsh.

Then Yugabyte's recommendation in this space is stated. And then the rules are illustrate with examples.

Statement of the rules

The statement of these rules depends on understanding the notion of the canonical form of a literal. Defining the "canonical form of a literal explained that the ::text typecast of any kind of array shows you that this form of the literal (more carefully stated, the text of this literal) can be used to recreate the value.

In fact, this definition, and the property that the canonical form of the literal is sufficient to recreate the value, hold for values of all data types.

Recall that every value within an array necessarily has the same data type. If you follow the rules that are stated here, and illustrated in the demonstrations below, you will always produce a syntactically valid literal which expresses the semantics that you intend. It turns out that many other variants, especially for text[] arrays, are legal and can produce the values that you intend. However, the rules that govern these exotic uses will not documented because it is always sufficient to create your literals in canonical form.

Here is the sufficient set of rules.

  • The commas that delimit successive values, the curly braces that enclose the entire literal, and the inner curly braces that are used in the literals for multidimensional arrays, can be surrounded by arbitrary amounts of whitespace. If you want strictly to adhere to canonical form, then you ought not to do this. But doing so can improve the readability of ad hoc manually typed literals. It can also make it easier to read trace output in a program that constructs array literals programmatically.
  • In numeric and boolean array literals, do not surround the individual values with double quotes.
  • In the literal for a timestamp[] array, do surround the individual values with double quotes—even though this is not strictly necessary.
  • In the literal for a text[] array, do surround every individual value with double quotes, even though this is not always necessary. It is necessary for any value that itself contains, as ordinary text, any whitespace or any of the characters that have syntactic significance within the outermost curly brace pair. This is the list:
   <space>   {   }   ,   "   \
  • It's sufficient to write the curly braces and the comma ordinarily within the enclosing double quotes. But each of the double quote character and the backslash character must be escaped with an immediately preceding single backslash.

Always write array literals in canonical form

Bear in mind that you will rarely manually type literals in the way that this section does to demonstrate the rules. You'll do this only when teaching yourself, when prototyping new code, or when debugging. Rather, you'll typically create the literals programmatically—often in a client-side program that parses out the data values from, for example, an XML text file or, these days, probably a JSON text file. In these scenarios, the target array is likely to have the data type "some_user_defined_row_type[]". And when you create literals programmatically, you want to use the simplest rules that work and you have no need at all to omit arguably unnecessary double quote characters.

Yugabyte recommends that the array literals that you generate programmatically are always spelled using the canonical representations

You can relax this recommendation, to make tracing or debugging your code easier (as mentioned above), by using a newline between each successive encoded value in the array—at least when the values themselves use a lot of characters, as they might for "row" type values.

Note: You can hope that the client side programming language that you use, together with the driver that you use to issue SQL to YugabyteDB and to retrieve results, will allow the direct use of data types that your language defines that map directly to the YSQL array and "row" type, just as they have scalar data types that map to int, text, timestamp, and boolean. For example Python has "list" that maps to array and "tuple" that maps to "row" type. And the "psycopg2" driver that you use for YugabyteDB can map values of these data types to, for example, a PREPARE statement like the one shown below.

Note: YSQL has support for converting a JSON array (and this includes a JSON array of JSON objects) directly into the corresponding YSQL array values.

The rules for constructing literals for arrays of "row" type values are described in literal for an array of "row" type values section.

Your program will parse the input and create the required literals as ordinary text strings that you'll then provide as the actual argument to a PREPARE statement execution, leaving the typecast of the text actual argument, to the appropriate array data type, to the prepared INSERT or UPDATE statement like this:

prepare stmt(text) as insert into t(rs) values($1::rt[]);

Assume that in, this example, "rt" is some particular user-define "row" type.

Examples to illustrate the rules

Here are some examples of kinds array of primitive values:

  • array of numeric values (like int and numeric)
  • array of stringy values (like text, varchar, and char)
  • array of date-time values (like timestamp)
  • array of boolean values.

In order to illustrate the rules that govern the construction of an array literal, it is sufficient to consider only these.

You'll use the array[] constructor to create representative values of each kind and inspect its ::text typecast.

One-dimensional array of int values

This example demonstrates the principle:

create table t(k serial primary key, v1 int[], v2 int[]);
insert into t(v1) values (array[1, 2, 3]);
select v1::text as text_typecast from t where k = 1
\gset result_
\echo :result_text_typecast

The \gset metacommand was used first in this "Array data types and functionality" major section in array_agg() and unnest().

Notice that, in this example, the SELECT statement is terminated by the \gset metacommand on the next line rather than by the usual semicolon. The \gset metacommand is silent. The \echo metacommand shows this:

{1,2,3}

You can see the general form already:

  • The (text of) an array literal starts with the left curly brace and ends with the right curly brace.

  • The items within the braces are delimited by commas, and there is no space between one item, the comma, and the next item. Nor is there any space between the left curly brace and the first item or between the last item and the right curly brace.

One-dimensional array of text values shows that more needs to be said. But the two rules that you've already noticed always hold.

To use the literal that you produced to create a value, you must enquote it and typecast it. Do this with the \set metacommand:

\set canonical_literal '\'':result_text_typecast'\'::int[]'
\echo :canonical_literal

. The \echo metacommand now shows this:

'{1,2,3}'::int[]

Next, use the canonical literal that was have produced to update "t.v2" to confirm that the value that the row constructor created was recreated:

update t set v2 = :canonical_literal where k = 1;
select (v1 = v2)::text as "v1 = v2" from t where k = 1;

It shows this:

 v1 = v2
---------
 true

As promised, the canonical form of the array literal does indeed recreate the identical value that the array[] constructor created.

Note:

Try this:

select 12512454.872::text;

The result is the canonical form, 12512454.872. So this (though you rarely see it):

select 12512454.872::numeric;

runs without error. Now try this:

select to_number('12,512,454.872', '999G999G999D999999')::text;

This, too, runs without error because it uses the to_number() built-in function. The result here, too, is the canonical form, 12512454.872—with no commas. Now try this:

select '12,512,454.872'::numeric;

This causes the "22P02: invalid input syntax for type numeric" error. In other words, only a numeric value in canonical form can be directly typecast using ::numeric.

Here, using an array literal, is an informal first look at what follows. For now, take its syntax to mean what you'd intuitively expect. You must spell the representations for the values in a numeric[] array in canonical form. Try this:

select ('{123.456, -456.789}'::numeric[])::text;

It shows this:

 {123.456,-456.789}

Now try this:

select ('{9,123.456, -8,456.789}'::numeric[])::text;

It silently produces this presumably unintended result (an array of four numeric values) because the commas are taken as delimiters and not as part of the representation of a single numeric value:

 {9,123.456,-8,456.789}

In an array literal (or in a "row" type value literal), there is no way to accommodate forms that cannot be directly typecast. (The same holds for timestamp values as for numeric values.) YSQL inherits this limitation from PostgreSQL. It is the user's responsibility to work around this when preparing the literal because, of course, functions like "to_number()" cannot be used within literals. Functions can, however, be used in a value constructor as array[] value constructor shows.

One-dimensional array of text values

Use One-dimensional array of int values as a template for this and the subsequent sections. The example sets array values each of which, apart from the single character a, needs some discussion. These are the characters (or, in one case, character sequence), listed here "bare" and with ten spaces between each:

     a          a b          ()          ,          '          "          \
create table t(k serial primary key, v1 text[], v2 text[]);
insert into t(v1) values (array['a', 'a b', '()', ',', '{}', $$'$$, '"', '\']);
select v1::text as text_typecast from t where k = 1
\gset result_
\echo :result_text_typecast

For ordinary reasons, something special is needed to establish the single quote within the surrounding array literal which itself must be enquoted for using in SQL. Dollar quotes are a convenient choice. The \echo metacommand shows this:

{a,"a b",(),",","{}",',"\"","\\"}

This is rather hard (for the human) to parse. To make the rules easier to see, this list doesn't show the left and right curly braces. And the syntactically significant commas are surrounded with four spaces on each side:

     a    ,    "a b"    ,    ()    ,    ","    ,    "{}"    '    ,    "\""    ,    "\\"

In addition to the first two rules, notice the following.

  • Double quotes are used to surround a value that includes any spaces. (Though the example doesn't show it, this applies to leading and trailing spaces too.)
  • The left and right parentheses are not surrounded with double quotes. Though these have syntactic significance in other parsing contexts, they are insignificant within the curly braces of an array literal.
  • The comma has been surrounded by double quotes. This is because it does have syntactic significance, as the value delimiter, within the curly braces of an array literal.
  • The curly braces have been surrounded by double quotes. This is because interior curly braces do have syntactic significance, as you'll see below, in the array literal for a multidimensional array.
  • The single quote is not surrounded with double quotes. Though it has syntactic significance in other parsing contexts, it is insignificant within the curly braces of an array literal. This holds, also, for all sorts of other punctuation characters like ; and : and [ and ] and so on.
  • The double quote has been escaped with a single backslash and this has been then surrounded with double quotes. This is because it does have syntactic significance, as the (one and only) quoting mechanism, within the curly braces of an array literal.
  • The backslash has also been escaped with another single backslash and this has been then surrounded with double quotes. This is because it does have syntactic significance, as the escape character, within the curly braces of an array literal.

There's another rule that the present example does not show. Though not every comma-separated value was surrounded by double quotes, it's never harmful to do this. You can confirm this with your own test, Yugabyte recommends that, for consistency, you always surround every text value within the curly braces for a text[] array literal with double quotes.

To use the text of the literal that was produced above to recreate the value, you must enquote it and typecast it. Do this, as you did for the int[] example above, with the \set metacommand. But you must use dollar quotes because the literal itself has an interior single quote.

\set canonical_literal '$$':result_text_typecast'$$'::text[]
\echo :canonical_literal

The \echo metacommand now shows this:

$${a,"a b",(),",",',"\"","\\"}$$::text[]

Next, use the canonical literal to update "t.v2" to confirm that the value that the row constructor created was recreated:

update t set v2 = :canonical_literal where k = 1;
select (v1 = v2)::text as "v1 = v2" from t where k = 1;

Again, it shows this:

 v1 = v2
---------
 true

So, again as promised, the canonical form of the array literal does indeed recreate the identical value that the array[] constructor created.

One-dimensional array of timestamp values

This example demonstrates the principle:

create table t(k serial primary key, v1 timestamp[], v2 timestamp[]);
insert into t(v1) values (array[
    '2019-01-27 11:48:33'::timestamp,
    '2020-03-30 14:19:21'::timestamp
  ]);
select v1::text as text_typecast from t where k = 1
\gset result_
\echo :result_text_typecast

The \echo metacommand shows this:

{"2019-01-27 11:48:33","2020-03-30 14:19:21"}

You learn one further rule from this:

  • The ::timestamp typecastable strings within the curly braces are tightly surrounded with double quotes.

To use the text of the literal that was produced to create a value, you must enquote it and typecast it. Do this with the \set metacommand:

\set canonical_literal '\'':result_text_typecast'\'::timestamp[]'
\echo :canonical_literal

. The \echo metacommand now shows this:

'{"2019-01-27 11:48:33","2020-03-30 14:19:21"}'::timestamp[]

Next, use the canonical literal to update "t.v2" to confirm that the value that the row constructor created was recreated:

update t set v2 = :canonical_literal where k = 1;
select (v1 = v2)::text as "v1 = v2" from t where k = 1;

It shows this:

 v1 = v2
---------
 true

Once again, as promised, the canonical form of the array literal does indeed recreate the identical value that the array[] constructor created.

One-dimensional array of boolean values (and NULL in general)

This example demonstrates the principle:

create table t(k serial primary key, v1 boolean[], v2 boolean[]);
insert into t(v1) values (array[
    true,
    false,
    null
  ]);
select v1::text as text_typecast from t where k = 1
\gset result_
\echo :result_text_typecast

The \echo metacommand shows this:

{t,f,NULL}

You learn two further rules from this:

  • The canonical representations of TRUE and FALSE within the curly braces for a boolean[] array are t and f. They are not surrounded by double quotes.
  • To specify NULL, the canonical form uses upper case NULL and does not surround this with double quotes.

Though the example doesn't show this, NULL is not case-sensitive. But to compose a literal that adheres to canonical form, you ought to spell it using upper case. And this is how you specify NULL within the array literal for any data type. (A different rule applies for fields within the literal for "row" type value).

Note: If you surrounded NULL within a literal for a text[] array, then it would be silently interpreted as an ordinary text value that just happens to be spelled that way.

To use the literal that was produced to create a value, you must enquote it and typecast it. Do this with the \set metacommand:

\set canonical_literal '\'':result_text_typecast'\'::boolean[]'
\echo :canonical_literal

. The \echo metacommand now shows this:

'{t,f,NULL}'::boolean[]

Next use the canonical literal to update "t.v2" to can confirm that the value that the row constructor created has been recreated :

update t set v2 = :canonical_literal where k = 1;
select (v1 = v2)::text as "v1 = v2" from t where k = 1;

It shows this:

 v1 = v2
---------
 true

Yet again, as promised, the canonical form of the array literal does indeed recreate the identical value that the array[] constructor created.

Multidimensional array of int values

create table t(k serial primary key, v int[]);

-- Insert a 1-dimensional int[] value.
insert into t(v) values('
    {1,  2}
  '::int[]);

-- Insert a 2-dimensional int[] value.
insert into t(v) values('
    {
      {1,  2},
      {3,  4}
    }
  '::int[]);

-- Insert a 3-dimensional int[] value.
insert into t(v) values('
    {
      {
        {1,  2}, {3,  4}
      },
      {
        {5,  6}, {7,  8}
      }
    }
  '::int[]);

-- Insert a 3-dimensional int[] value, specifying
-- the lower and upper bounds along each dimension.
insert into t(v) values('
    [3:4][5:6][7:8]=
    {
      {
        {1,  2}, {3,  4}
      },
      {
        {5,  6}, {7,  8}
      }
    }
  '::int[]);

select k, array_ndims(v) as "ndims", v::text as "v::text" from t order by k;

Notice that the three different INSERT statements define arrays with different dimensionality, as the comments state. This illustrates what was explained in Synopsis: the column "t.v" can hold array values of any dimensionality.

Here is the SELECT result:

 k | ndims |                    v::text
---+-------+-----------------------------------------------
 1 |     1 | {1,2}
 2 |     2 | {{1,2},{3,4}}
 3 |     3 | {{{1,2},{3,4}},{{5,6},{7,8}}}
 4 |     3 | [3:4][5:6][7:8]={{{1,2},{3,4}},{{5,6},{7,8}}}

Again, whitespace in the inserted literals for numeric values is insignificant, and the text typecasts use whitespace (actually, the lack thereof) conventionally.

The literal for a multidimensional array has nested {} pairs, according to the dimensionality, and the innermost pair contains the literals for the primitive values.

Notice the spelling of the array literal for the row with "k = 4". The optional syntax [3:4][5:6][7:8] specifies the lower and upper bounds, respectively, for the first, the second, and the third dimension. This is the same syntax that you use to specify a slice of a array. (array slice operator) is described in its own section.) When the freedom to specify the bounds is not exercised, then they are assumed all to start at 1, and then the canonical form of the literal does not show the bounds.

When the freedom is exercised, the bounds for every dimension must be specified. Specifying the bounds gives you, of course, an opportunity for error. If the length along each axis that you (implicitly) specify doesn't agree with the lengths that emerge from the actual values listed between the surrounding outer {} pair, then you get the "22P02 invalid_text_representation" error with this prose explanation:

malformed array literal...
Specified array dimensions do not match array contents.
  • Statement of the rules
  • Always write array literals in canonical form
  • Examples to illustrate the rules
    • One-dimensional array of int values
    • One-dimensional array of text values
    • One-dimensional array of timestamp values
    • One-dimensional array of boolean values (and NULL in general)
    • Multidimensional array of int values
Ask our community
  • Slack
  • Github
  • Forum
  • StackOverflow
Yugabyte
Contact Us
Copyright © 2017-2022 Yugabyte, Inc. All rights reserved.