File: cte_max_recursion_depth_func.test

package info (click to toggle)
mysql-8.0 8.0.43-3
  • links: PTS, VCS
  • area: main
  • in suites: sid
  • size: 1,273,924 kB
  • sloc: cpp: 4,684,605; ansic: 412,450; pascal: 108,398; java: 83,641; perl: 30,221; cs: 27,067; sql: 26,594; sh: 24,181; python: 21,816; yacc: 17,169; php: 11,522; xml: 7,388; javascript: 7,076; makefile: 2,194; lex: 1,075; awk: 670; asm: 520; objc: 183; ruby: 97; lisp: 86
file content (117 lines) | stat: -rw-r--r-- 2,637 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
--echo #
--echo # Bug#26136509 ADD A MAX_RECURSION VARIABLE TO LIMIT RECURSION IN CTES
--echo #

SELECT @@cte_max_recursion_depth;

# UNION ALL then UNION DISTINCT

let $c=2;
while ($c)
{
if ($c == 2)
{
  let $union=ALL;
}
if ($c == 1)
{
  let $union=DISTINCT;
}
dec $c;

# One recursive query block which generates 1 row per input row.
# With the @m variable, we control how many iterations this query will
# want to do. By varying @m we can thus make it hit the cap or not.

let $q=
WITH RECURSIVE qn AS (
SELECT 1 AS a UNION $union
SELECT 1+a FROM qn WHERE a<@m)
SELECT COUNT(*) FROM qn;

SET @m = 1001;
--error ER_CTE_MAX_RECURSION_DEPTH
eval $q;

SET @m = 1000;
eval $q;

SET cte_max_recursion_depth=10;

SET @m = 11;
--error ER_CTE_MAX_RECURSION_DEPTH
eval $q;

SET @m = 10;
eval $q;

set cte_max_recursion_depth=default;

# 3 recursive query blocks. Each of them operates on its own data only.

let $q=
WITH RECURSIVE qn AS
(SELECT 1 AS a, 0 AS b UNION $union
SELECT 1+a, 1 FROM qn WHERE b IN (0,1) AND a<@m UNION $union
SELECT 1+a, 2 FROM qn WHERE b IN (0,2) AND a<@m UNION $union
SELECT 1+a, 3 FROM qn WHERE b IN (0,3) AND a<@m
) SELECT COUNT(*) FROM qn;

SET @m = 1001;
--error ER_CTE_MAX_RECURSION_DEPTH
eval $q;

SET @m = 999;
eval $q;

# You may wonder why there is a difference of 2, instead of 1, in the
# above values of @m. It is because with @m=1000, UNION ALL will throw
# error, while DISTINCT will not; which is because in UNION ALL, the
# first recursive query blocks need an extra pass over what the last
# one has produced, whereas in UNION DISTINCT, the three blocks walk
# in lock-step. So the count of iterations is higher for ALL. This
# difference is bounded by the number of query blocks, which is small
# enough. cte_max_recursion_depth does not intend to be 100% exact.

SET cte_max_recursion_depth=10;

SET @m = 11;
--error ER_CTE_MAX_RECURSION_DEPTH
eval $q;

SET @m = 9;
eval $q;

SET cte_max_recursion_depth=DEFAULT;

# One recursive query block which generates 2 rows per input row.
# Each iteration thus generates twice more rows than the previous.

let $q=
WITH RECURSIVE
onetwo(b) AS (SELECT 1 UNION SELECT 2),
qn AS (
SELECT 1 AS a, 0 AS b UNION $union
SELECT 1+a, onetwo.b FROM onetwo, qn WHERE a<@m)
SELECT COUNT(*) FROM qn;

SET cte_max_recursion_depth=10;

SET @m = 11;
--error ER_CTE_MAX_RECURSION_DEPTH
eval $q;

SET @m = 10;
eval $q;

SET cte_max_recursion_depth=default;

}

# Test that we can block any recursive query
SET cte_max_recursion_depth=0;
--error ER_CTE_MAX_RECURSION_DEPTH
WITH RECURSIVE qn AS (
SELECT 1 AS a UNION ALL
SELECT 1+a FROM qn WHERE a<0)
SELECT COUNT(*) FROM qn;