aboutsummaryrefslogtreecommitdiffstats
path: root/include/dba
diff options
context:
space:
mode:
authorHabeas Codice <habeascodice@federated.social>2014-11-13 12:21:58 -0800
committerHabeas Codice <habeascodice@federated.social>2014-11-13 12:21:58 -0800
commit1a5a5c7edb8697c93f8bababbafa80245378dd7e (patch)
treeb3d3b5ff30ecce1316ad0386d0e89fe18a867b4f /include/dba
parent31376de0665091f2dba04755562ccd238d57a13c (diff)
downloadvolse-hubzilla-1a5a5c7edb8697c93f8bababbafa80245378dd7e.tar.gz
volse-hubzilla-1a5a5c7edb8697c93f8bababbafa80245378dd7e.tar.bz2
volse-hubzilla-1a5a5c7edb8697c93f8bababbafa80245378dd7e.zip
PostgreSQL support initial commit
There were 11 main types of changes: - UPDATE's and DELETE's sometimes had LIMIT 1 at the end of them. This is not only non-compliant but it would certainly not do what whoever wrote it thought it would. It is likely this mistake was just copied from Friendica. All of these instances, the LIMIT 1 was simply removed. - Bitwise operations (and even some non-zero int checks) erroneously rely on MySQL implicit integer-boolean conversion in the WHERE clauses. This is non-compliant (and bad programming practice to boot). Proper explicit boolean conversions were added. New queries should use proper conventions. - MySQL has a different operator for bitwise XOR than postgres. Rather than add yet another dba_ func, I converted them to "& ~" ("AND NOT") when turning off, and "|" ("OR") when turning on. There were no true toggles (XOR). New queries should refrain from using XOR when not necessary. - There are several fields which the schema has marked as NOT NULL, but the inserts don't specify them. The reason this works is because mysql totally ignores the constraint and adds an empty text default automatically. Again, non-compliant, obviously. In these cases a default of empty text was added. - Several statements rely on a non-standard MySQL feature (http://dev.mysql.com/doc/refman/5.5/en/group-by-handling.html). These queries can all be rewritten to be standards compliant. Interestingly enough, the newly rewritten standards compliant queries run a zillion times faster, even on MySQL. - A couple of function/operator name translations were needed (RAND/RANDOM, GROUP_CONCAT/STRING_AGG, UTC_NOW, REGEXP/~, ^/#) -- assist functions added in the dba_ - INTERVALs: postgres requires quotes around the value, mysql requires that there are not quotes around the value -- assist functions added in the dba_ - NULL_DATE's -- Postgres does not allow the invalid date '0000-00-00 00:00:00' (there is no such thing as year 0 or month 0 or day 0). We use '0001-01-01 00:00:00' for postgres. Conversions are handled in Zot/item packets automagically by quoting all dates with dbescdate(). - char(##) specifications in the schema creates fields with blank spaces that aren't trimmed in the code. MySQL apparently treats char(##) as varchar(##), again, non-compliant. Since postgres works better with text fields anyway, this ball of bugs was simply side-stepped by using 'text' datatype for all text fields in the postgres schema. varchar was used in a couple of places where it actually seemed appropriate (size constraint), but without rigorously vetting that all of the PHP code actually validates data, new bugs might come out from under the rug. - postgres doesn't store nul bytes and a few other non-printables in text fields, even when quoted. bytea fields were used when storing binary data (photo.data, attach.data). A new dbescbin() function was added to handle this transparently. - postgres does not support LIMIT #,# syntax. All databases support LIMIT # OFFSET # syntax. Statements were updated to be standard. These changes require corresponding changes in the coding standards. Please review those before adding any code going forward. Still on my TODO list: - remove quotes from non-reserved identifiers and make reserved identifiers use dba func for quoting - Rewrite search queries for better results (both MySQL and Postgres)
Diffstat (limited to 'include/dba')
-rwxr-xr-xinclude/dba/dba_driver.php135
-rw-r--r--include/dba/dba_postgres.php112
2 files changed, 234 insertions, 13 deletions
diff --git a/include/dba/dba_driver.php b/include/dba/dba_driver.php
index 3e19b7aa4..2dcdb0234 100755
--- a/include/dba/dba_driver.php
+++ b/include/dba/dba_driver.php
@@ -1,25 +1,35 @@
<?php /** @file */
-function dba_factory($server, $port,$user,$pass,$db,$install = false) {
+function dba_factory($server, $port,$user,$pass,$db,$dbtype,$install = false) {
$dba = null;
- if(class_exists('mysqli')) {
- if (is_null($port)) $port = ini_get("mysqli.default_port");
- require_once('include/dba/dba_mysqli.php');
- $dba = new dba_mysqli($server, $port,$user,$pass,$db,$install);
- }
- else {
- if (is_null($port)) $port = "3306";
- require_once('include/dba/dba_mysql.php');
- $dba = new dba_mysql($server, $port,$user,$pass,$db,$install);
+ if($dbtype == 1) {
+ require_once('include/dba/dba_postgres.php');
+ if(is_null($port)) $port = 5432;
+ $dba = new dba_postgres($server, $port, $user, $pass, $db, $install);
+ } else {
+ if(class_exists('mysqli')) {
+ if (is_null($port)) $port = ini_get("mysqli.default_port");
+ require_once('include/dba/dba_mysqli.php');
+ $dba = new dba_mysqli($server, $port,$user,$pass,$db,$install);
+ } else {
+ if (is_null($port)) $port = "3306";
+ require_once('include/dba/dba_mysql.php');
+ $dba = new dba_mysql($server, $port,$user,$pass,$db,$install);
+ }
}
-
+ define('NULL_DATE', $dba->get_null_date());
+ define('ACTIVE_DBTYPE', $dbtype);
return $dba;
}
abstract class dba_driver {
-
+ // legacy behavior
+ const INSTALL_SCRIPT='install/schema_mysql.sql';
+ const NULL_DATE = '0000-00-00 00:00:00';
+ const UTC_NOW = 'UTC_TIMESTAMP()';
+
protected $debug = 0;
protected $db;
public $connected = false;
@@ -37,6 +47,17 @@ abstract class dba_driver {
$this->connect($server, $port, $user,$pass,$db);
}
+ function get_null_date() {
+ return static::NULL_DATE;
+ }
+
+ function get_install_script() {
+ return static::INSTALL_SCRIPT;
+ }
+
+ function utcnow() {
+ return static::UTC_NOW;
+ }
function install($server,$user,$pass,$db) {
if (!(strlen($server) && strlen($user))){
@@ -67,6 +88,26 @@ abstract class dba_driver {
}
}
+ function quote_interval($txt) {
+ return $txt;
+ }
+
+ function optimize_table($table) {
+ q('OPTIMIZE TABLE '.$table);
+ }
+
+ function concat($fld, $sep) {
+ return 'GROUP_CONCAT(DISTINCT '.$fld.' SEPARATOR \''.$sep.'\')';
+ }
+
+ function escapebin($str) {
+ return $this->escape($str);
+ }
+
+ function unescapebin($str) {
+ return $str;
+ }
+
}
@@ -95,8 +136,49 @@ function dbesc($str) {
else
return(str_replace("'","\\'",$str));
}
+function dbescbin($str) {
+ global $db;
+ return $db->escapebin($str);
+}
+function dbunescbin($str) {
+ global $db;
+ return $db->unescapebin($str);
+}
+function dbescdate($date) {
+ if(ACTIVE_DBTYPE == DBTYPE_POSTGRES && $date == '0000-00-00 00:00:00') {
+ $date = NULL_DATE;
+ } else if(ACTIVE_DBTYPE != DBTYPE_POSTGRES && $date == '0001-01-01 00:00:00') {
+ $date = NULL_DATE;
+ }
+ return $date;
+}
+
+function db_quoteinterval($txt) {
+ global $db;
+ return $db->quote_interval($txt);
+}
+
+function dbesc_identifier($str) {
+ global $db;
+ return $db->escape_identifier($txt);
+}
+
+function db_utcnow() {
+ global $db;
+ return $db->utcnow();
+}
+
+function db_optimizetable($table) {
+ global $db;
+ $db->optimize_table($table);
+}
+
+function db_concat($fld, $sep) {
+ global $db;
+ return $db->concat($fld, $sep);
+}
// Function: q($sql,$args);
// Description: execute SQL query with printf style args.
@@ -158,8 +240,11 @@ function dbq($sql) {
function dbesc_array_cb(&$item, $key) {
- if(is_string($item))
+ if(is_string($item)) {
+ if($item == '0000-00-00 00:00:00' && ACTIVE_DBTYPE == DBTYPE_POSTGRES)
+ $item = '0001-01-01 00:00:00';
$item = dbesc($item);
+ }
}
@@ -169,3 +254,27 @@ function dbesc_array(&$arr) {
array_walk($arr,'dbesc_array_cb');
}
}
+
+function db_getfunc($f) {
+ $lookup = array(
+ 'rand'=>array(
+ DBTYPE_MYSQL=>'RAND()',
+ DBTYPE_POSTGRES=>'RANDOM()'
+ ),
+ 'utc_timestamp'=>array(
+ DBTYPE_MYSQL=>'UTC_TIMESTAMP()',
+ DBTYPE_POSTGRES=>"now() at time zone 'UTC'"
+ ),
+ 'regexp'=>array(
+ DBTYPE_MYSQL=>'REGEXP',
+ DBTYPE_POSTGRES=>'~'
+ )
+ );
+ $f = strtolower($f);
+ if(isset($lookup[$f]) && isset($lookup[$f][ACTIVE_DBTYPE]))
+ return $lookup[$f][ACTIVE_DBTYPE];
+
+ logger('Unable to abstract DB function "'. $f . '"', LOG_DEBUG);
+ return $f;
+}
+
diff --git a/include/dba/dba_postgres.php b/include/dba/dba_postgres.php
new file mode 100644
index 000000000..a390292a5
--- /dev/null
+++ b/include/dba/dba_postgres.php
@@ -0,0 +1,112 @@
+<?php
+
+require_once('include/dba/dba_driver.php');
+
+
+class dba_postgres extends dba_driver {
+ const INSTALL_SCRIPT='install/schema_postgres.sql';
+ const NULL_DATE = '0001-01-01 00:00:00';
+ const UTC_NOW = "now() at time zone 'UTC'";
+
+ function connect($server,$port,$user,$pass,$db) {
+ if(!$port) $port = 5432;
+ $connstr = 'host=' . $server . ' port='.$port . ' user=' . $user . ' password=' . $pass . ' dbname='. $db;
+ $this->db = pg_connect($connstr);
+ if($this->db !== false) {
+ $this->connected = true;
+ } else {
+ $this->connected = false;
+ }
+ $this->q("SET standard_conforming_strings = 'off'; SET backslash_quote = 'on';"); // emulate mysql string escaping to prevent massive code-clobber
+ return $this->connected;
+ }
+
+ function q($sql) {
+ if((! $this->db) || (! $this->connected))
+ return false;
+
+ if(!strpos($sql, ';'))
+ $sql .= ';';
+
+ if(strpos($sql, '`')) // this is a hack. quoted identifiers should be replaced everywhere in the code with dbesc_identifier(), remove this once it is
+ $sql = str_replace('`', '"', $sql);
+
+ $this->error = '';
+ $result = @pg_query($this->db, $sql);
+ if(file_exists('db-allqueries.out')) {
+ $bt = debug_backtrace();
+ $trace = array();
+ foreach($bt as $frame) {
+ if(!empty($frame['file']) && @strstr($frame['file'], $_SERVER['DOCUMENT_ROOT']))
+ $frame['file'] = substr($frame['file'], strlen($_SERVER['DOCUMENT_ROOT'])+1);
+
+ $trace[] = $frame['file'] . ':' . $frame['function'] . '():' . $frame['line'] ;
+ }
+ $compact = join(', ', $trace);
+ file_put_contents('db-allqueries.out', datetime_convert() . ": " . $sql . ' is_resource: '.var_export(is_resource($result), true).', backtrace: '.$compact."\n\n", FILE_APPEND);
+ }
+
+ if($result === false)
+ $this->error = pg_last_error($this->db);
+
+ if($result === false || $this->error) {
+ //logger('dba_postgres: ' . printable($sql) . ' returned false.' . "\n" . $this->error);
+ if(file_exists('dbfail.out'))
+ file_put_contents('dbfail.out', datetime_convert() . "\n" . printable($sql) . ' returned false' . "\n" . $this->error . "\n", FILE_APPEND);
+ }
+
+ if(($result === true) || ($result === false))
+ return $result;
+
+ if(pg_result_status($result) == PGSQL_COMMAND_OK)
+ return true;
+
+ $r = array();
+ if(pg_num_rows($result)) {
+ while($x = pg_fetch_array($result, null, PGSQL_ASSOC))
+ $r[] = $x;
+ pg_free_result($result);
+ if($this->debug)
+ logger('dba_postgres: ' . printable(print_r($r,true)));
+ }
+ return $r;
+ }
+
+ function escape($str) {
+ if($this->db && $this->connected) {
+ $x = @pg_escape_string($this->db, $str);
+ return $x;
+ }
+ }
+
+ function escapebin($str) {
+ return pg_escape_bytea($str);
+ }
+
+ function unescapebin($str) {
+ return pg_unescape_bytea($str);
+ }
+
+ function close() {
+ if($this->db)
+ pg_close($this->db);
+ $this->connected = false;
+ }
+
+ function quote_interval($txt) {
+ return "'$txt'";
+ }
+
+ function escape_identifier($str) {
+ return pg_escape_identifier($this->db, $str);
+ }
+
+ function optimize_table($table) {
+ // perhaps do some equivalent thing here, vacuum, etc? I think this is the DBA's domain anyway. Applications should not need to muss with this.
+ // for now do nothing without a compelling reason. function overrides default legacy mysql.
+ }
+
+ function concat($fld, $sep) {
+ return 'string_agg(' . $fld . ',\'' . $sep . '\')';
+ }
+} \ No newline at end of file