Db2 (LUW and z) have some surprising limitations regarding recursive with clauses (documentation). The respective error message in all its glory:
The fullselect of the recursive common table expression name must be the UNION of two or more fullselects and cannot include column functions, GROUP BY clause, HAVING clause, ORDER BY clause, or an explicit join including an ON clause.
Among them is the inability to use the on clause in the recursive leg, which is commonly required when processing hierarchical structures.
WITH prev (id, parent) AS (
SELECT t.id, t.parent
FROM hierarchy t
WHERE t.id = ?
UNION ALL
SELECT t.id, t.parent
FROM hierarchy t
JOIN prev ON t.parent = prev.id
)
In case all you need is an inner join, the limitation can be bypassed with an implicit cross join using a comma (,) and moving the on condition to the where clause:
WITH prev (id, parent) AS (
SELECT t.id, t.parent
FROM hierarchy t
WHERE t.id = ?
UNION ALL
SELECT t.id, t.parent
FROM hierarchy t
, prev
WHERE t.parent = prev.id
)
In the simple case above the keyword join has been replaced by a comma (,) and the on by where.

