Skip to content

Commit

Permalink
MDEV-10862: Stored procedures: default values for parameters (optiona…
Browse files Browse the repository at this point in the history
…l parameters)

Implement default values for parameters of stored routines in both default and oracle mode. Default values for cursor parameters are *NOT* supported yet.

The default values can be either literals or expressions. When it is an expression, it is only evaluated if the parameter has not been supplied by the caller (important if the expression has side effects).
  • Loading branch information
iqbal-hasprime committed Nov 21, 2024
1 parent eff9c19 commit f46733b
Show file tree
Hide file tree
Showing 18 changed files with 943 additions and 21 deletions.
15 changes: 15 additions & 0 deletions mysql-test/main/sp-code.result
Original file line number Diff line number Diff line change
Expand Up @@ -1701,3 +1701,18 @@ DROP PROCEDURE p1;
#
# End of 10.5 tests
#
#
# MDEV-10862 Stored procedures: default values for parameters (optional parameters)
#
CREATE OR REPLACE PROCEDURE p1(par1 INT, par2 INT DEFAULT 1)
BEGIN
DECLARE var1 INT DEFAULT 5;
SELECT par1, par2 FROM DUAL;
END;
$$
SHOW PROCEDURE CODE p1;
Pos Instruction
0 set default param par2@1 1
1 set var1@2 5
2 stmt 0 "SELECT par1, par2 FROM DUAL"
DROP PROCEDURE p1;
16 changes: 16 additions & 0 deletions mysql-test/main/sp-code.test
Original file line number Diff line number Diff line change
Expand Up @@ -1219,3 +1219,19 @@ DROP PROCEDURE p1;
--echo #
--echo # End of 10.5 tests
--echo #


--echo #
--echo # MDEV-10862 Stored procedures: default values for parameters (optional parameters)
--echo #

DELIMITER $$;
CREATE OR REPLACE PROCEDURE p1(par1 INT, par2 INT DEFAULT 1)
BEGIN
DECLARE var1 INT DEFAULT 5;
SELECT par1, par2 FROM DUAL;
END;
$$
DELIMITER ;$$
SHOW PROCEDURE CODE p1;
DROP PROCEDURE p1;
117 changes: 117 additions & 0 deletions mysql-test/main/sp-default-param.result
Original file line number Diff line number Diff line change
@@ -0,0 +1,117 @@
#
# MDEV-10862 Stored procedures: default values for parameters (optional parameters)
#
#
# Basic default parameter test for procedures
#
CREATE OR REPLACE PROCEDURE p1(par1 INT, par2 INT DEFAULT 1)
BEGIN
SELECT par1, par2 FROM DUAL;
END;
$$
CALL p1(2,3);
par1 par2
2 3
CALL p1(2);
par1 par2
2 1
CALL p1(2,3,4);
ERROR 42000: Incorrect number of arguments for PROCEDURE test.p1; expected 2, got 3
CALL p1();
ERROR 42000: Incorrect number of arguments for PROCEDURE test.p1; expected 2, got 0
DROP PROCEDURE p1;
#
# Basic default parameter test for functions
#
CREATE OR REPLACE FUNCTION f1(par1 INT, par2 INT DEFAULT 1) RETURNS INT
RETURN par1 + par2;
$$
SELECT f1(2,3) FROM DUAL;
f1(2,3)
5
SELECT f1(2) FROM DUAL;
f1(2)
3
SELECT f1(2,3,4) FROM DUAL;
ERROR 42000: Incorrect number of arguments for FUNCTION test.f1; expected 2, got 3
SELECT f1() FROM DUAL;
ERROR 42000: Incorrect number of arguments for FUNCTION test.f1; expected 2, got 0
DROP FUNCTION f1;
#
# Test various data types
#
CREATE TABLE t1 (a INT, b VARCHAR(10));
CREATE DATABASE d1;
USE d1;
CREATE TABLE t1 (a INT, b VARCHAR(10));
USE test;
CREATE OR REPLACE PROCEDURE p1(par1 INT DEFAULT 1,
par2 VARCHAR(10) DEFAULT 'abc',
par3 DATE DEFAULT '2010-01-01',
par4 DECIMAL(10,2) DEFAULT 1.23,
par5 DOUBLE DEFAULT 1.23,
par6 FLOAT DEFAULT 1.23,
par7 CHAR DEFAULT 'a',
par8 BINARY DEFAULT 'a',
par9 BLOB DEFAULT 'a',
par10 TEXT DEFAULT 'a',
par11 ENUM('a','b') DEFAULT 'a',
par12 SET('a','b') DEFAULT 'a',
par13 TIMESTAMP DEFAULT '2010-01-01 00:00:00',
par14 DATETIME DEFAULT '2010-01-01 00:00:00',
par15 TIME DEFAULT '00:00:00',
par16 YEAR DEFAULT 2010,
par17 BOOLEAN DEFAULT TRUE,
par18 TYPE OF t1.a DEFAULT 10,
par19 TYPE OF d1.t1.a DEFAULT 10,
par20 ROW TYPE OF t1 DEFAULT ROW(1, 'cde'),
par21 ROW TYPE OF d1.t1 DEFAULT ROW(1, 'cde'))
BEGIN
SELECT par1, par2, par3, par4, par5, par6, par7, par8, par9,
par10, par11, par12, par13, par14, par15, par16, par17, par18,
par19, par20.b, par21.b
FROM DUAL;
END;
$$
CALL p1();
par1 par2 par3 par4 par5 par6 par7 par8 par9 par10 par11 par12 par13 par14 par15 par16 par17 par18 par19 par20.b par21.b
1 abc 2010-01-01 1.23 1.23 1.23 a a a a a a 2010-01-01 00:00:00 2010-01-01 00:00:00 00:00:00 2010 1 10 10 cde cde
DROP PROCEDURE p1;
DROP TABLE t1;
DROP DATABASE d1;
#
# Default parameters in package's routines
#
CREATE OR REPLACE PACKAGE p1
PROCEDURE p1(par1 INT,
par2 INT DEFAULT 2);
FUNCTION f1(par1 INT,
par2 INT DEFAULT 2) RETURNS INT;
END;
$$
CREATE OR REPLACE PACKAGE BODY p1
PROCEDURE p1(par1 INT,
par2 INT DEFAULT 2)
BEGIN
SELECT par1, par2 FROM DUAL;
END;
FUNCTION f1(par1 INT,
par2 INT DEFAULT 2) RETURNS INT
BEGIN
RETURN par1 + par2;
END;
END;
$$
CALL p1.p1(1,4);
par1 par2
1 4
CALL p1.p1(1);
par1 par2
1 2
SELECT p1.f1(1,4) FROM DUAL;
p1.f1(1,4)
5
SELECT p1.f1(1) FROM DUAL;
p1.f1(1)
3
DROP PACKAGE p1;
121 changes: 121 additions & 0 deletions mysql-test/main/sp-default-param.test
Original file line number Diff line number Diff line change
@@ -0,0 +1,121 @@
--echo #
--echo # MDEV-10862 Stored procedures: default values for parameters (optional parameters)
--echo #

--echo #
--echo # Basic default parameter test for procedures
--echo #

DELIMITER $$;
CREATE OR REPLACE PROCEDURE p1(par1 INT, par2 INT DEFAULT 1)
BEGIN
SELECT par1, par2 FROM DUAL;
END;
$$
DELIMITER ;$$
CALL p1(2,3);
CALL p1(2);
--error ER_SP_WRONG_NO_OF_ARGS
CALL p1(2,3,4);
--error ER_SP_WRONG_NO_OF_ARGS
CALL p1();

DROP PROCEDURE p1;

--echo #
--echo # Basic default parameter test for functions
--echo #
DELIMITER $$;
CREATE OR REPLACE FUNCTION f1(par1 INT, par2 INT DEFAULT 1) RETURNS INT
RETURN par1 + par2;
$$
DELIMITER ;$$
SELECT f1(2,3) FROM DUAL;
SELECT f1(2) FROM DUAL;
--error ER_SP_WRONG_NO_OF_ARGS
SELECT f1(2,3,4) FROM DUAL;
--error ER_SP_WRONG_NO_OF_ARGS
SELECT f1() FROM DUAL;

DROP FUNCTION f1;

--echo #
--echo # Test various data types
--echo #
CREATE TABLE t1 (a INT, b VARCHAR(10));

CREATE DATABASE d1;
USE d1;
CREATE TABLE t1 (a INT, b VARCHAR(10));

USE test;
DELIMITER $$;
CREATE OR REPLACE PROCEDURE p1(par1 INT DEFAULT 1,
par2 VARCHAR(10) DEFAULT 'abc',
par3 DATE DEFAULT '2010-01-01',
par4 DECIMAL(10,2) DEFAULT 1.23,
par5 DOUBLE DEFAULT 1.23,
par6 FLOAT DEFAULT 1.23,
par7 CHAR DEFAULT 'a',
par8 BINARY DEFAULT 'a',
par9 BLOB DEFAULT 'a',
par10 TEXT DEFAULT 'a',
par11 ENUM('a','b') DEFAULT 'a',
par12 SET('a','b') DEFAULT 'a',
par13 TIMESTAMP DEFAULT '2010-01-01 00:00:00',
par14 DATETIME DEFAULT '2010-01-01 00:00:00',
par15 TIME DEFAULT '00:00:00',
par16 YEAR DEFAULT 2010,
par17 BOOLEAN DEFAULT TRUE,
par18 TYPE OF t1.a DEFAULT 10,
par19 TYPE OF d1.t1.a DEFAULT 10,
par20 ROW TYPE OF t1 DEFAULT ROW(1, 'cde'),
par21 ROW TYPE OF d1.t1 DEFAULT ROW(1, 'cde'))
BEGIN
SELECT par1, par2, par3, par4, par5, par6, par7, par8, par9,
par10, par11, par12, par13, par14, par15, par16, par17, par18,
par19, par20.b, par21.b
FROM DUAL;
END;
$$
DELIMITER ;$$

CALL p1();

DROP PROCEDURE p1;
DROP TABLE t1;
DROP DATABASE d1;

--echo #
--echo # Default parameters in package's routines
--echo #
DELIMITER $$;
CREATE OR REPLACE PACKAGE p1
PROCEDURE p1(par1 INT,
par2 INT DEFAULT 2);
FUNCTION f1(par1 INT,
par2 INT DEFAULT 2) RETURNS INT;
END;
$$
CREATE OR REPLACE PACKAGE BODY p1
PROCEDURE p1(par1 INT,
par2 INT DEFAULT 2)
BEGIN
SELECT par1, par2 FROM DUAL;
END;
FUNCTION f1(par1 INT,
par2 INT DEFAULT 2) RETURNS INT
BEGIN
RETURN par1 + par2;
END;
END;
$$
DELIMITER ;$$

CALL p1.p1(1,4);
CALL p1.p1(1);
SELECT p1.f1(1,4) FROM DUAL;
SELECT p1.f1(1) FROM DUAL;

DROP PACKAGE p1;

16 changes: 16 additions & 0 deletions mysql-test/suite/compat/oracle/r/sp-code.result
Original file line number Diff line number Diff line change
Expand Up @@ -1514,3 +1514,19 @@ SHOW PROCEDURE CODE p1;
Pos Instruction
0 stmt 31 "max_error_count:=10"
DROP PROCEDURE p1;
#
# MDEV-10862 Stored procedures: default values for parameters (optional parameters)
#
CREATE OR REPLACE PROCEDURE p1(par1 IN INT, par2 IN INT DEFAULT 1)
AS
var1 INT DEFAULT 5;
BEGIN
SELECT par1, par2 FROM DUAL;
END;
$$
SHOW PROCEDURE CODE p1;
Pos Instruction
0 set default param par2@1 1
1 set var1@2 5
2 stmt 0 "SELECT par1, par2 FROM DUAL"
DROP PROCEDURE p1;
Loading

0 comments on commit f46733b

Please sign in to comment.