1
# suite/funcs_1/t/is_views.test
3
# Check the layout of information_schema.views and the impact of
4
# CREATE/ALTER/DROP TABLE/VIEW/SCHEMA ... on it.
7
# - This test should not check storage engine properties.
8
# - Please do not change the storage engines used within this test
9
# except you know that the impact is acceptable.
10
# Some storage engines might not support the modification of
11
# properties like in the following tests.
14
# 2008-01-23 mleich WL#4203 Reorganize and fix the data dictionary tests of
16
# Create this script based on older scripts and new code.
19
# --source suite/funcs_1/datadict/datadict.pre
21
let $engine_type = MEMORY;
22
let $other_engine_type = MyISAM;
24
let $is_table = VIEWS;
26
# The table INFORMATION_SCHEMA.VIEWS must exist
27
eval SHOW TABLES FROM information_schema LIKE '$is_table';
29
--echo #######################################################################
30
--echo # Testcase 3.2.1.1: INFORMATION_SCHEMA tables can be queried via SELECT
31
--echo #######################################################################
32
# Ensure that every INFORMATION_SCHEMA table can be queried with a SELECT
33
# statement, just as if it were an ordinary user-defined table.
35
--source suite/funcs_1/datadict/is_table_query.inc
38
--echo #########################################################################
39
--echo # Testcase 3.2.13.1: INFORMATION_SCHEMA.VIEWS layout
40
--echo #########################################################################
41
# Ensure that the INFORMATION_SCHEMA.VIEWS table has the following columns,
42
# in the following order:
44
# TABLE_CATALOG (always shows NULL),
45
# TABLE_SCHEMA (shows the database, or schema, in which an accessible
47
# TABLE_NAME (shows the name of a view accessible to the current user),
48
# VIEW_DEFINITION (shows the SELECT statement that makes up the
50
# CHECK_OPTION (shows the value of the WITH CHECK OPTION clause used to define
51
# the view, either NONE, LOCAL or CASCADED),
52
# IS_UPDATABLE (shows whether the view is an updatable view),
53
# DEFINER (added with 5.0.14),
54
# SECURITY_TYPE (added with 5.0.14).
56
# CHARACTER_SET_CLIENT
57
# COLLATION_CONNECTION
59
--source suite/funcs_1/datadict/datadict_bug_12777.inc
60
eval DESCRIBE information_schema.$is_table;
61
--source suite/funcs_1/datadict/datadict_bug_12777.inc
62
eval SHOW CREATE TABLE information_schema.$is_table;
63
--source suite/funcs_1/datadict/datadict_bug_12777.inc
64
eval SHOW COLUMNS FROM information_schema.$is_table;
66
# Note: Retrieval of information within information_schema.columns about
67
# information_schema.views is in is_columns_is.test.
69
# Show that TABLE_CATALOG is always NULL.
70
SELECT table_catalog, table_schema, table_name
71
FROM information_schema.views WHERE table_catalog IS NOT NULL;
74
--echo ################################################################################
75
--echo # Testcase 3.2.13.2 + 3.2.13.3: INFORMATION_SCHEMA.VIEWS accessible information
76
--echo ################################################################################
77
# 3.2.13.2: Ensure that the table shows the relevant information on every view for
78
# which the current user or PUBLIC has the SHOW CREATE VIEW privilege.
79
# 3.2.13.3: Ensure that the table does not show any information on any views for which
80
# the current user and PUBLIC have no SHOW CREATE VIEW privilege.
83
DROP DATABASE IF EXISTS db_datadict;
85
CREATE DATABASE db_datadict;
87
--error 0,ER_CANNOT_USER
88
DROP USER 'testuser1'@'localhost';
89
CREATE USER 'testuser1'@'localhost';
90
--error 0,ER_CANNOT_USER
91
DROP USER 'testuser2'@'localhost';
92
CREATE USER 'testuser2'@'localhost';
93
--error 0,ER_CANNOT_USER
94
DROP USER 'test_no_views'@'localhost';
95
CREATE USER 'test_no_views'@'localhost';
97
--replace_result $engine_type <engine_type>
99
CREATE TABLE db_datadict.t1(f1 INT, f2 INT, f3 INT)
100
ENGINE = $engine_type;
101
CREATE VIEW db_datadict.v_granted_to_1 AS SELECT * FROM db_datadict.t1;
102
CREATE VIEW db_datadict.v_granted_glob AS SELECT f2, f3 FROM db_datadict.t1;
104
GRANT SELECT ON db_datadict.t1 TO 'testuser1'@'localhost';
105
GRANT SELECT ON db_datadict.v_granted_to_1 TO 'testuser1'@'localhost';
106
GRANT SHOW VIEW, CREATE VIEW ON db_datadict.* TO 'testuser2'@'localhost';
108
let $select = SELECT * FROM information_schema.views
109
WHERE table_schema = 'db_datadict' ORDER BY table_name;
112
--echo # Establish connection testuser1 (user=testuser1)
113
--replace_result $MASTER_MYPORT MYSQL_PORT $MASTER_MYSOCK MYSQL_SOCK
114
connect (testuser1, localhost, testuser1, , test);
117
--echo # Establish connection testuser2 (user=testuser2)
118
--replace_result $MASTER_MYPORT MYSQL_PORT $MASTER_MYSOCK MYSQL_SOCK
119
connect (testuser2, localhost, testuser2, , test);
122
--echo # Establish connection test_no_views (user=test_no_views)
123
--replace_result $MASTER_MYPORT MYSQL_PORT $MASTER_MYSOCK MYSQL_SOCK
124
connect (test_no_views, localhost, test_no_views, , test);
128
--echo # Switch to connection default and close all other connections
130
disconnect testuser1;
131
disconnect testuser2;
132
disconnect test_no_views;
133
DROP USER 'testuser1'@'localhost';
134
DROP USER 'testuser2'@'localhost';
135
DROP USER 'test_no_views'@'localhost';
136
DROP DATABASE db_datadict;
138
--echo #########################################################################
139
--echo # 3.2.1.13+3.2.1.14+3.2.1.15: INFORMATION_SCHEMA.VIEWS modifications
140
--echo #########################################################################
141
# 3.2.1.13: Ensure that the creation of any new database object (e.g. table or
142
# column) automatically inserts all relevant information on that
143
# object into every appropriate INFORMATION_SCHEMA table.
144
# 3.2.1.14: Ensure that the alteration of any existing database object
145
# automatically updates all relevant information on that object in
146
# every appropriate INFORMATION_SCHEMA table.
147
# 3.2.1.15: Ensure that the dropping of any existing database object
148
# automatically deletes all relevant information on that object from
149
# every appropriate INFORMATION_SCHEMA table.
152
DROP TABLE IF EXISTS test.t1_my_table;
153
DROP DATABASE IF EXISTS db_datadict;
155
CREATE DATABASE db_datadict;
156
--replace_result $engine_type <engine_type>
158
CREATE TABLE test.t1_table (f1 BIGINT, f2 CHAR(10))
159
DEFAULT CHARACTER SET latin1 COLLATE latin1_swedish_ci
160
ENGINE = $engine_type;
161
--error 0,ER_CANNOT_USER
162
DROP USER 'testuser1'@'localhost';
163
CREATE USER 'testuser1'@'localhost';
165
# Check just created VIEW
166
SELECT * FROM information_schema.views
167
WHERE table_name LIKE 't1_%';
168
CREATE VIEW test.t1_view AS SELECT DISTINCT f1 FROM test.t1_table;
169
SELECT * FROM information_schema.views
170
WHERE table_name LIKE 't1_%';
172
# Check modification of DEFINER, SECURITY_TYPE, IS_UPDATABLE, VIEW_DEFINITION,
174
SELECT table_name,definer FROM information_schema.views
175
WHERE table_name = 't1_view';
176
ALTER DEFINER = 'testuser1'@'localhost' VIEW test.t1_view AS
177
SELECT DISTINCT f1 FROM test.t1_table;
178
# The next result set could suffer from
179
# Bug#22763 Disrepancy between SHOW CREATE VIEW and I_S.VIEWS
180
# because the VIEW definition is missing.
181
# Therefore we exclude the problematic columns from the result set.
182
SELECT table_name,definer,security_type FROM information_schema.views
183
WHERE table_name LIKE 't1_%';
184
ALTER DEFINER = 'root'@'localhost' SQL SECURITY INVOKER VIEW test.t1_view AS
185
SELECT f1 FROM test.t1_table WITH LOCAL CHECK OPTION;
186
SELECT table_name,definer,security_type FROM information_schema.views
187
WHERE table_name LIKE 't1_%';
189
# Check modification of TABLE_SCHEMA
190
SELECT table_schema,table_name FROM information_schema.views
191
WHERE table_name LIKE 't1_%'
192
ORDER BY table_schema,table_name;
193
--error ER_FORBID_SCHEMA_CHANGE
194
RENAME TABLE test.t1_view TO db_datadict.t1_view;
195
# Workaround for missing move to another database
196
DROP VIEW test.t1_view;
197
CREATE VIEW db_datadict.t1_view AS SELECT * FROM test.t1_table;
198
SELECT table_schema,table_name FROM information_schema.views
199
WHERE table_name LIKE 't1_%'
200
ORDER BY table_schema,table_name;
202
# Check modification of TABLE_NAME
203
SELECT table_name FROM information_schema.views
204
WHERE table_name LIKE 't1_%'
206
RENAME TABLE db_datadict.t1_view TO db_datadict.t1_viewx;
207
SELECT table_name FROM information_schema.views
208
WHERE table_name LIKE 't1_%'
211
# Check impact of DROP VIEW
212
SELECT table_name FROM information_schema.views
213
WHERE table_name LIKE 't1_%'
215
DROP VIEW db_datadict.t1_viewx;
216
SELECT table_name FROM information_schema.views
217
WHERE table_name LIKE 't1_%'
219
CREATE VIEW db_datadict.t1_view AS SELECT * FROM test.t1_table;
221
# Check impact of DROP base TABLE of VIEW
222
SELECT table_name FROM information_schema.views
223
WHERE table_name LIKE 't1_%'
225
DROP TABLE test.t1_table;
226
SELECT table_name FROM information_schema.views
227
WHERE table_name LIKE 't1_%'
229
--replace_result $engine_type <engine_type>
231
CREATE TABLE test.t1_table (f1 BIGINT, f2 CHAR(10))
232
DEFAULT CHARACTER SET latin1 COLLATE latin1_swedish_ci COMMENT = 'Initial Comment'
233
ENGINE = $engine_type;
235
# Check impact of DROP SCHEMA
236
SELECT table_name FROM information_schema.views
237
WHERE table_name LIKE 't1_%'
239
DROP DATABASE db_datadict;
240
SELECT table_name FROM information_schema.views
241
WHERE table_name LIKE 't1_%'
245
DROP USER 'testuser1'@'localhost';
246
DROP TABLE test.t1_table;
248
--echo ########################################################################
249
--echo # Testcases 3.2.1.3-3.2.1.5 + 3.2.1.8-3.2.1.12: INSERT/UPDATE/DELETE and
250
--echo # DDL on INFORMATION_SCHEMA table are not supported
251
--echo ########################################################################
252
# 3.2.1.3: Ensure that no user may execute an INSERT statement on any
253
# INFORMATION_SCHEMA table.
254
# 3.2.1.4: Ensure that no user may execute an UPDATE statement on any
255
# INFORMATION_SCHEMA table.
256
# 3.2.1.5: Ensure that no user may execute a DELETE statement on any
257
# INFORMATION_SCHEMA table.
258
# 3.2.1.8: Ensure that no user may create an index on an
259
# INFORMATION_SCHEMA table.
260
# 3.2.1.9: Ensure that no user may alter the definition of an
261
# INFORMATION_SCHEMA table.
262
# 3.2.1.10: Ensure that no user may drop an INFORMATION_SCHEMA table.
263
# 3.2.1.11: Ensure that no user may move an INFORMATION_SCHEMA table to any
265
# 3.2.1.12: Ensure that no user may directly add to, alter, or delete any data
266
# in an INFORMATION_SCHEMA table.
269
DROP DATABASE IF EXISTS db_datadict;
271
CREATE DATABASE db_datadict;
272
CREATE VIEW db_datadict.v1 AS SELECT 1;
274
--error ER_DBACCESS_DENIED_ERROR
275
INSERT INTO information_schema.views
276
SELECT * FROM information_schema.views;
277
--error ER_DBACCESS_DENIED_ERROR
278
INSERT INTO information_schema.views(table_schema, table_name)
279
VALUES ('db2', 'v2');
281
--error ER_DBACCESS_DENIED_ERROR
282
UPDATE information_schema.views SET table_schema = 'test'
283
WHERE table_name = 't1';
285
--error ER_DBACCESS_DENIED_ERROR
286
DELETE FROM information_schema.views WHERE table_name = 't1';
287
--error ER_DBACCESS_DENIED_ERROR
288
TRUNCATE information_schema.views;
290
--error ER_DBACCESS_DENIED_ERROR
291
CREATE INDEX my_idx_on_views ON information_schema.views(table_schema);
293
--error ER_DBACCESS_DENIED_ERROR
294
ALTER TABLE information_schema.views DROP PRIMARY KEY;
295
--error ER_DBACCESS_DENIED_ERROR
296
ALTER TABLE information_schema.views ADD f1 INT;
298
--error ER_DBACCESS_DENIED_ERROR
299
DROP TABLE information_schema.views;
301
--error ER_DBACCESS_DENIED_ERROR
302
ALTER TABLE information_schema.views RENAME db_datadict.views;
303
--error ER_DBACCESS_DENIED_ERROR
304
ALTER TABLE information_schema.views RENAME information_schema.xviews;
307
DROP DATABASE db_datadict;