From 91f1612d10cc415824314c02907df905d4eef1df Mon Sep 17 00:00:00 2001 From: Matthew Bucci Date: Sun, 26 Nov 2023 01:34:10 -0800 Subject: [PATCH 01/15] add tests for table creation --- pg4wp/rewriters/CreateTableSQLRewriter.php | 25 ++++++++++--- tests/rewriteTest.php | 41 ++++++++++++++++++++++ 2 files changed, 62 insertions(+), 4 deletions(-) diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index fd31e4e..67586a4 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -6,6 +6,7 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter 'bigint(20)' => 'bigint', 'bigint(10)' => 'int', 'int(11)' => 'int', + 'int(1)' => 'smallint', 'tinytext' => 'text', 'mediumtext' => 'text', 'longtext' => 'text', @@ -45,22 +46,22 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter $sql = trim($sql) . ';'; // Translate types and some other replacements - $sql = str_replace( + $sql = str_ireplace( array_keys($this->stringReplacements), array_values($this->stringReplacements), $sql ); // Fix auto_increment by adding a sequence - $pattern = '/int[ ]+NOT NULL auto_increment/'; + $pattern = '/int[ ]+NOT NULL auto_increment/i'; preg_match($pattern, $sql, $matches); if($matches) { $seq = $table . '_seq'; - $sql = str_replace('NOT NULL auto_increment', "NOT NULL DEFAULT nextval('$seq'::text)", $sql); + $sql = str_ireplace('NOT NULL auto_increment', "NOT NULL DEFAULT nextval('$seq'::text)", $sql); $sql .= "\nCREATE SEQUENCE $seq;"; } - // Support for INDEX creation + // Support for UNIQUE INDEX creation $pattern = '/,\s+(UNIQUE |)KEY\s+([^\s]+)\s+\(((?:[\w]+(?:\([\d]+\))?[,]?)*)\)/'; if(preg_match_all($pattern, $sql, $matches, PREG_SET_ORDER)) { foreach($matches as $match) { @@ -75,6 +76,22 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter } // Now remove handled indexes $sql = preg_replace($pattern, '', $sql); + + // Support for PRIMARY INDEX creation + $pattern = '/,\s+(PRIMARY |)KEY\s+\(((?:[\w]+(?:\([\d]+\))?[,]?)*)\)/'; + if(preg_match_all($pattern, $sql, $matches, PREG_SET_ORDER)) { + foreach($matches as $match) { + $primary = $match[1]; + $columns = $match[2]; + $columns = preg_replace('/\(\d+\)/', '', $columns); + $index = $columns; + // Workaround for index name duplicate + $index = $table . '_' . $index; + $sql .= "\nCREATE {$primary}INDEX $index ON $table ($columns);"; + } + } + // Now remove handled indexes + $sql = preg_replace($pattern, '', $sql); return $sql; } diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index 3328587..f01ab14 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -31,4 +31,45 @@ final class rewriteTest extends TestCase $postgresql = pg4wp_rewrite($sql); $this->assertSame($postgresql, $expected); } + + public function test_it_handles_auto_increment() + { + $sql = <<assertSame(trim($postgresql), trim($expected)); + } } \ No newline at end of file From cbd3d8391858f0a6a9dd4b4a35f164119cde64fa Mon Sep 17 00:00:00 2001 From: Matthew Bucci Date: Sun, 26 Nov 2023 01:42:21 -0800 Subject: [PATCH 02/15] postgres does support primary keys in the mysql format, we don't need to rewrite --- pg4wp/rewriters/CreateTableSQLRewriter.php | 16 ---------------- tests/rewriteTest.php | 4 ++-- 2 files changed, 2 insertions(+), 18 deletions(-) diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index 67586a4..c431579 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -77,22 +77,6 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter // Now remove handled indexes $sql = preg_replace($pattern, '', $sql); - // Support for PRIMARY INDEX creation - $pattern = '/,\s+(PRIMARY |)KEY\s+\(((?:[\w]+(?:\([\d]+\))?[,]?)*)\)/'; - if(preg_match_all($pattern, $sql, $matches, PREG_SET_ORDER)) { - foreach($matches as $match) { - $primary = $match[1]; - $columns = $match[2]; - $columns = preg_replace('/\(\d+\)/', '', $columns); - $index = $columns; - // Workaround for index name duplicate - $index = $table . '_' . $index; - $sql .= "\nCREATE {$primary}INDEX $index ON $table ($columns);"; - } - } - // Now remove handled indexes - $sql = preg_replace($pattern, '', $sql); - return $sql; } } diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index f01ab14..8855ebd 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -63,10 +63,10 @@ final class rewriteTest extends TestCase lockout_user bigint , lockout_username varchar(60), lockout_active smallint NOT NULL DEFAULT 1, - lockout_context TEXT + lockout_context TEXT, + PRIMARY KEY (lockout_id) ); CREATE SEQUENCE wp_itsec_lockouts_seq; - CREATE PRIMARY INDEX wp_itsec_lockouts_lockout_id ON wp_itsec_lockouts (lockout_id); SQL; $postgresql = pg4wp_rewrite($sql); From fd2467c00b58b1f0ea335834478fd8cbfadade91 Mon Sep 17 00:00:00 2001 From: Matthew Bucci Date: Sun, 26 Nov 2023 15:07:33 -0800 Subject: [PATCH 03/15] switch to serial numeric types --- pg4wp/rewriters/CreateTableSQLRewriter.php | 31 ++++++++++++++++++---- tests/rewriteTest.php | 25 +++++++++++++++-- 2 files changed, 49 insertions(+), 7 deletions(-) diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index c431579..bbd09d6 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -52,13 +52,34 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter $sql ); - // Fix auto_increment by adding a sequence - $pattern = '/int[ ]+NOT NULL auto_increment/i'; + // bigint + $pattern = '/bigint(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i'; preg_match($pattern, $sql, $matches); if($matches) { - $seq = $table . '_seq'; - $sql = str_ireplace('NOT NULL auto_increment', "NOT NULL DEFAULT nextval('$seq'::text)", $sql); - $sql .= "\nCREATE SEQUENCE $seq;"; + $sql = preg_replace($pattern, 'bigserial', $sql); + } + + // int + $pattern = '/int(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i'; + preg_match($pattern, $sql, $matches); + if($matches) { + $sql = preg_replace($pattern, 'serial', $sql); + } + + // smallint + $pattern = '/smallint(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i'; + preg_match($pattern, $sql, $matches); + if($matches) { + $sql = preg_replace($pattern, 'smallserial', $sql); + } + + // Handle for numeric and decimal -- being replaced with serial + $numeric_patterns = ['/numeric(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i', '/decimal(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i']; + foreach($numeric_patterns as $pattern) { + preg_match($pattern, $sql, $matches); + if($matches) { + $sql = preg_replace($pattern, 'serial', $sql); + } } // Support for UNIQUE INDEX creation diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index 8855ebd..12d56f1 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -53,7 +53,7 @@ final class rewriteTest extends TestCase $expected = <<assertSame(trim($postgresql), trim($expected)); + } + + public function test_it_handles_auto_increment_without_null() + { + $sql = << Date: Sun, 26 Nov 2023 15:17:26 -0800 Subject: [PATCH 04/15] handle unique keys --- pg4wp/rewriters/CreateTableSQLRewriter.php | 5 ++++ tests/rewriteTest.php | 31 ++++++++++++++++++++++ 2 files changed, 36 insertions(+) diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index bbd09d6..649d94d 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -97,6 +97,11 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter } // Now remove handled indexes $sql = preg_replace($pattern, '', $sql); + + + $pattern = "/(,\s*)?UNIQUE KEY\s+[a-zA-Z0-9_]+\s+(\([a-zA-Z0-9_,\s]+\))/"; + $replacement = "$1UNIQUE $2"; + $sql = preg_replace($pattern, $replacement, $sql); return $sql; } diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index 12d56f1..9d417df 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -93,4 +93,35 @@ final class rewriteTest extends TestCase $postgresql = pg4wp_rewrite($sql); $this->assertSame(trim($postgresql), trim($expected)); } + + + public function test_it_handles_keys() + { + $sql = <<assertSame(trim($postgresql), trim($expected)); + } + + } \ No newline at end of file From d7bf645504afb334e52c247e5ca44eb0dcb9a777 Mon Sep 17 00:00:00 2001 From: Matthew Bucci Date: Sun, 26 Nov 2023 15:24:45 -0800 Subject: [PATCH 05/15] handle regular key expressions --- tests/rewriteTest.php | 42 ++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 42 insertions(+) diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index 9d417df..e2d2ad7 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -123,5 +123,47 @@ final class rewriteTest extends TestCase $this->assertSame(trim($postgresql), trim($expected)); } + public function test_it_handles_keys_without_unique() + { + $sql = <<assertSame(trim($postgresql), trim($expected)); + } + } \ No newline at end of file From 7471e353e94bb6122c4503227936c1a7d45dce18 Mon Sep 17 00:00:00 2001 From: mattbucci Date: Mon, 8 Jan 2024 01:15:25 +0000 Subject: [PATCH 06/15] Merge --- tests/rewriteTest.php | 3 --- 1 file changed, 3 deletions(-) diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index 659253c..bc9441c 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -167,9 +167,6 @@ final class rewriteTest extends TestCase $this->assertSame(trim($postgresql), trim($expected)); } - -} - protected function setUp(): void { global $wpdb; From 200dfaa0b22d86e5f5a7f58a012217349c8b1668 Mon Sep 17 00:00:00 2001 From: mattbucci Date: Mon, 8 Jan 2024 04:08:35 +0000 Subject: [PATCH 07/15] Add space before replacements to avoid any issues with similar types --- pg4wp/rewriters/AlterTableSQLRewriter.php | 30 ++++++++++++---------- pg4wp/rewriters/CreateTableSQLRewriter.php | 28 ++++++++++---------- 2 files changed, 31 insertions(+), 27 deletions(-) diff --git a/pg4wp/rewriters/AlterTableSQLRewriter.php b/pg4wp/rewriters/AlterTableSQLRewriter.php index 0bd820a..6d39041 100644 --- a/pg4wp/rewriters/AlterTableSQLRewriter.php +++ b/pg4wp/rewriters/AlterTableSQLRewriter.php @@ -3,30 +3,32 @@ class AlterTableSQLRewriter extends AbstractSQLRewriter { private $stringReplacements = [ - 'bigint(20)' => 'bigint', - 'bigint(10)' => 'int', - 'int(11)' => 'int', - 'tinytext' => 'text', - 'mediumtext' => 'text', - 'longtext' => 'text', - 'unsigned' => '', + ' bigint(40)' => ' bigint', + ' bigint(20)' => ' bigint', + ' bigint(10)' => ' int', + ' int(11)' => ' int', + ' int(10)' => ' int', + ' tinytext' => ' text', + ' mediumtext' => ' text', + ' longtext' => ' text', + ' unsigned' => ' ', 'gmt datetime NOT NULL default \'0000-00-00 00:00:00\'' => 'gmt timestamp NOT NULL DEFAULT timezone(\'gmt\'::text, now())', 'default \'0000-00-00 00:00:00\'' => 'DEFAULT now()', '\'0000-00-00 00:00:00\'' => 'now()', - 'datetime' => 'timestamp', + ' datetime' => ' timestamp', 'DEFAULT CHARACTER SET utf8' => '', // WP 2.7.1 compatibility - 'int(4)' => 'smallint', + ' int(4)' => ' smallint', // For WPMU (starting with WP 3.2) - 'tinyint(2)' => 'smallint', - 'tinyint(1)' => 'smallint', - "enum('0','1')" => 'smallint', - 'COLLATE utf8_general_ci' => '', + ' tinyint(2)' => ' smallint', + ' tinyint(1)' => ' smallint', + " enum('0','1')" => ' smallint', + ' COLLATE utf8_general_ci' => ' ', // For flash-album-gallery plugin - 'tinyint' => 'smallint' + ' tinyint' => ' smallint' ]; public function rewrite(): string diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index 67c1237..d61ea2d 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -3,14 +3,16 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter { private $stringReplacements = [ - 'bigint(20)' => 'bigint', - 'bigint(10)' => 'int', - 'int(11)' => 'int', - 'int(1)' => 'smallint', - 'tinytext' => 'text', - 'mediumtext' => 'text', - 'longtext' => 'text', - 'unsigned' => '', + ' bigint(40)' => ' bigint', + ' bigint(20)' => ' bigint', + ' bigint(10)' => ' int', + ' int(11)' => ' int', + ' int(10)' => ' int', + ' int(1)' => ' smallint', + ' tinytext' => ' text', + ' mediumtext' => ' text', + ' longtext' => ' text', + ' unsigned' => ' ', 'gmt datetime NOT NULL default \'0000-00-00 00:00:00\'' => 'gmt timestamp NOT NULL DEFAULT timezone(\'gmt\'::text, now())', 'default \'0000-00-00 00:00:00\'' => 'DEFAULT now()', '\'0000-00-00 00:00:00\'' => 'now()', @@ -19,17 +21,17 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter 'DEFAULT CHARACTER SET utf8' => '', // WP 2.7.1 compatibility - 'int(4)' => 'smallint', + ' int(4)' => ' smallint', // For WPMU (starting with WP 3.2) - 'tinyint(2)' => 'smallint', - 'tinyint(1)' => 'smallint', - "enum('0','1')" => 'smallint', + ' tinyint(2)' => ' smallint', + ' tinyint(1)' => ' smallint', + " enum('0','1')" => ' smallint', 'COLLATE utf8mb4_unicode_520_ci' => '', 'COLLATE utf8_general_ci' => '', // For flash-album-gallery plugin - 'tinyint' => 'smallint' + ' tinyint' => ' smallint' ]; public function rewrite(): string From aca566b8bf9bd56cf6c6ec6aba254e0510d9d642 Mon Sep 17 00:00:00 2001 From: mattbucci Date: Mon, 8 Jan 2024 04:13:06 +0000 Subject: [PATCH 08/15] pgrewrite should not remove IF NOT EXISTS --- pg4wp/rewriters/CreateTableSQLRewriter.php | 4 ++-- tests/rewriteTest.php | 28 ++++++++++++++++++++++ 2 files changed, 30 insertions(+), 2 deletions(-) diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index d61ea2d..d16e190 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -39,9 +39,9 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter $sql = $this->original(); - $sql = str_replace('CREATE TABLE IF NOT EXISTS ', 'CREATE TABLE ', $sql); + $tableSQL = str_replace('CREATE TABLE IF NOT EXISTS ', 'CREATE TABLE ', $sql); $pattern = '/CREATE TABLE [`]?(\w+)[`]?/'; - preg_match($pattern, $sql, $matches); + preg_match($pattern, $tableSQL, $matches); $table = $matches[1]; // Remove trailing spaces diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index bc9441c..d08c203 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -167,6 +167,34 @@ final class rewriteTest extends TestCase $this->assertSame(trim($postgresql), trim($expected)); } + public function test_it_does_not_remove_if_not_exists() + { + $sql = <<assertSame(trim($postgresql), trim($expected)); + } + protected function setUp(): void { global $wpdb; From 5f27c893b30d9f96e1eb8146534e345cc863a23c Mon Sep 17 00:00:00 2001 From: mattbucci Date: Mon, 8 Jan 2024 04:22:59 +0000 Subject: [PATCH 09/15] Remove Default character set --- pg4wp/rewriters/AlterTableSQLRewriter.php | 4 +- pg4wp/rewriters/CreateTableSQLRewriter.php | 9 +++-- tests/rewriteTest.php | 46 ++++++++++++++++++++++ 3 files changed, 53 insertions(+), 6 deletions(-) diff --git a/pg4wp/rewriters/AlterTableSQLRewriter.php b/pg4wp/rewriters/AlterTableSQLRewriter.php index 6d39041..658a499 100644 --- a/pg4wp/rewriters/AlterTableSQLRewriter.php +++ b/pg4wp/rewriters/AlterTableSQLRewriter.php @@ -16,7 +16,7 @@ class AlterTableSQLRewriter extends AbstractSQLRewriter 'default \'0000-00-00 00:00:00\'' => 'DEFAULT now()', '\'0000-00-00 00:00:00\'' => 'now()', ' datetime' => ' timestamp', - 'DEFAULT CHARACTER SET utf8' => '', + ' DEFAULT CHARACTER SET utf8' => '', // WP 2.7.1 compatibility ' int(4)' => ' smallint', @@ -25,7 +25,7 @@ class AlterTableSQLRewriter extends AbstractSQLRewriter ' tinyint(2)' => ' smallint', ' tinyint(1)' => ' smallint', " enum('0','1')" => ' smallint', - ' COLLATE utf8_general_ci' => ' ', + ' COLLATE utf8_general_ci' => '', // For flash-album-gallery plugin ' tinyint' => ' smallint' diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index d16e190..25512cf 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -17,8 +17,8 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter 'default \'0000-00-00 00:00:00\'' => 'DEFAULT now()', '\'0000-00-00 00:00:00\'' => 'now()', 'datetime' => 'timestamp', - 'DEFAULT CHARACTER SET utf8mb4' => '', - 'DEFAULT CHARACTER SET utf8' => '', + ' DEFAULT CHARACTER SET utf8mb4' => '', + ' DEFAULT CHARACTER SET utf8' => '', // WP 2.7.1 compatibility ' int(4)' => ' smallint', @@ -27,8 +27,9 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter ' tinyint(2)' => ' smallint', ' tinyint(1)' => ' smallint', " enum('0','1')" => ' smallint', - 'COLLATE utf8mb4_unicode_520_ci' => '', - 'COLLATE utf8_general_ci' => '', + ' COLLATE utf8mb4_unicode_520_ci' => '', + ' COLLATE utf8_general_ci' => '', + ' CHARACTER SET utf8' => '', // For flash-album-gallery plugin ' tinyint' => ' smallint' diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index d08c203..b588e51 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -195,6 +195,52 @@ final class rewriteTest extends TestCase $this->assertSame(trim($postgresql), trim($expected)); } + + public function test_it_removes_character_sets() + { + $sql = <<assertSame(trim($postgresql), trim($expected)); + } + + protected function setUp(): void { global $wpdb; From 53125aec2d7b3fa3a48436ffe81d904ba693d6e6 Mon Sep 17 00:00:00 2001 From: mattbucci Date: Mon, 8 Jan 2024 05:00:42 +0000 Subject: [PATCH 10/15] Add support for keys with multiple values --- pg4wp/rewriters/CreateTableSQLRewriter.php | 20 +++-- tests/rewriteTest.php | 87 ++++++++++++++++------ tests/verifyAgainstStubsTest.php | 2 +- 3 files changed, 78 insertions(+), 31 deletions(-) diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index 25512cf..3f23cc1 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -86,16 +86,24 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter } // Support for UNIQUE INDEX creation - $pattern = '/,\s+(UNIQUE |)KEY\s+([^\s]+)\s+\(((?:[\w]+(?:\([\d]+\))?[,]?)*)\)/'; + $pattern = '/,\s*(UNIQUE |)KEY\s+(`[^`]+`|\w+)\s+\(([^)]+)\)/'; if(preg_match_all($pattern, $sql, $matches, PREG_SET_ORDER)) { foreach($matches as $match) { $unique = $match[1]; $index = $match[2]; $columns = $match[3]; - $columns = preg_replace('/\(\d+\)/', '', $columns); - // Workaround for index name duplicate - $index = $table . '_' . $index; - $sql .= "\nCREATE {$unique}INDEX $index ON $table ($columns);"; + + // Removing backticks from the index names + $index = str_replace('`', '', $index); + + // Removing backticks from the columns + $columns = str_replace('`', '', $columns); + + // Creating a unique index name + $indexName = $table . '_' . $index; + + // Appending the CREATE INDEX statement to SQL + $sql .= "\nCREATE {$unique}INDEX $indexName ON $table ($columns);"; } } // Now remove handled indexes @@ -105,7 +113,7 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter $pattern = "/(,\s*)?UNIQUE KEY\s+[a-zA-Z0-9_]+\s+(\([a-zA-Z0-9_,\s]+\))/"; $replacement = "$1UNIQUE $2"; $sql = preg_replace($pattern, $replacement, $sql); - + return $sql; } } diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index b588e51..d71f75a 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -21,7 +21,7 @@ final class rewriteTest extends TestCase $sql = 'SELECT COUNT(NULLIF(`meta_value` LIKE \'%"administrator"%\', false)), COUNT(NULLIF(`meta_value` = \'a:0:{}\', false)), COUNT(*) FROM wp_usermeta INNER JOIN wp_users ON user_id = ID WHERE meta_key = \'wp_capabilities\''; $expected = 'SELECT COUNT(NULLIF(meta_value ILIKE \'%"administrator"%\', false)) AS count0, COUNT(NULLIF(meta_value = \'a:0:{}\', false)) AS count1, COUNT(*) FROM wp_usermeta INNER JOIN wp_users ON user_id = "ID" WHERE meta_key = \'wp_capabilities\''; $postgresql = pg4wp_rewrite($sql); - $this->assertSame($postgresql, $expected); + $this->assertSame(trim($expected), trim($postgresql)); } @@ -31,10 +31,10 @@ final class rewriteTest extends TestCase $sql = 'SELECT COUNT(id), username FROM users'; $expected = 'SELECT COUNT(id) AS count0, username FROM users GROUP BY username'; $postgresql = pg4wp_rewrite($sql); - $this->assertSame($postgresql, $expected); + $this->assertSame(trim($expected), trim($postgresql)); } - public function test_it_handles_auto_increment() + public function test_it_handles_auto_increment() { $sql = <<assertSame(trim($postgresql), trim($expected)); + $this->assertSame(trim($expected), trim($postgresql)); } - public function test_it_handles_auto_increment_without_null() + public function test_it_handles_auto_increment_without_null() { $sql = <<assertSame(trim($postgresql), trim($expected)); + $this->assertSame(trim($expected), trim($postgresql)); } - public function test_it_handles_keys() + public function test_it_handles_keys() { $sql = <<assertSame(trim($postgresql), trim($expected)); + $this->assertSame(trim($expected), trim($postgresql)); } - public function test_it_handles_keys_without_unique() + public function test_it_handles_keys_without_unique() { $sql = <<assertSame(trim($postgresql), trim($expected)); + $this->assertSame(trim($expected), trim($postgresql)); } - public function test_it_does_not_remove_if_not_exists() + public function test_it_does_not_remove_if_not_exists() { $sql = <<assertSame(trim($postgresql), trim($expected)); + $this->assertSame(trim($expected), trim($postgresql)); } - public function test_it_removes_character_sets() + public function test_it_removes_character_sets() { $sql = <<assertSame(trim($postgresql), trim($expected)); + $this->assertSame(trim($expected), trim($postgresql)); } + public function test_it_handles_multiple_keys() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } protected function setUp(): void { diff --git a/tests/verifyAgainstStubsTest.php b/tests/verifyAgainstStubsTest.php index 35c56e4..04dd652 100644 --- a/tests/verifyAgainstStubsTest.php +++ b/tests/verifyAgainstStubsTest.php @@ -22,7 +22,7 @@ final class verifyAgainstStubsTest extends TestCase $files = array_diff(scandir(self::STUBS_DIRECTORY), array('.', '..')); foreach($files as $file) { $data = json_decode(file_get_contents(self::STUBS_DIRECTORY . "/" . $file), true); - $this->assertSame(pg4wp_rewrite($data['mysql']), $data['postgresql']); + $this->assertSame($data['postgresql'], pg4wp_rewrite($data['mysql'])); } } From a90ab01a9b98cee00a9d2eef966abd1e72cb57c5 Mon Sep 17 00:00:00 2001 From: mattbucci Date: Mon, 8 Jan 2024 05:08:57 +0000 Subject: [PATCH 11/15] handle table charsets --- pg4wp/rewriters/CreateTableSQLRewriter.php | 8 ++++++- tests/rewriteTest.php | 26 ++++++++++++++++++++++ 2 files changed, 33 insertions(+), 1 deletion(-) diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index 3f23cc1..6120ca7 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -30,6 +30,7 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter ' COLLATE utf8mb4_unicode_520_ci' => '', ' COLLATE utf8_general_ci' => '', ' CHARACTER SET utf8' => '', + ' DEFAULT CHARSET=utf8' => '', // For flash-album-gallery plugin ' tinyint' => ' smallint' @@ -46,7 +47,12 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter $table = $matches[1]; // Remove trailing spaces - $sql = trim($sql) . ';'; + $sql = trim($sql); + + // Add a slash if needed + if (substr($sql,strlen($sql)-1, 1) != ";") { + $sql = $sql . ";"; + } // Translate types and some other replacements $sql = str_ireplace( diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index d71f75a..18bd6e4 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -280,6 +280,32 @@ final class rewriteTest extends TestCase $this->assertSame(trim($expected), trim($postgresql)); } + + public function test_it_removes_table_charsets() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } + + + + protected function setUp(): void { global $wpdb; From 8f1f65db47493b890dc92a41b0b9abd030185b5d Mon Sep 17 00:00:00 2001 From: Matthew Bucci Date: Thu, 11 Jan 2024 01:10:57 -0800 Subject: [PATCH 12/15] handle tables with fixed key lengths --- pg4wp/rewriters/CreateTableSQLRewriter.php | 10 ++++---- tests/rewriteTest.php | 30 ++++++++++++++++++++++ 2 files changed, 35 insertions(+), 5 deletions(-) diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index 6120ca7..bc88bdd 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -50,7 +50,7 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter $sql = trim($sql); // Add a slash if needed - if (substr($sql,strlen($sql)-1, 1) != ";") { + if (substr($sql, strlen($sql) - 1, 1) != ";") { $sql = $sql . ";"; } @@ -92,18 +92,18 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter } // Support for UNIQUE INDEX creation - $pattern = '/,\s*(UNIQUE |)KEY\s+(`[^`]+`|\w+)\s+\(([^)]+)\)/'; + $pattern = '/,\s*(UNIQUE |)KEY\s+(`[^`]+`|\w+)\s+\((.*?)\)(?!\))/'; if(preg_match_all($pattern, $sql, $matches, PREG_SET_ORDER)) { foreach($matches as $match) { $unique = $match[1]; $index = $match[2]; $columns = $match[3]; - // Removing backticks from the index names + // Removing backticks from the index names $index = str_replace('`', '', $index); - // Removing backticks from the columns - $columns = str_replace('`', '', $columns); + // Removing backticks and key length constraints from the columns + $columns = preg_replace(["/`/", "/\(\d+\)/"], '', $columns); // Creating a unique index name $indexName = $table . '_' . $index; diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index 18bd6e4..3ccc2e3 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -304,6 +304,36 @@ final class rewriteTest extends TestCase } + public function test_it_can_create_keys_with_length() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } + protected function setUp(): void From ade3d6ad8731035cd8d8a2f08a2a32acf5b754e5 Mon Sep 17 00:00:00 2001 From: Matthew Bucci Date: Thu, 11 Jan 2024 01:28:43 -0800 Subject: [PATCH 13/15] handle case with keys across multiple columns with defined lengths --- pg4wp/rewriters/CreateTableSQLRewriter.php | 2 +- tests/rewriteTest.php | 48 ++++++++++++++++++++++ 2 files changed, 49 insertions(+), 1 deletion(-) diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index bc88bdd..e7aba47 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -92,7 +92,7 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter } // Support for UNIQUE INDEX creation - $pattern = '/,\s*(UNIQUE |)KEY\s+(`[^`]+`|\w+)\s+\((.*?)\)(?!\))/'; + $pattern = '/,\s*(UNIQUE |)KEY\s+(`[^`]+`|\w+)\s+\(((?:[^()]|\([^)]*\))*)\)/'; if(preg_match_all($pattern, $sql, $matches, PREG_SET_ORDER)) { foreach($matches as $match) { $unique = $match[1]; diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index 3ccc2e3..985f7d4 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -333,6 +333,54 @@ final class rewriteTest extends TestCase $postgresql = pg4wp_rewrite($sql); $this->assertSame(trim($expected), trim($postgresql)); } + + + + public function test_it_can_create_double_keys_with_length() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } From 66d8a3df0e415c27abe416295c9aca4fd09cdbde Mon Sep 17 00:00:00 2001 From: Matthew Bucci Date: Tue, 16 Jan 2024 21:35:32 -0800 Subject: [PATCH 14/15] update sequence handling to support bigserial and serial types --- pg4wp/driver_pgsql.php | 51 +++++++++++++++++----- pg4wp/driver_pgsql_rewrite.php | 2 +- pg4wp/rewriters/CreateTableSQLRewriter.php | 7 ++- tests/parseTest.php | 1 - tests/rewriteTest.php | 50 ++++++++++----------- 5 files changed, 71 insertions(+), 40 deletions(-) diff --git a/pg4wp/driver_pgsql.php b/pg4wp/driver_pgsql.php index 26be48c..06c99d5 100644 --- a/pg4wp/driver_pgsql.php +++ b/pg4wp/driver_pgsql.php @@ -1039,6 +1039,38 @@ function wpsqli_affected_rows(&$connection) return pg_affected_rows($result); } +// Gets the list of sequences from postgres +function wpsqli_get_list_of_sequences(&$connection) +{ + $sql = "SELECT sequencename FROM pg_sequences"; + $result = pg_query($connection, $sql); + if(!$result) { + if (PG4WP_DEBUG || PG4WP_LOG) { + $log = "Unable to get list of sequences\n"; + error_log($log, 3, PG4WP_LOG . 'pg4wp_errors.log'); + } + return []; + } + + $data = pg_fetch_all($result); + return array_column($data, 'sequencename'); +} + +// Get the primary sequence for a table +function wpsqli_get_primary_sequence_for_table(&$connection, $table) +{ + $sequences = wpsqli_get_list_of_sequences($connection); + foreach($sequences as $sequence) { + if (strncmp($sequence, $table, strlen($table)) === 0) { + return $sequence; + } + } + + // Fallback to default if we don't find a sequence + // Note: this will probably fail + return $table . '_seq'; +} + /** * Fetches the ID generated for an AUTO_INCREMENT column by the previous INSERT query. * @@ -1057,19 +1089,13 @@ function wpsqli_insert_id(&$connection = null) $ins_field = $GLOBALS['pg4wp_ins_field']; $table = $GLOBALS['pg4wp_ins_table']; $lastq = $GLOBALS['pg4wp_last_insert']; - $seq = $table . '_seq'; + $seq = wpsqli_get_primary_sequence_for_table($connection, $table); - // Special case for 'term_relationships' table, which does not have a sequence in PostgreSQL. - if ($table == $wpdb->term_relationships) { - // PostgreSQL: Using CURRVAL() to get the current value of the sequence. - $sql = "SELECT CURRVAL('$seq')"; - $res = pg_query($connection, $sql); - if (false !== $res) { - $data = pg_fetch_result($res, 0, 0); - } - } // Special case when using WP_Import plugin where ID is defined in the query itself. - elseif ('post_author' == $ins_field && false !== strpos($lastq, 'ID')) { + if($table == $wpdb->term_relationships) { + $sql = 'NO QUERY'; + $data = 0; + } elseif ('post_author' == $ins_field && false !== strpos($lastq, 'ID')) { // No PostgreSQL specific operation here. $sql = 'ID was in query '; $pattern = '/.+\'(\d+).+$/'; @@ -1080,7 +1106,8 @@ function wpsqli_insert_id(&$connection = null) $GLOBALS['pg4wp_queued_query'] = "SELECT SETVAL('$seq',(SELECT MAX(\"ID\") FROM $table)+1);"; } else { // PostgreSQL: Using CURRVAL() to get the current value of the sequence. - $sql = "SELECT CURRVAL('$seq')"; + // Double quoting is needed to prevent seq from being lowercased automatically + $sql = "SELECT CURRVAL('\"$seq\"')"; $res = pg_query($connection, $sql); if (false !== $res) { $data = pg_fetch_result($res, 0, 0); diff --git a/pg4wp/driver_pgsql_rewrite.php b/pg4wp/driver_pgsql_rewrite.php index 473e895..0292cd0 100644 --- a/pg4wp/driver_pgsql_rewrite.php +++ b/pg4wp/driver_pgsql_rewrite.php @@ -53,7 +53,7 @@ function pg4wp_rewrite($sql) // When installing, the sequence for table terms has to be updated if(defined('WP_INSTALLING') && WP_INSTALLING && false !== strpos($sql, 'INSERT INTO `' . $wpdb->terms . '`')) { - $end .= ';SELECT setval(\'' . $wpdb->terms . '_seq\', (SELECT MAX(term_id) FROM ' . $wpdb->terms . ')+1);'; + $end .= ';SELECT setval(\'' . $wpdb->terms . '_term_id_seq\', (SELECT MAX(term_id) FROM ' . $wpdb->terms . ')+1);'; } break; case 'Insert': diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index e7aba47..35c1061 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -46,6 +46,11 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter preg_match($pattern, $tableSQL, $matches); $table = $matches[1]; + // change all creates into create if not exists + $pattern = "/CREATE TABLE (IF NOT EXISTS )?(\w+)\s*\(/i"; + $replacement = 'CREATE TABLE IF NOT EXISTS $2 ('; + $sql = preg_replace($pattern, $replacement, $sql); + // Remove trailing spaces $sql = trim($sql); @@ -109,7 +114,7 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter $indexName = $table . '_' . $index; // Appending the CREATE INDEX statement to SQL - $sql .= "\nCREATE {$unique}INDEX $indexName ON $table ($columns);"; + $sql .= "\nCREATE {$unique}INDEX IF NOT EXISTS $indexName ON $table ($columns);"; } } // Now remove handled indexes diff --git a/tests/parseTest.php b/tests/parseTest.php index fe40a36..ca58a5f 100644 --- a/tests/parseTest.php +++ b/tests/parseTest.php @@ -33,7 +33,6 @@ final class parseTest extends TestCase $this->assertSame($GLOBALS['pg4wp_ins_field'], "post_author"); } - protected function setUp(): void { global $wpdb; diff --git a/tests/rewriteTest.php b/tests/rewriteTest.php index 985f7d4..786c3a3 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -54,7 +54,7 @@ final class rewriteTest extends TestCase SQL; $expected = <<assertSame(trim($expected), trim($postgresql)); } - + public function test_it_removes_table_charsets() { $sql = <<assertSame(trim($expected), trim($postgresql)); } - + public function test_it_can_create_double_keys_with_length() @@ -359,7 +359,7 @@ final class rewriteTest extends TestCase SQL; $expected = <<assertSame(trim($expected), trim($postgresql)); } - + protected function setUp(): void { From 98bcd4aad0bfef2c7bf3c91811a34a511d072504 Mon Sep 17 00:00:00 2001 From: Matthew Bucci Date: Tue, 16 Jan 2024 21:49:06 -0800 Subject: [PATCH 15/15] improve performance of sequence lookup --- pg4wp/driver_pgsql.php | 11 +++++++++++ 1 file changed, 11 insertions(+) diff --git a/pg4wp/driver_pgsql.php b/pg4wp/driver_pgsql.php index 06c99d5..cea215a 100644 --- a/pg4wp/driver_pgsql.php +++ b/pg4wp/driver_pgsql.php @@ -1059,9 +1059,20 @@ function wpsqli_get_list_of_sequences(&$connection) // Get the primary sequence for a table function wpsqli_get_primary_sequence_for_table(&$connection, $table) { + // TODO: it should be possible to use a WP transient here for object caching + global $sequence_lookup; + if (empty($sequence_lookup)) { + $sequence_lookup = []; + } + + if (isset($sequence_lookup[$table])) { + return $sequence_lookup[$table]; + } + $sequences = wpsqli_get_list_of_sequences($connection); foreach($sequences as $sequence) { if (strncmp($sequence, $table, strlen($table)) === 0) { + $sequence_lookup[$table] = $sequence; return $sequence; } }