Can I use… cycle … (Recursive Queries)


Apache DerbyBigQueryDb2 (LUW)H2MariaDBMySQLOracle DBPostgreSQLSQL ServerSQLite20072009201120132015201720192021⊘ 3.5.7 - 3.42.0⊘ 2008R2 - 2022✓ 14+⊘ 8.3 - 13⚠ 11gR2 - 21ca⊘ 11gR1⊘ 5.0 - 8.0.33⚠ 10.5 - 10.11ab⊘ 5.1 - 10.4⊘ 1.4.191 - 2.1.214⊘ 9.7 - 11.5.8⊘ 2.0⊘ 10.15.1.3 - 10.16.1.1
  1. No using … sub-clause
  2. Use cycle … restrict

The cycle clause monitors selected columns of the result of a recursive query for recurring values. If the same values appear a second time, the cycle clause prevents following that path a second time. Thereby the cycle clause prevents infinite loops.

WITH RECURSIVE path (a, b) AS (
  SELECT edges.* FROM edges
                WHERE a = 1
UNION ALL
  SELECT edges.* FROM edges
                 JOIN path 
                   ON edges.a = path.b
)
CYCLE a
  SET cycl TO 'Y' DEFAULT 'N'
USING path_array
SELECT *
  FROM path
 WHERE cycl = 'N'

Note that the result will have one row for each cycle twice. The cycl column defined in set can be used to drop the duplicates.

The cycle clause consists of three parts:

CYCLE <cycle column list>

List of columns for which a loop—and only a loop—causes recurring values.

SET <column name> [TO <value> DEFAULT <value>]

Adds a column to identify rows that were closing a cycle.

The optional to and default sub-clauses specify the values that mark rows processed before a cycle was closed (to) and those that were closing a cycle (default). If skipped it defaults to false default true.0

USING <column name>

Adds a column that contains an array with a list of steps that have led to each row.

The values in the array are row-values of the columns listed right after the cycle keyword.

Even though the SQL standard strictly requires the set and using sub-clauses, they are conceptually not required if the columns they define are not needed in the result. Some products do not support these sub-clauses at all. Note that skipping set has a logical impact: the duplicate rows cannot be filtered as shown in the where clause above. Therefore, skipping set may also imply not repeating the rows that close a cycle.

Normative References

The cycle clause is defined in ISO/IEC 9075:2016-2 as part of optional feature T131, “Recursive query”.

You can’t catch up on 20 years of SQL evolution in one day. Subscribe the newsletter via E-Mail, Twitter or RSS to gradually catch up and to keep modern-⁠sql.com on your radar.

About the Author

Photo of Markus Winand

Markus Winand provides insights into SQL and shows how different systems support it at modern-sql.com. Previously he made use-the-index-luke.com, which is still actively maintained. Markus can be hired as trainer, speaker and consultant via winand.at.

Buy the Book

Cover of “SQL Performance Explained”: Squirrel running on grass

The essence of SQL tuning in 200 pages

Buy now!
(paperback and/or PDF)

Paperback also available at Amazon.com.

Hire Markus

Markus offers SQL training and consulting for developers working at companies of all sizes.
Learn more »

Footnotes

  1. The to and default sub-clauses accept values of the types char(1) and boolean only.

Connect with Markus Winand

Markus Winand on LinkedInMarkus Winand on XINGMarkus Winand on Twitter
“modern SQL” by Markus Winand is licensed under a Creative Commons Attribution-Noncommercial-No Derivative Works 3.0 Unported License.
Legal | Contact | NO WARRANTY | Trademarks | Privacy and GDPR | CC-BY-NC-ND 3.0 license