summaryrefslogtreecommitdiff
path: root/mysql-test/t/information_schema_routines.test
blob: 190410c2b8290fd3a30ab60f63484ab83f759313 (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
#------------------------------------------------------------------------------
# i_s_routines.test
# .test file for MySQL regression suite
# Purpose:  To test the presence, structure, and behavior
#                    of INFORMATION_SCHEMA.ROUTINES
# Author:  pcrews
# Last modified:  2007-12-04
#------------------------------------------------------------------------------

################################################################################
# Testcase routines.1: Ensure that the INFORMATION_SCHEMA.ROUTINES
#                   table has the following columns, in the following order:
#
#                   SPECIFIC_NAME (shows the name of an accessible stored
#                          procedure, or routine),
#                   ROUTINE_CATALOG (always shows NULL),
#                   ROUTINE_SCHEMA (shows the database, or schema, in which
#                          the routine resides),
#                   ROUTINE_NAME (shows the same stored procedure name),
#                   ROUTINE_TYPE (shows whether the stored procedure is a
#                          procedure or a function),
#                   DATA_TYPE (new column as of 6.0)
#                   CHARACTER_MAXIMUM_LENGTH  (new column as of 6.0)
#                   CHARACTER_OCTET_LENGTH  (new column as of 6.0)
#                   NUMERIC_PRECISION  (new column as of 6.0)
#                   NUMERIC_SCALE  (new column as of 6.0)
#                   CHARACTER_SET_NAME  (new column as of 6.0)
#                   COLLATION_NAME  (new column as of 6.0)
#                   DTD_IDENTIFIER (shows, for a function, the complete
#                          data type definition of the value the function will
#                          return; otherwise NULL),
#                   ROUTINE_BODY (shows the language in which the stored
#                          procedure is written; currently always SQL),
#                   ROUTINE_DEFINITION (shows as much of the routine body as
#                          is possible in the allotted space),
#                   EXTERNAL_NAME (always shows NULL),
#                   EXTERNAL_LANGUAGE (always shows NULL),
#                   PARAMETER_STYLE (shows the routine's parameter style;
#                          always SQL),
#                   IS_DETERMINISTIC (shows whether the routine is
#                          deterministic),
#                   SQL_DATA_ACCESS (shows the routine's defined
#                          sql-data-access clause value),
#                   SQL_PATH (always shows NULL),
#                   SECURITY_TYPE (shows whether the routine's defined
#                          security_type is 'definer' or 'invoker'),
#                   CREATED (shows the timestamp of the time the routine was
#                          created),
#                   LAST_ALTERED (shows the timestamp of the time the routine
#                          was last altered),
#                   SQL_MODE (shows the sql_mode setting at the time the
#                          routine was created),
#                   ROUTINE_COMMENT (shows the comment, if any, defined for
#                          the routine; otherwise NULL),
#                   DEFINER (shows the user who created the routine).
################################################################################
set sql_mode="";
set sql_mode="";
-- echo # ========== routines.1 ==========
USE INFORMATION_SCHEMA;
--replace_result ENGINE=MyISAM "" ENGINE=MARIA "" ENGINE=Aria "" " PAGE_CHECKSUM=1" "" " PAGE_CHECKSUM=0" ""
SHOW CREATE TABLE INFORMATION_SCHEMA.ROUTINES;

# embedded server does not display privileges
--replace_column 19 #
query_vertical SELECT * FROM information_schema.columns
WHERE table_schema = 'information_schema'
  AND table_name   = 'routines'
ORDER BY ordinal_position;

DESCRIBE INFORMATION_SCHEMA.ROUTINES;

###############################################################################
# Testcase routines.2:  Unsuccessful stored procedure CREATE will not populate
#                     I_S.ROUTINES view
###############################################################################
-- echo # ========== routines.2 ==========
--disable_warnings
DROP DATABASE IF EXISTS i_s_routines_test;
--enable_warnings

CREATE DATABASE i_s_routines_test;
USE i_s_routines_test;

# Missing closing ')' character at the end of 's char(20) in func declaration
--error ER_PARSE_ERROR
CREATE FUNCTION test_func1 (s char(20) RETURNS CHAR(50)
RETURN CONCAT('Hello', ,s,'!');
--replace_column 24 <created> 25 <modified>
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_SCHEMA = 'i_s_routines_test' AND ROUTINE_NAME = 'test_func1';

###############################################################################
# Testcase routines.3:  DROP FUNCTION - Verify DROP of a stored procedure
#                                     removes I_S.PARAMETERS data for that
#                                     function / procedure
###############################################################################
-- echo # ========== routines.3 ==========
--disable_warnings
DROP DATABASE IF EXISTS i_s_routines_test;
--enable_warnings

CREATE DATABASE i_s_routines_test;
USE i_s_routines_test;

CREATE FUNCTION test_func1 (s char(20)) RETURNS CHAR(50)
RETURN CONCAT('Hello, ',s,'!');
--replace_column 24 <created> 25 <modified>
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_SCHEMA = 'i_s_routines_test' AND ROUTINE_NAME = 'test_func1';
DROP FUNCTION test_func1;
--replace_column 24 <created> 25 <modified>
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_SCHEMA = 'i_s_routines_test' AND ROUTINE_NAME = 'test_func1';


################################################################################
# Testcase routines.4:  Verify that the new columns from WL#2822 are NULL for a
#                    stored procedure
################################################################################
-- echo # ========== routines.4 ==========
--disable_warnings
DROP DATABASE IF EXISTS i_s_routines_test;
--enable_warnings

CREATE DATABASE i_s_routines_test;
USE i_s_routines_test;

delimiter //;
CREATE PROCEDURE testproc (OUT param1 INT)
  BEGIN
   SELECT 2+2 as param1;
  END;
//
delimiter ;//
--replace_column 24 <created> 25 <modified>
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_SCHEMA = 'i_s_routines_test' AND ROUTINE_NAME = 'testproc';


################################################################################
# Testcase routines.5:  Verify that the new columns from WL#2822 are populated
#                    for a stored function, that the NUMERIC columns
#                    are not populated when the function returns non-numeric
#                    data, and that the CHARACTER columns are populated
#                    for CHAR functions
################################################################################
-- echo # ========== routines.5 ==========
--disable_warnings
DROP DATABASE IF EXISTS i_s_routines_test;
--enable_warnings

CREATE DATABASE i_s_routines_test;
USE i_s_routines_test;

CREATE FUNCTION test_func1 (s char(20)) RETURNS CHAR(50)
RETURN CONCAT('Hello, ',s,'!');
--replace_column 24 <created> 25 <modified>
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_SCHEMA = 'i_s_routines_test' AND ROUTINE_NAME = 'test_func1';



################################################################################
# Testcase routines.6:  Verify that the new columns from WL#2822 are populated
#                    for a stored function, that the CHARACTER columns
#                    are not populated when the function returns numeric
#                    data, and that the NUMERIC columns are populated
#                    for numeric functions
################################################################################
-- echo # ========== routines.6 ==========
--disable_warnings
DROP DATABASE IF EXISTS i_s_routines_test;
--enable_warnings

CREATE DATABASE i_s_routines_test;
USE i_s_routines_test;

CREATE FUNCTION test_func2 (s int) RETURNS INT RETURN s*2;
--replace_column 24 <created> 25 <modified>
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_SCHEMA = 'i_s_routines_test' AND ROUTINE_NAME = 'test_func2';

################################################################################
# Testcase routines.7:  Verify that the new columns from WL#2822 are populated
#                    for a stored function, that the CHARACTER and NUMERIC
#                    columns are not populated when the function returns date
#                    or time data
################################################################################
-- echo # ========== routines.7 ==========
--disable_warnings
DROP DATABASE IF EXISTS i_s_routines_test;
--enable_warnings

CREATE DATABASE i_s_routines_test;
USE i_s_routines_test;

CREATE FUNCTION test_func5 (s date) RETURNS TIMESTAMP
RETURN CURRENT_TIMESTAMP;
--replace_column 24 <created> 25 <modified>
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_SCHEMA = 'i_s_routines_test' AND ROUTINE_NAME = 'test_func5';

###############################################################################
# Testcase routines.8:  ALTER FUNCTION
#                     Quick check to ensure ALTER properly updates
#                     I_S.ROUTINES.COMMENT
###############################################################################
-- echo # ========== routines.8 ==========
--disable_warnings
DROP DATABASE IF EXISTS i_s_routines_test;
--enable_warnings

CREATE DATABASE i_s_routines_test;
USE i_s_routines_test;

CREATE FUNCTION test_func5 (s date) RETURNS TIMESTAMP
RETURN CURRENT_TIMESTAMP;
--replace_column 24 <created> 25 <modified>
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_SCHEMA = 'i_s_routines_test' AND ROUTINE_NAME = 'test_func5';
ALTER FUNCTION test_func5 COMMENT 'new comment added';
--replace_column 24 <created> 25 <modified>
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_SCHEMA = 'i_s_routines_test' AND ROUTINE_NAME = 'test_func5';

###############################################################################
# Testcase routines.9:  MULTI-BYTE CHAR SETS
#                     Verify that CHAR_MAX_LENGTH and CHAR_OCTET_LENGTH
#                     differ as expected for multi-byte char sets
#                     Normally both values are equal
###############################################################################
-- echo # ========== routines.9 ==========
--disable_warnings
DROP DATABASE IF EXISTS i_s_routines_test;
--enable_warnings


CREATE DATABASE i_s_routines_test CHARACTER SET  utf8;
USE i_s_routines_test;

CREATE FUNCTION test_func5 (s CHAR(20)) RETURNS VARCHAR(30)
RETURN CONCAT('XYZ, ' ,s);
--replace_column 24 <created> 25 <modified>
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_SCHEMA = 'i_s_routines_test' AND ROUTINE_NAME = 'test_func5';

# final clean up
DROP DATABASE i_s_routines_test;