Permalink
Browse files

Bug #22011361 - SYS.CREATE_SYNONYM_DB() DOES NOT LIKE RESERVED-WORD D…

…B NAMES

Fix so the sys.create_synonym_db() procedure can handle schemas and table
name that are reserved names or contains one or more `s (backticks).

This also adds the sys.quote_identifier() function which is now used by
sys.create_synonym_db() to ensure the schema and table names are quoted
correctly.
  • Loading branch information...
1 parent 3cf1a2c commit c2beae2c1ef962491b1ae280f41b81131e38eabe @JesperWisborgKrogh JesperWisborgKrogh committed May 23, 2016
View
@@ -4031,6 +4031,40 @@ sys.ps_thread_trx_info(48): [
1 row in set (0.03 sec)
```
+#### quote_identifier
+
+##### Description
+
+Takes an unquoted identifier (schema name, table name, etc.) and
+returns the identifier quoted with backticks.
+
+##### Parameters
+
+* in_identifier (TEXT): The identifier to quote.
+
+##### Returns
+
+TEXT
+
+##### Example
+```SQL
+mysql> SELECT sys.quote_identifier('my_identifier') AS Identifier;
++-----------------+
+| Identifier |
++-----------------+
+| `my_identifier` |
++-----------------+
+1 row in set (0.00 sec)
+
+mysql> SELECT sys.quote_identifier('my`idenfier') AS Identifier;
++----------------+
+| Identifier |
++----------------+
+| `my``idenfier` |
++----------------+
+1 row in set (0.00 sec)
+```
+
#### sys_get_config
##### Description
@@ -4178,11 +4212,11 @@ mysql> SHOW DATABASES;
5 rows in set (0.00 sec)
mysql> CALL sys.create_synonym_db('performance_schema', 'ps');
-+-------------------------------------+
-| summary |
-+-------------------------------------+
-| Created 74 views in the ps database |
-+-------------------------------------+
++---------------------------------------+
+| summary |
++---------------------------------------+
+| Created 74 views in the `ps` database |
++---------------------------------------+
1 row in set (8.57 sec)
Query OK, 0 rows affected (8.57 sec)
@@ -0,0 +1,65 @@
+-- Copyright (c) 2016, Oracle and/or its affiliates. All rights reserved.
+--
+-- This program is free software; you can redistribute it and/or modify
+-- it under the terms of the GNU General Public License as published by
+-- the Free Software Foundation; version 2 of the License.
+--
+-- This program is distributed in the hope that it will be useful,
+-- but WITHOUT ANY WARRANTY; without even the implied warranty of
+-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
+-- GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License
+-- along with this program; if not, write to the Free Software
+-- Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA
+
+DROP FUNCTION IF EXISTS quote_identifier;
+
+-- https://dev.mysql.com/doc/refman/5.7/en/identifiers.html
+-- Maximum supported length for any of the current identifiers in 5.7.5+ is 256 characters.
+-- Before that, user variables could have any length.
+--
+-- Based on Paul Dubois' suggestion in Bug #78823/Bug #22011361.
+CREATE DEFINER='root'@'localhost' FUNCTION quote_identifier(in_identifier TEXT)
+ RETURNS TEXT CHARSET UTF8
+ COMMENT '
+ Description
+ -----------
+
+ Takes an unquoted identifier (schema name, table name, etc.) and
+ returns the identifier quoted with backticks.
+
+ Parameters
+ -----------
+
+ in_identifier (TEXT):
+ The identifier to quote.
+
+ Returns
+ -----------
+
+ TEXT
+
+ Example
+ -----------
+
+ mysql> SELECT sys.quote_identifier(''my_identifier'') AS Identifier;
+ +-----------------+
+ | Identifier |
+ +-----------------+
+ | `my_identifier` |
+ +-----------------+
+ 1 row in set (0.00 sec)
+
+ mysql> SELECT sys.quote_identifier(''my`idenfier'') AS Identifier;
+ +----------------+
+ | Identifier |
+ +----------------+
+ | `my``idenfier` |
+ +----------------+
+ 1 row in set (0.00 sec)
+ '
+ SQL SECURITY INVOKER
+ DETERMINISTIC
+ NO SQL
+ RETURN CONCAT('`', REPLACE(in_identifier, '`', '``'), '`');
@@ -121,6 +121,7 @@ ps_thread_account FUNCTION
ps_thread_id FUNCTION
ps_thread_stack FUNCTION
ps_thread_trx_info FUNCTION
+quote_identifier FUNCTION
sys_get_config FUNCTION
version_major FUNCTION
version_minor FUNCTION
@@ -0,0 +1,21 @@
+SELECT sys.quote_identifier(NULL);
+sys.quote_identifier(NULL)
+NULL
+SELECT sys.quote_identifier('abc');
+sys.quote_identifier('abc')
+`abc`
+SELECT sys.quote_identifier('ab`c');
+sys.quote_identifier('ab`c')
+`ab``c`
+SELECT sys.quote_identifier('ab``c');
+sys.quote_identifier('ab``c')
+`ab````c`
+SELECT sys.quote_identifier('ab```c');
+sys.quote_identifier('ab```c')
+`ab``````c`
+SELECT sys.quote_identifier('a`b`c');
+sys.quote_identifier('a`b`c')
+`a``b``c`
+SELECT sys.quote_identifier('a`b``c');
+sys.quote_identifier('a`b``c')
+`a``b````c`
@@ -0,0 +1,52 @@
+CREATE TABLE t1 (t1_id int PRIMARY KEY, t1_val varchar(10));
+CREATE TABLE t2 (t2_id int PRIMARY KEY, t1_id int, t2_val int, INDEX (t1_id));
+CREATE TABLE `is` (t1_id int PRIMARY KEY, t1_val varchar(10));
+CREATE TABLE `ab``c` (t1_id int PRIMARY KEY, t1_val varchar(10));
+CREATE SQL SECURITY INVOKER VIEW myview AS SELECT * FROM t1 NATURAL JOIN t2;
+CALL sys.create_synonym_db('test', 'test1');
+summary
+Created 5 views in the `test1` database
+SELECT TABLE_NAME, SECURITY_TYPE FROM information_schema.VIEWS WHERE TABLE_SCHEMA = 'test1' ORDER BY TABLE_NAME;
+TABLE_NAME SECURITY_TYPE
+ab`c INVOKER
+is INVOKER
+myview INVOKER
+t1 INVOKER
+t2 INVOKER
+CALL sys.create_synonym_db('test', 'test1');
+ERROR HY000: Can't create database test1; database exists
+CREATE SCHEMA test2;
+CALL sys.create_synonym_db('test', 'test2');
+ERROR HY000: Can't create database test2; database exists
+SELECT COUNT(*) FROM information_schema.TABLES WHERE TABLE_SCHEMA = 'test2';
+COUNT(*)
+0
+CALL sys.create_synonym_db('test', 'is');
+summary
+Created 5 views in the `is` database
+SELECT TABLE_NAME, SECURITY_TYPE FROM information_schema.VIEWS WHERE TABLE_SCHEMA = 'is' ORDER BY TABLE_NAME;
+TABLE_NAME SECURITY_TYPE
+ab`c INVOKER
+is INVOKER
+myview INVOKER
+t1 INVOKER
+t2 INVOKER
+CALL sys.create_synonym_db('is', 'i`s');
+summary
+Created 5 views in the `i``s` database
+SELECT TABLE_NAME, SECURITY_TYPE FROM information_schema.VIEWS WHERE TABLE_SCHEMA = 'i`s' ORDER BY TABLE_NAME;
+TABLE_NAME SECURITY_TYPE
+ab`c INVOKER
+is INVOKER
+myview INVOKER
+t1 INVOKER
+t2 INVOKER
+DROP SCHEMA test1;
+DROP SCHEMA test2;
+DROP SCHEMA `is`;
+DROP SCHEMA `i``s`;
+DROP VIEW test.myview;
+DROP TABLE test.t1;
+DROP TABLE test.t2;
+DROP TABLE `is`;
+DROP TABLE `ab``c`;
@@ -0,0 +1,25 @@
+########### suite/sysschema/t/fn_quote_identifier.test #############
+# #
+# Testing of of the sys.quote_identifier() function #
+# #
+# Creation: #
+# 2016-05-23 jkrogh Implement this test as part of bug 22011361 #
+# #
+####################################################################
+
+-- source include/not_embedded.inc
+# Tests for sys schema
+# Verify the sys.quote_identifer() function perfoms as expected
+
+# Passing NULL should return NULL
+SELECT sys.quote_identifier(NULL);
+
+# Passing a simple string
+SELECT sys.quote_identifier('abc');
+
+# Passing a string containing backticks (`)
+SELECT sys.quote_identifier('ab`c');
+SELECT sys.quote_identifier('ab``c');
+SELECT sys.quote_identifier('ab```c');
+SELECT sys.quote_identifier('a`b`c');
+SELECT sys.quote_identifier('a`b``c');
@@ -0,0 +1,52 @@
+########### suite/sysschema/t/pr_create_synonym_db.test #############
+# #
+# Testing of of the sys.pr_create_synonym_db() procedure #
+# #
+# Creation: #
+# 2016-05-23 jkrogh Implement this test as part of bug 22011361 #
+# #
+#####################################################################
+
+-- source include/not_embedded.inc
+# Create a couple of tables and a view
+CREATE TABLE t1 (t1_id int PRIMARY KEY, t1_val varchar(10));
+CREATE TABLE t2 (t2_id int PRIMARY KEY, t1_id int, t2_val int, INDEX (t1_id));
+CREATE TABLE `is` (t1_id int PRIMARY KEY, t1_val varchar(10));
+CREATE TABLE `ab``c` (t1_id int PRIMARY KEY, t1_val varchar(10));
+CREATE SQL SECURITY INVOKER VIEW myview AS SELECT * FROM t1 NATURAL JOIN t2;
+
+# Make synonym db of test into test1
+CALL sys.create_synonym_db('test', 'test1');
+# Verify there's one view in test1 per table and view in test
+SELECT TABLE_NAME, SECURITY_TYPE FROM information_schema.VIEWS WHERE TABLE_SCHEMA = 'test1' ORDER BY TABLE_NAME;
+# Try again (should fail)
+-- error ER_SIGNAL_EXCEPTION
+CALL sys.create_synonym_db('test', 'test1');
+
+# Try to make the synonym db for an existing empty schema
+CREATE SCHEMA test2;
+-- error ER_SIGNAL_EXCEPTION
+CALL sys.create_synonym_db('test', 'test2');
+# Ensure test2 is still empty
+SELECT COUNT(*) FROM information_schema.TABLES WHERE TABLE_SCHEMA = 'test2';
+
+# Use a reserved identifer, Bug #22011361
+CALL sys.create_synonym_db('test', 'is');
+# Verify there's one view in is per table and view in test
+SELECT TABLE_NAME, SECURITY_TYPE FROM information_schema.VIEWS WHERE TABLE_SCHEMA = 'is' ORDER BY TABLE_NAME;
+
+# Copy the is schema to i`s schema:
+CALL sys.create_synonym_db('is', 'i`s');
+# Verify there's one view in i`s per table and view in is
+SELECT TABLE_NAME, SECURITY_TYPE FROM information_schema.VIEWS WHERE TABLE_SCHEMA = 'i`s' ORDER BY TABLE_NAME;
+
+# Clean up
+DROP SCHEMA test1;
+DROP SCHEMA test2;
+DROP SCHEMA `is`;
+DROP SCHEMA `i``s`;
+DROP VIEW test.myview;
+DROP TABLE test.t1;
+DROP TABLE test.t2;
+DROP TABLE `is`;
+DROP TABLE `ab``c`;
@@ -1,4 +1,4 @@
--- Copyright (c) 2014, 2015, Oracle and/or its affiliates. All rights reserved.
+-- Copyright (c) 2014, 2016, Oracle and/or its affiliates. All rights reserved.
--
-- This program is free software; you can redistribute it and/or modify
-- it under the terms of the GNU General Public License as published by
@@ -56,11 +56,11 @@ CREATE DEFINER='root'@'localhost' PROCEDURE create_synonym_db (
5 rows in set (0.00 sec)
mysql> CALL sys.create_synonym_db(\'performance_schema\', \'ps\');
- +-------------------------------------+
- | summary |
- +-------------------------------------+
- | Created 74 views in the ps database |
- +-------------------------------------+
+ +---------------------------------------+
+ | summary |
+ +---------------------------------------+
+ | Created 74 views in the `ps` database |
+ +---------------------------------------+
1 row in set (8.57 sec)
Query OK, 0 rows affected (8.57 sec)
@@ -131,7 +131,7 @@ BEGIN
END IF;
-- All good, create the database and views
- SET @create_db_stmt := CONCAT('CREATE DATABASE ', in_synonym);
+ SET @create_db_stmt := CONCAT('CREATE DATABASE ', sys.quote_identifier(in_synonym));
PREPARE create_db_stmt FROM @create_db_stmt;
EXECUTE create_db_stmt;
DEALLOCATE PREPARE create_db_stmt;
@@ -144,7 +144,16 @@ BEGIN
LEAVE c_table_names;
END IF;
- SET @create_view_stmt = CONCAT('CREATE SQL SECURITY INVOKER VIEW ', in_synonym, '.', v_table, ' AS SELECT * FROM ', in_db_name, '.', v_table);
+ SET @create_view_stmt = CONCAT(
+ 'CREATE SQL SECURITY INVOKER VIEW ',
+ sys.quote_identifier(in_synonym),
+ '.',
+ sys.quote_identifier(v_table),
+ ' AS SELECT * FROM ',
+ sys.quote_identifier(in_db_name),
+ '.',
+ sys.quote_identifier(v_table)
+ );
PREPARE create_view_stmt FROM @create_view_stmt;
EXECUTE create_view_stmt;
DEALLOCATE PREPARE create_view_stmt;
@@ -153,7 +162,11 @@ BEGIN
END LOOP;
CLOSE c_table_names;
- SELECT CONCAT('Created ', v_views_created, ' view', IF(v_views_created != 1, 's', ''), ' in the ', in_synonym, ' database') AS summary;
+ SELECT CONCAT(
+ 'Created ', v_views_created, ' view',
+ IF(v_views_created != 1, 's', ''), ' in the ',
+ sys.quote_identifier(in_synonym), ' database'
+ ) AS summary;
END$$
View
@@ -39,6 +39,7 @@ SOURCE ./functions/ps_is_thread_instrumented.sql
SOURCE ./functions/ps_thread_id.sql
SOURCE ./functions/ps_thread_account.sql
SOURCE ./functions/ps_thread_stack.sql
+SOURCE ./functions/quote_identifier.sql
SOURCE ./functions/sys_get_config.sql
SOURCE ./functions/version_major.sql
SOURCE ./functions/version_minor.sql
View
@@ -40,6 +40,7 @@ SOURCE ./functions/ps_thread_id.sql
SOURCE ./functions/ps_thread_account.sql
SOURCE ./functions/ps_thread_stack.sql
SOURCE ./functions/ps_thread_trx_info.sql
+SOURCE ./functions/quote_identifier.sql
SOURCE ./functions/sys_get_config.sql
SOURCE ./functions/version_major.sql
SOURCE ./functions/version_minor.sql

0 comments on commit c2beae2

Please sign in to comment.