- No
using …sub-clause - 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
toanddefaultsub-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 defaultsto false default true.0USING <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
cyclekeyword.
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.
Related
Break cycles if all columns have a repeated value:
with recursive (… union [distinct] …)Search depth/breadth first: Compute an Extra Column to Order the Result of Recursive QueriesIf both are present,
searchandcycle,searchmust be first.Tutorial:
With— Organize Complex Queries
Normative References
The cycle clause is defined in ISO/IEC 9075-2:2023 §7.18 as part of optional feature T131, “Recursive query”.

