summaryrefslogtreecommitdiffstats
path: root/mysql-test/suite/compat/oracle/t/sp-package-security.test
blob: 583f70afe14707f8d705b0422f88238802cd6536 (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
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
--source include/not_embedded.inc
--source include/default_charset.inc

SET sql_mode=ORACLE;

CREATE DATABASE db1;
CREATE USER u1@localhost IDENTIFIED BY '';
GRANT SELECT ON db1.* TO u1@localhost;

connect (conn1,localhost,u1,,db1);
SELECT CURRENT_USER;
SET sql_mode=ORACLE;

--echo #
--echo # User u1 cannot drop PROCEDURE, PACKAGE, PACKAGE BODY by default
--echo #

--error ER_PROCACCESS_DENIED_ERROR
DROP PROCEDURE p1;
--error ER_PROCACCESS_DENIED_ERROR
DROP PACKAGE pkg1;
--error ER_PROCACCESS_DENIED_ERROR
DROP PACKAGE BODY pkg1;

--echo #
--echo # User u1 cannot create PROCEDURE, PACKAGE, PACKAGE BODY by default
--echo #

DELIMITER $$;
--error ER_DBACCESS_DENIED_ERROR
CREATE PROCEDURE p1 AS
BEGIN
  NULL;
END;
$$
DELIMITER ;$$

DELIMITER $$;
--error ER_DBACCESS_DENIED_ERROR
CREATE PACKAGE pkg1 AS
  PROCEDURE p1;
END;
$$
DELIMITER ;$$

# TODO: this should probably return ER_DBACCESS_DENIED_ERROR
DELIMITER $$;
--error ER_SP_DOES_NOT_EXIST
CREATE PACKAGE BODY pkg1 AS
  PROCEDURE p1 AS BEGIN NULL; END;
END;
$$
DELIMITER ;$$


--echo #
--echo # Now create a PACKAGE by root
--echo #

connection default;
USE db1;

DELIMITER $$;
CREATE PROCEDURE p1root AS
BEGIN
  SELECT 1;
END;
$$
DELIMITER ;$$

DELIMITER $$;
CREATE PACKAGE pkg1 AS
  PROCEDURE p1;
  FUNCTION f1 RETURN TEXT;
END;
$$
DELIMITER ;$$
SHOW CREATE PACKAGE pkg1;

--echo #
--echo # u1 cannot SHOW yet:
--echo # - the standalone procedure earlier created by root
--echo # - the package specifications earlier create by root
--echo #

connection conn1;
--error ER_SP_DOES_NOT_EXIST
SHOW CREATE PROCEDURE p1root;
--error ER_SP_DOES_NOT_EXIST
SHOW CREATE PACKAGE pkg1;


--echo #
--echo # User u1 still cannot create a PACKAGE BODY
--echo #

connection conn1;
DELIMITER $$;
--error ER_DBACCESS_DENIED_ERROR
CREATE PACKAGE BODY pkg1 AS
  PROCEDURE p1 AS BEGIN NULL; END;
  FUNCTION f1 RETURN TEXT AS BEGIN RETURN 'This is f1'; END;
END;
$$
DELIMITER ;$$


--echo #
--echo # Now grant EXECUTE:
--echo # - on the standalone procedure earlier created by root
--echo # - on the package specification earlier created by root
--echo #
connection default;
GRANT EXECUTE ON PROCEDURE db1.p1root TO u1@localhost;
GRANT EXECUTE ON PACKAGE db1.pkg1 TO u1@localhost;

--echo #
--echo # Now u1 can do SHOW for:
--echo # - the standalone procedure earlier created by root
--echo # - the package specification earlier created by root
--echo #

disconnect conn1;
connect (conn1,localhost,u1,,db1);
SET sql_mode=ORACLE;
SHOW CREATE PROCEDURE db1.p1root;
SHOW CREATE PACKAGE db1.pkg1;


--echo #
--echo # Now revoke EXECUTE and grant CREATE ROUTINE instead
--echo #

connection default;
REVOKE EXECUTE ON PROCEDURE db1.p1root FROM u1@localhost;
REVOKE EXECUTE ON PACKAGE db1.pkg1 FROM u1@localhost;
GRANT CREATE ROUTINE ON db1.* TO u1@localhost;

--echo #
--echo # Reconnect u1 to make new grants have effect
--echo #

disconnect conn1;
connect (conn1,localhost,u1,,db1);
SET sql_mode=ORACLE;

--echo #
--echo # Now u1 can SHOW:
--echo # - standalone routines earlier created by root
--echo # - package specifications earlier created by root
--echo #
SHOW CREATE PROCEDURE p1root;
SHOW CREATE PACKAGE pkg1;

--echo #
--echo # Now u1 can CREATE, DROP and EXECUTE its own standalone procedures
--echo #

DELIMITER $$;
CREATE PROCEDURE p1 AS
BEGIN
  NULL;
END;
$$
DELIMITER ;$$
SHOW GRANTS;
CALL p1;
DROP PROCEDURE p1;
SHOW GRANTS;

--echo #
--echo # Now u1 can also CREATE, DROP its own package specifications
--echo #

DELIMITER $$;
CREATE PACKAGE pkg2 AS
  PROCEDURE p1;
  FUNCTION f1 RETURN TEXT;
END;
$$
DELIMITER ;$$
SHOW CREATE PACKAGE pkg2;
SHOW GRANTS;
DROP PACKAGE pkg2;
SHOW GRANTS;


--echo #
--echo # Now u1 can also CREATE, DROP package bodies and EXECUTE package body routines
--echo #

DELIMITER $$;
CREATE PACKAGE BODY pkg1 AS
  PROCEDURE p1 AS BEGIN SELECT 'This is pkg1.p1' AS `comment`; END;
  FUNCTION f1 RETURN TEXT AS BEGIN RETURN 'This is pkg1.f1'; END;
END;
$$
DELIMITER ;$$
SHOW CREATE PACKAGE pkg1;
SHOW CREATE PACKAGE BODY pkg1;
SHOW GRANTS;
CALL pkg1.p1;
SELECT pkg1.f1();
DROP PACKAGE BODY pkg1;
SHOW GRANTS;

--echo #
--echo # Now create a PACKAGE BODY by root.
--echo # u1 does not have EXECUTE access by default.
--echo #

connection default;
DELIMITER $$;
CREATE PACKAGE BODY pkg1 AS
  PROCEDURE p1 AS BEGIN SELECT 'This is pkg1.p1' AS `comment`; END;
  FUNCTION f1 RETURN TEXT AS BEGIN RETURN 'This is pkg1.f1'; END;
END;
$$
DELIMITER ;$$

connection conn1;
SHOW CREATE PACKAGE pkg1;
SHOW CREATE PACKAGE BODY pkg1;
--error ER_PROCACCESS_DENIED_ERROR
CALL pkg1.p1;
--error ER_PROCACCESS_DENIED_ERROR
SELECT pkg1.f1();

--echo #
--echo # Now grant EXECUTE to u1 on the PACKAGE BODY created by root
--echo #

connection default;
GRANT EXECUTE ON PACKAGE BODY db1.pkg1 TO u1@localhost;
disconnect conn1;
connect (conn1,localhost,u1,,db1);
SELECT CURRENT_USER;
SET sql_mode=ORACLE;
SHOW GRANTS;
CALL pkg1.p1;
SELECT pkg1.f1();

connection default;
DROP PACKAGE BODY pkg1;


--echo #
--echo # u1 still cannot DROP the package specification earlier created by root.
--echo #

connection conn1;
--error ER_PROCACCESS_DENIED_ERROR
DROP PACKAGE pkg1;

--echo #
--echo # Grant ALTER ROUTINE to u1
--echo #

connection default;
GRANT ALTER ROUTINE ON db1.* TO u1@localhost;

--echo #
--echo # Now u1 can DROP:
--echo # - the standalone procedure earlier created by root
--echo # - the package specification earlier created by root
--echo #

disconnect conn1;
connect (conn1,localhost,u1,,db1);
SET sql_mode=ORACLE;
DROP PACKAGE pkg1;
DROP PROCEDURE p1root;

disconnect conn1;
connection default;

DROP USER u1@localhost;
DROP DATABASE db1;
USE test;


--echo #
--echo # Creator=root, definer=xxx
--echo #

CREATE USER xxx@localhost;
DELIMITER $$;
CREATE DEFINER=xxx@localhost PACKAGE p1 AS
  PROCEDURE p1;
END;
$$
CREATE DEFINER=xxx@localhost PACKAGE BODY p1 AS
  PROCEDURE p1 AS
  BEGIN
    SELECT SESSION_USER(), CURRENT_USER(), 'p1.p1' AS msg;
  END;
BEGIN
  SELECT SESSION_USER(), CURRENT_USER(), 'package body p1' AS msg;
END;
$$
DELIMITER ;$$
--error ER_PROCACCESS_DENIED_ERROR
CALL p1.p1;
GRANT EXECUTE ON PACKAGE BODY test.p1 TO xxx@localhost;
CALL p1.p1;
DROP PACKAGE p1;
DROP USER xxx@localhost;


--echo #
--echo # Creator=root, definer=xxx, SQL SECURITY INVOKER
--echo #

CREATE USER xxx@localhost;
DELIMITER $$;
CREATE DEFINER=xxx@localhost PACKAGE p1 AS
  PROCEDURE p1;
END;
$$
CREATE DEFINER=xxx@localhost PACKAGE BODY p1 SQL SECURITY INVOKER AS
  PROCEDURE p1 AS
  BEGIN
    SELECT SESSION_USER(), CURRENT_USER(), 'p1.p1' AS msg;
  END;
BEGIN
  SELECT SESSION_USER(), CURRENT_USER(), 'package body p1' AS msg;
END;
$$
DELIMITER ;$$
CALL p1.p1;
DROP PACKAGE p1;
DROP USER xxx@localhost;