diff --git a/pg4wp/driver_pgsql.php b/pg4wp/driver_pgsql.php index 26be48c..cea215a 100644 --- a/pg4wp/driver_pgsql.php +++ b/pg4wp/driver_pgsql.php @@ -1039,6 +1039,49 @@ 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) +{ + // 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; + } + } + + // 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 +1100,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 +1117,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/AlterTableSQLRewriter.php b/pg4wp/rewriters/AlterTableSQLRewriter.php index 0bd820a..658a499 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', - 'DEFAULT CHARACTER SET utf8' => '', + ' 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 add5175..35c1061 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -3,32 +3,37 @@ class CreateTableSQLRewriter 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', + ' 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()', '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', + ' int(4)' => ' smallint', // For WPMU (starting with WP 3.2) - 'tinyint(2)' => 'smallint', - 'tinyint(1)' => 'smallint', - "enum('0','1')" => 'smallint', - 'COLLATE utf8mb4_unicode_520_ci' => '', - 'COLLATE utf8_general_ci' => '', + ' tinyint(2)' => ' smallint', + ' tinyint(1)' => ' smallint', + " enum('0','1')" => ' smallint', + ' COLLATE utf8mb4_unicode_520_ci' => '', + ' COLLATE utf8_general_ci' => '', + ' CHARACTER SET utf8' => '', + ' DEFAULT CHARSET=utf8' => '', // For flash-album-gallery plugin - 'tinyint' => 'smallint' + ' tinyint' => ' smallint' ]; public function rewrite(): string @@ -36,46 +41,90 @@ 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]; + // 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) . ';'; + $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_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/'; + // bigint + $pattern = '/bigint(\(\d+\))?([ ]*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 .= "\nCREATE SEQUENCE $seq;"; + $sql = preg_replace($pattern, 'bigserial', $sql); } - // Support for INDEX creation - $pattern = '/,\s+(UNIQUE |)KEY\s+([^\s]+)\s+\(((?:[\w]+(?:\([\d]+\))?[,]?)*)\)/'; + // 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 + $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 and key length constraints from the columns + $columns = preg_replace(["/`/", "/\(\d+\)/"], '', $columns); + + // Creating a unique index name + $indexName = $table . '_' . $index; + + // Appending the CREATE INDEX statement to SQL + $sql .= "\nCREATE {$unique}INDEX IF NOT EXISTS $indexName ON $table ($columns);"; } } // 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/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 bd5599a..786c3a3 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,9 +31,359 @@ 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() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } + + public function test_it_handles_auto_increment_without_null() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } + + + public function test_it_handles_keys() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } + + public function test_it_handles_keys_without_unique() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } + + public function test_it_does_not_remove_if_not_exists() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } + + + public function test_it_removes_character_sets() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } + + public function test_it_handles_multiple_keys() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } + + + public function test_it_removes_table_charsets() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } + + + public function test_it_can_create_keys_with_length() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } + + + + public function test_it_can_create_double_keys_with_length() + { + $sql = <<assertSame(trim($expected), trim($postgresql)); + } + + + protected function setUp(): void { global $wpdb; 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'])); } }