Commit 5f7c764f authored by Alexander Barkov's avatar Alexander Barkov

MDEV-11952 Oracle-style packages: stage#5

Backporting from bb-10.2-compatibility to bb-10.2-ext

Version: 2018-01-26

- CREATE PACKAGE [BODY] statements are now
  entirely written to mysql.proc with type='PACKAGE' and type='PACKAGE BODY'.
- CREATE PACKAGE BODY now supports IF NOT EXISTS
- DROP PACKAGE BODY now supports IF EXISTS
- CREATE OR REPLACE PACKAGE [BODY] is now supported
- CREATE PACKAGE [BODY] now support the DEFINER clause:

    CREATE DEFINER user@host PACKAGE pkg ... END;
    CREATE DEFINER user@host PACKAGE BODY pkg ... END;

- CREATE PACKAGE [BODY] now supports SQL SECURITY and COMMENT clauses, e.g.:

    CREATE PACKAGE p1 SQL SECURITY INVOKER COMMENT "comment" AS ... END;

- Package routines are now created from the package CREATE PACKAGE BODY
  statement and don't produce individual records in mysql.proc.

- CREATE PACKAGE BODY now supports package-wide variables.
  Package variables can be read and set inside package routines.
  Package variables are stored in a separate sp_rcontext,
  which is cached in THD on the first packate routine call.

- CREATE PACKAGE BODY now supports the initialization section.

- All public routines (i.e. declared in CREATE PACKAGE)
  must have implementations in CREATE PACKAGE BODY

- Only public package routines are available outside of the package

- {CREATE|DROP} PACKAGE [BODY] now respects CREATE ROUTINE and ALTER ROUTINE
  privileges

- "GRANT EXECUTE ON PACKAGE BODY pkg" is now supported

- SHOW CREATE PACKAGE [BODY] is now supported

- SHOW PACKAGE [BODY] STATUS is now supported

- CREATE and DROP for PACKAGE [BODY] now works for non-current databases

- mysqldump now supports packages

- "SHOW {PROCEDURE|FUNCTION) CODE pkg.routine" now works for package routines

- "SHOW PACKAGE BODY CODE pkg" now works (the package initialization section)

- A new package body level MDL was added

- Recursive calls for package procedures are now possible

- Routine forward declarations in CREATE PACKATE BODY are now supported.

- Package body variables now work as SP OUT parameters

- Package body variables now work as SELECT INTO targets

- Package body variables now support ROW, %ROWTYPE, %TYPE
parent b8af22af
......@@ -2478,7 +2478,14 @@ static void print_blob_as_hex(FILE *output_file, const char *str, ulong len)
static uint dump_routines_for_db(char *db)
{
char query_buff[QUERY_LENGTH];
const char *routine_type[]= {"FUNCTION", "PROCEDURE"};
const char *routine_type[]= {"FUNCTION",
"PROCEDURE",
"PACKAGE",
"PACKAGE BODY"};
const char *create_caption_xml[]= {"Create Function",
"Create Procedure",
"Create Package",
"Create Package Body"};
char db_name_buff[NAME_LEN*2+3], name_buff[NAME_LEN*2+3];
char *routine_name;
int i;
......@@ -2516,8 +2523,8 @@ static uint dump_routines_for_db(char *db)
if (opt_xml)
fputs("\t<routines>\n", sql_file);
/* 0, retrieve and dump functions, 1, procedures */
for (i= 0; i <= 1; i++)
/* 0, retrieve and dump functions, 1, procedures, etc. */
for (i= 0; i < 4; i++)
{
my_snprintf(query_buff, sizeof(query_buff),
"SHOW %s STATUS WHERE Db = '%s'",
......@@ -2567,12 +2574,8 @@ static uint dump_routines_for_db(char *db)
{
if (opt_xml)
{
if (i) /* Procedures. */
print_xml_row(sql_file, "routine", routine_res, &row,
"Create Procedure");
else /* Functions. */
print_xml_row(sql_file, "routine", routine_res, &row,
"Create Function");
print_xml_row(sql_file, "routine", routine_res, &row,
create_caption_xml[i]);
continue;
}
if (opt_drop)
......
......@@ -647,7 +647,7 @@ select * from t115;
table_name column_name column_type
proc db char(64)
proc name char(64)
proc type enum('FUNCTION','PROCEDURE')
proc type enum('FUNCTION','PROCEDURE','PACKAGE','PACKAGE BODY')
proc specific_name char(64)
proc language enum('SQL')
proc sql_data_access enum('CONTAINS_SQL','NO_SQL','READS_SQL_DATA','MODIFIES_SQL_DATA')
......
......@@ -9,7 +9,7 @@ ROUTINES CREATE TEMPORARY TABLE `ROUTINES` (
`ROUTINE_CATALOG` varchar(512) NOT NULL DEFAULT '',
`ROUTINE_SCHEMA` varchar(64) NOT NULL DEFAULT '',
`ROUTINE_NAME` varchar(64) NOT NULL DEFAULT '',
`ROUTINE_TYPE` varchar(9) NOT NULL DEFAULT '',
`ROUTINE_TYPE` varchar(13) NOT NULL DEFAULT '',
`DATA_TYPE` varchar(64) NOT NULL DEFAULT '',
`CHARACTER_MAXIMUM_LENGTH` int(21) DEFAULT NULL,
`CHARACTER_OCTET_LENGTH` int(21) DEFAULT NULL,
......@@ -137,14 +137,14 @@ ORDINAL_POSITION 5
COLUMN_DEFAULT ''
IS_NULLABLE NO
DATA_TYPE varchar
CHARACTER_MAXIMUM_LENGTH 9
CHARACTER_OCTET_LENGTH 27
CHARACTER_MAXIMUM_LENGTH 13
CHARACTER_OCTET_LENGTH 39
NUMERIC_PRECISION NULL
NUMERIC_SCALE NULL
DATETIME_PRECISION NULL
CHARACTER_SET_NAME utf8
COLLATION_NAME utf8_general_ci
COLUMN_TYPE varchar(9)
COLUMN_TYPE varchar(13)
COLUMN_KEY
EXTRA
PRIVILEGES #
......@@ -729,7 +729,7 @@ SPECIFIC_NAME varchar(64) NO
ROUTINE_CATALOG varchar(512) NO
ROUTINE_SCHEMA varchar(64) NO
ROUTINE_NAME varchar(64) NO
ROUTINE_TYPE varchar(9) NO
ROUTINE_TYPE varchar(13) NO
DATA_TYPE varchar(64) NO
CHARACTER_MAXIMUM_LENGTH int(21) YES NULL
CHARACTER_OCTET_LENGTH int(21) YES NULL
......
......@@ -1421,7 +1421,7 @@ performance-schema-max-rwlock-instances -1
performance-schema-max-socket-classes 10
performance-schema-max-socket-instances -1
performance-schema-max-stage-classes 160
performance-schema-max-statement-classes 191
performance-schema-max-statement-classes 200
performance-schema-max-table-handles -1
performance-schema-max-table-instances -1
performance-schema-max-thread-classes 50
......
......@@ -1131,7 +1131,7 @@ def information_schema ROUTINES ROUTINES SPECIFIC_NAME SPECIFIC_NAME 253 192 2 N
def information_schema ROUTINES ROUTINES ROUTINE_CATALOG ROUTINE_CATALOG 253 1536 3 N 1 0 33
def information_schema ROUTINES ROUTINES ROUTINE_SCHEMA ROUTINE_SCHEMA 253 192 4 N 1 0 33
def information_schema ROUTINES ROUTINES ROUTINE_NAME ROUTINE_NAME 253 192 2 N 1 0 33
def information_schema ROUTINES ROUTINES ROUTINE_TYPE ROUTINE_TYPE 253 27 9 N 1 0 33
def information_schema ROUTINES ROUTINES ROUTINE_TYPE ROUTINE_TYPE 253 39 9 N 1 0 33
def information_schema ROUTINES ROUTINES DTD_IDENTIFIER DTD_IDENTIFIER 252 589815 0 Y 16 0 33
def information_schema ROUTINES ROUTINES ROUTINE_BODY ROUTINE_BODY 253 24 3 N 1 0 33
def information_schema ROUTINES ROUTINES ROUTINE_DEFINITION ROUTINE_DEFINITION 252 589815 8 Y 16 0 33
......@@ -1186,7 +1186,7 @@ def information_schema ROUTINES ROUTINES SPECIFIC_NAME SPECIFIC_NAME 253 192 2 N
def information_schema ROUTINES ROUTINES ROUTINE_CATALOG ROUTINE_CATALOG 253 1536 3 N 1 0 33
def information_schema ROUTINES ROUTINES ROUTINE_SCHEMA ROUTINE_SCHEMA 253 192 4 N 1 0 33
def information_schema ROUTINES ROUTINES ROUTINE_NAME ROUTINE_NAME 253 192 2 N 1 0 33
def information_schema ROUTINES ROUTINES ROUTINE_TYPE ROUTINE_TYPE 253 27 8 N 1 0 33
def information_schema ROUTINES ROUTINES ROUTINE_TYPE ROUTINE_TYPE 253 39 8 N 1 0 33
def information_schema ROUTINES ROUTINES DTD_IDENTIFIER DTD_IDENTIFIER 252 589815 7 Y 16 0 33
def information_schema ROUTINES ROUTINES ROUTINE_BODY ROUTINE_BODY 253 24 3 N 1 0 33
def information_schema ROUTINES ROUTINES ROUTINE_DEFINITION ROUTINE_DEFINITION 252 589815 8 Y 16 0 33
......
......@@ -88,6 +88,8 @@ Acl_column_grants 0
Acl_database_grants 0
Acl_function_grants 0
Acl_procedure_grants 0
Acl_package_spec_grants 0
Acl_package_body_grants 0
Acl_proxy_users 0
Acl_role_grants 0
Acl_roles 0
......
......@@ -176,7 +176,7 @@ procs_priv CREATE TABLE `procs_priv` (
`Db` char(64) COLLATE utf8_bin NOT NULL DEFAULT '',
`User` char(80) COLLATE utf8_bin NOT NULL DEFAULT '',
`Routine_name` char(64) CHARACTER SET utf8 NOT NULL DEFAULT '',
`Routine_type` enum('FUNCTION','PROCEDURE') COLLATE utf8_bin NOT NULL,
`Routine_type` enum('FUNCTION','PROCEDURE','PACKAGE','PACKAGE BODY') COLLATE utf8_bin NOT NULL,
`Grantor` char(141) COLLATE utf8_bin NOT NULL DEFAULT '',
`Proc_priv` set('Execute','Alter Routine','Grant') CHARACTER SET utf8 NOT NULL DEFAULT '',
`Timestamp` timestamp NOT NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
......@@ -202,7 +202,7 @@ Table Create Table
proc CREATE TABLE `proc` (
`db` char(64) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL DEFAULT '',
`name` char(64) NOT NULL DEFAULT '',
`type` enum('FUNCTION','PROCEDURE') NOT NULL,
`type` enum('FUNCTION','PROCEDURE','PACKAGE','PACKAGE BODY') NOT NULL,
`specific_name` char(64) NOT NULL DEFAULT '',
`language` enum('SQL') NOT NULL DEFAULT 'SQL',
`sql_data_access` enum('CONTAINS_SQL','NO_SQL','READS_SQL_DATA','MODIFIES_SQL_DATA') NOT NULL DEFAULT 'CONTAINS_SQL',
......
......@@ -176,7 +176,7 @@ procs_priv CREATE TABLE `procs_priv` (
`Db` char(64) COLLATE utf8_bin NOT NULL DEFAULT '',
`User` char(80) COLLATE utf8_bin NOT NULL DEFAULT '',
`Routine_name` char(64) CHARACTER SET utf8 NOT NULL DEFAULT '',
`Routine_type` enum('FUNCTION','PROCEDURE') COLLATE utf8_bin NOT NULL,
`Routine_type` enum('FUNCTION','PROCEDURE','PACKAGE','PACKAGE BODY') COLLATE utf8_bin NOT NULL,
`Grantor` char(141) COLLATE utf8_bin NOT NULL DEFAULT '',
`Proc_priv` set('Execute','Alter Routine','Grant') CHARACTER SET utf8 NOT NULL DEFAULT '',
`Timestamp` timestamp NOT NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
......@@ -202,7 +202,7 @@ Table Create Table
proc CREATE TABLE `proc` (
`db` char(64) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL DEFAULT '',
`name` char(64) NOT NULL DEFAULT '',
`type` enum('FUNCTION','PROCEDURE') NOT NULL,
`type` enum('FUNCTION','PROCEDURE','PACKAGE','PACKAGE BODY') NOT NULL,
`specific_name` char(64) NOT NULL DEFAULT '',
`language` enum('SQL') NOT NULL DEFAULT 'SQL',
`sql_data_access` enum('CONTAINS_SQL','NO_SQL','READS_SQL_DATA','MODIFIES_SQL_DATA') NOT NULL DEFAULT 'CONTAINS_SQL',
......
......@@ -176,7 +176,7 @@ procs_priv CREATE TABLE `procs_priv` (
`Db` char(64) COLLATE utf8_bin NOT NULL DEFAULT '',
`User` char(80) COLLATE utf8_bin NOT NULL DEFAULT '',
`Routine_name` char(64) CHARACTER SET utf8 NOT NULL DEFAULT '',
`Routine_type` enum('FUNCTION','PROCEDURE') COLLATE utf8_bin NOT NULL,
`Routine_type` enum('FUNCTION','PROCEDURE','PACKAGE','PACKAGE BODY') COLLATE utf8_bin NOT NULL,
`Grantor` char(141) COLLATE utf8_bin NOT NULL DEFAULT '',
`Proc_priv` set('Execute','Alter Routine','Grant') CHARACTER SET utf8 NOT NULL DEFAULT '',
`Timestamp` timestamp NOT NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
......@@ -202,7 +202,7 @@ Table Create Table
proc CREATE TABLE `proc` (
`db` char(64) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL DEFAULT '',
`name` char(64) NOT NULL DEFAULT '',
`type` enum('FUNCTION','PROCEDURE') NOT NULL,
`type` enum('FUNCTION','PROCEDURE','PACKAGE','PACKAGE BODY') NOT NULL,
`specific_name` char(64) NOT NULL DEFAULT '',
`language` enum('SQL') NOT NULL DEFAULT 'SQL',
`sql_data_access` enum('CONTAINS_SQL','NO_SQL','READS_SQL_DATA','MODIFIES_SQL_DATA') NOT NULL DEFAULT 'CONTAINS_SQL',
......
......@@ -176,7 +176,7 @@ procs_priv CREATE TABLE `procs_priv` (
`Db` char(64) COLLATE utf8_bin NOT NULL DEFAULT '',
`User` char(80) COLLATE utf8_bin NOT NULL DEFAULT '',
`Routine_name` char(64) CHARACTER SET utf8 NOT NULL DEFAULT '',
`Routine_type` enum('FUNCTION','PROCEDURE') COLLATE utf8_bin NOT NULL,
`Routine_type` enum('FUNCTION','PROCEDURE','PACKAGE','PACKAGE BODY') COLLATE utf8_bin NOT NULL,
`Grantor` char(141) COLLATE utf8_bin NOT NULL DEFAULT '',
`Proc_priv` set('Execute','Alter Routine','Grant') CHARACTER SET utf8 NOT NULL DEFAULT '',
`Timestamp` timestamp NOT NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
......@@ -202,7 +202,7 @@ Table Create Table
proc CREATE TABLE `proc` (
`db` char(64) CHARACTER SET utf8 COLLATE utf8_bin NOT NULL DEFAULT '',
`name` char(64) NOT NULL DEFAULT '',
`type` enum('FUNCTION','PROCEDURE') NOT NULL,
`type` enum('FUNCTION','PROCEDURE','PACKAGE','PACKAGE BODY') NOT NULL,
`specific_name` char(64) NOT NULL DEFAULT '',
`language` enum('SQL') NOT NULL DEFAULT 'SQL',
`sql_data_access` enum('CONTAINS_SQL','NO_SQL','READS_SQL_DATA','MODIFIES_SQL_DATA') NOT NULL DEFAULT 'CONTAINS_SQL',
......
SET sql_mode=ORACLE;
CREATE PACKAGE p1 AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END;
$$
CREATE PACKAGE IF NOT EXISTS p1 AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END;
$$
Warnings:
Note 1304 PACKAGE p1 already exists
CREATE PACKAGE BODY p1 AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
FUNCTION f1 RETURN INT AS
BEGIN
RETURN 10;
END;
END;
$$
DROP PACKAGE BODY p1;
DROP PACKAGE p1;
DROP PACKAGE IF EXISTS p1;
Warnings:
Note 1305 PACKAGE test.p1 does not exist
#
# Creating a package with a COMMENT clause
#
CREATE PACKAGE p1 COMMENT 'package-p1-comment' AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY p1 COMMENT 'package-body-p1-comment' AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
END;
$$
DROP PACKAGE p1;
#
# Creating a package with a different DEFINER
#
CREATE DEFINER=xxx@localhost PACKAGE p1 AS
PROCEDURE p1;
END;
$$
Warnings:
Note 1449 The user specified as a definer ('xxx'@'localhost') does not exist
CREATE DEFINER=xxx@localhost PACKAGE BODY p1 AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
END;
$$
Warnings:
Note 1449 The user specified as a definer ('xxx'@'localhost') does not exist
DROP PACKAGE p1;
#
# Creating a package with a different DEFINER, with SQL SECURITY INVOKER
#
CREATE DEFINER=xxx@localhost PACKAGE p1 SQL SECURITY INVOKER AS
PROCEDURE p1;
END;
$$
Warnings:
Note 1449 The user specified as a definer ('xxx'@'localhost') does not exist
CREATE DEFINER=xxx@localhost PACKAGE BODY p1 SQL SECURITY INVOKER AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
END;
$$
Warnings:
Note 1449 The user specified as a definer ('xxx'@'localhost') does not exist
DROP PACKAGE p1;
#
# Creating a new package in a remote database
#
CREATE DATABASE test2;
CREATE PACKAGE test2.test2 COMMENT 'package-test2-comment' AS
FUNCTION f1 RETURN INT;
PROCEDURE p1;
END
$$
CREATE PACKAGE BODY test2.test2 COMMENT 'package-body-test2-comment' AS
FUNCTION f1 RETURN INT AS BEGIN RETURN 10; END;
PROCEDURE p1 AS BEGIN SELECT f1(); END;
END;
$$
DROP PACKAGE BODY test2.test2;
DROP PACKAGE test2.test2;
DROP DATABASE test2;
#
# MDEV-13139 Package-wide variables in CREATE PACKAGE
#
CREATE TABLE t1 (a INT);
CREATE PACKAGE p1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY p1 AS
a INT:=0;
PROCEDURE p1 AS
BEGIN
INSERT INTO t1 VALUES (a);
a:=a+1;
END;
BEGIN
a:=10;
END;
$$
CALL p1.p1();
CALL p1.p1();
SELECT * FROM t1;
a
10
11
# sp-cache-invalidate
CALL p1.p1();
CALL p1.p1();
SELECT * FROM t1;
a
10
11
10
11
DROP PACKAGE p1;
DROP TABLE t1;
include/show_binlog_events.inc
Log_name Pos Event_type Server_id End_log_pos Info
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="root"@"localhost" PACKAGE "p1" AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="root"@"localhost" PACKAGE IF NOT EXISTS "p1" AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="root"@"localhost" PACKAGE BODY "p1" AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
FUNCTION f1 RETURN INT AS
BEGIN
RETURN 10;
END;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP PACKAGE BODY p1
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP PACKAGE p1
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP PACKAGE IF EXISTS p1
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="root"@"localhost" PACKAGE "p1" COMMENT 'package-p1-comment'
AS
PROCEDURE p1;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="root"@"localhost" PACKAGE BODY "p1" COMMENT 'package-body-p1-comment'
AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP PACKAGE p1
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="xxx"@"localhost" PACKAGE "p1" AS
PROCEDURE p1;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="xxx"@"localhost" PACKAGE BODY "p1" AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP PACKAGE p1
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="xxx"@"localhost" PACKAGE "p1" SQL SECURITY INVOKER
AS
PROCEDURE p1;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="xxx"@"localhost" PACKAGE BODY "p1" SQL SECURITY INVOKER
AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP PACKAGE p1
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # CREATE DATABASE test2
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="root"@"localhost" PACKAGE "test2"."test2" COMMENT 'package-test2-comment'
AS
FUNCTION f1 RETURN INT;
PROCEDURE p1;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="root"@"localhost" PACKAGE BODY "test2"."test2" COMMENT 'package-body-test2-comment'
AS
FUNCTION f1 RETURN INT AS BEGIN RETURN 10; END;
PROCEDURE p1 AS BEGIN SELECT f1(); END;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP PACKAGE BODY test2.test2
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP PACKAGE test2.test2
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # DROP DATABASE test2
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE TABLE t1 (a INT)
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="root"@"localhost" PACKAGE "p1" AS
PROCEDURE p1;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="root"@"localhost" PACKAGE BODY "p1" AS
a INT:=0;
PROCEDURE p1 AS
BEGIN
INSERT INTO t1 VALUES (a);
a:=a+1;
END;
BEGIN
a:=10;
END
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES ( NAME_CONST('a',10))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES ( NAME_CONST('a',11))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; CREATE DEFINER="root"@"localhost" FUNCTION "dummy"() RETURN int(11)
AS
BEGIN
RETURN 1;
END
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP FUNCTION dummy
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES ( NAME_CONST('a',10))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # BEGIN GTID #-#-#
master-bin.000001 # Query # # use `test`; INSERT INTO t1 VALUES ( NAME_CONST('a',11))
master-bin.000001 # Query # # COMMIT
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP PACKAGE p1
master-bin.000001 # Gtid # # GTID #-#-#
master-bin.000001 # Query # # use `test`; DROP TABLE "t1" /* generated by server */
include/master-slave.inc
[connection master]
connection master;
SET sql_mode=ORACLE;
CREATE PACKAGE pack AS
FUNCTION f1 RETURN INT;
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY pack AS
FUNCTION f1 RETURN INT AS
BEGIN
RETURN 10;
END;
PROCEDURE p1 AS
BEGIN
SELECT f1();
END;
END pack;
$$
connection slave;
connection slave;
SELECT * FROM mysql.proc WHERE db='test' AND name='pack';
db test
name pack
type PACKAGE
specific_name pack
language SQL
sql_data_access CONTAINS_SQL
is_deterministic NO
security_type DEFINER
param_list
returns
body AS
FUNCTION f1 RETURN INT;
PROCEDURE p1;
END
definer root@localhost
created #
modified #
sql_mode PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER
comment
character_set_client latin1
collation_connection latin1_swedish_ci
db_collation latin1_swedish_ci
body_utf8
db test
name pack
type PACKAGE BODY
specific_name pack
language SQL
sql_data_access CONTAINS_SQL
is_deterministic NO
security_type DEFINER
param_list
returns
body AS
FUNCTION f1 RETURN INT AS
BEGIN
RETURN 10;
END;
PROCEDURE p1 AS
BEGIN
SELECT f1();
END;
END
definer root@localhost
created #
modified #
sql_mode PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER
comment
character_set_client latin1
collation_connection latin1_swedish_ci
db_collation latin1_swedish_ci
body_utf8
SELECT * FROM mysql.proc WHERE db='test' AND name LIKE 'pack.%';
SET @@sql_mode=ORACLE;
SELECT pack.f1();
pack.f1()
10
CALL pack.p1();
f1()
10
SET @@sql_mode=DEFAULT;
connection master;
DROP PACKAGE pack;
connection slave;
connection slave;
SELECT COUNT(*) FROM mysql.proc WHERE db='test' AND name='pack';
COUNT(*)
0
#
# Creating a package with a COMMENT
#
connection master;
CREATE PACKAGE p1 COMMENT 'package-p1-comment' AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY p1 COMMENT 'package-body-p1-comment' AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
END;
$$
SELECT definer, name, security_type, type, `comment` FROM mysql.proc WHERE name LIKE 'p1%' ORDER BY definer, name, type;
definer name security_type type comment
root@localhost p1 DEFINER PACKAGE package-p1-comment
root@localhost p1 DEFINER PACKAGE BODY package-body-p1-comment
connection slave;
SELECT definer, name, security_type, type, `comment` FROM mysql.proc WHERE name LIKE 'p1%' ORDER BY definer, name, type;
definer name security_type type comment
root@localhost p1 DEFINER PACKAGE package-p1-comment
root@localhost p1 DEFINER PACKAGE BODY package-body-p1-comment
connection master;
DROP PACKAGE p1;
connection slave;
#
# Creating a package with a different DEFINER
#
connection master;
CREATE DEFINER=xxx@localhost PACKAGE p1 AS
PROCEDURE p1;
END;
$$
Warnings:
Note 1449 The user specified as a definer ('xxx'@'localhost') does not exist
CREATE DEFINER=xxx@localhost PACKAGE BODY p1 AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
END;
$$
Warnings:
Note 1449 The user specified as a definer ('xxx'@'localhost') does not exist
SELECT definer, name, security_type, type FROM mysql.proc WHERE name LIKE 'p1%' ORDER BY definer, name, type;
definer name security_type type
xxx@localhost p1 DEFINER PACKAGE
xxx@localhost p1 DEFINER PACKAGE BODY
connection slave;
SELECT definer, name, security_type, type FROM mysql.proc WHERE name LIKE 'p1%' ORDER BY definer, name, type;
definer name security_type type
xxx@localhost p1 DEFINER PACKAGE
xxx@localhost p1 DEFINER PACKAGE BODY
connection master;
DROP PACKAGE p1;
connection slave;
#
# Creating a package with a different DEFINER + SQL SECURITY INVOKER
#
connection master;
CREATE DEFINER=xxx@localhost PACKAGE p1 SQL SECURITY INVOKER AS
PROCEDURE p1;
END;
$$
Warnings:
Note 1449 The user specified as a definer ('xxx'@'localhost') does not exist
CREATE DEFINER=xxx@localhost PACKAGE BODY p1 SQL SECURITY INVOKER AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
END;
$$
Warnings:
Note 1449 The user specified as a definer ('xxx'@'localhost') does not exist
SELECT definer, name, security_type, type FROM mysql.proc WHERE name LIKE 'p1%' ORDER BY definer, name, type;
definer name security_type type
xxx@localhost p1 INVOKER PACKAGE
xxx@localhost p1 INVOKER PACKAGE BODY
connection slave;
SELECT definer, name, security_type, type FROM mysql.proc WHERE name LIKE 'p1%' ORDER BY definer, name, type;
definer name security_type type
xxx@localhost p1 INVOKER PACKAGE
xxx@localhost p1 INVOKER PACKAGE BODY
connection master;
DROP PACKAGE p1;
connection slave;
include/rpl_end.inc
include/master-slave.inc
[connection master]
connection master;
SET sql_mode=ORACLE;
#
# MDEV-13139 Package-wide variables in CREATE PACKAGE
#
connection master;
CREATE PACKAGE p1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY p1 AS
va INT:=10;
PROCEDURE p1 AS
BEGIN
INSERT INTO t1 VALUES (va);
END;
BEGIN
CREATE OR REPLACE TABLE t1 (a INT);
END;
$$
CALL p1.p1();
CALL p1.p1();
SELECT * FROM t1;
a
10
10
connection slave;
SELECT * FROM t1;
a
10
10
connection master;
DROP PACKAGE p1;
DROP TABLE t1;
connection slave;
include/rpl_end.inc
SET sql_mode=ORACLE;
CREATE PACKAGE pkg1 AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
PROCEDURE p2show;
PROCEDURE p2public;
FUNCTION f2public RETURN TEXT;
END;
$$
CREATE PACKAGE BODY pkg1 AS
a INT:=10;
PROCEDURE p1 AS
b INT:=20;
BEGIN
b:=a;
b:=a+1;
a:=b;
a:=b+1;
a:=a+1;
SET @a:=@a+2;
SELECT f1() FROM DUAL;
END;
FUNCTION f1 RETURN INT AS
BEGIN
RETURN a;
END;
PROCEDURE p2private AS
BEGIN
SELECT 'This is p2private';
END;
PROCEDURE p2public AS
BEGIN
SELECT 'This is p2public';
END;
FUNCTION f2private RETURN TEXT AS
BEGIN
RETURN 'This is f2private';
END;
FUNCTION f2public RETURN TEXT AS
BEGIN
RETURN 'This is f2public';
END;
PROCEDURE p2show AS
BEGIN
SHOW FUNCTION CODE f2public;
SHOW FUNCTION CODE f2private;
SHOW PROCEDURE CODE p2public;
SHOW PROCEDURE CODE p2private;
SHOW PROCEDURE CODE p2show;
END;
BEGIN
a:=a+1;
DECLARE
b INT;
BEGIN
b:=a;
b:=a+1;
a:=b;
a:=b+1;
END;
END;
$$
SHOW PROCEDURE CODE pkg1.p1;
Pos Instruction
0 set b@0 20
1 set b@0 PACKAGE_BODY.a@0
2 set b@0 PACKAGE_BODY.a@0 + 1
3 set PACKAGE_BODY.a@0 b@0
4 set PACKAGE_BODY.a@0 b@0 + 1
5 set PACKAGE_BODY.a@0 PACKAGE_BODY.a@0 + 1
6 stmt 31 "SET @a:=@a+2"
7 stmt 0 "SELECT f1() FROM DUAL"
SHOW FUNCTION CODE pkg1.f1;
Pos Instruction
0 freturn int PACKAGE_BODY.a@0
SHOW PACKAGE BODY CODE pkg1;
Pos Instruction
0 set a@0 10
1 set a@0 a@0 + 1
2 set b@1 NULL
3 set b@1 a@0
4 set b@1 a@0 + 1
5 set a@0 b@1
6 set a@0 b@1 + 1
7 jump 11
CALL pkg1.p2show;
Pos Instruction
0 freturn blob 'This is f2public'
Pos Instruction
0 freturn blob 'This is f2private'
Pos Instruction
0 stmt 0 "SELECT 'This is p2public'"
Pos Instruction
0 stmt 0 "SELECT 'This is p2private'"
Pos Instruction
0 stmt 110 "SHOW FUNCTION CODE f2public"
1 stmt 110 "SHOW FUNCTION CODE f2private"
2 stmt 109 "SHOW PROCEDURE CODE p2public"
3 stmt 109 "SHOW PROCEDURE CODE p2private"
4 stmt 109 "SHOW PROCEDURE CODE p2show"
DROP PACKAGE pkg1;
CREATE TABLE t1 (a INT);
CREATE PACKAGE pkg1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY pkg1 AS
a t1.a%TYPE:=10;
PROCEDURE p1 AS
b t1.a%TYPE:=20;
BEGIN
b:=a;
b:=a+1;
b:=b+1;
a:=b;
a:=b+1;
a:=a+1;
END;
BEGIN
a:=a+1;
DECLARE
b t1.a%TYPE;
BEGIN
b:=a;
b:=a+1;
a:=b;
a:=b+1;
END;
END;
$$
SHOW PROCEDURE CODE pkg1.p1;
Pos Instruction
0 set b@0 20
1 set b@0 PACKAGE_BODY.a@0
2 set b@0 PACKAGE_BODY.a@0 + 1
3 set b@0 b@0 + 1
4 set PACKAGE_BODY.a@0 b@0
5 set PACKAGE_BODY.a@0 b@0 + 1
6 set PACKAGE_BODY.a@0 PACKAGE_BODY.a@0 + 1
SHOW PACKAGE BODY CODE pkg1;
Pos Instruction
0 set a@0 10
1 set a@0 a@0 + 1
2 set b@1 NULL
3 set b@1 a@0
4 set b@1 a@0 + 1
5 set a@0 b@1
6 set a@0 b@1 + 1
7 jump 11
DROP PACKAGE pkg1;
DROP TABLE t1;
CREATE PACKAGE pkg1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY pkg1 AS
a ROW(a INT,b TEXT):=ROW(10,'x10');
PROCEDURE p1 AS
b ROW(a INT,b TEXT):=ROW(20,'x20');
BEGIN
b:=a;
a:=b;
b.a:=a.a+1;
a.a:=b.a+1;
a.a:=a.a+1;
END;
BEGIN
a.a:=a.a+1;
DECLARE
b ROW(a INT,b TEXT):=ROW(30,'x30');
BEGIN
b:=a;
b.a:=a.a+1;
a:=b;
a.a:=b.a+1;
END;
END;
$$
SHOW PROCEDURE CODE pkg1.p1;
Pos Instruction
0 set b@0 (20,'x20')
1 set b@0 PACKAGE_BODY.a@0
2 set PACKAGE_BODY.a@0 b@0
3 set b.a@0[0] PACKAGE_BODY.a.a@0[0] + 1
4 set PACKAGE_BODY.a.a@0[0] b.a@0[0] + 1
5 set PACKAGE_BODY.a.a@0[0] PACKAGE_BODY.a.a@0[0] + 1
SHOW PACKAGE BODY CODE pkg1;
Pos Instruction
0 set a@0 (10,'x10')
1 set a.a@0[0] a.a@0[0] + 1
2 set b@1 (30,'x30')
3 set b@1 a@0
4 set b.a@1[0] a.a@0[0] + 1
5 set a@0 b@1
6 set a.a@0[0] b.a@1[0] + 1
7 jump 11
DROP PACKAGE pkg1;
CREATE TABLE t1 (a INT, b TEXT);
CREATE PACKAGE pkg1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY pkg1 AS
a t1%ROWTYPE:=ROW(10,'x10');
PROCEDURE p1 AS
b t1%ROWTYPE:=ROW(20,'x20');
BEGIN
b:=a;
a:=b;
b.a:=a.a+1;
a.a:=b.a+1;
a.a:=a.a+1;
END;
BEGIN
a.a:=a.a+1;
DECLARE
b t1%ROWTYPE:=ROW(30,'x30');
BEGIN
b:=a;
b.a:=a.a+1;
a:=b;
a.a:=b.a+1;
END;
END;
$$
SHOW PROCEDURE CODE pkg1.p1;
Pos Instruction
0 set b@0 (20,'x20')
1 set b@0 PACKAGE_BODY.a@0
2 set PACKAGE_BODY.a@0 b@0
3 set b.a@0["a"] PACKAGE_BODY.a.a@0["a"] + 1
4 set PACKAGE_BODY.a.a@0["a"] b.a@0["a"] + 1
5 set PACKAGE_BODY.a.a@0["a"] PACKAGE_BODY.a.a@0["a"] + 1
SHOW PACKAGE BODY CODE pkg1;
Pos Instruction
0 set a@0 (10,'x10')
1 set a.a@0["a"] a.a@0["a"] + 1
2 set b@1 (30,'x30')
3 set b@1 a@0
4 set b.a@1["a"] a.a@0["a"] + 1
5 set a@0 b@1
6 set a.a@0["a"] b.a@1["a"] + 1
7 jump 11
DROP PACKAGE pkg1;
DROP TABLE t1;
#
# MDEV-15070 Crash when doing a CREATE VIEW inside a package routine
#
SET @object_type='db';
#
# Start of sp-package-concurrent-dml.inc
#
SET sql_mode=ORACLE;
CREATE PACKAGE pkg1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY pkg1 AS
PROCEDURE p2 AS
BEGIN
SELECT 'This is p2' AS msg;
END;
PROCEDURE p1 AS
BEGIN
SELECT 'This is p1' AS msg;
DO GET_LOCK('mdev15070',120);
CALL p2();
DO RELEASE_LOCK('mdev15070');
END;
END;
$$
connect con2,localhost,root;
connection con2;
DO GET_LOCK('mdev15070', 120);
connection default;
CALL pkg1.p1;
connection con2;
CREATE DATABASE test1;
CREATE FUNCTION test1.f1() RETURNS INT RETURN 10;
DROP DATABASE test1;
DO RELEASE_LOCK('mdev15070');
disconnect con2;
connection default;
msg
This is p1
msg
This is p2
DROP PACKAGE IF EXISTS pkg1;
#
# MDEV-15070 Crash when doing a CREATE VIEW inside a package routine
#
SET @object_type='package_replace_pkg1';
#
# Start of sp-package-concurrent-dml.inc
#
SET sql_mode=ORACLE;
CREATE PACKAGE pkg1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY pkg1 AS
PROCEDURE p2 AS
BEGIN
SELECT 'This is p2' AS msg;
END;
PROCEDURE p1 AS
BEGIN
SELECT 'This is p1' AS msg;
DO GET_LOCK('mdev15070',120);
CALL p2();
DO RELEASE_LOCK('mdev15070');
END;
END;
$$
connect con2,localhost,root;
connection con2;
DO GET_LOCK('mdev15070', 120);
connection default;
CALL pkg1.p1;
connection con2;
SET sql_mode=ORACLE;
CREATE OR REPLACE PACKAGE pkg1 AS
PROCEDURE p1;
END;
$$
DROP PACKAGE pkg1;
DO RELEASE_LOCK('mdev15070');
disconnect con2;
connection default;
msg
This is p1
msg
This is p2
DROP PACKAGE IF EXISTS pkg1;
Warnings:
Note 1305 PACKAGE test.pkg1 does not exist
SET @object_type='package_body_replace_pkg1';
#
# Start of sp-package-concurrent-dml.inc
#
SET sql_mode=ORACLE;
CREATE PACKAGE pkg1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY pkg1 AS
PROCEDURE p2 AS
BEGIN
SELECT 'This is p2' AS msg;
END;
PROCEDURE p1 AS
BEGIN
SELECT 'This is p1' AS msg;
DO GET_LOCK('mdev15070',120);
CALL p2();
DO RELEASE_LOCK('mdev15070');
END;
END;
$$
connect con2,localhost,root;
connection con2;
DO GET_LOCK('mdev15070', 120);
connection default;
CALL pkg1.p1;
connection con2;
SET sql_mode=ORACLE;
CREATE OR REPLACE PACKAGE BODY pkg1 AS
PROCEDURE p1 AS
BEGIN
SELECT 'This is p1 version 2' AS msg;
END;
END;
$$
DROP PACKAGE pkg1;
DO RELEASE_LOCK('mdev15070');
disconnect con2;
connection default;
msg
This is p1
msg
This is p2
DROP PACKAGE IF EXISTS pkg1;
Warnings:
Note 1305 PACKAGE test.pkg1 does not exist
#
# MDEV-15070 Crash when doing a CREATE VIEW inside a package routine
#
SET @object_type='trigger';
#
# Start of sp-package-concurrent-dml.inc
#
SET sql_mode=ORACLE;
CREATE PACKAGE pkg1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY pkg1 AS
PROCEDURE p2 AS
BEGIN
SELECT 'This is p2' AS msg;
END;
PROCEDURE p1 AS
BEGIN
SELECT 'This is p1' AS msg;
DO GET_LOCK('mdev15070',120);
CALL p2();
DO RELEASE_LOCK('mdev15070');
END;
END;
$$
connect con2,localhost,root;
connection con2;
DO GET_LOCK('mdev15070', 120);
connection default;
CALL pkg1.p1;
connection con2;
CREATE TABLE t1 (a INT);
CREATE TRIGGER tr1 BEFORE INSERT ON t1 FOR EACH ROW SET NEW.a=1;
DROP TRIGGER tr1;
DROP TABLE t1;
DO RELEASE_LOCK('mdev15070');
disconnect con2;
connection default;
msg
This is p1
msg
This is p2
DROP PACKAGE IF EXISTS pkg1;
#
# MDEV-15070 Crash when doing a CREATE VIEW inside a package routine
#
SET @object_type='view';
#
# Start of sp-package-concurrent-dml.inc
#
SET sql_mode=ORACLE;
CREATE PACKAGE pkg1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY pkg1 AS
PROCEDURE p2 AS
BEGIN
SELECT 'This is p2' AS msg;
END;
PROCEDURE p1 AS
BEGIN
SELECT 'This is p1' AS msg;
DO GET_LOCK('mdev15070',120);
CALL p2();
DO RELEASE_LOCK('mdev15070');
END;
END;
$$
connect con2,localhost,root;
connection con2;
DO GET_LOCK('mdev15070', 120);
connection default;
CALL pkg1.p1;
connection con2;
CREATE VIEW v1 AS SELECT 1 AS c;
DROP VIEW v1;
DO RELEASE_LOCK('mdev15070');
disconnect con2;
connection default;
msg
This is p1
msg
This is p2
DROP PACKAGE IF EXISTS pkg1;
SET default_storage_engine=InnoDB;
SET sql_mode=ORACLE;
CREATE TABLE t1 (a INT, routine TEXT);
SELECT ENGINE FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_SCHEMA='test' AND TABLE_NAME='t1';
ENGINE
InnoDB
INSERT INTO t1 VALUES (10,'none');
CREATE PACKAGE pkg1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY pkg1 AS
a INT;
PROCEDURE p1 AS
BEGIN
a:=a+1;
INSERT INTO t1 VALUES (a,'p1');
END;
BEGIN
SELECT MAX(t1.a) FROM t1 INTO a;
a:=a+1;
INSERT INTO t1 VALUES (a,'pkg1 initialization');
END;
$$
CALL pkg1.p1;
SELECT * FROM t1 ORDER BY a;
a routine
10 none
11 pkg1 initialization
12 p1
DELETE FROM t1;
# sp-cache-invalidate
START TRANSACTION;
CALL pkg1.p1;
SELECT * FROM t1 ORDER BY a;
a routine
NULL pkg1 initialization
NULL p1
ROLLBACK;
SELECT * FROM t1 ORDER BY a;
a routine
DELETE FROM t1;
# sp-cache-invalidate
INSERT INTO t1 VALUES (20,'none');
START TRANSACTION;
CALL pkg1.p1;
SELECT * FROM t1 ORDER BY a;
a routine
20 none
21 pkg1 initialization
22 p1
COMMIT;
SELECT * FROM t1 ORDER BY a;
a routine
20 none
21 pkg1 initialization
22 p1
DELETE FROM t1;
# sp-cache-invalidate
INSERT INTO t1 VALUES (20,'none');
START TRANSACTION;
CALL pkg1.p1;
SELECT * FROM t1 ORDER BY a;
a routine
20 none
21 pkg1 initialization
22 p1
ROLLBACK;
SELECT * FROM t1 ORDER BY a;
a routine
20 none
DELETE FROM t1;
DROP PACKAGE pkg1;
DROP TABLE t1;
SET sql_mode=ORACLE;
DO GET_LOCK('lock',300);
connect conn1,localhost,root,,;
SET sql_mode=ORACLE;
CREATE PACKAGE pkg1 AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END;
$$
CREATE PACKAGE BODY pkg1 AS
PROCEDURE p1 AS
BEGIN
DO GET_LOCK('lock',300);
END;
FUNCTION f1 RETURN INT AS
BEGIN
CALL p1;
RETURN 1;
END;
END;
$$
SELECT pkg1.f1();
connection default;
connect conn2,localhost,root,,;
SET sql_mode=ORACLE;
DROP PACKAGE pkg1;
connection default;
SELECT ID-CONNECTION_ID() AS CONN,INFO,STATE,LOCK_MODE,LOCK_TYPE,TABLE_NAME
FROM INFORMATION_SCHEMA.PROCESSLIST
LEFT JOIN INFORMATION_SCHEMA.METADATA_LOCK_INFO
ON (ID=THREAD_ID)
ORDER BY ID,TABLE_NAME,LOCK_MODE,LOCK_TYPE;
CONN 0
INFO SELECT ID-CONNECTION_ID() AS CONN,INFO,STATE,LOCK_MODE,LOCK_TYPE,TABLE_NAME
FROM INFORMATION_SCHEMA.PROCESSLIST
LEFT JOIN INFORMATION_SCHEMA.METADATA_LOCK_INFO
ON (ID=THREAD_ID)
ORDER BY ID,TABLE_NAME,LOCK_MODE,LOCK_TYPE
STATE Filling schema table
LOCK_MODE MDL_SHARED_NO_WRITE
LOCK_TYPE User lock
TABLE_NAME
CONN 1
INFO DO GET_LOCK('lock',300)
STATE User lock
LOCK_MODE MDL_SHARED
LOCK_TYPE Stored package body metadata lock
TABLE_NAME pkg1
CONN 1
INFO DO GET_LOCK('lock',300)
STATE User lock
LOCK_MODE MDL_SHARED
LOCK_TYPE Stored function metadata lock
TABLE_NAME pkg1.f1
CONN 1
INFO DO GET_LOCK('lock',300)
STATE User lock
LOCK_MODE MDL_SHARED
LOCK_TYPE Stored procedure metadata lock
TABLE_NAME pkg1.p1
CONN 2
INFO DROP PACKAGE pkg1
STATE Waiting for stored package body metadata lock
LOCK_MODE MDL_INTENTION_EXCLUSIVE
LOCK_TYPE Global read lock
TABLE_NAME
CONN 2
INFO DROP PACKAGE pkg1
STATE Waiting for stored package body metadata lock
LOCK_MODE MDL_INTENTION_EXCLUSIVE
LOCK_TYPE Schema metadata lock
TABLE_NAME
DO RELEASE_LOCK('lock');
connection conn1;
pkg1.f1()
1
disconnect conn1;
connection conn2;
disconnect conn2;
connection default;
SET sql_mode=ORACLE;
CREATE PROCEDURE p1 AS
BEGIN
SELECT pkg1.f1(); -- a standalone routine calls a package routine
END;
$$
CREATE PACKAGE pkg1 AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END;
$$
CREATE PACKAGE BODY pkg1 AS
PROCEDURE p1 AS
BEGIN
CALL test.p1; -- a package routine calls a standalone routine
END;
FUNCTION f1 RETURN INT AS
BEGIN
RETURN 10;
END;
END;
$$
CALL p1;
pkg1.f1()
10
CALL pkg1.p1;
pkg1.f1()
10
SELECT pkg1.f1();
pkg1.f1()
10
CREATE PACKAGE pkg2 AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END;
$$
/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
/*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */;
/*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */;
/*!40101 SET NAMES utf8 */;
/*!40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */;
/*!40103 SET TIME_ZONE='+00:00' */;
/*!40014 SET @OLD_UNIQUE_CHECKS=@@UNIQUE_CHECKS, UNIQUE_CHECKS=0 */;
/*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */;
/*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */;
/*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */;
/*!50003 DROP PROCEDURE IF EXISTS `p1` */;
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
/*!50003 SET @saved_col_connection = @@collation_connection */ ;
/*!50003 SET character_set_client = latin1 */ ;
/*!50003 SET character_set_results = latin1 */ ;
/*!50003 SET collation_connection = latin1_swedish_ci */ ;
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
/*!50003 SET sql_mode = 'PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER' */ ;
DELIMITER ;;
CREATE DEFINER="root"@"localhost" PROCEDURE "p1"()
AS
BEGIN
SELECT pkg1.f1(); -- a standalone routine calls a package routine
END ;;
DELIMITER ;
/*!50003 SET sql_mode = @saved_sql_mode */ ;
/*!50003 SET character_set_client = @saved_cs_client */ ;
/*!50003 SET character_set_results = @saved_cs_results */ ;
/*!50003 SET collation_connection = @saved_col_connection */ ;
/*!50003 DROP PACKAGE IF EXISTS `pkg1` */;
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
/*!50003 SET @saved_col_connection = @@collation_connection */ ;
/*!50003 SET character_set_client = latin1 */ ;
/*!50003 SET character_set_results = latin1 */ ;
/*!50003 SET collation_connection = latin1_swedish_ci */ ;
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
/*!50003 SET sql_mode = 'PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER' */ ;
DELIMITER ;;
CREATE DEFINER="root"@"localhost" PACKAGE "pkg1" AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END ;;
DELIMITER ;
/*!50003 SET sql_mode = @saved_sql_mode */ ;
/*!50003 SET character_set_client = @saved_cs_client */ ;
/*!50003 SET character_set_results = @saved_cs_results */ ;
/*!50003 SET collation_connection = @saved_col_connection */ ;
/*!50003 DROP PACKAGE IF EXISTS `pkg2` */;
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
/*!50003 SET @saved_col_connection = @@collation_connection */ ;
/*!50003 SET character_set_client = latin1 */ ;
/*!50003 SET character_set_results = latin1 */ ;
/*!50003 SET collation_connection = latin1_swedish_ci */ ;
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
/*!50003 SET sql_mode = 'PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER' */ ;
DELIMITER ;;
CREATE DEFINER="root"@"localhost" PACKAGE "pkg2" AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END ;;
DELIMITER ;
/*!50003 SET sql_mode = @saved_sql_mode */ ;
/*!50003 SET character_set_client = @saved_cs_client */ ;
/*!50003 SET character_set_results = @saved_cs_results */ ;
/*!50003 SET collation_connection = @saved_col_connection */ ;
/*!50003 DROP PACKAGE BODY IF EXISTS `pkg1` */;
/*!50003 SET @saved_cs_client = @@character_set_client */ ;
/*!50003 SET @saved_cs_results = @@character_set_results */ ;
/*!50003 SET @saved_col_connection = @@collation_connection */ ;
/*!50003 SET character_set_client = latin1 */ ;
/*!50003 SET character_set_results = latin1 */ ;
/*!50003 SET collation_connection = latin1_swedish_ci */ ;
/*!50003 SET @saved_sql_mode = @@sql_mode */ ;
/*!50003 SET sql_mode = 'PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER' */ ;
DELIMITER ;;
CREATE DEFINER="root"@"localhost" PACKAGE BODY "pkg1" AS
PROCEDURE p1 AS
BEGIN
CALL test.p1; -- a package routine calls a standalone routine
END;
FUNCTION f1 RETURN INT AS
BEGIN
RETURN 10;
END;
END ;;
DELIMITER ;
/*!50003 SET sql_mode = @saved_sql_mode */ ;
/*!50003 SET character_set_client = @saved_cs_client */ ;
/*!50003 SET character_set_results = @saved_cs_results */ ;
/*!50003 SET collation_connection = @saved_col_connection */ ;
/*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */;
/*!40101 SET SQL_MODE=@OLD_SQL_MODE */;
/*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */;
/*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */;
/*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */;
/*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */;
/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;
/*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */;
<?xml version="1.0"?>
<mysqldump xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance">
<database name="test">
<routines>
<routine Procedure="p1" sql_mode="PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER" character_set_client="latin1" collation_connection="latin1_swedish_ci" Database_Collation="latin1_swedish_ci">
<![CDATA[
CREATE DEFINER="root"@"localhost" PROCEDURE "p1"()
AS
BEGIN
SELECT pkg1.f1(); -- a standalone routine calls a package routine
END
]]>
</routine>
<routine Package="pkg1" sql_mode="PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER" character_set_client="latin1" collation_connection="latin1_swedish_ci" Database_Collation="latin1_swedish_ci">
<![CDATA[
CREATE DEFINER="root"@"localhost" PACKAGE "pkg1" AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END
]]>
</routine>
<routine Package="pkg2" sql_mode="PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER" character_set_client="latin1" collation_connection="latin1_swedish_ci" Database_Collation="latin1_swedish_ci">
<![CDATA[
CREATE DEFINER="root"@"localhost" PACKAGE "pkg2" AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END
]]>
</routine>
<routine Package_body="pkg1" sql_mode="PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER" character_set_client="latin1" collation_connection="latin1_swedish_ci" Database_Collation="latin1_swedish_ci">
<![CDATA[
CREATE DEFINER="root"@"localhost" PACKAGE BODY "pkg1" AS
PROCEDURE p1 AS
BEGIN
CALL test.p1; -- a package routine calls a standalone routine
END;
FUNCTION f1 RETURN INT AS
BEGIN
RETURN 10;
END;
END
]]>
</routine>
</routines>
</database>
</mysqldump>
DROP PACKAGE pkg1;
DROP PACKAGE pkg2;
DROP PROCEDURE p1;
SHOW PACKAGE STATUS;
Db test
Name pkg1
Type PACKAGE
Definer root@localhost
Modified 0000-00-00 00:00:00
Created 0000-00-00 00:00:00
Security_type DEFINER
Comment
character_set_client latin1
collation_connection latin1_swedish_ci
Database Collation latin1_swedish_ci
Db test
Name pkg2
Type PACKAGE
Definer root@localhost
Modified 0000-00-00 00:00:00
Created 0000-00-00 00:00:00
Security_type DEFINER
Comment
character_set_client latin1
collation_connection latin1_swedish_ci
Database Collation latin1_swedish_ci
SHOW PACKAGE BODY STATUS;
Db test
Name pkg1
Type PACKAGE BODY
Definer root@localhost
Modified 0000-00-00 00:00:00
Created 0000-00-00 00:00:00
Security_type DEFINER
Comment
character_set_client latin1
collation_connection latin1_swedish_ci
Database Collation latin1_swedish_ci
SHOW CREATE PACKAGE pkg1;
Package sql_mode Create Package character_set_client collation_connection Database Collation
pkg1 PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER CREATE DEFINER="root"@"localhost" PACKAGE "pkg1" AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END latin1 latin1_swedish_ci latin1_swedish_ci
SHOW CREATE PACKAGE pkg2;
Package sql_mode Create Package character_set_client collation_connection Database Collation
pkg2 PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER CREATE DEFINER="root"@"localhost" PACKAGE "pkg2" AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END latin1 latin1_swedish_ci latin1_swedish_ci
SHOW CREATE PACKAGE BODY pkg1;
Package body sql_mode Create Package Body character_set_client collation_connection Database Collation
pkg1 PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER CREATE DEFINER="root"@"localhost" PACKAGE BODY "pkg1" AS
PROCEDURE p1 AS
BEGIN
CALL test.p1;
END;
FUNCTION f1 RETURN INT AS
BEGIN
RETURN 10;
END;
END latin1 latin1_swedish_ci latin1_swedish_ci
CALL p1;
pkg1.f1()
10
CALL pkg1.p1;
pkg1.f1()
10
SELECT pkg1.f1();
pkg1.f1()
10
DROP PACKAGE pkg1;
DROP PACKAGE pkg2;
DROP PROCEDURE p1;
# removing the dump file
This diff is collapsed.
This diff is collapsed.
......@@ -166,6 +166,13 @@ IF a=10 THEN NULL; ELSE NULL; END IF;
END;
/
DROP PROCEDURE p1;
# Keywords that are OK for table names, but not for SP variables
CREATE TABLE function (function int);
INSERT INTO function SET function=10;
SELECT function.function FROM function;
function
10
DROP TABLE function;
# Testing that (some) keyword_sp are allowed in Oracle-style assignments
CREATE PROCEDURE p1 (action OUT INT) AS BEGIN action:=10; END;/
DROP PROCEDURE p1/
......
--source include/not_embedded.inc
--source include/have_binlog_format_statement.inc
--disable_query_log
reset master; # get rid of previous tests binlog
--enable_query_log
SET sql_mode=ORACLE;
DELIMITER $$;
CREATE PACKAGE p1 AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END;
$$
CREATE PACKAGE IF NOT EXISTS p1 AS
PROCEDURE p1;
FUNCTION f1 RETURN INT;
END;
$$
CREATE PACKAGE BODY p1 AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
FUNCTION f1 RETURN INT AS
BEGIN
RETURN 10;
END;
END;
$$
DELIMITER ;$$
DROP PACKAGE BODY p1;
DROP PACKAGE p1;
DROP PACKAGE IF EXISTS p1;
--echo #
--echo # Creating a package with a COMMENT clause
--echo #
DELIMITER $$;
CREATE PACKAGE p1 COMMENT 'package-p1-comment' AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY p1 COMMENT 'package-body-p1-comment' AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
END;
$$
DELIMITER ;$$
DROP PACKAGE p1;
--echo #
--echo # Creating a package with a different DEFINER
--echo #
DELIMITER $$;
CREATE DEFINER=xxx@localhost PACKAGE p1 AS
PROCEDURE p1;
END;
$$
CREATE DEFINER=xxx@localhost PACKAGE BODY p1 AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
END;
$$
DELIMITER ;$$
DROP PACKAGE p1;
--echo #
--echo # Creating a package with a different DEFINER, with SQL SECURITY INVOKER
--echo #
DELIMITER $$;
CREATE DEFINER=xxx@localhost PACKAGE p1 SQL SECURITY INVOKER AS
PROCEDURE p1;
END;
$$
CREATE DEFINER=xxx@localhost PACKAGE BODY p1 SQL SECURITY INVOKER AS
PROCEDURE p1 AS
BEGIN
NULL;
END;
END;
$$
DELIMITER ;$$
DROP PACKAGE p1;
--echo #
--echo # Creating a new package in a remote database
--echo #
CREATE DATABASE test2;
DELIMITER $$;
CREATE PACKAGE test2.test2 COMMENT 'package-test2-comment' AS
FUNCTION f1 RETURN INT;
PROCEDURE p1;
END
$$
DELIMITER ;$$
DELIMITER $$;
CREATE PACKAGE BODY test2.test2 COMMENT 'package-body-test2-comment' AS
FUNCTION f1 RETURN INT AS BEGIN RETURN 10; END;
PROCEDURE p1 AS BEGIN SELECT f1(); END;
END;
$$
DELIMITER ;$$
DROP PACKAGE BODY test2.test2;
DROP PACKAGE test2.test2;
DROP DATABASE test2;
--echo #
--echo # MDEV-13139 Package-wide variables in CREATE PACKAGE
--echo #
CREATE TABLE t1 (a INT);
DELIMITER $$;
CREATE PACKAGE p1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY p1 AS
a INT:=0;
PROCEDURE p1 AS
BEGIN
INSERT INTO t1 VALUES (a);
a:=a+1;
END;
BEGIN
a:=10;
END;
$$
DELIMITER ;$$
CALL p1.p1();
CALL p1.p1();
SELECT * FROM t1;
--source sp-cache-invalidate.inc
CALL p1.p1();
CALL p1.p1();
SELECT * FROM t1;
DROP PACKAGE p1;
DROP TABLE t1;
--let $binlog_file = LAST
source include/show_binlog_events.inc;
This diff is collapsed.
--source include/master-slave.inc
connection master;
SET sql_mode=ORACLE;
--echo #
--echo # MDEV-13139 Package-wide variables in CREATE PACKAGE
--echo #
connection master;
DELIMITER $$;
CREATE PACKAGE p1 AS
PROCEDURE p1;
END;
$$
CREATE PACKAGE BODY p1 AS
va INT:=10;
PROCEDURE p1 AS
BEGIN
INSERT INTO t1 VALUES (va);
END;
BEGIN
CREATE OR REPLACE TABLE t1 (a INT);
END;
$$
DELIMITER ;$$
CALL p1.p1();
CALL p1.p1();
SELECT * FROM t1;
sync_slave_with_master;
SELECT * FROM t1;
connection master;
DROP PACKAGE p1;
DROP TABLE t1;
sync_slave_with_master;
--source include/rpl_end.inc
--echo # sp-cache-invalidate
--disable_query_log
DELIMITER $$;
CREATE FUNCTION dummy RETURN INT AS
BEGIN
RETURN 1;
END;
$$
DELIMITER ;$$
DROP FUNCTION dummy;
--enable_query_log
This diff is collapsed.
--echo #
--echo # MDEV-15070 Crash when doing a CREATE VIEW inside a package routine
--echo #
SET @object_type='db';
--source sp-package-concurrent-dml.inc
--echo #
--echo # MDEV-15070 Crash when doing a CREATE VIEW inside a package routine
--echo #
SET @object_type='package_replace_pkg1';
--source sp-package-concurrent-dml.inc
SET @object_type='package_body_replace_pkg1';
--source sp-package-concurrent-dml.inc
--echo #
--echo # MDEV-15070 Crash when doing a CREATE VIEW inside a package routine
--echo #
SET @object_type='trigger';
--source sp-package-concurrent-dml.inc
--echo #
--echo # MDEV-15070 Crash when doing a CREATE VIEW inside a package routine
--echo #
SET @object_type='view';
--source sp-package-concurrent-dml.inc
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
......@@ -170,6 +170,11 @@ END;
DELIMITER ;/
DROP PROCEDURE p1;
--echo # Keywords that are OK for table names, but not for SP variables
CREATE TABLE function (function int);
INSERT INTO function SET function=10;
SELECT function.function FROM function;
DROP TABLE function;
--echo # Testing that (some) keyword_sp are allowed in Oracle-style assignments
DELIMITER /;
......
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment