Available in versions: Dev (3.20) | Latest (3.19) | 3.18

ARRAY_REPLACE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ARRAY_REPLACE function allows for replacing all occurrences of an element by another value in an array:

SELECT array_replace(ARRAY[1, 2, 2, 3], 2, -1)
create.select(arrayReplace(array(1, 2, 2, 3), val(2), val(-1))).fetch();

The result would look like this:

+----------------+
| array_replace  |
+----------------+
| [1, -1, -1, 3] |
+----------------+

Dialect support

This example using jOOQ:

arrayReplace(array(1, 2, 2, 3), val(2), val(-1))

Translates to the following dialect specific expressions:

Aurora Postgres, CockroachDB, Postgres, YugabyteDB

array_replace(
  ARRAY[1, 2, 2, 3],
  2,
  -1
)

DuckDB

array_transform(
  ARRAY[1, 2, 2, 3],
  e -> CASE
    WHEN e IS NOT DISTINCT FROM 2 THEN -1
    ELSE e
  END
)

H2, HSQLDB

(
  SELECT coalesce(
    array_agg(CASE
      WHEN e IS NOT DISTINCT FROM 2 THEN -1
      ELSE e
    END),
    CAST(ARRAY[] AS int array)
  )
  FROM UNNEST(ARRAY[1, 2, 2, 3]) t (e)
)

Trino

transform(
  ARRAY[1, 2, 2, 3],
  e -> CASE
    WHEN e IS NOT DISTINCT FROM 2 THEN -1
    ELSE e
  END
)

ASE, Access, Aurora MySQL, BigQuery, ClickHouse, DB2, Derby, Exasol, Firebird, Hana, Informix, MariaDB, MemSQL, MySQL, Oracle, Redshift, SQLDataWarehouse, SQLServer, SQLite, Snowflake, Sybase, Teradata, Vertica

/* UNSUPPORTED */

(These are currently generated with jOOQ 3.20, see #10141), or translate your own on our website

Feedback

Do you have any feedback about this page? We'd love to hear it!

The jOOQ Logo