Skip to content

Commit

Permalink
Merge pull request #76 from PostgreSQL-For-Wordpress/mb-fix-auto-incr…
Browse files Browse the repository at this point in the history
…ement

Improve table creation
  • Loading branch information
mattbucci authored Jan 17, 2024
2 parents d45c7d5 + 98bcd4a commit 23da9c0
Show file tree
Hide file tree
Showing 7 changed files with 501 additions and 63 deletions.
62 changes: 50 additions & 12 deletions pg4wp/driver_pgsql.php
Original file line number Diff line number Diff line change
Expand Up @@ -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.
*
Expand All @@ -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+).+$/';
Expand All @@ -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);
Expand Down
2 changes: 1 addition & 1 deletion pg4wp/driver_pgsql_rewrite.php
Original file line number Diff line number Diff line change
Expand Up @@ -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':
Expand Down
32 changes: 17 additions & 15 deletions pg4wp/rewriters/AlterTableSQLRewriter.php
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
111 changes: 80 additions & 31 deletions pg4wp/rewriters/CreateTableSQLRewriter.php
Original file line number Diff line number Diff line change
Expand Up @@ -3,79 +3,128 @@
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
{
$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;
}
}
1 change: 0 additions & 1 deletion tests/parseTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -33,7 +33,6 @@ public function test_it_can_parse_a_page_creation_correctly()
$this->assertSame($GLOBALS['pg4wp_ins_field'], "post_author");
}


protected function setUp(): void
{
global $wpdb;
Expand Down
Loading

0 comments on commit 23da9c0

Please sign in to comment.