From b33aa78976f177dea693905eaf401dfc56b2d0fb Mon Sep 17 00:00:00 2001 From: Matthew Bucci Date: Thu, 22 Feb 2024 19:11:41 -0800 Subject: [PATCH] add support for REPLACE INTO rewriting --- pg4wp/driver_pgsql_rewrite.php | 2 +- pg4wp/rewriters/ReplaceIntoSQLRewriter.php | 107 +++++++++++++++++++++ tests/rewriteTest.php | 12 +++ 3 files changed, 120 insertions(+), 1 deletion(-) create mode 100644 pg4wp/rewriters/ReplaceIntoSQLRewriter.php diff --git a/pg4wp/driver_pgsql_rewrite.php b/pg4wp/driver_pgsql_rewrite.php index 0292cd0..4b16556 100644 --- a/pg4wp/driver_pgsql_rewrite.php +++ b/pg4wp/driver_pgsql_rewrite.php @@ -12,7 +12,7 @@ spl_autoload_register(function ($className) { 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)\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/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/tests/rewriteTest.php b/tests/rewriteTest.php index 786c3a3..bd50816 100644 --- a/tests/rewriteTest.php +++ b/tests/rewriteTest.php @@ -383,6 +383,18 @@ final class rewriteTest extends TestCase } + 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)); + } + + + + protected function setUp(): void {