From 38bb4caa1e3839fbd88468fdad0764e23242480e Mon Sep 17 00:00:00 2001
From: Roman Khabibov <roman.habibov@tarantool.org>
Date: Mon, 29 Jul 2019 18:00:34 +0300
Subject: [PATCH] sql: allow to create view as <WITH> clause
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit

Allow views to use CTEs, which can be in any (nested) select after
<AS>. Before this patch, during view creation all referenced
spaces were fetched by name from SELECT and their reference
counters were incremented to avoid dangling references. It
occurred in update_view_references(). Obviously, CTE tables
weren't held in space cache, ergo error "space doesn’t exist" was
raised. Add check if a space from FROM is CTE. If it is, don't
increment its reference counter and don't raise the error.

Closes #4149
---
 src/box/alter.cc           | 10 ++++
 src/box/sql.h              | 13 ++++++
 src/box/sql/select.c       | 40 ++++++++++++++++
 test/sql-tap/view.test.lua | 94 +++++++++++++++++++++++++++++++++++++-
 4 files changed, 156 insertions(+), 1 deletion(-)

diff --git a/src/box/alter.cc b/src/box/alter.cc
index 499df1ca25..bb3686d6ef 100644
--- a/src/box/alter.cc
+++ b/src/box/alter.cc
@@ -1760,6 +1760,16 @@ update_view_references(struct Select *select, int update_value,
 		const char *space_name = sql_src_list_entry_name(list, i);
 		if (space_name == NULL)
 			continue;
+		/*
+		 * Views are allowed to contain CTEs. CTE is a
+		 * temporary object, created and destroyed at SQL
+		 * runtime (it is represented by an ephemeral
+		 * table). So, it is absent in space cache and as
+		 * a consequence we can't increment its reference
+		 * counter. Skip iteration.
+		 */
+		if (sql_select_constains_cte(select, space_name))
+			continue;
 		struct space *space = space_by_name(space_name);
 		if (space == NULL) {
 			if (! suppress_error) {
diff --git a/src/box/sql.h b/src/box/sql.h
index 7644051b4f..0fa52fc0bf 100644
--- a/src/box/sql.h
+++ b/src/box/sql.h
@@ -323,6 +323,19 @@ sql_select_delete(struct sql *db, struct Select *select);
 struct SrcList *
 sql_select_expand_from_tables(struct Select *select);
 
+/**
+ * Check if @a name matches with at least one of CTE names typed
+ * in <WITH> clauses within @a select except <WITH>s that are
+ * nested within other <WITH>s.
+ *
+ * @param select Select which may contain CTE.
+ * @param name The name of CTE, that may contained.
+ * @retval true Has CTE with @a name.
+ * @retval false Hasn't CTE with @a name.
+*/
+bool
+sql_select_constains_cte(struct Select *select, const char *name);
+
 /**
  * Temporary getter in order to avoid including sqlInt.h
  * in alter.cc.
diff --git a/src/box/sql/select.c b/src/box/sql/select.c
index cdcdbaf2b8..8f93edd169 100644
--- a/src/box/sql/select.c
+++ b/src/box/sql/select.c
@@ -332,6 +332,46 @@ sql_select_expand_from_tables(struct Select *select)
 	return walker.u.pSrcList;
 }
 
+bool
+sql_select_constains_cte(struct Select *select, const char *name)
+{
+	assert(select != NULL && name != NULL);
+	struct With *with = select->pWith;
+	if (with != NULL) {
+		for (int i = 0; i < with->nCte; i++) {
+			const struct Cte *cte = &with->a[i];
+			/*
+			 * Don't use recursive call for
+			 * cte->pSelect, because this function is
+			 * used during view creation. Consider
+			 * the nested <WITH>s query schema:
+			 * CREATE VIEW v AS
+			 *     WITH w AS (
+			 *         WITH w_nested AS
+			 *             (...)
+			 *         SELECT ...)
+			 *     SELECT ... FROM ...;
+			 * The use of CTE "w_nested" after the
+			 * external select's <FROM> is disallowed.
+			 * So, it is pointless to check <WITH>,
+			 * which is nested to other <WITH>.
+			 */
+			if (memcmp(name, cte->zName, strlen(name)) == 0)
+				return true;
+		}
+	}
+	struct SrcList *list = select->pSrc;
+	int item_count = sql_src_list_entry_count(list);
+	for (int i = 0; i < item_count; ++i) {
+		if (list->a[i].pSelect != NULL) {
+			if (sql_select_constains_cte(list->a[i].pSelect,
+							 name))
+				return true;
+		}
+	}
+	return false;
+}
+
 /*
  * Given 1 to 3 identifiers preceding the JOIN keyword, determine the
  * type of join.  Return an integer constant that expresses that type
diff --git a/test/sql-tap/view.test.lua b/test/sql-tap/view.test.lua
index 101f4c3e74..6234f863eb 100755
--- a/test/sql-tap/view.test.lua
+++ b/test/sql-tap/view.test.lua
@@ -1,6 +1,6 @@
 #!/usr/bin/env tarantool
 test = require("sqltester")
-test:plan(73)
+test:plan(78)
 
 --!./tcltestrunner.lua
 -- 2002 February 26
@@ -1233,4 +1233,96 @@ test:do_catchsql_test(
         -- </view-23.8>
     })
 
+-- gh-4149: Make sure that VIEW can be created as CTE.
+test:do_execsql_test(
+    "view-24.1",
+    [[
+        CREATE TABLE ts (s1 INT PRIMARY KEY);
+        INSERT INTO ts VALUES (1);
+    ]], {
+        -- <view-24.1>
+        -- </view-24.1>
+    })
+
+test:do_execsql_test(
+    "view-24.2",
+    [[
+        CREATE VIEW v AS WITH w(id) AS (
+            SELECT 1)
+          SELECT * FROM ts, w;
+        SELECT * FROM v;
+    ]], {
+        -- <view-24.2>
+        1, 1
+        -- </view-24.2>
+    })
+
+test:do_execsql_test(
+    "view-24.3",
+    [[
+        DROP VIEW v;
+        CREATE VIEW v AS WITH RECURSIVE w AS (
+            SELECT s1 FROM ts
+            UNION ALL
+            SELECT s1+1 FROM w WHERE s1 < 4)
+          SELECT * FROM w;
+        SELECT * FROM v;
+    ]], {
+        -- <view-24.3>
+        1,2,3,4
+        -- </view-24.3>
+    })
+
+test:do_execsql_test(
+    "view-24.4",
+    [[
+        DROP VIEW v;
+        CREATE VIEW v AS SELECT * FROM
+            (SELECT 1),
+            (SELECT 2) JOIN
+            (WITH RECURSIVE w AS (
+                SELECT s1 FROM ts
+                UNION ALL
+                SELECT s1+1 FROM w WHERE s1 < 4)
+              SELECT * FROM w);
+          SELECT * FROM v;
+    ]], {
+        -- <view-24.4>
+        1,2,1,1,2,2,1,2,3,1,2,4
+        -- </view-24.4>
+    })
+
+test:do_execsql_test(
+    "view-24.5",
+    [[
+        DROP VIEW v;
+        DROP TABLE ts;
+        CREATE VIEW v AS WITH RECURSIVE
+            xaxis(x) AS (
+                VALUES(-2.0)
+                UNION ALL
+                SELECT x+0.5 FROM xaxis WHERE x<1.2),
+            yaxis(y) AS (
+                VALUES(-1.0)
+                UNION ALL
+                SELECT y+0.5 FROM yaxis WHERE y<1.0),
+            m(iter, cx, cy, x, y) AS (
+                SELECT 0, x, y, 0.0, 0.0 FROM xaxis, yaxis
+                UNION ALL
+                SELECT iter+1, cx, cy, x*x-y*y + cx, 2.0*x*y + cy FROM m WHERE (x*x + y*y) < 4.0 AND iter<1
+            ),
+            m2(iter, cx, cy) AS (
+            SELECT max(iter), cx, cy FROM m GROUP BY cx, cy
+            ),
+            a(t) AS (
+                SELECT group_concat( substr('a', 1+least(iter/7,4), 1), '') FROM m2 GROUP BY cy
+            )
+          SELECT group_concat(trim(t),x'0a') FROM a;
+        SELECT * FROM v;
+    ]], {
+        -- <view-24.5>
+        "aaaaaaaa\naaaaaaaa\naaaaaaaa\naaaaaaaa\naaaaaaaa"
+        -- </view-24.5>
+    })
+
 test:finish_test()
-- 
GitLab