summaryrefslogtreecommitdiff
path: root/mysql-test/suite/compat/oracle/t/sp-cursor-decl.test
blob: 21683dd4220e2f401c906b6bf31ac0e6e1a15bb5 (plain)
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
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
SET sql_mode=ORACLE;

--echo #
--echo # MDEV-10598 sql_mode=ORACLE: Variable declarations can go after cursor declarations
--echo #

--echo #
--echo # Variable after cursor declaration
--echo #

CREATE TABLE t1 (a INT);
insert into t1 values (1);
insert into t1 values (2);
DELIMITER $$;
CREATE PROCEDURE p1
AS
  CURSOR c IS SELECT a FROM t1;
  var1 varchar(10);
BEGIN
  OPEN c;
  fetch c into var1;
  SELECT c%ROWCOUNT,var1;
  close c;
END;
$$
DELIMITER ;$$
CALL p1;
DROP PROCEDURE p1;
drop table t1;

--echo #
--echo # Variable after condition declaration
--echo #

CREATE TABLE t1 (col1 INT);
insert into t1 values (1);
create unique index t1_col1 on t1 (col1);
DELIMITER $$;
CREATE PROCEDURE p1
AS
  dup_key CONDITION FOR SQLSTATE '23000';
  var1 varchar(40);
  CONTINUE HANDLER FOR dup_key
  BEGIN
    var1:='duplicate key in index';
  END;
BEGIN
  var1:='';
  insert into t1 values (1);
  select var1;
END;
$$
DELIMITER ;$$
CALL p1;
DROP PROCEDURE p1;
drop table t1;

--echo #
--echo # Condition after cursor declaration
--echo #

CREATE TABLE t1 (col1 INT);
insert into t1 values (1);
create unique index t1_col1 on t1 (col1);
DELIMITER $$;
CREATE PROCEDURE p1
AS
  var1 varchar(40);
  var2 integer;
  CURSOR c IS SELECT col1 FROM t1;
  dup_key CONDITION FOR SQLSTATE '23000';
  CONTINUE HANDLER FOR dup_key
  BEGIN
    var1:='duplicate key in index';
  END;
BEGIN
  var1:='';
  insert into t1 values (1);
  SELECT var1;
END;
$$
DELIMITER ;$$
CALL p1;
DROP PROCEDURE p1;
drop table t1;

--echo #
--echo # Cursor after handler declaration
--echo #

CREATE TABLE t1 (col1 INT);
insert into t1 values (1);
create unique index t1_col1 on t1 (col1);
DELIMITER $$;
--error ER_PARSE_ERROR
CREATE PROCEDURE p1
AS
  var1 varchar(40);
  var2 integer;
  dup_key CONDITION FOR SQLSTATE '23000';
  CONTINUE HANDLER FOR dup_key
  BEGIN
    var1:='duplicate key in index';
  END;
  CURSOR c IS SELECT col1 FROM t1;
BEGIN
  var1:='';
  insert into t1 values (1);
  SELECT var1;
END;
$$
DELIMITER ;$$
drop table t1;

--echo #
--echo # Condition after handler declaration
--echo #

CREATE TABLE t1 (col1 INT);
insert into t1 values (1);
create unique index t1_col1 on t1 (col1);
DELIMITER $$;
--error ER_PARSE_ERROR
CREATE PROCEDURE p1
AS
  var1 varchar(40);
  var2 integer;
  dup_key CONDITION FOR SQLSTATE '23000';
  CURSOR c IS SELECT col1 FROM t1;
  CONTINUE HANDLER FOR dup_key
  BEGIN
    var1:='duplicate key in index';
  END;
  divide_by_zero CONDITION FOR SQLSTATE '22012';
BEGIN
  var1:='';
  insert into t1 values (1);
  SELECT var1;
END;
$$
DELIMITER ;$$
drop table t1;

--echo #
--echo # Variable after handler declaration
--echo #

CREATE TABLE t1 (col1 INT);
insert into t1 values (1);
create unique index t1_col1 on t1 (col1);
DELIMITER $$;
--error ER_PARSE_ERROR
CREATE PROCEDURE p1
AS
  var1 varchar(40);
  var2 integer;
  dup_key CONDITION FOR SQLSTATE '23000';
  CURSOR c IS SELECT col1 FROM t1;
  CONTINUE HANDLER FOR dup_key
  BEGIN
    var1:='duplicate key in index';
  END;
  divide_by_zero CONDITION FOR SQLSTATE '22012';
BEGIN
  var1:='';
  insert into t1 values (1);
  SELECT var1;
END;
$$
DELIMITER ;$$
drop table t1;

--echo #
--echo # Variable after cursor (inner block)
--echo #

CREATE TABLE t1 (col1 INT);
insert into t1 values (1);
insert into t1 values (2);
create unique index t1_col1 on t1 (col1);
DELIMITER $$;
CREATE PROCEDURE p1
AS
  CURSOR c IS SELECT col1 FROM t1;
  var1 varchar(40);
BEGIN
  OPEN c;
  begin
    declare
      CURSOR c IS SELECT col1 FROM t1 where col1=2;
      var2 integer;
      dup_key CONDITION FOR SQLSTATE '23000';
      CONTINUE HANDLER FOR dup_key
      BEGIN
        var1:='duplicate key in index';
      END;
    begin
      OPEN c;
      fetch c into var1;
      SELECT 'inner cursor',var1;
      insert into t1 values (2);
      close c;
    end;
  end;
  SELECT var1;
  fetch c into var1;
  SELECT c%ROWCOUNT,var1;
  begin
    insert into t1 values (2);
  exception when 1062 then
    begin
      SELECT 'dup key caugth';
    end;
  end;
  close c;
END;
$$
DELIMITER ;$$
CALL p1;
DROP PROCEDURE p1;
drop table t1;

--echo #
--echo # Cursor declaration and row type declaration in same block
--echo #

CREATE TABLE t1 (a INT, b VARCHAR(10));
insert into t1 values(1,'a');
delimiter $$;
CREATE PROCEDURE p1()
AS
  CURSOR cur1 IS SELECT a FROM t1;
  rec1 cur1%ROWTYPE;
BEGIN
  rec1.a:= 10;
END;
$$
delimiter ;$$
call p1;
DROP PROCEDURE p1;
drop table t1;


--echo #
--echo # Recursive cursor and cursor%ROWTYPE declarations in the same block
--echo #

delimiter $$;
CREATE PROCEDURE p1
AS
  a INT:=10;
  b VARCHAR(10):='b0';
  c DOUBLE:=0.1;
  CURSOR cur1 IS SELECT a, b, c;
  rec1 cur1%ROWTYPE;
  CURSOR cur2 IS SELECT rec1.a + 1 "a", rec1.b||'0' AS b, rec1.c AS c;
  rec2 cur2%ROWTYPE;
BEGIN
  OPEN cur1;
  FETCH cur1 INTO rec1;
  CLOSE cur1;
  SELECT rec1.a;
  OPEN cur2;
  FETCH cur2 INTO rec2;
  CLOSE cur2;
  SELECT rec2.a;
  CREATE TABLE t2 AS SELECT rec2.a AS a, rec2.b AS b, rec2.c AS c;
  SHOW CREATE TABLE t2;
  DROP TABLE t2;
END;
$$
DELIMITER ;$$
CALL p1();
DROP PROCEDURE p1;


--echo #
--echo # MDEV-12916 Wrong column data type for an INT field of a cursor-anchored ROW variable
--echo #

DELIMITER $$;
CREATE PROCEDURE p1
AS
  a INT DEFAULT 10;
  CURSOR cur1 IS SELECT a;
  rec1 cur1%ROWTYPE;
BEGIN
  CREATE TABLE t1 AS SELECT rec1.a;
  SHOW CREATE TABLE t1;
  DROP TABLE t1;
END;
$$
DELIMITER ;$$
CALL p1();
DROP PROCEDURE p1;