As I putter around the MySQL INFORMATION_SCHEMA
, I am finding lots of undocumented behavior for fields that should be straightforward. For example, the VIEWS
table holds information about views, and the VIEW_DEFINITION
field contains the view definition, right?
Well, when I was looking at the VIEW_DEFINITION
today, I noticed an odd thing. Even though I had permissions to see the view definition (as proven by the SHOW CREATE VIEW
command), the INFORMATION_SCHEMA.VIEWS
table sometimes came up blank for the VIEW_DEFINITION
. I had to figure out why, and now that I know, I’m not sure if it’s a bug or a feature…..can you figure it out?
mysql> USE INFORMATION_SCHEMA; Database changed mysql> SELECT TABLE_NAME,VIEW_DEFINITION FROM VIEWS WHERE TABLE_SCHEMA='sakila'; +----------------------------+-----------------+ | TABLE_NAME | VIEW_DEFINITION | +----------------------------+-----------------+ | actor_info | | | customer_list | | | film_list | | | nicer_but_slower_film_list | | | sales_by_film_category | | | sales_by_store | | | staff_list | | +----------------------------+-----------------+ 7 rows in set (0.16 sec) mysql> SHOW CREATE VIEW sakila.actor_info\G *************************** 1. row *************************** View: actor_info Create View: CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY INVOKER VIEW `sakila`.`actor_info` AS select `a`.`actor_id` AS `actor_i d`,`a`.`first_name` AS `first_name`,`a`.`last_name` AS `last_name`,group_concat( distinct concat(`c`.`name`,': ',(select group_concat(`f`.`title` order by `f`.`t itle` ASC separator ', ') AS `GROUP_CONCAT(f.title ORDER BY f.title SEPARATOR ', ')` from ((`sakila`.`film` `f` join `sakila`.`film_category` `fc` on((`f`.`film _id` = `fc`.`film_id`))) join `sakila`.`film_actor` `fa` on((`f`.`film_id` = `fa `.`film_id`))) where ((`fc`.`category_id` = `c`.`category_id`) and (`fa`.`actor_ id` = `a`.`actor_id`)))) order by `c`.`name` ASC separator '; ') AS `film_info` from (((`sakila`.`actor` `a` left join `sakila`.`film_actor` `fa` on((`a`.`actor _id` = `fa`.`actor_id`))) left join `sakila`.`film_category` `fc` on((`fa`.`film _id` = `fc`.`film_id`))) left join `sakila`.`category` `c` on((`fc`.`category_id ` = `c`.`category_id`))) group by `a`.`actor_id`,`a`.`first_name`,`a`.`last_name ` character_set_client: latin1 collation_connection: latin1_swedish_ci 1 row in set (0.02 sec) mysql> SHOW CREATE VIEW sakila.customer_list\G *************************** 1. row *************************** View: customer_list Create View: CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `sakila`.`customer_list` AS select `cu`.`customer_id` AS ` ID`,concat(`cu`.`first_name`,_utf8' ',`cu`.`last_name`) AS `name`,`a`.`address` AS `address`,`a`.`postal_code` AS `zip code`,`a`.`phone` AS `phone`,`sakila`.`ci ty`.`city` AS `city`,`sakila`.`country`.`country` AS `country`,if(`cu`.`active`, _utf8'active',_utf8'') AS `notes`,`cu`.`store_id` AS `SID` from (((`sakila`.`cus tomer` `cu` join `sakila`.`address` `a` on((`cu`.`address_id` = `a`.`address_id` ))) join `sakila`.`city` on((`a`.`city_id` = `sakila`.`city`.`city_id`))) join ` sakila`.`country` on((`sakila`.`city`.`country_id` = `sakila`.`country`.`country _id`))) character_set_client: latin1 collation_connection: latin1_swedish_ci 1 row in set (0.00 sec) mysql>
(some people read the dictionary, I read the data dictionary!)