diff --git a/.github/ISSUE_TEMPLATE/sql-rewriting-issue.md b/.github/ISSUE_TEMPLATE/sql-rewriting-issue.md new file mode 100644 index 0000000..99ff380 --- /dev/null +++ b/.github/ISSUE_TEMPLATE/sql-rewriting-issue.md @@ -0,0 +1,31 @@ +--- +name: SQL Rewriting Issue +about: This is used for filing bugs or problems with PG4WP +title: '' +labels: '' +assignees: '' + +--- + +WP Version: +PG4WP Version: + +Error: +``` + +``` + +RAW SQL +``` + +``` + +Expected Rewritten SQL +``` + +``` + +Actual Rewritten SQL +``` + +``` diff --git a/.github/pull_request_template.md b/.github/pull_request_template.md new file mode 100644 index 0000000..9497582 --- /dev/null +++ b/.github/pull_request_template.md @@ -0,0 +1,6 @@ + +Related Issues: + - + +Added Tests: + - \ No newline at end of file diff --git a/pg4wp/driver_pgsql_rewrite.php b/pg4wp/driver_pgsql_rewrite.php index 0292cd0..8bd1a9d 100644 --- a/pg4wp/driver_pgsql_rewrite.php +++ b/pg4wp/driver_pgsql_rewrite.php @@ -12,7 +12,7 @@ function createSQLRewriter(string $sql): AbstractSQLRewriter { $sql = trim($sql); - if (preg_match('/^(SELECT|INSERT|UPDATE|DELETE|DESCRIBE|ALTER TABLE|CREATE TABLE|DROP TABLE|SHOW INDEX|SHOW VARIABLES|SHOW TABLES|OPTIMIZE TABLE|SET NAMES|SHOW FULL COLUMNS)\b/i', $sql, $matches)) { + if (preg_match('/^(SELECT|INSERT|REPLACE INTO|UPDATE|DELETE|DESCRIBE|ALTER TABLE|CREATE TABLE|DROP TABLE|SHOW INDEX|SHOW VARIABLES|SHOW TABLES|OPTIMIZE TABLE|SET NAMES|SHOW FULL COLUMNS|SHOW TABLE STATUS)\b/i', $sql, $matches)) { // Convert to a format suitable for class names (e.g., "SHOW TABLES" becomes "ShowTables") $type = str_replace(' ', '', ucwords(str_replace('_', ' ', strtolower($matches[1])))); $className = $type . 'SQLRewriter'; diff --git a/pg4wp/rewriters/AlterTableSQLRewriter.php b/pg4wp/rewriters/AlterTableSQLRewriter.php index 054c7ce..db819e7 100644 --- a/pg4wp/rewriters/AlterTableSQLRewriter.php +++ b/pg4wp/rewriters/AlterTableSQLRewriter.php @@ -3,11 +3,6 @@ class AlterTableSQLRewriter extends AbstractSQLRewriter { private $stringReplacements = [ - ' bigint(40)' => ' bigint', - ' bigint(20)' => ' bigint', - ' bigint(10)' => ' int', - ' int(11)' => ' int', - ' int(10)' => ' int', ' tinytext' => ' text', ' mediumtext' => ' text', ' longtext' => ' text', @@ -16,16 +11,15 @@ 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 utf8mb4' => '', ' DEFAULT CHARACTER SET utf8' => '', - // WP 2.7.1 compatibility - ' 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' => '', + ' CHARACTER SET utf8' => '', + ' DEFAULT CHARSET=utf8' => '', // For flash-album-gallery plugin ' tinyint' => ' smallint' @@ -34,11 +28,14 @@ class AlterTableSQLRewriter extends AbstractSQLRewriter public function rewrite(): string { $sql = $this->original(); + + $sql = $this->rewrite_numeric_type($sql); if (str_contains($sql, 'ADD INDEX') || str_contains($sql, 'ADD UNIQUE INDEX')) { $sql = $this->rewriteAddIndex($sql); return $sql; } + if (str_contains($sql, 'CHANGE COLUMN')) { $sql = $this->rewriteChangeColumn($sql); return $sql; @@ -219,4 +216,50 @@ private function rewriteDropPrimaryKey(string $sql): string return $sql; } + + private function rewrite_numeric_type($sql){ + // Numeric types in MySQL which need to be rewritten + $numeric_types = ["bigint", "int", "integer", "smallint", "mediumint", "tinyint", "double", "decimal"]; + $numeric_types_imploded = implode('|', $numeric_types); + + // Prepare regex pattern to match 'type(x)' + $pattern = "/(" . $numeric_types_imploded . ")\(\d+\)/"; + + // Execute type find & replace + $sql = preg_replace_callback($pattern, function ($matches) { + return $matches[1]; + }, $sql); + + // bigint + $pattern = '/bigint(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i'; + preg_match($pattern, $sql, $matches); + if($matches) { + $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); + } + } + + return $sql; + } } diff --git a/pg4wp/rewriters/CreateTableSQLRewriter.php b/pg4wp/rewriters/CreateTableSQLRewriter.php index 35c1061..8bd2b4f 100644 --- a/pg4wp/rewriters/CreateTableSQLRewriter.php +++ b/pg4wp/rewriters/CreateTableSQLRewriter.php @@ -3,12 +3,6 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter { private $stringReplacements = [ - ' bigint(40)' => ' bigint', - ' bigint(20)' => ' bigint', - ' bigint(10)' => ' int', - ' int(11)' => ' int', - ' int(10)' => ' int', - ' int(1)' => ' smallint', ' tinytext' => ' text', ' mediumtext' => ' text', ' longtext' => ' text', @@ -16,16 +10,11 @@ class CreateTableSQLRewriter extends AbstractSQLRewriter '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 utf8mb4' => '', ' DEFAULT CHARACTER SET utf8' => '', - // WP 2.7.1 compatibility - ' 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' => '', @@ -40,7 +29,6 @@ public function rewrite(): string { $sql = $this->original(); - $tableSQL = str_replace('CREATE TABLE IF NOT EXISTS ', 'CREATE TABLE ', $sql); $pattern = '/CREATE TABLE [`]?(\w+)[`]?/'; preg_match($pattern, $tableSQL, $matches); @@ -66,35 +54,7 @@ public function rewrite(): string $sql ); - // bigint - $pattern = '/bigint(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i'; - preg_match($pattern, $sql, $matches); - if($matches) { - $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); - } - } + $sql = $this->rewrite_numeric_type($sql); // Support for UNIQUE INDEX creation $pattern = '/,\s*(UNIQUE |)KEY\s+(`[^`]+`|\w+)\s+\(((?:[^()]|\([^)]*\))*)\)/'; @@ -127,4 +87,50 @@ public function rewrite(): string return $sql; } + + private function rewrite_numeric_type($sql){ + // Numeric types in MySQL which need to be rewritten + $numeric_types = ["bigint", "int", "integer", "smallint", "mediumint", "tinyint", "double", "decimal"]; + $numeric_types_imploded = implode('|', $numeric_types); + + // Prepare regex pattern to match 'type(x)' + $pattern = "/(" . $numeric_types_imploded . ")\(\d+\)/"; + + // Execute type find & replace + $sql = preg_replace_callback($pattern, function ($matches) { + return $matches[1]; + }, $sql); + + // bigint + $pattern = '/bigint(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i'; + preg_match($pattern, $sql, $matches); + if($matches) { + $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); + } + } + + return $sql; + } } diff --git a/pg4wp/rewriters/DescribeSQLRewriter.php b/pg4wp/rewriters/DescribeSQLRewriter.php index 6b841c1..98dfb8c 100644 --- a/pg4wp/rewriters/DescribeSQLRewriter.php +++ b/pg4wp/rewriters/DescribeSQLRewriter.php @@ -28,9 +28,10 @@ protected function extractTableName($sql) * Generates a PostgreSQL-compatible SQL query to mimic MySQL's "DESCRIBE". * * @param string $tableName The table name + * @param string $schema The schema name * @return string The generated SQL query */ - public function generatePostgresDescribeTable($tableName) + public function generatePostgresDescribeTable($tableName, $schema = "public") { $sql = << 0 ORDER BY number SQL; diff --git a/pg4wp/rewriters/InsertSQLRewriter.php b/pg4wp/rewriters/InsertSQLRewriter.php index fe753c7..b401e28 100644 --- a/pg4wp/rewriters/InsertSQLRewriter.php +++ b/pg4wp/rewriters/InsertSQLRewriter.php @@ -8,15 +8,6 @@ public function rewrite(): string $sql = $this->original(); - $sql = str_replace('(0,', "('0',", $sql); - $sql = str_replace('(1,', "('1',", $sql); - - // Fix inserts into wp_categories - if(false !== strpos($sql, 'INSERT INTO ' . $wpdb->categories)) { - $sql = str_replace('"cat_ID",', '', $sql); - $sql = str_replace("VALUES ('0',", "VALUES(", $sql); - } - // Those are used when we need to set the date to now() in gmt time $sql = str_replace("'0000-00-00 00:00:00'", 'now() AT TIME ZONE \'gmt\'', $sql); diff --git a/pg4wp/rewriters/ReplaceIntoSQLRewriter.php b/pg4wp/rewriters/ReplaceIntoSQLRewriter.php new file mode 100644 index 0000000..a47aab5 --- /dev/null +++ b/pg4wp/rewriters/ReplaceIntoSQLRewriter.php @@ -0,0 +1,107 @@ +original(); + + $splitStatements = function (string $sql): array { + $statements = []; + $buffer = ''; + $quote = null; + + for ($i = 0, $len = strlen($sql); $i < $len; $i++) { + $char = $sql[$i]; + + if ($quote) { + if ($char === $quote && $sql[$i - 1] !== '\\') { + $quote = null; + } + } elseif ($char === '"' || $char === "'") { + $quote = $char; + } elseif ($char === ';') { + $statements[] = $buffer . ';'; + $buffer = ''; + continue; + } + + $buffer .= $char; + } + + if (!empty($buffer)) { + $statements[] = $buffer; + } + + return $statements; + }; + + $statements = $splitStatements($sql); + + foreach ($statements as $statement) { + $statement = trim($statement); + + // Skip empty statements + if (empty($statement)) { + continue; + } + + // Replace backticks with double quotes for PostgreSQL compatibility + $statement = str_replace('`', '"', $statement); + + // Find index positions for the SQL components + $insertIndex = strpos($statement, 'REPLACE INTO'); + $columnsStartIndex = strpos($statement, "("); + $columnsEndIndex = strpos($statement, ")"); + $valuesIndex = strpos($statement, 'VALUES'); + $onDuplicateKeyIndex = strpos($statement, 'ON DUPLICATE KEY UPDATE'); + + // Extract SQL components + $tableSection = trim(substr($statement, $insertIndex, $columnsStartIndex - $insertIndex)); + $valuesSection = trim(substr($statement, $valuesIndex, strlen($statement) - $valuesIndex)); + $columnsSection = trim(substr($statement, $columnsStartIndex, $columnsEndIndex - $columnsStartIndex + 1)); + + // Extract and clean up column names from the update section + $updateCols = explode(',', substr($columnsSection, 1, strlen($columnsSection) - 2)); + $updateCols = array_map(function ($col) { + return trim($col); + }, $updateCols); + + // Choose a primary key for ON CONFLICT + $primaryKey = 'option_name'; + if (!in_array($primaryKey, $updateCols)) { + $primaryKey = 'meta_name'; + if (!in_array($primaryKey, $updateCols)) { + $primaryKey = $updateCols[0] ?? ''; + } + } + + // SWAP REPLACE INTO for INSERT INTO + $tableSection = str_replace("REPLACE INTO", "INSERT INTO", $tableSection); + + // Construct the PostgreSQL ON CONFLICT DO UPDATE section + $updateSection = ""; + foreach($updateCols as $col) { + if ($col !== $primaryKey) { + $updateSection .= ", "; + $updateSection .= "$col = EXCLUDED.$col"; + } + } + + // trim any preceding commas + $updateSection = ltrim($updateSection,", "); + + // Construct the PostgreSQL query + $postgresSQL = sprintf('%s %s %s ON CONFLICT (%s) DO UPDATE SET %s', $tableSection, $columnsSection, $valuesSection, $primaryKey, $updateSection); + + // Append to the converted statements list + $convertedStatements[] = $postgresSQL; + } + + $sql = implode('; ', $convertedStatements); + + return $sql; + } +} diff --git a/pg4wp/rewriters/SelectSQLRewriter.php b/pg4wp/rewriters/SelectSQLRewriter.php index d90b8f0..129dbb1 100644 --- a/pg4wp/rewriters/SelectSQLRewriter.php +++ b/pg4wp/rewriters/SelectSQLRewriter.php @@ -24,6 +24,9 @@ public function rewrite(): string // Remove the LIMIT clause if it exists $sql = preg_replace('/\s+LIMIT\s+\d+(\s*,\s*\d+)?/i', '', $sql); + // Remove the ORDER BY containing case / end clause if it exists + $sql = preg_replace('/\s+ORDER\s+BY\s+.+END\),[^)]+/is', '', $sql); + // Remove the ORDER BY clause if it exists $sql = preg_replace('/\s+ORDER\s+BY\s+[^)]+/i', '', $sql); @@ -31,6 +34,16 @@ public function rewrite(): string $sql = preg_replace('/SELECT\s+.*?\s+FROM\s+/is', 'SELECT COUNT(*) FROM ', $sql, 1); } + if(false !== strpos($sql, 'information_schema')) { + // WP Site Health rewrites + if (false !== strpos($sql, "SELECT TABLE_NAME AS 'table', TABLE_ROWS AS 'rows', SUM(data_length + index_length)")) { + $sql = $this->postgresTableSizeRewrite(); + return $sql; + } + + throw new Exception("Unsupported call to information_schema, this probably won't work correctly and needs to be specifically handled, open a github issue with the SQL"); + } + $sql = $this->ensureOrderByInSelect($sql); // Convert CONVERT to CAST @@ -346,4 +359,29 @@ protected function convertToPostgresLimitSyntax($sql) return $sql; } + // This method is specifically to handle should_suggest_persistent_object_cache in wp site health + protected function postgresTableSizeRewrite($schema = 'public') + { + + $sql = <<original(); + return $this->generatePostgresShowTableStatus(); + } + + + /** + * Generates a PostgreSQL-compatible SQL query to mimic MySQL's "SHOW TABLE STATUS". + * + * @return string The generated SQL query + */ + public function generatePostgresShowTableStatus($schema = "public") + { + $sql = <<assertSame(trim($expected), trim($postgresql)); } + public function test_it_will_handle_found_rows_on_queries_with_order_by_case() + { + $GLOBALS['pg4wp_numrows_query'] = <<assertSame(trim($expected), trim($postgresql)); + } + + + public function test_it_can_handle_replacement_sql() + { + $sql = "REPLACE INTO test2 (column1, column2, column3) VALUES (1, 'Old', '2014-08-20 18:47:00')"; + $expected = "INSERT INTO test2 (column1, column2, column3) VALUES (1, 'Old', '2014-08-20 18:47:00') ON CONFLICT (column1) DO UPDATE SET column2 = EXCLUDED.column2, column3 = EXCLUDED.column3"; + + $postgresql = pg4wp_rewrite($sql); + $this->assertSame(trim($expected), trim($postgresql)); + } + + + public function test_it_can_handle_insert_sql_containing_nested_parathesis_with_numbers() + { + $sql = <<