-
Notifications
You must be signed in to change notification settings - Fork 45
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Address PK issues for show create table queries (#127)
Fixes: #123 In this PR i propose a refactor of the handling of `show create table` queries. The main issue was that it is possible for a primary key to be composite (more than one column). The existing implementation only supports a single PK which causes the `CREATE TABLE` statement to be invalid. An example of such a table is the `wp_term_relationships` found in WordPress: ```mysql -- original MySQL statement CREATE TABLE `wp_term_relationships` ( `object_id` bigint(20) unsigned NOT NULL DEFAULT 0, `term_taxonomy_id` bigint(20) unsigned NOT NULL DEFAULT 0, `term_order` int(11) NOT NULL DEFAULT 0, PRIMARY KEY (`object_id`,`term_taxonomy_id`), KEY `term_taxonomy_id` (`term_taxonomy_id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- statement produced by SQLite database integration CREATE TABLE wp_term_relationships ( `object_id` bigint(20) unsigned PRIMARY KEY AUTO_INCREMENT NOT NULL, `term_taxonomy_id` bigint(20) unsigned NOT NULL, `term_order` int(11) NOT NULL, KEY wp_term_relationships__term_taxonomy_id (term_taxonomy_id), UNIQUE KEY sqlite_autoindex_wp_term_relationships_1 (object_id, term_taxonomy_id) ); ``` SQLite also creates a unique key for any primary key (single or composite) which is something that is not necessary for MySQL and should be skipped from the final create statement. ## In this PR - Refactor the code to separate things into smaller methods. - Add the PK definition before the keys and remove it from the column definitions. - Use backticks around table names, column names and key identifiers. This is to prevent issues when names of identifiers are using reserved keywords, ensure case sensitivity and allow them to contain special chars or spaces. - Improve detection of AUTO_INCREMENT column. Now we falsely mark columns as AUTO_INCREMENT just because they happen to be the primary key and be of type integer. - Fix creating an invalid UNIQUE KEY for the PK. When we find that the unique key is identical to the primary key, we can skip the unique key as it is redundant. The final query output for `show create wp_term_relationships` looks as follows: ```mysql DROP TABLE IF EXISTS `wp_term_relationships`; CREATE TABLE `wp_term_relationships` ( `object_id` bigint(20) unsigned NOT NULL DEFAULT 0, `term_taxonomy_id` bigint(20) unsigned NOT NULL DEFAULT 0, `term_order` int(11) NOT NULL DEFAULT 0, PRIMARY KEY (`object_id`, `term_taxonomy_id`), KEY `wp_term_relationships__idx_term_taxonomy_id_x` (`term_taxonomy_id`) ); ``` ## Testing - Run the unit tests - Create a site with SQLite and then run `$wpdb->query('show create wp_term_relationships')` - The result should be a valid MySQL compatible query as shown above.
- Loading branch information
Showing
2 changed files
with
241 additions
and
71 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters