From 658f32fd71405cc5311fd6e12ff572b4e2d9d958 Mon Sep 17 00:00:00 2001 From: Wojtek Naruniec Date: Fri, 20 Dec 2024 16:12:38 +0100 Subject: [PATCH] Fix unlimited key lengths issue (#168) Fixes https://github.com/WordPress/sqlite-database-integration/issues/167 I propose to fix an issue where dumping the table with keys that use multiple long fields produces SQL code that produces an error. --- tests/WP_SQLite_Translator_Tests.php | 67 ++++++++++++++----- .../sqlite/class-wp-sqlite-translator.php | 23 ++++++- 2 files changed, 72 insertions(+), 18 deletions(-) diff --git a/tests/WP_SQLite_Translator_Tests.php b/tests/WP_SQLite_Translator_Tests.php index b93afe30..33fa9ade 100644 --- a/tests/WP_SQLite_Translator_Tests.php +++ b/tests/WP_SQLite_Translator_Tests.php @@ -267,8 +267,8 @@ public function testShowCreateTable1() { ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, option_name VARCHAR(255) default '', option_value TEXT NOT NULL, - UNIQUE KEY option_name (option_name), - KEY composite (option_name, option_value) + UNIQUE KEY option_name (option_name(100)), + KEY composite (option_name(100), option_value(100)) );" ); @@ -283,8 +283,8 @@ public function testShowCreateTable1() { `option_name` varchar(255) DEFAULT '', `option_value` text NOT NULL DEFAULT '', PRIMARY KEY (`ID`), - KEY `composite` (`option_name`, `option_value`), - UNIQUE KEY `option_name` (`option_name`) + KEY `composite` (`option_name`(100), `option_value`(100)), + UNIQUE KEY `option_name` (`option_name`(100)) );", $results[0]->{'Create Table'} ); @@ -337,8 +337,8 @@ public function testShowCreateTableQuoted() { ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, option_name VARCHAR(255) default '', option_value TEXT NOT NULL, - UNIQUE KEY option_name (option_name), - KEY composite (option_name, option_value) + UNIQUE KEY option_name (option_name(100)), + KEY composite (option_name, option_value(100)) );" ); @@ -353,8 +353,8 @@ public function testShowCreateTableQuoted() { `option_name` varchar(255) DEFAULT '', `option_value` text NOT NULL DEFAULT '', PRIMARY KEY (`ID`), - KEY `composite` (`option_name`, `option_value`), - UNIQUE KEY `option_name` (`option_name`) + KEY `composite` (`option_name`(100), `option_value`(100)), + UNIQUE KEY `option_name` (`option_name`(100)) );", $results[0]->{'Create Table'} ); @@ -418,8 +418,8 @@ public function testCreateTablseWithIdenticalIndexNames() { ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, option_name VARCHAR(255) default '', option_value TEXT NOT NULL, - KEY `option_name` (`option_name`), - KEY `double__underscores` (`option_name`, `ID`) + KEY `option_name` (`option_name`(100)), + KEY `double__underscores` (`option_name`(100), `ID`) );" ); @@ -428,8 +428,8 @@ public function testCreateTablseWithIdenticalIndexNames() { ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, option_name VARCHAR(255) default '', option_value TEXT NOT NULL, - KEY `option_name` (`option_name`), - KEY `double__underscores` (`option_name`, `ID`) + KEY `option_name` (`option_name`(100)), + KEY `double__underscores` (`option_name`(100), `ID`) );" ); } @@ -440,8 +440,8 @@ public function testShowCreateTablePreservesDoubleUnderscoreKeyNames() { ID BIGINT PRIMARY KEY AUTO_INCREMENT NOT NULL, option_name VARCHAR(255) default '', option_value TEXT NOT NULL, - KEY `option_name` (`option_name`), - KEY `double__underscores` (`option_name`, `ID`) + KEY `option_name` (`option_name`(100)), + KEY `double__underscores` (`option_name`(100), `ID`) );" ); @@ -455,8 +455,43 @@ public function testShowCreateTablePreservesDoubleUnderscoreKeyNames() { `option_name` varchar(255) DEFAULT \'\', `option_value` text NOT NULL DEFAULT \'\', PRIMARY KEY (`ID`), - KEY `double__underscores` (`option_name`, `ID`), - KEY `option_name` (`option_name`) + KEY `double__underscores` (`option_name`(100), `ID`), + KEY `option_name` (`option_name`(100)) +);', + $results[0]->{'Create Table'} + ); + } + + public function testShowCreateTableLimitsKeyLengths() { + $this->assertQuery( + 'CREATE TABLE _tmp__table ( + `id` bigint(20) unsigned NOT NULL AUTO_INCREMENT, + `order_id` bigint(20) unsigned DEFAULT NULL, + `meta_key` varchar(20) DEFAULT NULL, + `meta_value` text DEFAULT NULL, + `meta_data` mediumblob DEFAULT NULL, + PRIMARY KEY (`id`), + KEY `meta_key_value` (`meta_key`(20),`meta_value`(82)), + KEY `order_id_meta_key_meta_value` (`order_id`,`meta_key`(100),`meta_value`(82)), + KEY `order_id_meta_key_meta_data` (`order_id`,`meta_key`(100),`meta_data`(100)) + );' + ); + + $this->assertQuery( + 'SHOW CREATE TABLE _tmp__table;' + ); + $results = $this->engine->get_query_results(); + $this->assertEquals( + 'CREATE TABLE `_tmp__table` ( + `id` bigint(20) unsigned NOT NULL AUTO_INCREMENT, + `order_id` bigint(20) unsigned DEFAULT NULL, + `meta_key` varchar(20) DEFAULT NULL, + `meta_value` text DEFAULT NULL, + `meta_data` mediumblob DEFAULT NULL, + PRIMARY KEY (`id`), + KEY `order_id_meta_key_meta_data` (`order_id`, `meta_key`(20), `meta_data`(100)), + KEY `order_id_meta_key_meta_value` (`order_id`, `meta_key`(20), `meta_value`(100)), + KEY `meta_key_value` (`meta_key`(20), `meta_value`(100)) );', $results[0]->{'Create Table'} ); diff --git a/wp-includes/sqlite/class-wp-sqlite-translator.php b/wp-includes/sqlite/class-wp-sqlite-translator.php index 0f61a7c7..44996cd6 100644 --- a/wp-includes/sqlite/class-wp-sqlite-translator.php +++ b/wp-includes/sqlite/class-wp-sqlite-translator.php @@ -3725,7 +3725,8 @@ protected function get_column_definitions( $table_name, $columns ) { * @return array An array of key definitions */ private function get_key_definitions( $table_name, $columns ) { - $key_definitions = array(); + $key_length_limit = 100; + $key_definitions = array(); $pks = array(); foreach ( $columns as $column ) { @@ -3756,7 +3757,25 @@ private function get_key_definitions( $table_name, $columns ) { $key_definition[] = sprintf( '`%s`', $index_name ); $cols = array_map( - function ( $column ) { + function ( $column ) use ( $table_name, $key_length_limit ) { + $data_type = strtolower( $this->get_cached_mysql_data_type( $table_name, $column['name'] ) ); + $data_length = $key_length_limit; + + // Extract the length from the data type. Make it lower if needed. Skip 'unsigned' parts and whitespace. + if ( 1 === preg_match( '/^(\w+)\s*\(\s*(\d+)\s*\)/', $data_type, $matches ) ) { + $data_type = $matches[1]; // "varchar" + $data_length = min( $matches[2], $key_length_limit ); // "255" + } + + // Set the data length to the varchar and text key lengths + // char, varchar, varbinary, tinyblob, tinytext, blob, text, mediumblob, mediumtext, longblob, longtext + if ( str_ends_with( $data_type, 'char' ) || + str_ends_with( $data_type, 'text' ) || + str_ends_with( $data_type, 'blob' ) || + str_starts_with( $data_type, 'var' ) + ) { + return sprintf( '`%s`(%s)', $column['name'], $data_length ); + } return sprintf( '`%s`', $column['name'] ); }, $key['columns']