Available in versions: Dev (3.21) | Latest (3.20) | 3.19 | 3.18 | 3.17 | 3.16 | 3.15 | 3.14 | 3.13 | 3.12 | 3.11

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.

CONNECT_BY_ROOT

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

The CONNECT_BY_ROOT operator allows for accessing a row's hierarchy root row and evaluate an expression on that root row.

SELECT
  child,
  parent,
  sys_connect_by_path(child, '/'),
  connectByRoot(child)
FROM (
  VALUES
    (1, null),
    (2, 1),
    (3, null),
    (4, 3)
) AS t (child, parent)
START WITH
  parent IS NULL
CONNECT BY NOCYCLE
  PRIOR child = parent;
Field<Integer> child = field("child", INTEGER);
Field<Integer> parent = field("parent", INTEGER);

create.select(
            child,
            parent,
            sysConnectByPath(child, "/"),
            connectByRoot(child))
      .from(values(
            row(val(1), val(null, INTEGER)),
            row(2, 1),
            row(val(3), val(null, INTEGER)),
            row(4, 3)).as(table("t"), child, parent))
      .startWith(parent.isNull())
      .connectByNoCycle(prior(child).eq(parent))
      .fetch();

The result being, for example

+-------+--------+---------------------+-----------------+
| child | parent | sys_connect_by_path | connect_by_root |
+-------+--------+---------------------+-----------------+
|     1 | {null} | /1                  |               1 |
|     2 |      1 | /1/2                |               1 |
|     3 | {null} | /3                  |               3 |
|     4 |      3 | /3/4                |               3 |
+-------+--------+---------------------+-----------------+

Dialect support

This example using jOOQ:

connectByRoot(AUTHOR.ID)

Translates to the following dialect specific expressions:

Exasol, Informix, Oracle, Snowflake

connect_by_root AUTHOR.ID

ASE, Access, Aurora MySQL, Aurora Postgres, BigQuery, ClickHouse, CockroachDB, DB2, Databricks, Derby, DuckDB, Firebird, H2, HSQLDB, Hana, MariaDB, MemSQL, MySQL, Postgres, Redshift, SQLDataWarehouse, SQLServer, SQLite, Sybase, Teradata, Trino, Vertica, YugabyteDB

/* UNSUPPORTED */
Generated with jOOQ 3.21. Support in older jOOQ versions may differ. 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