1############### include/query_cache_sql_prepare.inc ################
2#
3# This is to see how statements prepared via the PREPARE SQL command
4# go into the query cache.
5# Query cache is abbreviated as "QC"
6#
7# Last update:
8# 2008-05-26 Kostja
9#               - Add test coverage for automatic statement reprepare
10#
11# 2007-05-03 ML - Move t/query_cache_sql_prepare.test
12#                 to   include/query_cache_sql_prepare.inc
13#               - Create two toplevel tests sourcing this routine
14#               - Add tests checking that
15#                 - another connection gets the same amount of QC hits
16#                 - statements running via ps-protocol do not hit QC results
17#                   of preceding sql EXECUTEs
18#
19
20--source include/have_query_cache.inc
21# embedded can't make more than one connection, which this test needs
22-- source include/not_embedded.inc
23set GLOBAL query_cache_type=ON;
24set LOCAL query_cache_type=ON;
25
26connect (con1,localhost,root,,test,$MASTER_MYPORT,);
27connection default;
28
29set @initial_query_cache_size = @@global.query_cache_size;
30set @@global.query_cache_size=102400;
31flush status;
32--disable_warnings
33drop table if exists t1;
34--enable_warnings
35create table t1(c1 int);
36insert into t1 values(1),(10),(100);
37
38# First, prepared statements with no parameters
39prepare stmt1 from "select * from t1 where c1=10";
40show status like 'Qcache_hits';
41execute stmt1;
42show status like 'Qcache_hits';
43execute stmt1;
44show status like 'Qcache_hits';
45execute stmt1;
46show status like 'Qcache_hits';
47# Another prepared statement (same text, same connection), should hit the QC
48prepare stmt2 from "select * from t1 where c1=10";
49execute stmt2;
50show status like 'Qcache_hits';
51execute stmt2;
52show status like 'Qcache_hits';
53execute stmt2;
54show status like 'Qcache_hits';
55# Another prepared statement (same text, other connection), should hit the QC
56connection con1;
57prepare stmt3 from "select * from t1 where c1=10";
58execute stmt3;
59show status like 'Qcache_hits';
60execute stmt3;
61show status like 'Qcache_hits';
62execute stmt3;
63show status like 'Qcache_hits';
64connection default;
65
66# Mixup tests, where statements without PREPARE.../EXECUTE.... meet statements
67# with PREPARE.../EXECUTE.... (text protocol). Both statements have the
68# same text. QC hits occur only when both statements use the same protocol.
69# The outcome of the test depends on the mysqltest startup options
70# - with "--ps-protocol"
71#   Statements without PREPARE.../EXECUTE.... run as prepared statements
72#   with binary protocol. Expect to get no QC hits.
73# - without any "--<whatever>-protocol"
74#   Statements without PREPARE.../EXECUTE run as non prepared statements
75#   with text protocol. Expect to get QC hits.
76############################################################################
77#
78# Statement with PREPARE.../EXECUTE.... first
79let $my_stmt= SELECT * FROM t1 WHERE c1 = 100;
80eval prepare stmt10 from "$my_stmt";
81show status like 'Qcache_hits';
82execute stmt10;
83show status like 'Qcache_hits';
84execute stmt10;
85show status like 'Qcache_hits';
86eval $my_stmt;
87show status like 'Qcache_hits';
88connection con1;
89eval $my_stmt;
90show status like 'Qcache_hits';
91connection default;
92#
93# Statement without PREPARE.../EXECUTE.... first
94let $my_stmt= SELECT * FROM t1 WHERE c1 = 1;
95eval prepare stmt11 from "$my_stmt";
96connection con1;
97eval prepare stmt12 from "$my_stmt";
98connection default;
99eval $my_stmt;
100show status like 'Qcache_hits';
101eval $my_stmt;
102show status like 'Qcache_hits';
103execute stmt11;
104show status like 'Qcache_hits';
105connection con1;
106execute stmt12;
107show status like 'Qcache_hits';
108connection default;
109
110# Query caching also works when statement has parameters
111# (BUG#29318 Statements prepared with PREPARE and with one parameter don't use
112# query cache)
113prepare stmt1 from "select * from t1 where c1=?";
114show status like 'Qcache_hits';
115set @a=1;
116execute stmt1 using @a;
117show status like 'Qcache_hits';
118execute stmt1 using @a;
119show status like 'Qcache_hits';
120connection con1;
121set @a=1;
122prepare stmt4 from "select * from t1 where c1=?";
123execute stmt4 using @a;
124show status like 'Qcache_hits';
125# verify that presence of user variables forbids caching
126prepare stmt4 from "select @a from t1 where c1=?";
127execute stmt4 using @a;
128show status like 'Qcache_hits';
129execute stmt4 using @a;
130show status like 'Qcache_hits';
131connection default;
132
133# See if enabling/disabling the query cache between PREPARE and
134# EXECUTE is an issue; the expected result is that the query cache
135# will not be used.
136# Indeed, decision to read/write the query cache is taken at PREPARE
137# time, so if the query cache was disabled at PREPARE time then no
138# execution of the statement will read/write the query cache.
139# If the query cache was enabled at PREPARE time, but disabled at
140# EXECUTE time, at EXECUTE time the query cache internal functions do
141# nothing so again the query cache is not read/written. But if the
142# query cache is re-enabled before another execution then that
143# execution will read/write the query cache.
144
145# QC is enabled at PREPARE
146prepare stmt1 from "select * from t1 where c1=10";
147# then QC is disabled at EXECUTE
148# Expect to see no additional Qcache_hits.
149set global query_cache_size=0;
150show status like 'Qcache_hits';
151execute stmt1;
152show status like 'Qcache_hits';
153execute stmt1;
154show status like 'Qcache_hits';
155execute stmt1;
156show status like 'Qcache_hits';
157# The QC is global = affects also other connections.
158# Expect to see no additional Qcache_hits.
159connection con1;
160execute stmt3;
161show status like 'Qcache_hits';
162execute stmt3;
163show status like 'Qcache_hits';
164execute stmt3;
165show status like 'Qcache_hits';
166#
167# then QC is re-enabled for more EXECUTE.
168connection default;
169set global query_cache_size=102400;
170# Expect to see additional Qcache_hits.
171# The fact that the QC was temporary disabled should have no affect
172# except that the first execute will not hit results from the
173# beginning of the test (because QC has been emptied meanwhile by
174# setting its size to 0).
175execute stmt1;
176show status like 'Qcache_hits';
177execute stmt1;
178show status like 'Qcache_hits';
179execute stmt1;
180show status like 'Qcache_hits';
181# The QC is global = affects also other connections.
182connection con1;
183execute stmt3;
184show status like 'Qcache_hits';
185execute stmt3;
186show status like 'Qcache_hits';
187execute stmt3;
188show status like 'Qcache_hits';
189connection default;
190#
191# then QC is re-disabled for more EXECUTE.
192# Expect to see no additional Qcache_hits.
193# The fact that the QC was temporary enabled should have no affect.
194set global query_cache_size=0;
195show status like 'Qcache_hits';
196execute stmt1;
197show status like 'Qcache_hits';
198execute stmt1;
199show status like 'Qcache_hits';
200execute stmt1;
201show status like 'Qcache_hits';
202# The QC is global = affects also other connections.
203connection con1;
204execute stmt3;
205show status like 'Qcache_hits';
206execute stmt3;
207show status like 'Qcache_hits';
208execute stmt3;
209show status like 'Qcache_hits';
210#
211
212connection default;
213# QC is disabled at PREPARE
214set global query_cache_size=0;
215prepare stmt1 from "select * from t1 where c1=10";
216connection con1;
217prepare stmt3 from "select * from t1 where c1=10";
218connection default;
219# then QC is enabled at EXECUTE
220set global query_cache_size=102400;
221show status like 'Qcache_hits';
222execute stmt1;
223show status like 'Qcache_hits';
224execute stmt1;
225show status like 'Qcache_hits';
226execute stmt1;
227show status like 'Qcache_hits';
228# The QC is global = affects also other connections.
229connection con1;
230show status like 'Qcache_hits';
231execute stmt3;
232show status like 'Qcache_hits';
233execute stmt3;
234show status like 'Qcache_hits';
235execute stmt3;
236show status like 'Qcache_hits';
237connection default;
238#
239# QC is disabled at PREPARE
240set global query_cache_size=0;
241prepare stmt1 from "select * from t1 where c1=?";
242# then QC is enabled at EXECUTE
243set global query_cache_size=102400;
244show status like 'Qcache_hits';
245set @a=1;
246execute stmt1 using @a;
247show status like 'Qcache_hits';
248set @a=100;
249execute stmt1 using @a;
250show status like 'Qcache_hits';
251set @a=10;
252execute stmt1 using @a;
253show status like 'Qcache_hits';
254
255
256drop table t1;
257disconnect con1;
258
259#
260# Bug #25843 Changing default database between PREPARE and EXECUTE of statement
261# breaks binlog.
262#
263# There were actually two problems discovered by this bug:
264#
265#   1. Default (current) database is not fixed at the creation time.
266#      That leads to wrong output of DATABASE() function.
267#
268#   2. Database attributes (@@collation_database) are not fixed at the creation
269#      time. That leads to wrong resultset.
270#
271# Binlog breakage and Query Cache wrong output happened because of the first
272# problem.
273#
274
275--echo ########################################################################
276--echo #
277--echo # BUG#25843: Changing default database between PREPARE and EXECUTE of
278--echo # statement breaks binlog.
279--echo #
280--echo ########################################################################
281
282###############################################################################
283
284--echo
285--echo #
286--echo # Check that default database and its attributes are fixed at the
287--echo # creation time.
288--echo #
289
290# Prepare data structures.
291
292--echo
293--disable_warnings
294DROP DATABASE IF EXISTS mysqltest1;
295DROP DATABASE IF EXISTS mysqltest2;
296--enable_warnings
297
298--echo
299CREATE DATABASE mysqltest1 COLLATE utf8_unicode_ci;
300CREATE DATABASE mysqltest2 COLLATE utf8_general_ci;
301
302--echo
303CREATE TABLE mysqltest1.t1(msg VARCHAR(255));
304CREATE TABLE mysqltest2.t1(msg VARCHAR(255));
305
306# - Create a prepared statement with mysqltest1 as default database;
307
308--echo
309
310use mysqltest1;
311
312PREPARE stmt_a_1 FROM 'INSERT INTO t1 VALUES(DATABASE())';
313PREPARE stmt_a_2 FROM 'INSERT INTO t1 VALUES(@@collation_database)';
314
315# - Execute on mysqltest1.
316
317--echo
318
319EXECUTE stmt_a_1;
320EXECUTE stmt_a_2;
321
322# - Execute on mysqltest2.
323
324--echo
325
326use mysqltest2;
327
328EXECUTE stmt_a_1;
329EXECUTE stmt_a_2;
330
331# - Check the results;
332
333--echo
334SELECT * FROM mysqltest1.t1;
335
336--echo
337SELECT * FROM mysqltest2.t1;
338
339# - Drop prepared statements.
340
341--echo
342DROP PREPARE stmt_a_1;
343DROP PREPARE stmt_a_2;
344
345###############################################################################
346
347--echo
348--echo #
349--echo # The Query Cache test case.
350--echo #
351
352--echo
353DELETE FROM mysqltest1.t1;
354DELETE FROM mysqltest2.t1;
355
356--echo
357INSERT INTO mysqltest1.t1 VALUES('mysqltest1.t1');
358INSERT INTO mysqltest2.t1 VALUES('mysqltest2.t1');
359
360--echo
361use mysqltest1;
362PREPARE stmt_b_1 FROM 'SELECT * FROM t1';
363
364--echo
365use mysqltest2;
366PREPARE stmt_b_2 FROM 'SELECT * FROM t1';
367
368--echo
369EXECUTE stmt_b_1;
370
371--echo
372EXECUTE stmt_b_2;
373
374--echo
375use mysqltest1;
376
377--echo
378EXECUTE stmt_b_1;
379
380--echo
381EXECUTE stmt_b_2;
382
383--echo
384DROP PREPARE stmt_b_1;
385DROP PREPARE stmt_b_2;
386
387# Cleanup.
388
389--echo
390use test;
391
392--echo
393DROP DATABASE mysqltest1;
394DROP DATABASE mysqltest2;
395
396###############################################################################
397
398--echo
399--echo #
400--echo # Check that prepared statements work properly when there is no current
401--echo # database.
402--echo #
403
404--echo
405CREATE DATABASE mysqltest1 COLLATE utf8_unicode_ci;
406CREATE DATABASE mysqltest2 COLLATE utf8_general_ci;
407
408--echo
409use mysqltest1;
410
411--echo
412PREPARE stmt_c_1 FROM 'SELECT DATABASE(), @@collation_database';
413
414--echo
415use mysqltest2;
416
417--echo
418PREPARE stmt_c_2 FROM 'SELECT DATABASE(), @@collation_database';
419
420--echo
421DROP DATABASE mysqltest2;
422
423--echo
424SELECT DATABASE(), @@collation_database;
425
426# -- Here we have: current db: NULL; stmt db: mysqltest1;
427--echo
428EXECUTE stmt_c_1;
429
430--echo
431SELECT DATABASE(), @@collation_database;
432
433# -- Here we have: current db: NULL; stmt db: mysqltest2 (non-existent);
434--echo
435EXECUTE stmt_c_2;
436
437--echo
438SELECT DATABASE(), @@collation_database;
439
440# -- Create prepared statement, which has no current database.
441
442--echo
443PREPARE stmt_c_3 FROM 'SELECT DATABASE(), @@collation_database';
444
445# -- Here we have: current db: NULL; stmt db: NULL;
446--echo
447EXECUTE stmt_c_3;
448
449--echo
450use mysqltest1;
451
452# -- Here we have: current db: mysqltest1; stmt db: mysqltest2 (non-existent);
453--echo
454EXECUTE stmt_c_2;
455
456--echo
457SELECT DATABASE(), @@collation_database;
458
459# -- Here we have: current db: mysqltest1; stmt db: NULL;
460--echo
461EXECUTE stmt_c_3;
462
463--echo
464SELECT DATABASE(), @@collation_database;
465
466--echo
467DROP DATABASE mysqltest1;
468
469--echo
470use test;
471
472--echo
473--echo ########################################################################
474--echo #
475--echo # Bug#27430 Crash in subquery code when in PS and table DDL changed
476--echo # after PREPARE
477--echo # Check the effect of automatic reprepare on query cache
478--echo #
479--echo ########################################################################
480--disable_warnings
481drop table if exists t1;
482--enable_warnings
483create table t1 (a varchar(255));
484insert into t1 (a) values ("Pack my box with five dozen liquor jugs.");
485flush status;
486prepare stmt from "select a from t1";
487execute stmt;
488set @@global.query_cache_size=0;
489alter table t1 add column b int;
490execute stmt;
491set @@global.query_cache_size=102400;
492execute stmt;
493execute stmt;
494--echo #
495--echo # Sic: ALTER TABLE caused an automatic reprepare
496--echo # of the prepared statement. Since the query cache was disabled
497--echo # at the time of reprepare, the new prepared statement doesn't
498--echo # work with it.
499--echo #
500show status like 'Qcache_hits';
501show status like 'Qcache_queries_in_cache';
502--echo # Cleanup
503deallocate prepare stmt;
504drop table t1;
505
506###############################################################################
507
508set @@global.query_cache_size=@initial_query_cache_size;
509flush status; # reset Qcache status variables for next tests
510set GLOBAL query_cache_type=default;
511