Skip to content

Commit 23da9c0

Browse files
authored
Merge pull request #76 from PostgreSQL-For-Wordpress/mb-fix-auto-increment
Improve table creation
2 parents d45c7d5 + 98bcd4a commit 23da9c0

File tree

7 files changed

+501
-63
lines changed

7 files changed

+501
-63
lines changed

pg4wp/driver_pgsql.php

Lines changed: 50 additions & 12 deletions
Original file line numberDiff line numberDiff line change
@@ -1039,6 +1039,49 @@ function wpsqli_affected_rows(&$connection)
10391039
return pg_affected_rows($result);
10401040
}
10411041

1042+
// Gets the list of sequences from postgres
1043+
function wpsqli_get_list_of_sequences(&$connection)
1044+
{
1045+
$sql = "SELECT sequencename FROM pg_sequences";
1046+
$result = pg_query($connection, $sql);
1047+
if(!$result) {
1048+
if (PG4WP_DEBUG || PG4WP_LOG) {
1049+
$log = "Unable to get list of sequences\n";
1050+
error_log($log, 3, PG4WP_LOG . 'pg4wp_errors.log');
1051+
}
1052+
return [];
1053+
}
1054+
1055+
$data = pg_fetch_all($result);
1056+
return array_column($data, 'sequencename');
1057+
}
1058+
1059+
// Get the primary sequence for a table
1060+
function wpsqli_get_primary_sequence_for_table(&$connection, $table)
1061+
{
1062+
// TODO: it should be possible to use a WP transient here for object caching
1063+
global $sequence_lookup;
1064+
if (empty($sequence_lookup)) {
1065+
$sequence_lookup = [];
1066+
}
1067+
1068+
if (isset($sequence_lookup[$table])) {
1069+
return $sequence_lookup[$table];
1070+
}
1071+
1072+
$sequences = wpsqli_get_list_of_sequences($connection);
1073+
foreach($sequences as $sequence) {
1074+
if (strncmp($sequence, $table, strlen($table)) === 0) {
1075+
$sequence_lookup[$table] = $sequence;
1076+
return $sequence;
1077+
}
1078+
}
1079+
1080+
// Fallback to default if we don't find a sequence
1081+
// Note: this will probably fail
1082+
return $table . '_seq';
1083+
}
1084+
10421085
/**
10431086
* Fetches the ID generated for an AUTO_INCREMENT column by the previous INSERT query.
10441087
*
@@ -1057,19 +1100,13 @@ function wpsqli_insert_id(&$connection = null)
10571100
$ins_field = $GLOBALS['pg4wp_ins_field'];
10581101
$table = $GLOBALS['pg4wp_ins_table'];
10591102
$lastq = $GLOBALS['pg4wp_last_insert'];
1060-
$seq = $table . '_seq';
1103+
$seq = wpsqli_get_primary_sequence_for_table($connection, $table);
10611104

1062-
// Special case for 'term_relationships' table, which does not have a sequence in PostgreSQL.
1063-
if ($table == $wpdb->term_relationships) {
1064-
// PostgreSQL: Using CURRVAL() to get the current value of the sequence.
1065-
$sql = "SELECT CURRVAL('$seq')";
1066-
$res = pg_query($connection, $sql);
1067-
if (false !== $res) {
1068-
$data = pg_fetch_result($res, 0, 0);
1069-
}
1070-
}
10711105
// Special case when using WP_Import plugin where ID is defined in the query itself.
1072-
elseif ('post_author' == $ins_field && false !== strpos($lastq, 'ID')) {
1106+
if($table == $wpdb->term_relationships) {
1107+
$sql = 'NO QUERY';
1108+
$data = 0;
1109+
} elseif ('post_author' == $ins_field && false !== strpos($lastq, 'ID')) {
10731110
// No PostgreSQL specific operation here.
10741111
$sql = 'ID was in query ';
10751112
$pattern = '/.+\'(\d+).+$/';
@@ -1080,7 +1117,8 @@ function wpsqli_insert_id(&$connection = null)
10801117
$GLOBALS['pg4wp_queued_query'] = "SELECT SETVAL('$seq',(SELECT MAX(\"ID\") FROM $table)+1);";
10811118
} else {
10821119
// PostgreSQL: Using CURRVAL() to get the current value of the sequence.
1083-
$sql = "SELECT CURRVAL('$seq')";
1120+
// Double quoting is needed to prevent seq from being lowercased automatically
1121+
$sql = "SELECT CURRVAL('\"$seq\"')";
10841122
$res = pg_query($connection, $sql);
10851123
if (false !== $res) {
10861124
$data = pg_fetch_result($res, 0, 0);

pg4wp/driver_pgsql_rewrite.php

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -53,7 +53,7 @@ function pg4wp_rewrite($sql)
5353

5454
// When installing, the sequence for table terms has to be updated
5555
if(defined('WP_INSTALLING') && WP_INSTALLING && false !== strpos($sql, 'INSERT INTO `' . $wpdb->terms . '`')) {
56-
$end .= ';SELECT setval(\'' . $wpdb->terms . '_seq\', (SELECT MAX(term_id) FROM ' . $wpdb->terms . ')+1);';
56+
$end .= ';SELECT setval(\'' . $wpdb->terms . '_term_id_seq\', (SELECT MAX(term_id) FROM ' . $wpdb->terms . ')+1);';
5757
}
5858
break;
5959
case 'Insert':

pg4wp/rewriters/AlterTableSQLRewriter.php

Lines changed: 17 additions & 15 deletions
Original file line numberDiff line numberDiff line change
@@ -3,30 +3,32 @@
33
class AlterTableSQLRewriter extends AbstractSQLRewriter
44
{
55
private $stringReplacements = [
6-
'bigint(20)' => 'bigint',
7-
'bigint(10)' => 'int',
8-
'int(11)' => 'int',
9-
'tinytext' => 'text',
10-
'mediumtext' => 'text',
11-
'longtext' => 'text',
12-
'unsigned' => '',
6+
' bigint(40)' => ' bigint',
7+
' bigint(20)' => ' bigint',
8+
' bigint(10)' => ' int',
9+
' int(11)' => ' int',
10+
' int(10)' => ' int',
11+
' tinytext' => ' text',
12+
' mediumtext' => ' text',
13+
' longtext' => ' text',
14+
' unsigned' => ' ',
1315
'gmt datetime NOT NULL default \'0000-00-00 00:00:00\'' => 'gmt timestamp NOT NULL DEFAULT timezone(\'gmt\'::text, now())',
1416
'default \'0000-00-00 00:00:00\'' => 'DEFAULT now()',
1517
'\'0000-00-00 00:00:00\'' => 'now()',
16-
'datetime' => 'timestamp',
17-
'DEFAULT CHARACTER SET utf8' => '',
18+
' datetime' => ' timestamp',
19+
' DEFAULT CHARACTER SET utf8' => '',
1820

1921
// WP 2.7.1 compatibility
20-
'int(4)' => 'smallint',
22+
' int(4)' => ' smallint',
2123

2224
// For WPMU (starting with WP 3.2)
23-
'tinyint(2)' => 'smallint',
24-
'tinyint(1)' => 'smallint',
25-
"enum('0','1')" => 'smallint',
26-
'COLLATE utf8_general_ci' => '',
25+
' tinyint(2)' => ' smallint',
26+
' tinyint(1)' => ' smallint',
27+
" enum('0','1')" => ' smallint',
28+
' COLLATE utf8_general_ci' => '',
2729

2830
// For flash-album-gallery plugin
29-
'tinyint' => 'smallint'
31+
' tinyint' => ' smallint'
3032
];
3133

3234
public function rewrite(): string

pg4wp/rewriters/CreateTableSQLRewriter.php

Lines changed: 80 additions & 31 deletions
Original file line numberDiff line numberDiff line change
@@ -3,79 +3,128 @@
33
class CreateTableSQLRewriter extends AbstractSQLRewriter
44
{
55
private $stringReplacements = [
6-
'bigint(20)' => 'bigint',
7-
'bigint(10)' => 'int',
8-
'int(11)' => 'int',
9-
'tinytext' => 'text',
10-
'mediumtext' => 'text',
11-
'longtext' => 'text',
12-
'unsigned' => '',
6+
' bigint(40)' => ' bigint',
7+
' bigint(20)' => ' bigint',
8+
' bigint(10)' => ' int',
9+
' int(11)' => ' int',
10+
' int(10)' => ' int',
11+
' int(1)' => ' smallint',
12+
' tinytext' => ' text',
13+
' mediumtext' => ' text',
14+
' longtext' => ' text',
15+
' unsigned' => ' ',
1316
'gmt datetime NOT NULL default \'0000-00-00 00:00:00\'' => 'gmt timestamp NOT NULL DEFAULT timezone(\'gmt\'::text, now())',
1417
'default \'0000-00-00 00:00:00\'' => 'DEFAULT now()',
1518
'\'0000-00-00 00:00:00\'' => 'now()',
1619
'datetime' => 'timestamp',
17-
'DEFAULT CHARACTER SET utf8mb4' => '',
18-
'DEFAULT CHARACTER SET utf8' => '',
20+
' DEFAULT CHARACTER SET utf8mb4' => '',
21+
' DEFAULT CHARACTER SET utf8' => '',
1922

2023
// WP 2.7.1 compatibility
21-
'int(4)' => 'smallint',
24+
' int(4)' => ' smallint',
2225

2326
// For WPMU (starting with WP 3.2)
24-
'tinyint(2)' => 'smallint',
25-
'tinyint(1)' => 'smallint',
26-
"enum('0','1')" => 'smallint',
27-
'COLLATE utf8mb4_unicode_520_ci' => '',
28-
'COLLATE utf8_general_ci' => '',
27+
' tinyint(2)' => ' smallint',
28+
' tinyint(1)' => ' smallint',
29+
" enum('0','1')" => ' smallint',
30+
' COLLATE utf8mb4_unicode_520_ci' => '',
31+
' COLLATE utf8_general_ci' => '',
32+
' CHARACTER SET utf8' => '',
33+
' DEFAULT CHARSET=utf8' => '',
2934

3035
// For flash-album-gallery plugin
31-
'tinyint' => 'smallint'
36+
' tinyint' => ' smallint'
3237
];
3338

3439
public function rewrite(): string
3540
{
3641
$sql = $this->original();
3742

3843

39-
$sql = str_replace('CREATE TABLE IF NOT EXISTS ', 'CREATE TABLE ', $sql);
44+
$tableSQL = str_replace('CREATE TABLE IF NOT EXISTS ', 'CREATE TABLE ', $sql);
4045
$pattern = '/CREATE TABLE [`]?(\w+)[`]?/';
41-
preg_match($pattern, $sql, $matches);
46+
preg_match($pattern, $tableSQL, $matches);
4247
$table = $matches[1];
4348

49+
// change all creates into create if not exists
50+
$pattern = "/CREATE TABLE (IF NOT EXISTS )?(\w+)\s*\(/i";
51+
$replacement = 'CREATE TABLE IF NOT EXISTS $2 (';
52+
$sql = preg_replace($pattern, $replacement, $sql);
53+
4454
// Remove trailing spaces
45-
$sql = trim($sql) . ';';
55+
$sql = trim($sql);
56+
57+
// Add a slash if needed
58+
if (substr($sql, strlen($sql) - 1, 1) != ";") {
59+
$sql = $sql . ";";
60+
}
4661

4762
// Translate types and some other replacements
48-
$sql = str_replace(
63+
$sql = str_ireplace(
4964
array_keys($this->stringReplacements),
5065
array_values($this->stringReplacements),
5166
$sql
5267
);
5368

54-
// Fix auto_increment by adding a sequence
55-
$pattern = '/int[ ]+NOT NULL auto_increment/';
69+
// bigint
70+
$pattern = '/bigint(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i';
5671
preg_match($pattern, $sql, $matches);
5772
if($matches) {
58-
$seq = $table . '_seq';
59-
$sql = str_replace('NOT NULL auto_increment', "NOT NULL DEFAULT nextval('$seq'::text)", $sql);
60-
$sql .= "\nCREATE SEQUENCE $seq;";
73+
$sql = preg_replace($pattern, 'bigserial', $sql);
6174
}
6275

63-
// Support for INDEX creation
64-
$pattern = '/,\s+(UNIQUE |)KEY\s+([^\s]+)\s+\(((?:[\w]+(?:\([\d]+\))?[,]?)*)\)/';
76+
// int
77+
$pattern = '/int(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i';
78+
preg_match($pattern, $sql, $matches);
79+
if($matches) {
80+
$sql = preg_replace($pattern, 'serial', $sql);
81+
}
82+
83+
// smallint
84+
$pattern = '/smallint(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i';
85+
preg_match($pattern, $sql, $matches);
86+
if($matches) {
87+
$sql = preg_replace($pattern, 'smallserial', $sql);
88+
}
89+
90+
// Handle for numeric and decimal -- being replaced with serial
91+
$numeric_patterns = ['/numeric(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i', '/decimal(\(\d+\))?([ ]*NOT NULL)?[ ]*auto_increment/i'];
92+
foreach($numeric_patterns as $pattern) {
93+
preg_match($pattern, $sql, $matches);
94+
if($matches) {
95+
$sql = preg_replace($pattern, 'serial', $sql);
96+
}
97+
}
98+
99+
// Support for UNIQUE INDEX creation
100+
$pattern = '/,\s*(UNIQUE |)KEY\s+(`[^`]+`|\w+)\s+\(((?:[^()]|\([^)]*\))*)\)/';
65101
if(preg_match_all($pattern, $sql, $matches, PREG_SET_ORDER)) {
66102
foreach($matches as $match) {
67103
$unique = $match[1];
68104
$index = $match[2];
69105
$columns = $match[3];
70-
$columns = preg_replace('/\(\d+\)/', '', $columns);
71-
// Workaround for index name duplicate
72-
$index = $table . '_' . $index;
73-
$sql .= "\nCREATE {$unique}INDEX $index ON $table ($columns);";
106+
107+
// Removing backticks from the index names
108+
$index = str_replace('`', '', $index);
109+
110+
// Removing backticks and key length constraints from the columns
111+
$columns = preg_replace(["/`/", "/\(\d+\)/"], '', $columns);
112+
113+
// Creating a unique index name
114+
$indexName = $table . '_' . $index;
115+
116+
// Appending the CREATE INDEX statement to SQL
117+
$sql .= "\nCREATE {$unique}INDEX IF NOT EXISTS $indexName ON $table ($columns);";
74118
}
75119
}
76120
// Now remove handled indexes
77121
$sql = preg_replace($pattern, '', $sql);
78122

123+
124+
$pattern = "/(,\s*)?UNIQUE KEY\s+[a-zA-Z0-9_]+\s+(\([a-zA-Z0-9_,\s]+\))/";
125+
$replacement = "$1UNIQUE $2";
126+
$sql = preg_replace($pattern, $replacement, $sql);
127+
79128
return $sql;
80129
}
81130
}

tests/parseTest.php

Lines changed: 0 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -33,7 +33,6 @@ public function test_it_can_parse_a_page_creation_correctly()
3333
$this->assertSame($GLOBALS['pg4wp_ins_field'], "post_author");
3434
}
3535

36-
3736
protected function setUp(): void
3837
{
3938
global $wpdb;

0 commit comments

Comments
 (0)