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 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346
|
SET sql_mode=ORACLE;
--echo #
--echo # MDEV-10578 sql_mode=ORACLE: SP control functions SQLCODE, SQLERRM
--echo #
--echo #
--echo # Using SQLCODE and SQLERRM outside of an SP
--echo #
--error ER_BAD_FIELD_ERROR
SELECT SQLCODE;
--error ER_BAD_FIELD_ERROR
SELECT SQLERRM;
CREATE TABLE t1 (SQLCODE INT, SQLERRM VARCHAR(10));
INSERT INTO t1 VALUES (10, 'test');
SELECT SQLCODE, SQLERRM FROM t1;
DROP TABLE t1;
--echo #
--echo # Normal SQLCODE and SQLERRM usage
--echo #
DELIMITER $$;
CREATE PROCEDURE p1(stmt VARCHAR)
AS
BEGIN
EXECUTE IMMEDIATE stmt;
SELECT 'Error1: ' || SQLCODE || ' ' || SQLERRM;
EXCEPTION
WHEN OTHERS THEN
SELECT 'Error2: ' || SQLCODE || ' ' || SQLERRM;
END;
$$
DELIMITER ;$$
CALL p1('SELECT 1');
CALL p1('xxx');
CALL p1('SELECT 1');
DROP PROCEDURE p1;
--echo #
--echo # SQLCODE and SQLERRM hidden by local variables
--echo #
DELIMITER $$;
CREATE PROCEDURE p1()
AS
sqlcode INT:= 10;
sqlerrm VARCHAR(64) := 'test';
BEGIN
SELECT 'Error: ' || SQLCODE || ' ' || SQLERRM;
END;
$$
DELIMITER ;$$
CALL p1;
DROP PROCEDURE p1;
DELIMITER $$;
CREATE PROCEDURE p1()
AS
sqlcode INT;
sqlerrm VARCHAR(64);
BEGIN
SQLCODE:= 10;
sqlerrm:= 'test';
SELECT 'Error: ' || SQLCODE || ' ' || SQLERRM;
END;
$$
DELIMITER ;$$
CALL p1;
DROP PROCEDURE p1;
--echo #
--echo # SQLCODE and SQLERRM hidden by parameters
--echo #
DELIMITER $$;
CREATE PROCEDURE p1(sqlcode INT, sqlerrm VARCHAR)
AS
BEGIN
SELECT 'Error: ' || SQLCODE || ' ' || SQLERRM;
END;
$$
DELIMITER ;$$
CALL p1(10, 'test');
DROP PROCEDURE p1;
--echo #
--echo # SQLCODE and SQLERRM in CREATE..SELECT
--echo #
DELIMITER $$;
CREATE PROCEDURE p1
AS
BEGIN
CREATE TABLE t1 AS SELECT SQLCODE, SQLERRM;
END;
$$
DELIMITER ;$$
CALL p1;
SHOW CREATE TABLE t1;
DROP TABLE t1;
DROP PROCEDURE p1;
--echo #
--echo # SQLCODE and SQLERRM in EXPLAIN EXTENDED SELECT
--echo #
DELIMITER $$;
CREATE PROCEDURE p1
AS
BEGIN
EXPLAIN EXTENDED SELECT SQLCode, SQLErrm;
END;
$$
DELIMITER ;$$
CALL p1;
DROP PROCEDURE p1;
--echo #
--echo # Warning-alike errors in stored functions
--echo #
CREATE TABLE t1 (a INT);
DELIMITER $$;
CREATE FUNCTION f1 RETURN VARCHAR
AS
a INT;
BEGIN
SELECT a INTO a FROM t1;
RETURN 'No exception ' || SQLCODE || ' ' || SQLERRM;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RETURN 'Exception ' || SQLCODE || ' ' || SQLERRM;
END;
$$
DELIMITER ;$$
SELECT f1() FROM DUAL;
DROP FUNCTION f1;
DROP TABLE t1;
CREATE TABLE t1 (a INT);
DELIMITER $$;
CREATE FUNCTION f1 RETURN VARCHAR
AS
a INT;
BEGIN
SELECT a INTO a FROM t1;
RETURN 'No exception ' || SQLCODE || ' ' || SQLERRM;
EXCEPTION
WHEN OTHERS THEN
RETURN 'Exception ' || SQLCODE || ' ' || SQLERRM;
END;
$$
DELIMITER ;$$
SELECT f1() FROM DUAL;
DROP FUNCTION f1;
DROP TABLE t1;
--echo #
--echo # Warning-alike errors in stored procedures
--echo #
CREATE TABLE t1 (a INT);
DELIMITER $$;
CREATE PROCEDURE p1(res OUT VARCHAR)
AS
a INT;
BEGIN
SELECT a INTO a FROM t1;
res:= 'No exception ' || SQLCODE || ' ' || SQLERRM;
EXCEPTION
WHEN NO_DATA_FOUND THEN
res:= 'Exception ' || SQLCODE || ' ' || SQLERRM;
END;
$$
DELIMITER ;$$
CALL p1(@a);
SELECT @a;
DROP PROCEDURE p1;
DROP TABLE t1;
CREATE TABLE t1 (a INT);
DELIMITER $$;
CREATE PROCEDURE p1(res OUT VARCHAR)
AS
a INT;
BEGIN
SELECT a INTO a FROM t1;
res:= 'No exception ' || SQLCODE || ' ' || SQLERRM;
EXCEPTION
WHEN OTHERS THEN
res:= 'Exception ' || SQLCODE || ' ' || SQLERRM;
END;
$$
DELIMITER ;$$
CALL p1(@a);
SELECT @a;
DROP PROCEDURE p1;
DROP TABLE t1;
--echo #
--echo # SQLCODE and SQLERRM are cleared on RETURN
--echo #
CREATE TABLE t1 (a INT);
DELIMITER $$;
CREATE FUNCTION f1 RETURN VARCHAR
AS
a INT:=10;
BEGIN
SELECT a INTO a FROM t1;
RETURN 'Value=' || a;
EXCEPTION
WHEN NO_DATA_FOUND THEN RETURN 'Exception|' || SQLCODE || ' ' || SQLERRM;
END;
$$
CREATE FUNCTION f2 RETURN VARCHAR
AS
a VARCHAR(128);
BEGIN
RETURN f1() || '|' || SQLCODE || ' ' || SQLERRM;
END;
$$
DELIMITER ;$$
SELECT f1() FROM DUAL;
SELECT f2() FROM DUAL;
DROP TABLE t1;
DROP FUNCTION f2;
DROP FUNCTION f1;
CREATE TABLE t1 (a INT);
DELIMITER $$;
CREATE FUNCTION f1 RETURN VARCHAR
AS
a INT:=10;
BEGIN
SELECT a INTO a FROM t1;
RETURN 'Value=' || a;
EXCEPTION
WHEN OTHERS THEN RETURN 'Exception|' || SQLCODE || ' ' || SQLERRM;
END;
$$
CREATE FUNCTION f2 RETURN VARCHAR
AS
a VARCHAR(128);
BEGIN
RETURN f1() || '|' || SQLCODE || ' ' || SQLERRM;
END;
$$
DELIMITER ;$$
SELECT f1() FROM DUAL;
SELECT f2() FROM DUAL;
DROP TABLE t1;
DROP FUNCTION f2;
DROP FUNCTION f1;
--echo #
--echo # SQLCODE and SQLERRM are cleared on a return from a PROCEDURE
--echo #
CREATE TABLE t1 (a INT);
DELIMITER $$;
CREATE PROCEDURE p1(res OUT VARCHAR)
AS
a INT:=10;
BEGIN
SELECT a INTO a FROM t1;
res:='Value=' || a;
EXCEPTION
WHEN NO_DATA_FOUND THEN res:='Exception|' || SQLCODE || ' ' || SQLERRM;
END;
$$
CREATE FUNCTION f2 RETURN VARCHAR
AS
res VARCHAR(128);
BEGIN
CALL p1(res);
RETURN res || '|' || SQLCODE || ' ' || SQLERRM;
END;
$$
DELIMITER ;$$
SELECT f2() FROM DUAL;
DROP FUNCTION f2;
DROP PROCEDURE p1;
DROP TABLE t1;
CREATE TABLE t1 (a INT);
DELIMITER $$;
CREATE PROCEDURE p1(res OUT VARCHAR)
AS
a INT:=10;
BEGIN
SELECT a INTO a FROM t1;
res:='Value=' || a;
EXCEPTION
WHEN OTHERS THEN res:='Exception|' || SQLCODE || ' ' || SQLERRM;
END;
$$
CREATE FUNCTION f2 RETURN VARCHAR
AS
res VARCHAR(128);
BEGIN
CALL p1(res);
RETURN res || '|' || SQLCODE || ' ' || SQLERRM;
END;
$$
DELIMITER ;$$
SELECT f2() FROM DUAL;
DROP FUNCTION f2;
DROP PROCEDURE p1;
DROP TABLE t1;
--echo #
--echo # End of MDEV-10578 sql_mode=ORACLE: SP control functions SQLCODE, SQLERRM
--echo #
--echo #
--echo # MDEV-12854 Synchronize CREATE..SELECT data type and result set metadata data type for INT functions
--echo #
--enable_metadata
--disable_ps_protocol
DELIMITER $$;
BEGIN
SELECT SQLCODE;
END
$$
DELIMITER ;$$
--enable_ps_protocol
--disable_metadata
|