update sequence handling to support bigserial and serial types

This commit is contained in:
Matthew Bucci
2024-01-16 21:35:32 -08:00
parent ade3d6ad87
commit 66d8a3df0e
5 changed files with 71 additions and 40 deletions

View File

@ -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);

View File

@ -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':

View File

@ -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

View File

@ -33,7 +33,6 @@ final class parseTest extends TestCase
$this->assertSame($GLOBALS['pg4wp_ins_field'], "post_author");
}
protected function setUp(): void
{
global $wpdb;

View File

@ -54,7 +54,7 @@ final class rewriteTest extends TestCase
SQL;
$expected = <<<SQL
CREATE TABLE wp_itsec_lockouts (
CREATE TABLE IF NOT EXISTS wp_itsec_lockouts (
lockout_id bigserial,
lockout_type varchar(25) NOT NULL,
lockout_start timestamp NOT NULL,
@ -85,7 +85,7 @@ final class rewriteTest extends TestCase
SQL;
$expected = <<<SQL
CREATE TABLE wp_e_events (
CREATE TABLE IF NOT EXISTS wp_e_events (
id bigserial primary key,
event_data text null,
created_at timestamp not null
@ -111,14 +111,14 @@ final class rewriteTest extends TestCase
SQL;
$expected = <<<SQL
CREATE TABLE wp_itsec_dashboard_lockouts (
CREATE TABLE IF NOT EXISTS wp_itsec_dashboard_lockouts (
id serial,
ip varchar(40),
time timestamp NOT NULL,
count int NOT NULL,
PRIMARY KEY (id)
);
CREATE UNIQUE INDEX wp_itsec_dashboard_lockouts_ip__time ON wp_itsec_dashboard_lockouts (ip, time);
CREATE UNIQUE INDEX IF NOT EXISTS wp_itsec_dashboard_lockouts_ip__time ON wp_itsec_dashboard_lockouts (ip, time);
SQL;
$postgresql = pg4wp_rewrite($sql);
@ -146,7 +146,7 @@ final class rewriteTest extends TestCase
SQL;
$expected = <<<SQL
CREATE TABLE wp_itsec_vulnerabilities (
CREATE TABLE IF NOT EXISTS wp_itsec_vulnerabilities (
id varchar(128) NOT NULL,
software_type varchar(20) NOT NULL,
software_slug varchar(255) NOT NULL,
@ -158,9 +158,9 @@ final class rewriteTest extends TestCase
details text NOT NULL,
PRIMARY KEY (id)
);
CREATE INDEX wp_itsec_vulnerabilities_resolution ON wp_itsec_vulnerabilities (resolution);
CREATE INDEX wp_itsec_vulnerabilities_software_type ON wp_itsec_vulnerabilities (software_type);
CREATE INDEX wp_itsec_vulnerabilities_last_seen ON wp_itsec_vulnerabilities (last_seen);
CREATE INDEX IF NOT EXISTS wp_itsec_vulnerabilities_resolution ON wp_itsec_vulnerabilities (resolution);
CREATE INDEX IF NOT EXISTS wp_itsec_vulnerabilities_software_type ON wp_itsec_vulnerabilities (software_type);
CREATE INDEX IF NOT EXISTS wp_itsec_vulnerabilities_last_seen ON wp_itsec_vulnerabilities (last_seen);
SQL;
$postgresql = pg4wp_rewrite($sql);
@ -188,7 +188,7 @@ final class rewriteTest extends TestCase
count int NOT NULL,
PRIMARY KEY (id)
);
CREATE UNIQUE INDEX wp_itsec_dashboard_lockouts_ip__time ON wp_itsec_dashboard_lockouts (ip, time);
CREATE UNIQUE INDEX IF NOT EXISTS wp_itsec_dashboard_lockouts_ip__time ON wp_itsec_dashboard_lockouts (ip, time);
SQL;
$postgresql = pg4wp_rewrite($sql);
@ -218,7 +218,7 @@ final class rewriteTest extends TestCase
SQL;
$expected = <<<SQL
CREATE TABLE wp_statistics_useronline (
CREATE TABLE IF NOT EXISTS wp_statistics_useronline (
"ID" bigserial,
ip varchar(60) NOT NULL,
created int,
@ -260,7 +260,7 @@ final class rewriteTest extends TestCase
SQL;
$expected = <<<SQL
CREATE TABLE wp_statistics_pages (
CREATE TABLE IF NOT EXISTS wp_statistics_pages (
page_id bigserial,
uri varchar(190) NOT NULL,
type varchar(180) NOT NULL,
@ -269,18 +269,18 @@ final class rewriteTest extends TestCase
id int NOT NULL,
PRIMARY KEY (page_id)
);
CREATE UNIQUE INDEX wp_statistics_pages_date_2 ON wp_statistics_pages (date,uri);
CREATE INDEX wp_statistics_pages_url ON wp_statistics_pages (uri);
CREATE INDEX wp_statistics_pages_date ON wp_statistics_pages (date);
CREATE INDEX wp_statistics_pages_id ON wp_statistics_pages (id);
CREATE INDEX wp_statistics_pages_uri ON wp_statistics_pages (uri,count,id);
CREATE UNIQUE INDEX IF NOT EXISTS wp_statistics_pages_date_2 ON wp_statistics_pages (date,uri);
CREATE INDEX IF NOT EXISTS wp_statistics_pages_url ON wp_statistics_pages (uri);
CREATE INDEX IF NOT EXISTS wp_statistics_pages_date ON wp_statistics_pages (date);
CREATE INDEX IF NOT EXISTS wp_statistics_pages_id ON wp_statistics_pages (id);
CREATE INDEX IF NOT EXISTS wp_statistics_pages_uri ON wp_statistics_pages (uri,count,id);
SQL;
$postgresql = pg4wp_rewrite($sql);
$this->assertSame(trim($expected), trim($postgresql));
}
public function test_it_removes_table_charsets()
{
$sql = <<<SQL
@ -319,21 +319,21 @@ final class rewriteTest extends TestCase
SQL;
$expected = <<<SQL
CREATE TABLE wp_usermeta (
CREATE TABLE IF NOT EXISTS wp_usermeta (
umeta_id bigserial,
user_id bigint NOT NULL default '0',
meta_key varchar(255) default NULL,
meta_value text,
PRIMARY KEY (umeta_id)
);
CREATE INDEX wp_usermeta_user_id ON wp_usermeta (user_id);
CREATE INDEX wp_usermeta_meta_key ON wp_usermeta (meta_key);
CREATE INDEX IF NOT EXISTS wp_usermeta_user_id ON wp_usermeta (user_id);
CREATE INDEX IF NOT EXISTS wp_usermeta_meta_key ON wp_usermeta (meta_key);
SQL;
$postgresql = pg4wp_rewrite($sql);
$this->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 = <<<SQL
CREATE TABLE wp_blogs (
CREATE TABLE IF NOT EXISTS wp_blogs (
blog_id bigserial,
site_id bigint NOT NULL default '0',
domain varchar(200) NOT NULL default '',
@ -374,15 +374,15 @@ final class rewriteTest extends TestCase
lang_id int NOT NULL default '0',
PRIMARY KEY (blog_id)
);
CREATE INDEX wp_blogs_domain ON wp_blogs (domain,path);
CREATE INDEX wp_blogs_lang_id ON wp_blogs (lang_id);
CREATE INDEX IF NOT EXISTS wp_blogs_domain ON wp_blogs (domain,path);
CREATE INDEX IF NOT EXISTS wp_blogs_lang_id ON wp_blogs (lang_id);
SQL;
$postgresql = pg4wp_rewrite($sql);
$this->assertSame(trim($expected), trim($postgresql));
}
protected function setUp(): void
{