From: Tom Lane <tgl@sss.pgh.pa.us>
Date: Sun, 5 Oct 2008 22:50:55 +0000 (+0000)
Subject: Improve behavior of WITH RECURSIVE with an untyped literal in the
X-Git-Tag: REL8_4_BETA1~917
X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=1e4b03847c95287a81d531ab2a249ad07081c767;p=postgresql

Improve behavior of WITH RECURSIVE with an untyped literal in the
non-recursive term.  Per an example from Dickson S. Guedes.
---

diff --git a/src/backend/parser/parse_cte.c b/src/backend/parser/parse_cte.c
index 64f5e51c28..29111acb96 100644
--- a/src/backend/parser/parse_cte.c
+++ b/src/backend/parser/parse_cte.c
@@ -8,12 +8,13 @@
  *
  *
  * IDENTIFICATION
- *	  $PostgreSQL: pgsql/src/backend/parser/parse_cte.c,v 2.1 2008/10/04 21:56:54 tgl Exp $
+ *	  $PostgreSQL: pgsql/src/backend/parser/parse_cte.c,v 2.2 2008/10/05 22:50:55 tgl Exp $
  *
  *-------------------------------------------------------------------------
  */
 #include "postgres.h"
 
+#include "catalog/pg_type.h"
 #include "nodes/nodeFuncs.h"
 #include "parser/analyze.h"
 #include "parser/parse_cte.h"
@@ -339,6 +340,8 @@ analyzeCTETargetList(ParseState *pstate, CommonTableExpr *cte, List *tlist)
 	foreach(tlistitem, tlist)
 	{
 		TargetEntry *te = (TargetEntry *) lfirst(tlistitem);
+		Oid			coltype;
+		int32		coltypmod;
 
 		if (te->resjunk)
 			continue;
@@ -351,10 +354,23 @@ analyzeCTETargetList(ParseState *pstate, CommonTableExpr *cte, List *tlist)
 			attrname = pstrdup(te->resname);
 			cte->ctecolnames = lappend(cte->ctecolnames, makeString(attrname));
 		}
-		cte->ctecoltypes = lappend_oid(cte->ctecoltypes,
-									   exprType((Node *) te->expr));
-		cte->ctecoltypmods = lappend_int(cte->ctecoltypmods,
-										 exprTypmod((Node *) te->expr));
+		coltype = exprType((Node *) te->expr);
+		coltypmod = exprTypmod((Node *) te->expr);
+		/*
+		 * If the CTE is recursive, force the exposed column type of any
+		 * "unknown" column to "text".  This corresponds to the fact that
+		 * SELECT 'foo' UNION SELECT 'bar' will ultimately produce text.
+		 * We might see "unknown" as a result of an untyped literal in
+		 * the non-recursive term's select list, and if we don't convert
+		 * to text then we'll have a mismatch against the UNION result.
+		 */
+		if (cte->cterecursive && coltype == UNKNOWNOID)
+		{
+			coltype = TEXTOID;
+			coltypmod = -1;		/* should be -1 already, but be sure */
+		}
+		cte->ctecoltypes = lappend_oid(cte->ctecoltypes, coltype);
+		cte->ctecoltypmods = lappend_int(cte->ctecoltypmods, coltypmod);
 	}
 	if (varattno < numaliases)
 		ereport(ERROR,
diff --git a/src/test/regress/expected/with.out b/src/test/regress/expected/with.out
index 65afc1a0c6..5b45ac89df 100644
--- a/src/test/regress/expected/with.out
+++ b/src/test/regress/expected/with.out
@@ -69,6 +69,30 @@ SELECT * FROM t LIMIT 10;
  10
 (10 rows)
 
+-- Test behavior with an unknown-type literal in the WITH
+WITH q AS (SELECT 'foo' AS x)
+SELECT x, x IS OF (unknown) as is_unknown FROM q;
+  x  | is_unknown 
+-----+------------
+ foo | t
+(1 row)
+
+WITH RECURSIVE t(n) AS (
+    SELECT 'foo'
+UNION ALL
+    SELECT n || ' bar' FROM t WHERE length(n) < 20
+)
+SELECT n, n IS OF (text) as is_text FROM t;
+            n            | is_text 
+-------------------------+---------
+ foo                     | t
+ foo bar                 | t
+ foo bar bar             | t
+ foo bar bar bar         | t
+ foo bar bar bar bar     | t
+ foo bar bar bar bar bar | t
+(6 rows)
+
 --
 -- Some examples with a tree
 --
diff --git a/src/test/regress/sql/with.sql b/src/test/regress/sql/with.sql
index cd8831f4b1..c3ff5e285a 100644
--- a/src/test/regress/sql/with.sql
+++ b/src/test/regress/sql/with.sql
@@ -38,6 +38,17 @@ UNION ALL
     SELECT n+1 FROM t)
 SELECT * FROM t LIMIT 10;
 
+-- Test behavior with an unknown-type literal in the WITH
+WITH q AS (SELECT 'foo' AS x)
+SELECT x, x IS OF (unknown) as is_unknown FROM q;
+
+WITH RECURSIVE t(n) AS (
+    SELECT 'foo'
+UNION ALL
+    SELECT n || ' bar' FROM t WHERE length(n) < 20
+)
+SELECT n, n IS OF (text) as is_text FROM t;
+
 --
 -- Some examples with a tree
 --