Added tests

This commit is contained in:
Maksim Kita 2024-04-06 21:02:20 +03:00
parent 06d2c18f26
commit 126f3692cb
18 changed files with 2125 additions and 0 deletions

View File

@ -0,0 +1,97 @@
-- { echoOn }
WITH RECURSIVE recursive_cte AS (SELECT 1 AS n UNION ALL SELECT n + 1 FROM recursive_cte WHERE n < 10)
SELECT n FROM recursive_cte;
1
2
3
4
5
6
7
8
9
10
SELECT '--';
--
WITH RECURSIVE recursive_cte AS (SELECT toUInt8(1) AS n UNION ALL SELECT toUInt8(n + 1) FROM recursive_cte WHERE n < 10)
SELECT n FROM recursive_cte;
1
2
3
4
5
6
7
8
9
10
SELECT '--';
--
WITH RECURSIVE recursive_cte AS (SELECT toUInt16(1) AS n UNION ALL SELECT toUInt8(n + 1) FROM recursive_cte WHERE n < 10)
SELECT n FROM recursive_cte;
1
2
3
4
5
6
7
8
9
10
SELECT '--';
--
WITH RECURSIVE recursive_cte AS (SELECT materialize(toUInt16(1)) AS n UNION ALL SELECT toUInt8(n + 1) FROM recursive_cte WHERE n < 10)
SELECT n FROM recursive_cte;
1
2
3
4
5
6
7
8
9
10
SELECT '--';
--
WITH RECURSIVE recursive_cte AS (SELECT toUInt16(1) AS n UNION ALL SELECT materialize(toUInt8(n + 1)) FROM recursive_cte WHERE n < 10)
SELECT n FROM recursive_cte;
1
2
3
4
5
6
7
8
9
10
SELECT '--';
--
WITH RECURSIVE recursive_cte AS (SELECT toUInt16(1) AS n, '1' AS concat UNION ALL SELECT materialize(toUInt8(n + 1)), concat || toString(n + 1) FROM recursive_cte WHERE n < 10)
SELECT n, concat FROM recursive_cte;
1 1
2 12
3 123
4 1234
5 12345
6 123456
7 1234567
8 12345678
9 123456789
10 12345678910
SELECT '--';
--
WITH RECURSIVE recursive_cte AS (SELECT 1 AS n UNION ALL SELECT n + 1 FROM recursive_cte)
SELECT n FROM recursive_cte LIMIT 5;
1
2
3
4
5
SELECT '--';
--
WITH RECURSIVE recursive_cte AS (SELECT materialize(toUInt8(1)) AS n UNION ALL SELECT materialize(toUInt8(n + 1)) FROM recursive_cte WHERE n < 10)
SELECT n FROM recursive_cte FORMAT Null SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }

View File

@ -0,0 +1,41 @@
-- { echoOn }
WITH RECURSIVE recursive_cte AS (SELECT 1 AS n UNION ALL SELECT n + 1 FROM recursive_cte WHERE n < 10)
SELECT n FROM recursive_cte;
SELECT '--';
WITH RECURSIVE recursive_cte AS (SELECT toUInt8(1) AS n UNION ALL SELECT toUInt8(n + 1) FROM recursive_cte WHERE n < 10)
SELECT n FROM recursive_cte;
SELECT '--';
WITH RECURSIVE recursive_cte AS (SELECT toUInt16(1) AS n UNION ALL SELECT toUInt8(n + 1) FROM recursive_cte WHERE n < 10)
SELECT n FROM recursive_cte;
SELECT '--';
WITH RECURSIVE recursive_cte AS (SELECT materialize(toUInt16(1)) AS n UNION ALL SELECT toUInt8(n + 1) FROM recursive_cte WHERE n < 10)
SELECT n FROM recursive_cte;
SELECT '--';
WITH RECURSIVE recursive_cte AS (SELECT toUInt16(1) AS n UNION ALL SELECT materialize(toUInt8(n + 1)) FROM recursive_cte WHERE n < 10)
SELECT n FROM recursive_cte;
SELECT '--';
WITH RECURSIVE recursive_cte AS (SELECT toUInt16(1) AS n, '1' AS concat UNION ALL SELECT materialize(toUInt8(n + 1)), concat || toString(n + 1) FROM recursive_cte WHERE n < 10)
SELECT n, concat FROM recursive_cte;
SELECT '--';
WITH RECURSIVE recursive_cte AS (SELECT 1 AS n UNION ALL SELECT n + 1 FROM recursive_cte)
SELECT n FROM recursive_cte LIMIT 5;
SELECT '--';
WITH RECURSIVE recursive_cte AS (SELECT materialize(toUInt8(1)) AS n UNION ALL SELECT materialize(toUInt8(n + 1)) FROM recursive_cte WHERE n < 10)
SELECT n FROM recursive_cte FORMAT Null SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- { echoOff }

View File

@ -0,0 +1,9 @@
0 \N ROOT
1 0 Child_1
2 0 Child_2
3 1 Child_1_1
--
0 \N ROOT [0]
1 0 Child_1 [0,1]
2 0 Child_2 [0,2]
3 1 Child_1_1 [0,1,3]

View File

@ -0,0 +1,35 @@
DROP TABLE IF EXISTS tree;
CREATE TABLE tree
(
id UInt64,
link Nullable(UInt64),
data String
) ENGINE=TinyLog;
INSERT INTO tree VALUES (0, NULL, 'ROOT'), (1, 0, 'Child_1'), (2, 0, 'Child_2'), (3, 1, 'Child_1_1');
WITH RECURSIVE search_tree AS (
SELECT id, link, data
FROM tree t
WHERE t.id = 0
UNION ALL
SELECT t.id, t.link, t.data
FROM tree t, search_tree st
WHERE t.link = st.id
)
SELECT * FROM search_tree;
SELECT '--';
WITH RECURSIVE search_tree AS (
SELECT id, link, data, [t.id] AS path
FROM tree t
WHERE t.id = 0
UNION ALL
SELECT t.id, t.link, t.data, arrayConcat(path, [t.id])
FROM tree t, search_tree st
WHERE t.link = st.id
)
SELECT * FROM search_tree;
DROP TABLE tree;

View File

@ -0,0 +1,109 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
-- WITH RECURSIVE
-- sum of 1..100
WITH RECURSIVE t AS (
SELECT 1 AS n
UNION ALL
SELECT n+1 FROM t WHERE n < 100
)
SELECT sum(n) FROM t;
5050
WITH RECURSIVE t AS (
SELECT 1 AS n
UNION ALL
SELECT n+1 FROM t WHERE n < 5
)
SELECT * FROM t;
1
2
3
4
5
-- This'd be an infinite loop, but outside query reads only as much as needed
WITH RECURSIVE t AS (
SELECT 1 AS n
UNION ALL
SELECT n+1 FROM t)
SELECT * FROM t LIMIT 10;
1
2
3
4
5
6
7
8
9
10
WITH RECURSIVE t AS (
SELECT 'foo' AS n
UNION ALL
SELECT n || ' bar' FROM t WHERE length(n) < 20
)
SELECT n, toTypeName(n) FROM t;
foo String
foo bar String
foo bar bar String
foo bar bar bar String
foo bar bar bar bar String
foo bar bar bar bar bar String
WITH RECURSIVE t AS (
SELECT '7' AS n
UNION ALL
SELECT n+1 FROM t WHERE n < 10
)
SELECT n, toTypeName(n) FROM t; -- { serverError ILLEGAL_TYPE_OF_ARGUMENT }
-- Deeply nested WITH caused a list-munging problem in v13
-- Detection of cross-references and self-references
WITH RECURSIVE w1 AS
(WITH w2 AS
(WITH w3 AS
(WITH w4 AS
(WITH w5 AS
(WITH RECURSIVE w6 AS
(WITH w7 AS
(WITH w8 AS
(SELECT 1)
SELECT * FROM w8)
SELECT * FROM w7)
SELECT * FROM w6)
SELECT * FROM w5)
SELECT * FROM w4)
SELECT * FROM w3)
SELECT * FROM w2)
SELECT * FROM w1;
1

View File

@ -0,0 +1,93 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
-- WITH RECURSIVE
-- sum of 1..100
WITH RECURSIVE t AS (
SELECT 1 AS n
UNION ALL
SELECT n+1 FROM t WHERE n < 100
)
SELECT sum(n) FROM t;
WITH RECURSIVE t AS (
SELECT 1 AS n
UNION ALL
SELECT n+1 FROM t WHERE n < 5
)
SELECT * FROM t;
-- This'd be an infinite loop, but outside query reads only as much as needed
WITH RECURSIVE t AS (
SELECT 1 AS n
UNION ALL
SELECT n+1 FROM t)
SELECT * FROM t LIMIT 10;
WITH RECURSIVE t AS (
SELECT 'foo' AS n
UNION ALL
SELECT n || ' bar' FROM t WHERE length(n) < 20
)
SELECT n, toTypeName(n) FROM t;
WITH RECURSIVE t AS (
SELECT '7' AS n
UNION ALL
SELECT n+1 FROM t WHERE n < 10
)
SELECT n, toTypeName(n) FROM t; -- { serverError ILLEGAL_TYPE_OF_ARGUMENT }
-- Deeply nested WITH caused a list-munging problem in v13
-- Detection of cross-references and self-references
WITH RECURSIVE w1 AS
(WITH w2 AS
(WITH w3 AS
(WITH w4 AS
(WITH w5 AS
(WITH RECURSIVE w6 AS
(WITH w7 AS
(WITH w8 AS
(SELECT 1)
SELECT * FROM w8)
SELECT * FROM w7)
SELECT * FROM w6)
SELECT * FROM w5)
SELECT * FROM w4)
SELECT * FROM w3)
SELECT * FROM w2)
SELECT * FROM w1;
-- { echoOff }

View File

@ -0,0 +1,223 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
--
-- Some examples with a tree
--
-- department structure represented here is as follows:
--
-- ROOT-+->A-+->B-+->C
-- | |
-- | +->D-+->F
-- +->E-+->G
DROP TABLE IF EXISTS department;
CREATE TABLE department (
id UInt64, -- department ID
parent_department UInt64, -- upper department ID
name String -- department name
)
ENGINE=TinyLog;
INSERT INTO department VALUES (0, NULL, 'ROOT');
INSERT INTO department VALUES (1, 0, 'A');
INSERT INTO department VALUES (2, 1, 'B');
INSERT INTO department VALUES (3, 2, 'C');
INSERT INTO department VALUES (4, 2, 'D');
INSERT INTO department VALUES (5, 0, 'E');
INSERT INTO department VALUES (6, 4, 'F');
INSERT INTO department VALUES (7, 5, 'G');
-- extract all departments under 'A'. Result should be A, B, C, D and F
WITH RECURSIVE subdepartment AS
(
-- non recursive term
SELECT name as root_name, * FROM department WHERE name = 'A'
UNION ALL
-- recursive term
SELECT sd.root_name, d.* FROM department AS d, subdepartment AS sd
WHERE d.parent_department = sd.id
)
SELECT * FROM subdepartment ORDER BY name;
A 1 0 A
A 2 1 B
A 3 2 C
A 4 2 D
A 6 4 F
-- extract all departments under 'A' with "level" number
WITH RECURSIVE subdepartment AS
(
-- non recursive term
SELECT 1 AS level, * FROM department WHERE name = 'A'
UNION ALL
-- recursive term
SELECT sd.level + 1, d.* FROM department AS d, subdepartment AS sd
WHERE d.parent_department = sd.id
)
SELECT * FROM subdepartment ORDER BY name;
1 1 0 A
2 2 1 B
3 3 2 C
3 4 2 D
4 6 4 F
-- extract all departments under 'A' with "level" number.
-- Only shows level 2 or more
WITH RECURSIVE subdepartment AS
(
-- non recursive term
SELECT 1 AS level, * FROM department WHERE name = 'A'
UNION ALL
-- recursive term
SELECT sd.level + 1, d.* FROM department AS d, subdepartment AS sd
WHERE d.parent_department = sd.id
)
SELECT * FROM subdepartment WHERE level >= 2 ORDER BY name;
2 2 1 B
3 3 2 C
3 4 2 D
4 6 4 F
-- "RECURSIVE" is ignored if the query has no self-reference
WITH RECURSIVE subdepartment AS
(
-- note lack of recursive UNION structure
SELECT * FROM department WHERE name = 'A'
)
SELECT * FROM subdepartment ORDER BY name;
1 0 A
-- inside subqueries
SELECT count(*) FROM
(
WITH RECURSIVE t AS (
SELECT toUInt64(1) AS n UNION ALL SELECT n + 1 FROM t WHERE n < 500
)
SELECT * FROM t
) AS t WHERE n < (
SELECT count(*) FROM (
WITH RECURSIVE t AS (
SELECT toUInt64(1) AS n UNION ALL SELECT n + 1 FROM t WHERE n < 100
)
SELECT * FROM t WHERE n < 50000
) AS t WHERE n < 100);
98
-- corner case in which sub-WITH gets initialized first
WITH RECURSIVE q AS (
SELECT * FROM department
UNION ALL
(WITH x AS (SELECT * FROM q)
SELECT * FROM x)
)
SELECT * FROM q LIMIT 24;
0 0 ROOT
1 0 A
2 1 B
3 2 C
4 2 D
5 0 E
6 4 F
7 5 G
0 0 ROOT
1 0 A
2 1 B
3 2 C
4 2 D
5 0 E
6 4 F
7 5 G
0 0 ROOT
1 0 A
2 1 B
3 2 C
4 2 D
5 0 E
6 4 F
7 5 G
WITH RECURSIVE q AS (
SELECT * FROM department
UNION ALL
(WITH RECURSIVE x AS (
SELECT * FROM department
UNION ALL
(SELECT * FROM q UNION ALL SELECT * FROM x)
)
SELECT * FROM x)
)
SELECT * FROM q LIMIT 32;
0 0 ROOT
1 0 A
2 1 B
3 2 C
4 2 D
5 0 E
6 4 F
7 5 G
0 0 ROOT
1 0 A
2 1 B
3 2 C
4 2 D
5 0 E
6 4 F
7 5 G
0 0 ROOT
1 0 A
2 1 B
3 2 C
4 2 D
5 0 E
6 4 F
7 5 G
0 0 ROOT
1 0 A
2 1 B
3 2 C
4 2 D
5 0 E
6 4 F
7 5 G
-- recursive term has sub-UNION
WITH RECURSIVE t AS (
SELECT 1 AS i, 2 AS j
UNION ALL
SELECT t2.i, t.j+1 FROM
(SELECT 2 AS i UNION ALL SELECT 3 AS i) AS t2
JOIN t ON (t2.i = t.i+1))
SELECT * FROM t;
1 2
2 3
3 4

View File

@ -0,0 +1,160 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
--
-- Some examples with a tree
--
-- department structure represented here is as follows:
--
-- ROOT-+->A-+->B-+->C
-- | |
-- | +->D-+->F
-- +->E-+->G
DROP TABLE IF EXISTS department;
CREATE TABLE department (
id UInt64, -- department ID
parent_department UInt64, -- upper department ID
name String -- department name
)
ENGINE=TinyLog;
INSERT INTO department VALUES (0, NULL, 'ROOT');
INSERT INTO department VALUES (1, 0, 'A');
INSERT INTO department VALUES (2, 1, 'B');
INSERT INTO department VALUES (3, 2, 'C');
INSERT INTO department VALUES (4, 2, 'D');
INSERT INTO department VALUES (5, 0, 'E');
INSERT INTO department VALUES (6, 4, 'F');
INSERT INTO department VALUES (7, 5, 'G');
-- extract all departments under 'A'. Result should be A, B, C, D and F
WITH RECURSIVE subdepartment AS
(
-- non recursive term
SELECT name as root_name, * FROM department WHERE name = 'A'
UNION ALL
-- recursive term
SELECT sd.root_name, d.* FROM department AS d, subdepartment AS sd
WHERE d.parent_department = sd.id
)
SELECT * FROM subdepartment ORDER BY name;
-- extract all departments under 'A' with "level" number
WITH RECURSIVE subdepartment AS
(
-- non recursive term
SELECT 1 AS level, * FROM department WHERE name = 'A'
UNION ALL
-- recursive term
SELECT sd.level + 1, d.* FROM department AS d, subdepartment AS sd
WHERE d.parent_department = sd.id
)
SELECT * FROM subdepartment ORDER BY name;
-- extract all departments under 'A' with "level" number.
-- Only shows level 2 or more
WITH RECURSIVE subdepartment AS
(
-- non recursive term
SELECT 1 AS level, * FROM department WHERE name = 'A'
UNION ALL
-- recursive term
SELECT sd.level + 1, d.* FROM department AS d, subdepartment AS sd
WHERE d.parent_department = sd.id
)
SELECT * FROM subdepartment WHERE level >= 2 ORDER BY name;
-- "RECURSIVE" is ignored if the query has no self-reference
WITH RECURSIVE subdepartment AS
(
-- note lack of recursive UNION structure
SELECT * FROM department WHERE name = 'A'
)
SELECT * FROM subdepartment ORDER BY name;
-- inside subqueries
SELECT count(*) FROM
(
WITH RECURSIVE t AS (
SELECT toUInt64(1) AS n UNION ALL SELECT n + 1 FROM t WHERE n < 500
)
SELECT * FROM t
) AS t WHERE n < (
SELECT count(*) FROM (
WITH RECURSIVE t AS (
SELECT toUInt64(1) AS n UNION ALL SELECT n + 1 FROM t WHERE n < 100
)
SELECT * FROM t WHERE n < 50000
) AS t WHERE n < 100);
-- corner case in which sub-WITH gets initialized first
WITH RECURSIVE q AS (
SELECT * FROM department
UNION ALL
(WITH x AS (SELECT * FROM q)
SELECT * FROM x)
)
SELECT * FROM q LIMIT 24;
WITH RECURSIVE q AS (
SELECT * FROM department
UNION ALL
(WITH RECURSIVE x AS (
SELECT * FROM department
UNION ALL
(SELECT * FROM q UNION ALL SELECT * FROM x)
)
SELECT * FROM x)
)
SELECT * FROM q LIMIT 32;
-- recursive term has sub-UNION
WITH RECURSIVE t AS (
SELECT 1 AS i, 2 AS j
UNION ALL
SELECT t2.i, t.j+1 FROM
(SELECT 2 AS i UNION ALL SELECT 3 AS i) AS t2
JOIN t ON (t2.i = t.i+1))
SELECT * FROM t;
-- { echoOff }

View File

@ -0,0 +1,112 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
--
-- different tree example
--
DROP TABLE IF EXISTS tree;
CREATE TABLE tree(
id UInt64,
parent_id Nullable(UInt64)
)
ENGINE=TinyLog;
INSERT INTO tree
VALUES (1, NULL), (2, 1), (3,1), (4,2), (5,2), (6,2), (7,3), (8,3), (9,4), (10,4), (11,7), (12,7), (13,7), (14, 9), (15,11), (16,11);
--
-- get all paths from "second level" nodes to leaf nodes
--
WITH RECURSIVE t AS (
SELECT 1 AS id, []::Array(UInt64) AS path
UNION ALL
SELECT tree.id, arrayConcat(t.path, [tree.id])
FROM tree JOIN t ON (tree.parent_id = t.id)
)
SELECT t1.*, t2.* FROM t AS t1 JOIN t AS t2 ON
(t1.path[1] = t2.path[1] AND
length(t1.path) = 1 AND
length(t2.path) > 1)
ORDER BY t1.id, t2.id;
2 [2] 4 [2,4]
2 [2] 5 [2,5]
2 [2] 6 [2,6]
2 [2] 9 [2,4,9]
2 [2] 10 [2,4,10]
2 [2] 14 [2,4,9,14]
3 [3] 7 [3,7]
3 [3] 8 [3,8]
3 [3] 11 [3,7,11]
3 [3] 12 [3,7,12]
3 [3] 13 [3,7,13]
3 [3] 15 [3,7,11,15]
3 [3] 16 [3,7,11,16]
-- just count 'em
WITH RECURSIVE t AS (
SELECT 1 AS id, []::Array(UInt64) AS path
UNION ALL
SELECT tree.id, arrayConcat(t.path, [tree.id])
FROM tree JOIN t ON (tree.parent_id = t.id)
)
SELECT t1.id, count(t2.path) FROM t AS t1 JOIN t AS t2 ON
(t1.path[1] = t2.path[1] AND
length(t1.path) = 1 AND
length(t2.path) > 1)
GROUP BY t1.id
ORDER BY t1.id;
2 6
3 7
-- -- this variant tickled a whole-row-variable bug in 8.4devel
WITH RECURSIVE t AS (
SELECT 1 AS id, []::Array(UInt64) AS path
UNION ALL
SELECT tree.id, arrayConcat(t.path, [tree.id])
FROM tree JOIN t ON (tree.parent_id = t.id)
)
SELECT t1.id, t2.path, tuple(t2.*) FROM t AS t1 JOIN t AS t2 ON
(t1.id=t2.id);
1 [] (1,[])
2 [2] (2,[2])
3 [3] (3,[3])
4 [2,4] (4,[2,4])
5 [2,5] (5,[2,5])
6 [2,6] (6,[2,6])
7 [3,7] (7,[3,7])
8 [3,8] (8,[3,8])
9 [2,4,9] (9,[2,4,9])
10 [2,4,10] (10,[2,4,10])
11 [3,7,11] (11,[3,7,11])
12 [3,7,12] (12,[3,7,12])
13 [3,7,13] (13,[3,7,13])
14 [2,4,9,14] (14,[2,4,9,14])
15 [3,7,11,15] (15,[3,7,11,15])
16 [3,7,11,16] (16,[3,7,11,16])

View File

@ -0,0 +1,87 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
--
-- different tree example
--
DROP TABLE IF EXISTS tree;
CREATE TABLE tree(
id UInt64,
parent_id Nullable(UInt64)
)
ENGINE=TinyLog;
INSERT INTO tree
VALUES (1, NULL), (2, 1), (3,1), (4,2), (5,2), (6,2), (7,3), (8,3), (9,4), (10,4), (11,7), (12,7), (13,7), (14, 9), (15,11), (16,11);
--
-- get all paths from "second level" nodes to leaf nodes
--
WITH RECURSIVE t AS (
SELECT 1 AS id, []::Array(UInt64) AS path
UNION ALL
SELECT tree.id, arrayConcat(t.path, [tree.id])
FROM tree JOIN t ON (tree.parent_id = t.id)
)
SELECT t1.*, t2.* FROM t AS t1 JOIN t AS t2 ON
(t1.path[1] = t2.path[1] AND
length(t1.path) = 1 AND
length(t2.path) > 1)
ORDER BY t1.id, t2.id;
-- just count 'em
WITH RECURSIVE t AS (
SELECT 1 AS id, []::Array(UInt64) AS path
UNION ALL
SELECT tree.id, arrayConcat(t.path, [tree.id])
FROM tree JOIN t ON (tree.parent_id = t.id)
)
SELECT t1.id, count(t2.path) FROM t AS t1 JOIN t AS t2 ON
(t1.path[1] = t2.path[1] AND
length(t1.path) = 1 AND
length(t2.path) > 1)
GROUP BY t1.id
ORDER BY t1.id;
-- -- this variant tickled a whole-row-variable bug in 8.4devel
WITH RECURSIVE t AS (
SELECT 1 AS id, []::Array(UInt64) AS path
UNION ALL
SELECT tree.id, arrayConcat(t.path, [tree.id])
FROM tree JOIN t ON (tree.parent_id = t.id)
)
SELECT t1.id, t2.path, tuple(t2.*) FROM t AS t1 JOIN t AS t2 ON
(t1.id=t2.id);
-- { echoOff }

View File

@ -0,0 +1,113 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
--
-- test cycle detection
--
DROP TABLE IF EXISTS graph;
CREATE TABLE graph(
f UInt64,
t UInt64,
label String
)
ENGINE = TinyLog;
INSERT INTO graph VALUES (1, 2, 'arc 1 -> 2'), (1, 3, 'arc 1 -> 3'), (2, 3, 'arc 2 -> 3'), (1, 4, 'arc 1 -> 4'), (4, 5, 'arc 4 -> 5'), (5, 1, 'arc 5 -> 1');
WITH RECURSIVE search_graph AS (
SELECT *, false AS is_cycle, [tuple(g.f, g.t)] AS path FROM graph g
UNION ALL
SELECT g.*, has(path, tuple(g.f, g.t)), arrayConcat(sg.path, [tuple(g.f, g.t)])
FROM graph g, search_graph sg
WHERE g.f = sg.t AND NOT is_cycle
)
SELECT * FROM search_graph;
1 2 arc 1 -> 2 false [(1,2)]
1 3 arc 1 -> 3 false [(1,3)]
2 3 arc 2 -> 3 false [(2,3)]
1 4 arc 1 -> 4 false [(1,4)]
4 5 arc 4 -> 5 false [(4,5)]
5 1 arc 5 -> 1 false [(5,1)]
1 2 arc 1 -> 2 false [(5,1),(1,2)]
1 3 arc 1 -> 3 false [(5,1),(1,3)]
2 3 arc 2 -> 3 false [(1,2),(2,3)]
1 4 arc 1 -> 4 false [(5,1),(1,4)]
4 5 arc 4 -> 5 false [(1,4),(4,5)]
5 1 arc 5 -> 1 false [(4,5),(5,1)]
1 2 arc 1 -> 2 false [(4,5),(5,1),(1,2)]
1 3 arc 1 -> 3 false [(4,5),(5,1),(1,3)]
2 3 arc 2 -> 3 false [(5,1),(1,2),(2,3)]
1 4 arc 1 -> 4 false [(4,5),(5,1),(1,4)]
4 5 arc 4 -> 5 false [(5,1),(1,4),(4,5)]
5 1 arc 5 -> 1 false [(1,4),(4,5),(5,1)]
1 2 arc 1 -> 2 false [(1,4),(4,5),(5,1),(1,2)]
1 3 arc 1 -> 3 false [(1,4),(4,5),(5,1),(1,3)]
2 3 arc 2 -> 3 false [(4,5),(5,1),(1,2),(2,3)]
1 4 arc 1 -> 4 true [(1,4),(4,5),(5,1),(1,4)]
4 5 arc 4 -> 5 true [(4,5),(5,1),(1,4),(4,5)]
5 1 arc 5 -> 1 true [(5,1),(1,4),(4,5),(5,1)]
2 3 arc 2 -> 3 false [(1,4),(4,5),(5,1),(1,2),(2,3)]
-- ordering by the path column has same effect as SEARCH DEPTH FIRST
WITH RECURSIVE search_graph AS (
SELECT *, false AS is_cycle, [tuple(g.f, g.t)] AS path FROM graph g
UNION ALL
SELECT g.*, has(path, tuple(g.f, g.t)), arrayConcat(sg.path, [tuple(g.f, g.t)])
FROM graph g, search_graph sg
WHERE g.f = sg.t AND NOT is_cycle
)
SELECT * FROM search_graph ORDER BY path;
1 2 arc 1 -> 2 false [(1,2)]
2 3 arc 2 -> 3 false [(1,2),(2,3)]
1 3 arc 1 -> 3 false [(1,3)]
1 4 arc 1 -> 4 false [(1,4)]
4 5 arc 4 -> 5 false [(1,4),(4,5)]
5 1 arc 5 -> 1 false [(1,4),(4,5),(5,1)]
1 2 arc 1 -> 2 false [(1,4),(4,5),(5,1),(1,2)]
2 3 arc 2 -> 3 false [(1,4),(4,5),(5,1),(1,2),(2,3)]
1 3 arc 1 -> 3 false [(1,4),(4,5),(5,1),(1,3)]
1 4 arc 1 -> 4 true [(1,4),(4,5),(5,1),(1,4)]
2 3 arc 2 -> 3 false [(2,3)]
4 5 arc 4 -> 5 false [(4,5)]
5 1 arc 5 -> 1 false [(4,5),(5,1)]
1 2 arc 1 -> 2 false [(4,5),(5,1),(1,2)]
2 3 arc 2 -> 3 false [(4,5),(5,1),(1,2),(2,3)]
1 3 arc 1 -> 3 false [(4,5),(5,1),(1,3)]
1 4 arc 1 -> 4 false [(4,5),(5,1),(1,4)]
4 5 arc 4 -> 5 true [(4,5),(5,1),(1,4),(4,5)]
5 1 arc 5 -> 1 false [(5,1)]
1 2 arc 1 -> 2 false [(5,1),(1,2)]
2 3 arc 2 -> 3 false [(5,1),(1,2),(2,3)]
1 3 arc 1 -> 3 false [(5,1),(1,3)]
1 4 arc 1 -> 4 false [(5,1),(1,4)]
4 5 arc 4 -> 5 false [(5,1),(1,4),(4,5)]
5 1 arc 5 -> 1 true [(5,1),(1,4),(4,5),(5,1)]

View File

@ -0,0 +1,68 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
--
-- test cycle detection
--
DROP TABLE IF EXISTS graph;
CREATE TABLE graph(
f UInt64,
t UInt64,
label String
)
ENGINE = TinyLog;
INSERT INTO graph VALUES (1, 2, 'arc 1 -> 2'), (1, 3, 'arc 1 -> 3'), (2, 3, 'arc 2 -> 3'), (1, 4, 'arc 1 -> 4'), (4, 5, 'arc 4 -> 5'), (5, 1, 'arc 5 -> 1');
WITH RECURSIVE search_graph AS (
SELECT *, false AS is_cycle, [tuple(g.f, g.t)] AS path FROM graph g
UNION ALL
SELECT g.*, has(path, tuple(g.f, g.t)), arrayConcat(sg.path, [tuple(g.f, g.t)])
FROM graph g, search_graph sg
WHERE g.f = sg.t AND NOT is_cycle
)
SELECT * FROM search_graph;
-- ordering by the path column has same effect as SEARCH DEPTH FIRST
WITH RECURSIVE search_graph AS (
SELECT *, false AS is_cycle, [tuple(g.f, g.t)] AS path FROM graph g
UNION ALL
SELECT g.*, has(path, tuple(g.f, g.t)), arrayConcat(sg.path, [tuple(g.f, g.t)])
FROM graph g, search_graph sg
WHERE g.f = sg.t AND NOT is_cycle
)
SELECT * FROM search_graph ORDER BY path;
-- { echoOff }

View File

@ -0,0 +1,181 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
--
-- test multiple WITH queries
--
WITH RECURSIVE
y AS (SELECT 1 AS id),
x AS (SELECT * FROM y UNION ALL SELECT id+1 FROM x WHERE id < 5)
SELECT * FROM x;
1
2
3
4
5
-- forward reference OK
WITH RECURSIVE
x AS (SELECT * FROM y UNION ALL SELECT id+1 FROM x WHERE id < 5),
y AS (SELECT 1 AS id)
SELECT * FROM x;
1
2
3
4
5
WITH RECURSIVE
x AS
(SELECT 1 AS id UNION ALL SELECT id+1 FROM x WHERE id < 5),
y AS
(SELECT 1 AS id UNION ALL SELECT id+1 FROM y WHERE id < 10)
SELECT y.*, x.* FROM y LEFT JOIN x USING (id);
1 1
2 2
3 3
4 4
5 5
6 0
7 0
8 0
9 0
10 0
WITH RECURSIVE
x AS
(SELECT 1 AS id UNION ALL SELECT id+1 FROM x WHERE id < 5),
y AS
(SELECT 1 AS id UNION ALL SELECT id+1 FROM x WHERE id < 10)
SELECT y.*, x.* FROM y LEFT JOIN x USING (id);
1 1
2 2
3 3
4 4
5 5
6 0
WITH RECURSIVE
x AS
(SELECT 1 AS id UNION ALL SELECT id+1 FROM x WHERE id < 3 ),
y AS
(SELECT * FROM x UNION ALL SELECT * FROM x),
z AS
(SELECT * FROM x UNION ALL SELECT id+1 FROM z WHERE id < 10)
SELECT * FROM z;
1
2
3
2
3
4
3
4
5
4
5
6
5
6
7
6
7
8
7
8
9
8
9
10
9
10
10
WITH RECURSIVE
x AS
(SELECT 1 AS id UNION ALL SELECT id+1 FROM x WHERE id < 3 ),
y AS
(SELECT * FROM x UNION ALL SELECT * FROM x),
z AS
(SELECT * FROM y UNION ALL SELECT id+1 FROM z WHERE id < 10)
SELECT * FROM z;
1
1
2
2
3
3
2
2
3
3
4
4
3
3
4
4
5
5
4
4
5
5
6
6
5
5
6
6
7
7
6
6
7
7
8
8
7
7
8
8
9
9
8
8
9
9
10
10
9
9
10
10
10
10

View File

@ -0,0 +1,81 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
--
-- test multiple WITH queries
--
WITH RECURSIVE
y AS (SELECT 1 AS id),
x AS (SELECT * FROM y UNION ALL SELECT id+1 FROM x WHERE id < 5)
SELECT * FROM x;
-- forward reference OK
WITH RECURSIVE
x AS (SELECT * FROM y UNION ALL SELECT id+1 FROM x WHERE id < 5),
y AS (SELECT 1 AS id)
SELECT * FROM x;
WITH RECURSIVE
x AS
(SELECT 1 AS id UNION ALL SELECT id+1 FROM x WHERE id < 5),
y AS
(SELECT 1 AS id UNION ALL SELECT id+1 FROM y WHERE id < 10)
SELECT y.*, x.* FROM y LEFT JOIN x USING (id);
WITH RECURSIVE
x AS
(SELECT 1 AS id UNION ALL SELECT id+1 FROM x WHERE id < 5),
y AS
(SELECT 1 AS id UNION ALL SELECT id+1 FROM x WHERE id < 10)
SELECT y.*, x.* FROM y LEFT JOIN x USING (id);
WITH RECURSIVE
x AS
(SELECT 1 AS id UNION ALL SELECT id+1 FROM x WHERE id < 3 ),
y AS
(SELECT * FROM x UNION ALL SELECT * FROM x),
z AS
(SELECT * FROM x UNION ALL SELECT id+1 FROM z WHERE id < 10)
SELECT * FROM z;
WITH RECURSIVE
x AS
(SELECT 1 AS id UNION ALL SELECT id+1 FROM x WHERE id < 3 ),
y AS
(SELECT * FROM x UNION ALL SELECT * FROM x),
z AS
(SELECT * FROM y UNION ALL SELECT id+1 FROM z WHERE id < 10)
SELECT * FROM z;
-- { echoOff }

View File

@ -0,0 +1,95 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
--
-- error cases
--
-- INTERSECT
WITH RECURSIVE x AS (SELECT 1 AS n INTERSECT SELECT n+1 FROM x)
SELECT * FROM x; -- {serverError UNSUPPORTED_METHOD}
WITH RECURSIVE x AS (SELECT 1 AS n INTERSECT ALL SELECT n+1 FROM x)
SELECT * FROM x; -- {serverError UNSUPPORTED_METHOD}
-- EXCEPT
WITH RECURSIVE x AS (SELECT 1 AS n EXCEPT SELECT n+1 FROM x)
SELECT * FROM x; -- {serverError UNSUPPORTED_METHOD}
WITH RECURSIVE x AS (SELECT 1 AS n EXCEPT ALL SELECT n+1 FROM x)
SELECT * FROM x; -- {serverError UNSUPPORTED_METHOD}
-- no non-recursive term
WITH RECURSIVE x AS (SELECT n FROM x)
SELECT * FROM x; -- {serverError UNKNOWN_TABLE}
-- recursive term in the left hand side (strictly speaking, should allow this)
WITH RECURSIVE x AS (SELECT n FROM x UNION ALL SELECT 1 AS n)
SELECT * FROM x; -- {serverError UNKNOWN_TABLE}
DROP TABLE IF EXISTS y;
CREATE TABLE y (a UInt64) ENGINE=TinyLog;
INSERT INTO y SELECT * FROM numbers(1, 10);
-- LEFT JOIN
WITH RECURSIVE x AS (SELECT a AS n FROM y WHERE a = 1
UNION ALL
SELECT x.n+1 FROM y LEFT JOIN x ON x.n = y.a WHERE n < 10)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- RIGHT JOIN
WITH RECURSIVE x AS (SELECT a AS n FROM y WHERE a = 1
UNION ALL
SELECT x.n+1 FROM x RIGHT JOIN y ON x.n = y.a WHERE n < 10)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- FULL JOIN
WITH RECURSIVE x AS (SELECT a AS n FROM y WHERE a = 1
UNION ALL
SELECT x.n+1 FROM x FULL JOIN y ON x.n = y.a WHERE n < 10)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- subquery
WITH RECURSIVE x AS (SELECT 1 AS n UNION ALL SELECT n+1 FROM x
WHERE n IN (SELECT * FROM x))
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- aggregate functions
WITH RECURSIVE x AS (SELECT 1 AS n UNION ALL SELECT count(*) FROM x)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
WITH RECURSIVE x AS (SELECT 1 AS n UNION ALL SELECT sum(n) FROM x)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- ORDER BY
WITH RECURSIVE x AS (SELECT 1 AS n UNION ALL SELECT n+1 FROM x ORDER BY 1)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- target list has a recursive query name
WITH RECURSIVE x AS (SELECT 1 AS id
UNION ALL
SELECT (SELECT * FROM x) FROM x WHERE id < 5
) SELECT * FROM x; -- { serverError UNKNOWN_TABLE }
-- mutual recursive query (not implemented)
WITH RECURSIVE
x AS (SELECT 1 AS id UNION ALL SELECT id+1 FROM y WHERE id < 5),
y AS (SELECT 1 AS id UNION ALL SELECT id+1 FROM x WHERE id < 5)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }

View File

@ -0,0 +1,112 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
--
-- error cases
--
-- INTERSECT
WITH RECURSIVE x AS (SELECT 1 AS n INTERSECT SELECT n+1 FROM x)
SELECT * FROM x; -- {serverError UNSUPPORTED_METHOD}
WITH RECURSIVE x AS (SELECT 1 AS n INTERSECT ALL SELECT n+1 FROM x)
SELECT * FROM x; -- {serverError UNSUPPORTED_METHOD}
-- EXCEPT
WITH RECURSIVE x AS (SELECT 1 AS n EXCEPT SELECT n+1 FROM x)
SELECT * FROM x; -- {serverError UNSUPPORTED_METHOD}
WITH RECURSIVE x AS (SELECT 1 AS n EXCEPT ALL SELECT n+1 FROM x)
SELECT * FROM x; -- {serverError UNSUPPORTED_METHOD}
-- no non-recursive term
WITH RECURSIVE x AS (SELECT n FROM x)
SELECT * FROM x; -- {serverError UNKNOWN_TABLE}
-- recursive term in the left hand side (strictly speaking, should allow this)
WITH RECURSIVE x AS (SELECT n FROM x UNION ALL SELECT 1 AS n)
SELECT * FROM x; -- {serverError UNKNOWN_TABLE}
DROP TABLE IF EXISTS y;
CREATE TABLE y (a UInt64) ENGINE=TinyLog;
INSERT INTO y SELECT * FROM numbers(1, 10);
-- LEFT JOIN
WITH RECURSIVE x AS (SELECT a AS n FROM y WHERE a = 1
UNION ALL
SELECT x.n+1 FROM y LEFT JOIN x ON x.n = y.a WHERE n < 10)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- RIGHT JOIN
WITH RECURSIVE x AS (SELECT a AS n FROM y WHERE a = 1
UNION ALL
SELECT x.n+1 FROM x RIGHT JOIN y ON x.n = y.a WHERE n < 10)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- FULL JOIN
WITH RECURSIVE x AS (SELECT a AS n FROM y WHERE a = 1
UNION ALL
SELECT x.n+1 FROM x FULL JOIN y ON x.n = y.a WHERE n < 10)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- subquery
WITH RECURSIVE x AS (SELECT 1 AS n UNION ALL SELECT n+1 FROM x
WHERE n IN (SELECT * FROM x))
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- aggregate functions
WITH RECURSIVE x AS (SELECT 1 AS n UNION ALL SELECT count(*) FROM x)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
WITH RECURSIVE x AS (SELECT 1 AS n UNION ALL SELECT sum(n) FROM x)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- ORDER BY
WITH RECURSIVE x AS (SELECT 1 AS n UNION ALL SELECT n+1 FROM x ORDER BY 1)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- target list has a recursive query name
WITH RECURSIVE x AS (SELECT 1 AS id
UNION ALL
SELECT (SELECT * FROM x) FROM x WHERE id < 5
) SELECT * FROM x; -- { serverError UNKNOWN_TABLE }
-- mutual recursive query (not implemented)
WITH RECURSIVE
x AS (SELECT 1 AS id UNION ALL SELECT id+1 FROM y WHERE id < 5),
y AS (SELECT 1 AS id UNION ALL SELECT id+1 FROM x WHERE id < 5)
SELECT * FROM x FORMAT NULL SETTINGS max_recursive_cte_evaluation_depth = 5; -- { serverError TOO_DEEP_RECURSION }
-- { echoOff }

View File

@ -0,0 +1,396 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
WITH RECURSIVE foo AS
(SELECT 1 AS i
UNION ALL
(SELECT i+1 FROM foo WHERE i < 10
UNION ALL
SELECT i+1 FROM foo WHERE i < 5)
) SELECT * FROM foo;
1
2
2
3
3
3
3
4
4
4
4
4
4
4
4
5
5
5
5
5
5
5
5
5
5
5
5
5
5
5
5
6
6
6
6
6
6
6
6
6
6
6
6
6
6
6
6
7
7
7
7
7
7
7
7
7
7
7
7
7
7
7
7
8
8
8
8
8
8
8
8
8
8
8
8
8
8
8
8
9
9
9
9
9
9
9
9
9
9
9
9
9
9
9
9
10
10
10
10
10
10
10
10
10
10
10
10
10
10
10
10
WITH RECURSIVE foo AS
(SELECT 1 AS i
UNION ALL
SELECT * FROM
(SELECT i+1 FROM foo WHERE i < 10
UNION ALL
SELECT i+1 FROM foo WHERE i < 5) AS t
) SELECT * FROM foo;
1
2
2
3
3
3
3
4
4
4
4
4
4
4
4
5
5
5
5
5
5
5
5
5
5
5
5
5
5
5
5
6
6
6
6
6
6
6
6
6
6
6
6
6
6
6
6
7
7
7
7
7
7
7
7
7
7
7
7
7
7
7
7
8
8
8
8
8
8
8
8
8
8
8
8
8
8
8
8
9
9
9
9
9
9
9
9
9
9
9
9
9
9
9
9
10
10
10
10
10
10
10
10
10
10
10
10
10
10
10
10
WITH RECURSIVE foo AS
(SELECT 1 AS i
UNION ALL
(SELECT i+1 FROM foo WHERE i < 10
EXCEPT
SELECT i+1 FROM foo WHERE i < 5)
) SELECT * FROM foo;
1
WITH RECURSIVE foo AS
(SELECT 1 AS i
UNION ALL
(SELECT i+1 FROM foo WHERE i < 10
INTERSECT
SELECT i+1 FROM foo WHERE i < 5)
) SELECT * FROM foo;
1
2
3
4
5
--
-- test for nested-recursive-WITH bug
--
WITH RECURSIVE t AS (
WITH RECURSIVE s AS (
SELECT toUInt64(1) AS i
UNION ALL
SELECT i+1 FROM s WHERE i < 10
)
SELECT i AS j FROM s
UNION ALL
SELECT j+1 FROM t WHERE j < 10
)
SELECT * FROM t;
1
2
3
4
5
6
7
8
9
10
2
3
4
5
6
7
8
9
10
3
4
5
6
7
8
9
10
4
5
6
7
8
9
10
5
6
7
8
9
10
6
7
8
9
10
7
8
9
10
8
9
10
9
10
10
--
-- Test CTEs read in non-initialization orders
--
WITH RECURSIVE
tab AS (SELECT * FROM values('id_key UInt64, link UInt64', (1,17), (2,17), (3,17), (4,17), (6,17), (5,17))),
iter AS (
SELECT 0 AS id_key, 'base' AS row_type, 17 AS link
UNION ALL (
WITH remaining AS (
SELECT tab.id_key AS id_key, 'true'::text AS row_type, iter.link AS link, MIN(tab.id_key) OVER () AS min
FROM tab INNER JOIN iter USING (link)
WHERE tab.id_key > iter.id_key
),
first_remaining AS (
SELECT id_key, row_type, link
FROM remaining
WHERE id_key=min
),
effect AS (
SELECT tab.id_key AS id_key, 'new'::text AS row_type, tab.link AS link
FROM first_remaining e INNER JOIN tab ON e.id_key=tab.id_key
WHERE e.row_type = 'false'
)
SELECT * FROM first_remaining
UNION ALL SELECT * FROM effect
)
)
SELECT * FROM iter;
0 base 17
1 true 17
2 true 17
3 true 17
4 true 17
5 true 17
6 true 17

View File

@ -0,0 +1,113 @@
/**
* Based on https://github.com/postgres/postgres/blob/master/src/test/regress/sql/with.sql, license:
*
* PostgreSQL Database Management System
* (formerly known as Postgres, then as Postgres95)
*
* Portions Copyright (c) 1996-2024, PostgreSQL Global Development Group
*
* Portions Copyright (c) 1994, The Regents of the University of California
*
* Permission to use, copy, modify, and distribute this software and its
* documentation for any purpose, without fee, and without a written agreement
* is hereby granted, provided that the above copyright notice and this
* paragraph and the following two paragraphs appear in all copies.
*
* IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR
* DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
* LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS
* DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE
* POSSIBILITY OF SUCH DAMAGE.
*
* THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES,
* INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
* AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS
* ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO
*PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
*/
--
-- Tests for common table expressions (WITH query, ... SELECT ...)
--
-- { echoOn }
WITH RECURSIVE foo AS
(SELECT 1 AS i
UNION ALL
(SELECT i+1 FROM foo WHERE i < 10
UNION ALL
SELECT i+1 FROM foo WHERE i < 5)
) SELECT * FROM foo;
WITH RECURSIVE foo AS
(SELECT 1 AS i
UNION ALL
SELECT * FROM
(SELECT i+1 FROM foo WHERE i < 10
UNION ALL
SELECT i+1 FROM foo WHERE i < 5) AS t
) SELECT * FROM foo;
WITH RECURSIVE foo AS
(SELECT 1 AS i
UNION ALL
(SELECT i+1 FROM foo WHERE i < 10
EXCEPT
SELECT i+1 FROM foo WHERE i < 5)
) SELECT * FROM foo;
WITH RECURSIVE foo AS
(SELECT 1 AS i
UNION ALL
(SELECT i+1 FROM foo WHERE i < 10
INTERSECT
SELECT i+1 FROM foo WHERE i < 5)
) SELECT * FROM foo;
--
-- test for nested-recursive-WITH bug
--
WITH RECURSIVE t AS (
WITH RECURSIVE s AS (
SELECT toUInt64(1) AS i
UNION ALL
SELECT i+1 FROM s WHERE i < 10
)
SELECT i AS j FROM s
UNION ALL
SELECT j+1 FROM t WHERE j < 10
)
SELECT * FROM t;
--
-- Test CTEs read in non-initialization orders
--
WITH RECURSIVE
tab AS (SELECT * FROM values('id_key UInt64, link UInt64', (1,17), (2,17), (3,17), (4,17), (6,17), (5,17))),
iter AS (
SELECT 0 AS id_key, 'base' AS row_type, 17 AS link
UNION ALL (
WITH remaining AS (
SELECT tab.id_key AS id_key, 'true'::text AS row_type, iter.link AS link, MIN(tab.id_key) OVER () AS min
FROM tab INNER JOIN iter USING (link)
WHERE tab.id_key > iter.id_key
),
first_remaining AS (
SELECT id_key, row_type, link
FROM remaining
WHERE id_key=min
),
effect AS (
SELECT tab.id_key AS id_key, 'new'::text AS row_type, tab.link AS link
FROM first_remaining e INNER JOIN tab ON e.id_key=tab.id_key
WHERE e.row_type = 'false'
)
SELECT * FROM first_remaining
UNION ALL SELECT * FROM effect
)
)
SELECT * FROM iter;
-- { echoOff }