At the MySQL Mini Conference in Sydney this week we discussed how to use EXPLAIN EXTENDED to view the rewrites undertaken by the MySQL optimizer. IN particular, to see if MySQL performs a merge of the query into the view definition, or if it creates a temporary table.
It can be tricky to optimize queries using views, since it's often hard to know exactly how the query will be resovled - will MySQL push merge the text of the query and the view, or will it use a temporary table containing the views result set and then apply the query clauses to that?
In general, MySQL merges query text except when the view definition includes a GROUP BY or UNION. But to be sure we can use EXPLAIN EXTENDED. This also helps when we get confusing output in the EXPLAIN output.
For instance if we have a view definition like this:
CREATE VIEW
user_table_v AS
SELECT *
FROM
information_schema.tables ist
WHERE table_type='BASE TABLE';
and try and explain a query like this:
explain select * from user_table_v WHERE table_schema='mysql'\G
We get output like this, which might be difficult to interpret unless we know the view defition:
***************************
1. row ***************************
id: 1
select_type: SIMPLE
table: ist
type: ALL
possible_keys: NULL
key:
NULL
key_len: NULL
ref:
NULL
rows: 2
filtered: 100.00
Extra: Using where
Note the table "ist", only by looking at the view definition can we interepret this. But if we do an EXPLAIN EXTENDED followed by a SHOW WARNINGS we see the exact text:
***************************
1. row ***************************
Level: Note
Code: 1003
Message: select `ist`.`TABLE_NAME` AS `TABLE_NAME` from
`information_schema`.`tables` `ist` where ((
`ist`.`TABLE_SCHEMA` = _utf8'mysql') and (`ist`.`TABLE_TYPE` =
_utf8'BASE TABLE'))
1 row in set (0.00 sec)
And from this we can see that MySQL did indeed merge the WHERE clauses of both the query and the view definition.
If we look at the output for a view like this:
CREATE VIEW
table_types_v AS
SELECT table_type,count(*)
FROM
information_schema.tables ist
GROUP BY
table_type;
The we see the following output, in which we can see that MySQL created a temporary table and then applied the WHERE clause from the query:
***************************
1. row ***************************
id: 1
select_type: PRIMARY
table: NULL
type:
NULL
possible_keys: NULL
key:
NULL
key_len: NULL
ref:
NULL
rows:
NULL
filtered: NULL
Extra: Impossible
WHERE noticed after reading const tables
*************************** 2. row ***************************
id: 2
select_type: DERIVED
table: ist
type: ALL
possible_keys: NULL
key:
NULL
key_len: NULL
ref:
NULL
rows: 2
filtered: 100.00
Extra: Using
temporary; Using filesort
2 rows in set, 1 warning (0.00 sec)
***************************
1. row ***************************
Level: Note
Code: 1003
Message: select `table_types_v`.`table_type` AS
`table_type`,`table_types_v`.`count(*)` AS `count(*)
` from `mysql`.`table_types_v` where (`table_types_v`.`table_type` =
_utf8'BASE TABLE')
1 row in set (0.00 sec)
EXPLAIN EXTENDED is an invaluable tool for tuning SQL statements, and even more so when working with views.
Still far from a proper explain plan like the ones of Oracle or PostgreSQL ...
Posted by: p | January 18, 2007 at 08:41 PM
very interesting, but I don't agree with you
Idetrorce
Posted by: Idetrorce | December 16, 2007 at 12:22 AM
This blog is wonderful, really nice!!! , i stay impressive with the whole information here. I really like know about everything because i usually like to answer very well when a person ask me something. I Think the most important thing is to know about several information, and you look smarter all the time.
Posted by: Buy Viagra | September 22, 2010 at 03:33 PM