Merge pull request #144 from hellausefulsoftware/bugfix/hellauseful1-issue-0-postgres-delete-query-rewrite

Automated: Fix #1: SQL Replacements need to use DB_PREFIX when building the regex replacements
This commit is contained in:
Matthew Bucci
2025-05-06 21:25:11 -07:00
committed by GitHub
3 changed files with 100 additions and 7 deletions

View File

@ -19,6 +19,9 @@ class DeleteSQLRewriter extends AbstractSQLRewriter
$sql = str_replace('LIMIT 1', '', $sql);
$sql = str_replace(' REGEXP ', ' ~ ', $sql);
// Get the WordPress table prefix
$prefix = $wpdb->prefix;
// This handles removal of duplicate entries in table options
if(false !== strpos($sql, 'DELETE o1 FROM ')) {
$sql = "DELETE FROM $wpdb->options WHERE option_id IN " .
@ -26,28 +29,69 @@ class DeleteSQLRewriter extends AbstractSQLRewriter
"WHERE o1.option_name = o2.option_name " .
"AND o1.option_id < o2.option_id)";
}
// Rewrite _transient_timeout multi-table delete query
elseif(0 === strpos($sql, 'DELETE a, b FROM wp_options a, wp_options b')) {
// Rewrite _transient_timeout multi-table delete query with dynamic prefix for options table
elseif(preg_match('/DELETE a, b FROM ' . preg_quote($prefix, '/') . 'options a, ' . preg_quote($prefix, '/') . 'options b/', $sql)) {
$where = substr($sql, strpos($sql, 'WHERE ') + 6);
$where = rtrim($where, " \t\n\r;");
// Fix string/number comparison by adding check and cast
$where = str_replace('AND b.option_value', 'AND b.option_value ~ \'^[0-9]+$\' AND CAST(b.option_value AS BIGINT)', $where);
// Mirror WHERE clause to delete both sides of self-join.
$where2 = strtr($where, array('a.' => 'b.', 'b.' => 'a.'));
$sql = 'DELETE FROM wp_options a USING wp_options b WHERE ' .
$sql = "DELETE FROM {$wpdb->options} a USING {$wpdb->options} b WHERE " .
'(' . $where . ') OR (' . $where2 . ');';
}
// Rewrite _transient_timeout multi-table delete query
elseif(0 === strpos($sql, 'DELETE a, b FROM wp_sitemeta a, wp_sitemeta b')) {
// Rewrite _transient_timeout multi-table delete query with dynamic prefix for sitemeta table
elseif(preg_match('/DELETE a, b FROM ' . preg_quote($prefix, '/') . 'sitemeta a, ' . preg_quote($prefix, '/') . 'sitemeta b/', $sql)) {
$where = substr($sql, strpos($sql, 'WHERE ') + 6);
$where = rtrim($where, " \t\n\r;");
// Fix string/number comparison by adding check and cast
$where = str_replace('AND b.meta_value', 'AND b.meta_value ~ \'^[0-9]+$\' AND CAST(b.meta_value AS BIGINT)', $where);
// Mirror WHERE clause to delete both sides of self-join.
$where2 = strtr($where, array('a.' => 'b.', 'b.' => 'a.'));
$sql = 'DELETE FROM wp_sitemeta a USING wp_sitemeta b WHERE ' .
'(' . $where . ') OR (' . $where2 . ');';
// Use $wpdb's sitemeta table name which should already have the correct prefix
if(isset($wpdb->sitemeta)) {
$sql = "DELETE FROM {$wpdb->sitemeta} a USING {$wpdb->sitemeta} b WHERE " .
'(' . $where . ') OR (' . $where2 . ');';
} else {
// Fallback if $wpdb->sitemeta is not available
$sql = "DELETE FROM {$prefix}sitemeta a USING {$prefix}sitemeta b WHERE " .
'(' . $where . ') OR (' . $where2 . ');';
}
}
// Add a more general pattern to handle multi-table DELETE with aliases and dynamic table names
elseif(preg_match('/DELETE\s+([a-zA-Z0-9_]+),\s*([a-zA-Z0-9_]+)\s+FROM\s+([a-zA-Z0-9_' . preg_quote($prefix, '/') . ']+)\s+([a-zA-Z0-9_]+),\s*([a-zA-Z0-9_' . preg_quote($prefix, '/') . ']+)\s+([a-zA-Z0-9_]+)\s+WHERE/i', $sql, $matches)) {
// Extract aliases and table names
$firstAlias = $matches[1];
$secondAlias = $matches[2];
$firstTable = $matches[3];
$firstTableAlias = $matches[4];
$secondTable = $matches[5];
$secondTableAlias = $matches[6];
// Extract WHERE clause
$where = substr($sql, strpos($sql, 'WHERE ') + 6);
$where = rtrim($where, " \t\n\r;");
// Check if the table names are known WordPress tables and replace with dynamic property references
foreach([$firstTable, $secondTable] as $index => $tableName) {
// Strip prefix if it exists to get the base table name
$baseTableName = preg_replace('/^' . preg_quote($prefix, '/') . '/', '', $tableName);
// Check if $wpdb has a property for this table
if(isset($wpdb->$baseTableName)) {
// Replace the hardcoded table name with the dynamic property
if($index === 0) {
$firstTable = $wpdb->$baseTableName;
} else {
$secondTable = $wpdb->$baseTableName;
}
}
}
// Generate PostgreSQL DELETE...USING syntax
$sql = "DELETE FROM $firstTable $firstTableAlias USING $secondTable $secondTableAlias WHERE $where;";
}
// Akismet sometimes doesn't write 'comment_ID' with 'ID' in capitals where needed ...

View File

@ -81,6 +81,11 @@ PG4WP is provided "as-is" with no warranty in the hope it can be useful.
PG4WP is licensed under the [GNU GPL](http://www.gnu.org/licenses/gpl.html "GNU GPL") v2 or any newer version at your choice.
### Changelog
#### Latest Changes
- Fixed issue with SQL DELETE query rewriting to use DB_PREFIX consistently, which previously caused PostgreSQL syntax errors due to hardcoded table prefixes
### Contributors
Code originally by Hawk__ (http://www.hawkix.net/)
Modifications by @kevinoid and @mattbucci

View File

@ -854,6 +854,50 @@ final class rewriteTest extends TestCase
public $comments = "wp_comments";
public $prefix = "wp_";
public $options = "wp_options";
public $sitemeta = "wp_sitemeta";
};
}
public function test_it_properly_uses_dynamic_table_prefix_for_delete_queries()
{
global $wpdb;
// Change the prefix to a custom one
$wpdb->prefix = "custom_";
$wpdb->options = "custom_options";
$wpdb->sitemeta = "custom_sitemeta";
$wpdb->posts = "custom_posts";
$wpdb->postmeta = "custom_postmeta";
// Test DELETE with options table
$sql = "DELETE a, b FROM custom_options a, custom_options b WHERE a.option_name = '_transient_timeout_something' AND b.option_name = '_transient_something' AND b.option_value < 12345678";
$postgresql = pg4wp_rewrite($sql);
$this->assertStringContainsString("DELETE FROM custom_options a USING custom_options b", $postgresql);
$this->assertStringNotContainsString("wp_options", $postgresql);
// Test DELETE with sitemeta table
$sql = "DELETE a, b FROM custom_sitemeta a, custom_sitemeta b WHERE a.meta_key = '_site_transient_timeout_something' AND b.meta_key = '_site_transient_something' AND b.meta_value < 12345678";
$postgresql = pg4wp_rewrite($sql);
$this->assertStringContainsString("DELETE FROM custom_sitemeta a USING custom_sitemeta b", $postgresql);
$this->assertStringNotContainsString("wp_sitemeta", $postgresql);
// Test general pattern DELETE with any tables
$sql = "DELETE p, pm FROM custom_posts p, custom_postmeta pm WHERE p.ID = pm.post_id AND p.post_type = 'revision'";
$postgresql = pg4wp_rewrite($sql);
$this->assertStringContainsString("DELETE FROM custom_posts p USING custom_postmeta pm", $postgresql);
$this->assertStringNotContainsString("wp_posts", $postgresql);
$this->assertStringNotContainsString("wp_postmeta", $postgresql);
// Test with tables that don't exist as $wpdb properties
$sql = "DELETE a, b FROM custom_mytable a, custom_anothertable b WHERE a.id = b.ref_id";
$postgresql = pg4wp_rewrite($sql);
$this->assertStringContainsString("DELETE FROM custom_mytable a USING custom_anothertable b", $postgresql);
// Restore the original prefix for other tests
$wpdb->prefix = "wp_";
$wpdb->options = "wp_options";
$wpdb->sitemeta = "wp_sitemeta";
$wpdb->posts = "wp_posts";
$wpdb->postmeta = "wp_postmeta";
}
}