Example: Full Outer Join Usage - Teradata Vantage

Teradata® VantageCloud Lake

Deployment
VantageCloud
Edition
Lake
Product
Teradata Vantage
Published
January 2023
ft:locale
en-US
ft:lastEdition
2024-12-11
dita:mapPath
phg1621910019905.ditamap
dita:ditavalPath
pny1626732985837.ditaval
dita:id
phg1621910019905

You cannot code a full outer join within the recursive statement of a recursive view definition.

Full outer joins can be used without restriction in the seed statement of a recursive view definition.

The first recursive view definition demonstrates a correct use of a full outer join, which is bold. The usage is valid because the full outer join is coded within the seed statement of the view definition.

    CREATE RECURSIVE VIEW rec (f1, mycount) AS (
      SELECT a1, 0 AS mycount
      FROM  nonrec1 FULL OUTER JOIN nonrec2 ON nonrec1.a1 = nonrec2.a2 
    UNION ALL
      SELECT a2, mycount + 1
      FROM nonrec, rec
      WHERE rec.mycount <= 100);

The second recursive view definition demonstrates a non-valid use of a full outer join, which is bold. The usage is not valid because the recursive relation in the recursive statement of the view definition is used as the inner relation in the full outer join.

    CREATE RECURSIVE VIEW rec (f1, mycount) AS (
      SELECT a1, 0 AS mycount
      FROM nonrec
    UNION ALL
      SELECT a2, mycount + 1
      FROM  nonrec FULL OUTER JOIN rec ON nonrec.a1 = rec.f1 
      WHERE rec.mycount <= 100);