Available in versions: Dev (3.20)

This documentation is for the unreleased development version of jOOQ. Click on the above version links to get this documentation for a supported version of jOOQ.

ARRAY_FILTER

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

The ARRAY_FILTER function allows for filtering elements of an array given a predicate.

A few SQL dialects, including ClickHouse, DuckDB, and Trino have introduced higher order functions with a lambda syntax to help implement features like this one. jOOQ can map a Java lambda to a SQL lambda, and emulate the feature using standard SQL functionality (using UNNEST and ARRAY_AGG) if the function isn't available.
SELECT array_filter(ARRAY[1, 2, 2, 3], e -> mod(e, 2) = 0)
create.select(arrayFilter(array(1, 2, 2, 3), e -> e.mod(2).eq(0))).fetch();

The result would look like this:

+--------------+
| array_filter |
+--------------+
| [ 2, 2 ]     |
+--------------+

Dialect support

This example using jOOQ:

arrayFilter(array(1, 2, 2, 3), e -> e.mod(2).eq(0))

Translates to the following dialect specific expressions:

Aurora Postgres, Postgres

(
  SELECT coalesce(
    array_agg(e),
    CAST(ARRAY[] AS int[])
  )
  FROM UNNEST(ARRAY[1, 2, 2, 3]) t (e)
  WHERE mod(e, 2) = 0
)

BigQuery

(
  SELECT coalesce(
    array_agg(e),
    CAST(ARRAY[] AS Array<int64>)
  )
  FROM (
    SELECT null e
    FROM UNNEST([STRUCT(1 AS dual)]) AS dual
    WHERE FALSE
    UNION ALL
    SELECT *
    FROM UNNEST(ARRAY[1, 2, 2, 3]) t
  ) t
  WHERE mod(e, 2) = 0
)

ClickHouse

arrayFilter(
  e -> mod(e, 2) = 0,
  ARRAY(1, 2, 2, 3)
)

CockroachDB

(
  SELECT coalesce(
    array_agg(e),
    CAST(ARRAY[] AS int4[])
  )
  FROM UNNEST(ARRAY[1, 2, 2, 3]) t (e)
  WHERE mod(e, 2) = 0
)

DuckDB

array_filter(
  ARRAY[1, 2, 2, 3],
  e -> (e % 2) = 0
)

H2, HSQLDB

(
  SELECT coalesce(
    array_agg(e),
    CAST(ARRAY[] AS int array)
  )
  FROM UNNEST(ARRAY[1, 2, 2, 3]) t (e)
  WHERE mod(e, 2) = 0
)

Trino

filter(
  ARRAY[1, 2, 2, 3],
  e -> mod(e, 2) = 0
)

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

/* UNSUPPORTED */
Generated with jOOQ 3.20. Translate your own SQL on our website

Feedback

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

The jOOQ Logo