-
Notifications
You must be signed in to change notification settings - Fork 257
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Begin experimental support for PostgreSQL (#114)
- Loading branch information
Showing
12 changed files
with
288 additions
and
42 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.
Oops, something went wrong.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,151 @@ | ||
<?php | ||
|
||
namespace Tsugi\Core; | ||
|
||
use \Tsugi\Util\PS; | ||
|
||
/** | ||
* This is a helper class to transform between SQL Dialects | ||
*/ | ||
|
||
class SQLDialect | ||
{ | ||
public static function sqlPatch($PDOX, $sql) { | ||
// Our default dialect is MySQL | ||
if ( $PDOX->isMySQL() ) { | ||
return $sql; | ||
} | ||
if ( ! $PDOX->isPgSQL() ) { | ||
die('Only MySQL and PostgreSQL are supported'); | ||
} | ||
|
||
// echo("Dialect\n".$sql."\n"); | ||
$pieces = (new PS($sql))->split(); | ||
if ( count($pieces) < 1 ) return $sql; | ||
if ( strcasecmp($pieces[0], "create") == 0 ) { | ||
return self::sqlCreate2Postgres($PDOX, $sql); | ||
} else if ( strcasecmp($pieces[0], "insert") == 0 ) { | ||
return self::sqlInsert2Postgres($PDOX, $sql); | ||
} else if ( strcasecmp($pieces[0], "alter") == 0 ) { | ||
return self::sqlAlter2Postgres($PDOX, $sql); | ||
} | ||
return $sql; | ||
} | ||
|
||
public static function sqlCreate2Postgres($PDOX, $sql) { | ||
|
||
$nsql = self::patchPostgresQuotes($PDOX, $sql); | ||
$nsql = self::patchDataTypes($PDOX, $nsql); | ||
|
||
// ) ENGINE = InnoDB DEFAULT CHARSET=utf8;"; | ||
// ) COLLATE utf8_bin, ENGINE = InnoDB; | ||
$nsql = preg_replace('/\).*ENGINE\s*=\s*InnoDB.*$/i', ');', $nsql); | ||
$nsql = preg_replace('/\s+USING\s+HASH\s+/i', ' ', $nsql); | ||
|
||
return $nsql; | ||
} | ||
|
||
// ON DUPLICATE KEY /* plugin_path */ UPDATE | ||
// ON CONFLICT (plugin_path) DO UPDATE SET | ||
public static function sqlInsert2Postgres($PDOX, $sql) { | ||
$nsql = self::patchPostgresQuotes($PDOX, $sql); | ||
|
||
$matches = array(); | ||
preg_match('/ON\s+DUPLICATE\s+KEY\s\/\*\s+[^ *]*\s+\*\/\s+UPDATE\s+/i', $nsql, $matches, PREG_OFFSET_CAPTURE); | ||
if ( count($matches) < 1 ) return $nsql; | ||
$str = $matches[0][0]; | ||
$pos = $matches[0][1]; | ||
$len = strlen($str); | ||
$str = preg_replace('/\sDUPLICATE\s+KEY\s/i', ' CONFLICT ', $str); | ||
$str = preg_replace('/\/\*/i', '(', $str); | ||
$str = preg_replace('/\*\//i', ')', $str); | ||
$str = preg_replace('/\s+UPDATE\s+/i', " DO UPDATE SET\n", $str); | ||
|
||
$newsql = substr($nsql,0,$pos) . $str . substr($nsql, $pos+$len); | ||
return $newsql; | ||
} | ||
|
||
public static function sqlAlter2Postgres($PDOX, $sql) { | ||
|
||
$nsql = self::patchPostgresQuotes($PDOX, $sql); | ||
$nsql = self::patchDataTypes($PDOX, $nsql); | ||
|
||
// ALTER TABLE lms_tools_status MODIFY commit_log MEDIUMTEXT NULL | ||
// ALTER TABLE lms_tools_status ALTER COLUMN column_name TYPE new_data_type; | ||
// ALTER TABLE lms_tools_status ALTER COLUMN column_name DROP NOT NULL; | ||
$matches = array(); | ||
preg_match('/\s+MODIFY\s+[^\s]*\s+/i', $nsql, $matches, PREG_OFFSET_CAPTURE); | ||
if ( count($matches) < 1 ) return $nsql; | ||
$str = $matches[0][0]; | ||
$pos = $matches[0][1]; | ||
$len = strlen($str); | ||
$str = preg_replace('/\sMODIFY\s/i', ' ALTER COLUMN ', $str); | ||
|
||
$tail = substr($nsql, $pos+$len); | ||
$pieces = (new PS($tail))->split(); | ||
if ( count($pieces) < 1 ) { | ||
$newsql = substr($nsql,0,$pos) . $str . ' TYPE ' .substr($nsql, $pos+$len); | ||
return $newsql; | ||
} | ||
|
||
// Normal flow | ||
$retval = array(); | ||
$newsql = substr($nsql,0,$pos) . $str . ' TYPE ' . array_shift($pieces); | ||
$retval[] = $newsql; | ||
|
||
$alter = substr($nsql,0,$pos) . $str . ' '; | ||
if ( count($pieces) == 1 && strcasecmp($pieces[0], "null") == 0 ) { | ||
$newsql = $alter . "DROP NOT NULL;"; | ||
$retval[] = $newsql; | ||
} else if (count($pieces) == 2 && strcasecmp($pieces[0], "NOT") == 0 && | ||
strcasecmp($pieces[0], "NULL") == 0 ) { | ||
$newsql = $alter . "SET NOT NULL;"; | ||
$retval[] = $newsql; | ||
} | ||
if ( count($retval) == 1 ) { | ||
return $retval[0]; | ||
} | ||
return $retval; | ||
} | ||
|
||
|
||
public static function patchDataTypes($PDOX, $sql) { | ||
// https://wiki.postgresql.org/wiki/Don%27t_Do_This#Don.27t_use_serial | ||
// https://www.postgresqltutorial.com/postgresql-identity-column/ | ||
// https://www.depesz.com/2017/04/10/waiting-for-postgresql-10-identity-columns/ | ||
// plugin_id INTEGER NOT NULL AUTO_INCREMENT, | ||
// plugin_id INTEGER NOT NULL primary key generated always as identity | ||
$nsql = preg_replace('/AUTO_INCREMENT/i', "GENERATED BY DEFAULT AS IDENTITY", $sql); | ||
|
||
// created_at DATETIME NOT NULL, | ||
// created_at TIMESTAMP(0) NOT NULL, | ||
$nsql = preg_replace('/\sDATETIME([\s,])/i', ' TIMESTAMP(0)$1', $nsql); | ||
|
||
// deleted TINYINT(1) NOT NULL DEFAULT 0, | ||
// deleted SMALLINT NOT NULL DEFAULT 0, | ||
$nsql = preg_replace('/\sTINYINT\(1\)([\s,])/i', ' SMALLINT$1', $nsql); | ||
|
||
$nsql = preg_replace('/\sMEDIUMTEXT([\s,])/i', ' TEXT$1', $nsql); | ||
|
||
$nsql = preg_replace('/\sMEDIUMINT([\s,])/i', ' INTEGER$1', $nsql); | ||
$nsql = preg_replace('/\sTINYINT([\s,])/i', ' INTEGER$1', $nsql); | ||
|
||
$nsql = preg_replace('/\sUNSIGNED([\s,])/i', '$1', $nsql); | ||
|
||
$nsql = preg_replace('/\sVARBINARY\([0-9]+\)([\s,])/i', ' BYTEA$1', $nsql); | ||
|
||
$nsql = preg_replace('/\sBINARY\([0-9]+\)([\s,])/i', ' BYTEA$1', $nsql); | ||
|
||
$nsql = preg_replace('/\sDOUBLE([\s,])/i', ' DOUBLE PRECISION$1', $nsql); | ||
|
||
$nsql = preg_replace('/\sBLOB([\s,])/i', ' BYTEA$1', $nsql); | ||
|
||
return $nsql; | ||
} | ||
|
||
public static function patchPostgresQuotes($PDOX, $sql) { | ||
$nsql = str_replace('`', '"', $sql); | ||
return $nsql; | ||
} | ||
|
||
} |
Oops, something went wrong.